Fix view is not distributed error when view is used in modify statements (#3104)

pull/3135/head
Onur TIRTIR 2019-11-01 16:34:01 +03:00 committed by GitHub
parent c7ceca3216
commit d3f68bf44f
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
5 changed files with 939 additions and 18 deletions

View File

@ -132,6 +132,7 @@ static bool TargetEntryChangesValue(TargetEntry *targetEntry, Var *column,
static Job * RouterInsertJob(Query *originalQuery, Query *query,
DeferredErrorMessage **planningError);
static void ErrorIfNoShardsExist(DistTableCacheEntry *cacheEntry);
static DeferredErrorMessage * DeferErrorIfModifyView(Query *queryTree);
static bool CanShardPrune(Oid distributedTableId, Query *query);
static Job * CreateJob(Query *query);
static Task * CreateTask(TaskType taskType);
@ -567,6 +568,12 @@ ModifyQuerySupported(Query *queryTree, Query *originalQuery, bool multiShardQuer
uint32 queryTableCount = 0;
CmdType commandType = queryTree->commandType;
deferredError = DeferErrorIfModifyView(queryTree);
if (deferredError != NULL)
{
return deferredError;
}
/*
* Here, we check if a recursively planned query tries to modify
* rows based on the ctid column. This is a bad idea because ctid of
@ -656,29 +663,40 @@ ModifyQuerySupported(Query *queryTree, Query *originalQuery, bool multiShardQuer
if (rangeTableEntry->rtekind == RTE_RELATION)
{
Oid relationId = rangeTableEntry->relid;
if (!IsDistributedTable(relationId))
{
StringInfo errorMessage = makeStringInfo();
char *relationName = get_rel_name(rangeTableEntry->relid);
appendStringInfo(errorMessage, "relation %s is not distributed",
relationName);
return DeferredError(ERRCODE_FEATURE_NOT_SUPPORTED,
errorMessage->data, NULL, NULL);
}
queryTableCount++;
/* we do not expect to see a view in modify query */
if (rangeTableEntry->relkind == RELKIND_VIEW)
{
/*
* we already check if modify is run on a view in DeferErrorIfModifyView
* function call. In addition, since Postgres replaced views in FROM
* clause with subqueries, encountering with a view should not be a problem here.
*/
}
else if (rangeTableEntry->relkind == RELKIND_MATVIEW)
{
return DeferredError(ERRCODE_FEATURE_NOT_SUPPORTED,
"cannot modify views over distributed tables",
"materialized views in modify queries are not supported",
NULL, NULL);
}
/* for other kinds of relations, check if its distributed */
else
{
Oid relationId = rangeTableEntry->relid;
if (!IsDistributedTable(relationId))
{
StringInfo errorMessage = makeStringInfo();
char *relationName = get_rel_name(rangeTableEntry->relid);
appendStringInfo(errorMessage, "relation %s is not distributed",
relationName);
return DeferredError(ERRCODE_FEATURE_NOT_SUPPORTED,
errorMessage->data, NULL, NULL);
}
}
queryTableCount++;
}
else if (rangeTableEntry->rtekind == RTE_VALUES
#if PG_VERSION_NUM >= 120000
@ -895,6 +913,39 @@ ModifyQuerySupported(Query *queryTree, Query *originalQuery, bool multiShardQuer
}
/*
* Modify statements on simple updetable views are not supported yet.
* Actually, we need the original query (the query before postgres
* pg_rewrite_query) to detect if the view sitting in rtable is to
* be updated or just to be used in FROM clause.
* Hence, tracing the postgres source code, we deduced that postgres
* puts the relation to be modified to the first entry of rtable.
* If first element of the range table list is a simple updatable
* view and this view is not coming from FROM clause (inFromCl = False),
* then update is run "on" that view.
*/
static DeferredErrorMessage *
DeferErrorIfModifyView(Query *queryTree)
{
if (queryTree->rtable != NIL)
{
RangeTblEntry *firstRangeTableElement = (RangeTblEntry *) linitial(
queryTree->rtable);
if (firstRangeTableElement->rtekind == RTE_RELATION &&
firstRangeTableElement->relkind == RELKIND_VIEW &&
firstRangeTableElement->inFromCl == false)
{
return DeferredError(ERRCODE_FEATURE_NOT_SUPPORTED,
"cannot modify views over distributed tables", NULL,
NULL);
}
}
return NULL;
}
/*
* ErrorIfOnConflictNotSupprted returns an error if an INSERT query has an
* unsupported ON CONFLICT clause. In particular, changing the partition

View File

@ -200,3 +200,125 @@ SELECT count(*) FROM materialized_view;
DROP MATERIALIZED VIEW materialized_view;
DROP SCHEMA materialized_view CASCADE;
NOTICE: drop cascades to view air_shipped_lineitems
-- modify statements on/with views
-- create two tables and a view
CREATE TABLE large (id int, tenant_id int);
CREATE TABLE small (id int, tenant_id int);
SELECT create_distributed_table('large','tenant_id');
create_distributed_table
--------------------------
(1 row)
SELECT create_distributed_table('small','tenant_id');
create_distributed_table
--------------------------
(1 row)
\copy small FROM STDIN DELIMITER ','
CREATE MATERIALIZED VIEW small_view AS SELECT * from small where id < 100;
\copy large FROM STDIN DELIMITER ','
-- running any kind of modify statements "on" materialized views is not supported by postgres
UPDATE small_view SET id = 1;
ERROR: cannot change materialized view "small_view"
-- for now, using materialized views in modify statements' FROM / WHERE clauses is not supported
UPDATE large SET id=20 FROM small_view WHERE small_view.id=large.id;
ERROR: materialized views in modify queries are not supported
SELECT * FROM large ORDER BY 1, 2;
id | tenant_id
----+-----------
1 | 2
2 | 3
5 | 4
6 | 5
(4 rows)
-- test on a router executable update statement, this will also fail
UPDATE large SET id=28 FROM small_view WHERE small_view.id=large.id and small_view.tenant_id=2 and large.tenant_id=2;
ERROR: materialized views in modify queries are not supported
SELECT * FROM large ORDER BY 1, 2;
id | tenant_id
----+-----------
1 | 2
2 | 3
5 | 4
6 | 5
(4 rows)
-- delete statement on large with subquery, this should succeed
DELETE FROM large WHERE tenant_id in (SELECT tenant_id FROM small_view);
SELECT * FROM large ORDER BY 1, 2;
id | tenant_id
----+-----------
6 | 5
(1 row)
-- INSERT INTO views is already not supported by PostgreSQL
INSERT INTO small_view VALUES(3, 3);
ERROR: cannot change materialized view "small_view"
DROP TABLE small CASCADE;
NOTICE: drop cascades to materialized view small_view
DROP TABLE large;
-- now, run the same modify statement tests on a partitioned table
CREATE TABLE small (id int, tenant_id int);
CREATE TABLE large_partitioned (id int, tenant_id int) partition by range(tenant_id);
CREATE TABLE large_partitioned_p1 PARTITION OF large_partitioned FOR VALUES FROM (1) TO (10);
CREATE TABLE large_partitioned_p2 PARTITION OF large_partitioned FOR VALUES FROM (10) TO (20);
CREATE TABLE large_partitioned_p3 PARTITION OF large_partitioned FOR VALUES FROM (20) TO (100);
SELECT create_distributed_table('large_partitioned','tenant_id');
create_distributed_table
--------------------------
(1 row)
SELECT create_distributed_table('small','tenant_id');
create_distributed_table
--------------------------
(1 row)
\copy small FROM STDIN DELIMITER ','
CREATE MATERIALIZED VIEW small_view AS SELECT * from small where id < 100;
\copy large_partitioned FROM STDIN DELIMITER ','
-- running modify statements "on" views is still not supported, hence below two statements will fail
UPDATE small_view SET id = 1;
ERROR: cannot change materialized view "small_view"
DELETE FROM small_view;
ERROR: cannot change materialized view "small_view"
-- using mat. view in modify statements' FROM / WHERE clauses is not valid yet
UPDATE large_partitioned SET id=20 FROM small_view WHERE small_view.id=large_partitioned.id;
ERROR: materialized views in modify queries are not supported
SELECT * FROM large_partitioned ORDER BY 1, 2;
id | tenant_id
----+-----------
1 | 2
2 | 3
5 | 4
6 | 5
26 | 32
29 | 15
60 | 51
(7 rows)
-- delete statement on large_partitioned
DELETE FROM large_partitioned WHERE id in (SELECT id FROM small_view);
SELECT * FROM large_partitioned ORDER BY 1, 2;
id | tenant_id
----+-----------
2 | 3
5 | 4
26 | 32
29 | 15
60 | 51
(5 rows)
-- we should still have identical rows for next test statement, then insert new rows to both tables
INSERT INTO large_partitioned VALUES(14, 14);
INSERT INTO small VALUES(14, 14);
-- delete statement with CTE
WITH all_small_view_ids AS (SELECT id FROM small_view)
DELETE FROM large_partitioned WHERE id in (SELECT * FROM all_small_view_ids);
DROP TABLE large_partitioned;
DROP TABLE small CASCADE;
NOTICE: drop cascades to materialized view small_view

View File

@ -883,3 +883,404 @@ DROP VIEW recent_selected_users;
DROP VIEW selected_users;
DROP VIEW recent_events;
DROP VIEW recent_users;
-- modify statements on/with views
-- create two tables and a view
CREATE TABLE large (id int, tenant_id int);
-- constraint id to be unique for "insert into on conflict" test
CREATE TABLE small (id int, tenant_id int, unique(tenant_id));
SELECT create_distributed_table('large','tenant_id');
create_distributed_table
--------------------------
(1 row)
SELECT create_distributed_table('small','tenant_id');
create_distributed_table
--------------------------
(1 row)
CREATE VIEW small_view AS SELECT * from small where id < 100;
\copy small FROM STDIN DELIMITER ','
\copy large FROM STDIN DELIMITER ','
-- running modify statements "on" views is still not supported, hence below two statements will fail
UPDATE small_view SET id = 1;
ERROR: cannot modify views over distributed tables
DELETE FROM small_view;
ERROR: cannot modify views over distributed tables
INSERT INTO small_view VALUES(8, 5) ON CONFLICT(tenant_id) DO UPDATE SET tenant_id=99;
ERROR: cannot modify views over distributed tables
-- using views in modify statements' FROM / WHERE clauses is still valid
UPDATE large SET id=20 FROM small_view WHERE small_view.id=large.id;
SELECT * FROM large order by 1, 2;
id | tenant_id
----+-----------
2 | 3
5 | 4
20 | 2
20 | 5
(4 rows)
-- we should still have identical rows for next test statements, then insert new rows to both tables
INSERT INTO large VALUES(14, 14);
INSERT INTO small VALUES(14, 14);
-- using views in subqueries within modify statements is still valid
UPDATE large SET id=23 FROM (SELECT *, id*2 from small_view ORDER BY 1,2 LIMIT 5) as small_view WHERE small_view.id=large.id;
SELECT * FROM large order by 1, 2;
id | tenant_id
----+-----------
2 | 3
5 | 4
20 | 2
20 | 5
23 | 14
(5 rows)
-- we should still have identical rows for next test statements, then insert a new row to large table
INSERT INTO large VALUES(14, 14);
-- using views in modify statements' FROM / WHERE clauses is still valid
UPDATE large SET id=27 FROM small_view WHERE small_view.tenant_id=large.tenant_id;
SELECT * FROM large ORDER BY 1, 2;
id | tenant_id
----+-----------
27 | 2
27 | 3
27 | 4
27 | 5
27 | 14
27 | 14
(6 rows)
-- we should still have identical rows for next test statements, then insert a new row to large table
INSERT INTO large VALUES(14, 14);
-- test on a router executable update statement
UPDATE large SET id=28 FROM small_view WHERE small_view.id=large.id and small_view.tenant_id=14 and large.tenant_id=14;
SELECT * FROM large ORDER BY 1, 2;
id | tenant_id
----+-----------
27 | 2
27 | 3
27 | 4
27 | 5
27 | 14
27 | 14
28 | 14
(7 rows)
-- we should still have identical rows for next test statements, then insert new rows to both tables
INSERT INTO large VALUES(14, 14);
INSERT INTO large VALUES(99, 78);
INSERT INTO small VALUES(99, 99);
-- run these tests with RETURNING clause to observe the functionality
-- print the columns from the "view" as well to test "rewrite resjunk" behaviour
UPDATE large SET id=36 FROM small_view WHERE small_view.id=large.id RETURNING large.id, large.tenant_id, small_view.tenant_id;
id | tenant_id | tenant_id
----+-----------+-----------
36 | 14 | 14
36 | 78 | 99
(2 rows)
SELECT * FROM large ORDER BY 1, 2;
id | tenant_id
----+-----------
27 | 2
27 | 3
27 | 4
27 | 5
27 | 14
27 | 14
28 | 14
36 | 14
36 | 78
(9 rows)
-- below statement should not update anything. so it should return empty
UPDATE large SET id=46 FROM small_view WHERE small_view.id=large.id and large.id=15 RETURNING large.id, large.tenant_id;
id | tenant_id
----+-----------
(0 rows)
-- we should still have identical rows for next test statements, then insert a new row to large table
INSERT INTO large VALUES(14, 14);
-- delete statement on large
DELETE FROM large WHERE id in (SELECT id FROM small_view);
SELECT * FROM large ORDER BY 1, 2;
id | tenant_id
----+-----------
27 | 2
27 | 3
27 | 4
27 | 5
27 | 14
27 | 14
28 | 14
36 | 14
36 | 78
(9 rows)
-- we should still have identical rows for next test statement, then insert a new row to large table
INSERT INTO large VALUES(14, 14);
-- delete statement with CTE
WITH all_small_view_ids AS (SELECT id FROM small_view)
DELETE FROM large WHERE id in (SELECT * FROM all_small_view_ids);
SELECT * FROM large ORDER BY 1, 2;
id | tenant_id
----+-----------
27 | 2
27 | 3
27 | 4
27 | 5
27 | 14
27 | 14
28 | 14
36 | 14
36 | 78
(9 rows)
-- INSERT INTO views is still not supported
INSERT INTO small_view VALUES(3, 3);
ERROR: cannot modify views over distributed tables
DROP TABLE large;
DROP TABLE small CASCADE;
NOTICE: drop cascades to view small_view
-- now, run the same modify statement tests on a partitioned table
CREATE TABLE small (id int, tenant_id int);
CREATE TABLE large_partitioned (id int, tenant_id int) partition by range(tenant_id);
CREATE TABLE large_partitioned_p1 PARTITION OF large_partitioned FOR VALUES FROM (1) TO (10);
CREATE TABLE large_partitioned_p2 PARTITION OF large_partitioned FOR VALUES FROM (10) TO (20);
CREATE TABLE large_partitioned_p3 PARTITION OF large_partitioned FOR VALUES FROM (20) TO (100);
SELECT create_distributed_table('large_partitioned','tenant_id');
create_distributed_table
--------------------------
(1 row)
SELECT create_distributed_table('small','tenant_id');
create_distributed_table
--------------------------
(1 row)
CREATE VIEW small_view AS SELECT * from small where id < 100;
\copy small FROM STDIN DELIMITER ','
\copy large_partitioned FROM STDIN DELIMITER ','
-- running modify statements "on" views is still not supported, hence below two statements will fail
UPDATE small_view SET id = 1;
ERROR: cannot modify views over distributed tables
DELETE FROM small_view;
ERROR: cannot modify views over distributed tables
UPDATE large_partitioned SET id=27 FROM small_view WHERE small_view.tenant_id=large_partitioned.tenant_id;
SELECT * FROM large_partitioned ORDER BY 1, 2;
id | tenant_id
----+-----------
6 | 5
26 | 32
27 | 2
27 | 3
27 | 4
29 | 15
60 | 51
(7 rows)
-- we should still have identical rows for next test statements, then insert identical rows to both tables
INSERT INTO small VALUES(14, 14);
INSERT INTO large_partitioned VALUES(14, 14);
-- test on a router executable update statement
UPDATE large_partitioned SET id=28 FROM small_view WHERE small_view.id=large_partitioned.id and small_view.tenant_id=14 and large_partitioned.tenant_id=14;
SELECT * FROM large_partitioned ORDER BY 1, 2;
id | tenant_id
----+-----------
6 | 5
26 | 32
27 | 2
27 | 3
27 | 4
28 | 14
29 | 15
60 | 51
(8 rows)
-- we should still have identical rows for next test statements, then insert a new row to large_partitioned table
INSERT INTO large_partitioned VALUES(14, 14);
-- delete statement on large
DELETE FROM large_partitioned WHERE tenant_id in (SELECT tenant_id FROM small_view);
SELECT * FROM large_partitioned ORDER BY 1, 2;
id | tenant_id
----+-----------
6 | 5
26 | 32
29 | 15
60 | 51
(4 rows)
-- we should still have identical rows for next test statement, then insert a new row to large table
INSERT INTO large_partitioned VALUES(14, 14);
-- delete statement with CTE
WITH all_small_view_tenant_ids AS (SELECT tenant_id FROM small_view)
DELETE FROM large_partitioned WHERE tenant_id in (SELECT * FROM all_small_view_tenant_ids);
SELECT * FROM large_partitioned ORDER BY 1, 2;
id | tenant_id
----+-----------
6 | 5
26 | 32
29 | 15
60 | 51
(4 rows)
DROP TABLE large_partitioned;
DROP TABLE small CASCADE;
NOTICE: drop cascades to view small_view
-- perform similar tests with a little bit complicated view
-- create two tables and a view
CREATE TABLE large (id int, tenant_id int);
-- constraint id to be unique for "insert into on conflict" test
CREATE TABLE small (id int, tenant_id int, unique(tenant_id));
SELECT create_distributed_table('large','tenant_id');
create_distributed_table
--------------------------
(1 row)
SELECT create_distributed_table('small','tenant_id');
create_distributed_table
--------------------------
(1 row)
CREATE VIEW small_view AS SELECT id, tenant_id FROM (SELECT *, id*2 FROM small WHERE id < 100 ORDER BY 1,2 LIMIT 5) as foo;
\copy small FROM STDIN DELIMITER ','
\copy large FROM STDIN DELIMITER ','
-- using views in modify statements' FROM / WHERE clauses is still valid
UPDATE large SET id=20 FROM small_view WHERE small_view.id=large.id;
SELECT * FROM large order by 1, 2;
id | tenant_id
----+-----------
2 | 3
5 | 4
20 | 2
20 | 5
(4 rows)
-- we should still have identical rows for next test statements, then insert new rows to both tables
INSERT INTO large VALUES(14, 14);
INSERT INTO small VALUES(14, 14);
-- using views in subqueries within modify statements is still valid
UPDATE large SET id=23 FROM (SELECT *, id*2 from small_view ORDER BY 1,2 LIMIT 5) as small_view WHERE small_view.id=large.id;
SELECT * FROM large order by 1, 2;
id | tenant_id
----+-----------
2 | 3
5 | 4
20 | 2
20 | 5
23 | 14
(5 rows)
-- we should still have identical rows for next test statements, then insert a new row to large table
INSERT INTO large VALUES(14, 14);
-- using views in modify statements' FROM / WHERE clauses is still valid
UPDATE large SET id=27 FROM small_view WHERE small_view.tenant_id=large.tenant_id;
SELECT * FROM large ORDER BY 1, 2;
id | tenant_id
----+-----------
27 | 2
27 | 3
27 | 4
27 | 5
27 | 14
27 | 14
(6 rows)
-- we should still have identical rows for next test statements, then insert a new row to large table
INSERT INTO large VALUES(14, 14);
-- test on a router executable update statement
UPDATE large SET id=28 FROM small_view WHERE small_view.id=large.id and small_view.tenant_id=14 and large.tenant_id=14;
SELECT * FROM large ORDER BY 1, 2;
id | tenant_id
----+-----------
27 | 2
27 | 3
27 | 4
27 | 5
27 | 14
27 | 14
28 | 14
(7 rows)
-- we should still have identical rows for next test statements, then insert new rows to both tables
INSERT INTO large VALUES(14, 14);
INSERT INTO large VALUES(99, 78);
INSERT INTO small VALUES(99, 99);
-- run these tests with RETURNING clause to observe the functionality
-- print the columns from the "view" as well to test "rewrite resjunk" behaviour
UPDATE large SET id=36 FROM small_view WHERE small_view.id=large.id RETURNING large.id, large.tenant_id, small_view.tenant_id;
id | tenant_id | tenant_id
----+-----------+-----------
36 | 14 | 14
(1 row)
SELECT * FROM large ORDER BY 1, 2;
id | tenant_id
----+-----------
27 | 2
27 | 3
27 | 4
27 | 5
27 | 14
27 | 14
28 | 14
36 | 14
99 | 78
(9 rows)
-- below statement should not update anything. so it should return empty
UPDATE large SET id=46 FROM small_view WHERE small_view.id=large.id and large.id=15 RETURNING large.id, large.tenant_id;
id | tenant_id
----+-----------
(0 rows)
-- we should still have identical rows for next test statements, then insert a new row to large table
INSERT INTO large VALUES(14, 14);
-- delete statement on large
DELETE FROM large WHERE id in (SELECT id FROM small_view);
SELECT * FROM large ORDER BY 1, 2;
id | tenant_id
----+-----------
27 | 2
27 | 3
27 | 4
27 | 5
27 | 14
27 | 14
28 | 14
36 | 14
99 | 78
(9 rows)
-- we should still have identical rows for next test statement, then insert a new row to large table
INSERT INTO large VALUES(14, 14);
-- delete statement with CTE
WITH all_small_view_ids AS (SELECT id FROM small_view)
DELETE FROM large WHERE id in (SELECT * FROM all_small_view_ids);
SELECT * FROM large ORDER BY 1, 2;
id | tenant_id
----+-----------
27 | 2
27 | 3
27 | 4
27 | 5
27 | 14
27 | 14
28 | 14
36 | 14
99 | 78
(9 rows)
-- INSERT INTO views is still not supported
INSERT INTO small_view VALUES(3, 3);
ERROR: cannot insert into view "small_view"
DETAIL: Views that do not select from a single table or view are not automatically updatable.
HINT: To enable inserting into the view, provide an INSTEAD OF INSERT trigger or an unconditional ON INSERT DO INSTEAD rule.
DROP TABLE large;
DROP TABLE small CASCADE;
NOTICE: drop cascades to view small_view

View File

@ -144,4 +144,107 @@ REFRESH MATERIALIZED VIEW CONCURRENTLY materialized_view;
SELECT count(*) FROM materialized_view;
DROP MATERIALIZED VIEW materialized_view;
DROP SCHEMA materialized_view CASCADE;
DROP SCHEMA materialized_view CASCADE;
-- modify statements on/with views
-- create two tables and a view
CREATE TABLE large (id int, tenant_id int);
CREATE TABLE small (id int, tenant_id int);
SELECT create_distributed_table('large','tenant_id');
SELECT create_distributed_table('small','tenant_id');
\copy small FROM STDIN DELIMITER ','
250, 25
470, 13
8,2
6,3
7,4
1,2
\.
CREATE MATERIALIZED VIEW small_view AS SELECT * from small where id < 100;
\copy large FROM STDIN DELIMITER ','
1,2
2,3
5,4
6,5
\.
-- running any kind of modify statements "on" materialized views is not supported by postgres
UPDATE small_view SET id = 1;
-- for now, using materialized views in modify statements' FROM / WHERE clauses is not supported
UPDATE large SET id=20 FROM small_view WHERE small_view.id=large.id;
SELECT * FROM large ORDER BY 1, 2;
-- test on a router executable update statement, this will also fail
UPDATE large SET id=28 FROM small_view WHERE small_view.id=large.id and small_view.tenant_id=2 and large.tenant_id=2;
SELECT * FROM large ORDER BY 1, 2;
-- delete statement on large with subquery, this should succeed
DELETE FROM large WHERE tenant_id in (SELECT tenant_id FROM small_view);
SELECT * FROM large ORDER BY 1, 2;
-- INSERT INTO views is already not supported by PostgreSQL
INSERT INTO small_view VALUES(3, 3);
DROP TABLE small CASCADE;
DROP TABLE large;
-- now, run the same modify statement tests on a partitioned table
CREATE TABLE small (id int, tenant_id int);
CREATE TABLE large_partitioned (id int, tenant_id int) partition by range(tenant_id);
CREATE TABLE large_partitioned_p1 PARTITION OF large_partitioned FOR VALUES FROM (1) TO (10);
CREATE TABLE large_partitioned_p2 PARTITION OF large_partitioned FOR VALUES FROM (10) TO (20);
CREATE TABLE large_partitioned_p3 PARTITION OF large_partitioned FOR VALUES FROM (20) TO (100);
SELECT create_distributed_table('large_partitioned','tenant_id');
SELECT create_distributed_table('small','tenant_id');
\copy small FROM STDIN DELIMITER ','
250, 25
470, 13
8,2
6,3
7,4
1,2
\.
CREATE MATERIALIZED VIEW small_view AS SELECT * from small where id < 100;
\copy large_partitioned FROM STDIN DELIMITER ','
1,2
2,3
5,4
6,5
29,15
26,32
60,51
\.
-- running modify statements "on" views is still not supported, hence below two statements will fail
UPDATE small_view SET id = 1;
DELETE FROM small_view;
-- using mat. view in modify statements' FROM / WHERE clauses is not valid yet
UPDATE large_partitioned SET id=20 FROM small_view WHERE small_view.id=large_partitioned.id;
SELECT * FROM large_partitioned ORDER BY 1, 2;
-- delete statement on large_partitioned
DELETE FROM large_partitioned WHERE id in (SELECT id FROM small_view);
SELECT * FROM large_partitioned ORDER BY 1, 2;
-- we should still have identical rows for next test statement, then insert new rows to both tables
INSERT INTO large_partitioned VALUES(14, 14);
INSERT INTO small VALUES(14, 14);
-- delete statement with CTE
WITH all_small_view_ids AS (SELECT id FROM small_view)
DELETE FROM large_partitioned WHERE id in (SELECT * FROM all_small_view_ids);
DROP TABLE large_partitioned;
DROP TABLE small CASCADE;

View File

@ -399,3 +399,247 @@ DROP VIEW recent_selected_users;
DROP VIEW selected_users;
DROP VIEW recent_events;
DROP VIEW recent_users;
-- modify statements on/with views
-- create two tables and a view
CREATE TABLE large (id int, tenant_id int);
-- constraint id to be unique for "insert into on conflict" test
CREATE TABLE small (id int, tenant_id int, unique(tenant_id));
SELECT create_distributed_table('large','tenant_id');
SELECT create_distributed_table('small','tenant_id');
CREATE VIEW small_view AS SELECT * from small where id < 100;
\copy small FROM STDIN DELIMITER ','
250, 25
470, 13
8,5
6,3
7,4
1,2
\.
\copy large FROM STDIN DELIMITER ','
1,2
2,3
5,4
6,5
\.
-- running modify statements "on" views is still not supported, hence below two statements will fail
UPDATE small_view SET id = 1;
DELETE FROM small_view;
INSERT INTO small_view VALUES(8, 5) ON CONFLICT(tenant_id) DO UPDATE SET tenant_id=99;
-- using views in modify statements' FROM / WHERE clauses is still valid
UPDATE large SET id=20 FROM small_view WHERE small_view.id=large.id;
SELECT * FROM large order by 1, 2;
-- we should still have identical rows for next test statements, then insert new rows to both tables
INSERT INTO large VALUES(14, 14);
INSERT INTO small VALUES(14, 14);
-- using views in subqueries within modify statements is still valid
UPDATE large SET id=23 FROM (SELECT *, id*2 from small_view ORDER BY 1,2 LIMIT 5) as small_view WHERE small_view.id=large.id;
SELECT * FROM large order by 1, 2;
-- we should still have identical rows for next test statements, then insert a new row to large table
INSERT INTO large VALUES(14, 14);
-- using views in modify statements' FROM / WHERE clauses is still valid
UPDATE large SET id=27 FROM small_view WHERE small_view.tenant_id=large.tenant_id;
SELECT * FROM large ORDER BY 1, 2;
-- we should still have identical rows for next test statements, then insert a new row to large table
INSERT INTO large VALUES(14, 14);
-- test on a router executable update statement
UPDATE large SET id=28 FROM small_view WHERE small_view.id=large.id and small_view.tenant_id=14 and large.tenant_id=14;
SELECT * FROM large ORDER BY 1, 2;
-- we should still have identical rows for next test statements, then insert new rows to both tables
INSERT INTO large VALUES(14, 14);
INSERT INTO large VALUES(99, 78);
INSERT INTO small VALUES(99, 99);
-- run these tests with RETURNING clause to observe the functionality
-- print the columns from the "view" as well to test "rewrite resjunk" behaviour
UPDATE large SET id=36 FROM small_view WHERE small_view.id=large.id RETURNING large.id, large.tenant_id, small_view.tenant_id;
SELECT * FROM large ORDER BY 1, 2;
-- below statement should not update anything. so it should return empty
UPDATE large SET id=46 FROM small_view WHERE small_view.id=large.id and large.id=15 RETURNING large.id, large.tenant_id;
-- we should still have identical rows for next test statements, then insert a new row to large table
INSERT INTO large VALUES(14, 14);
-- delete statement on large
DELETE FROM large WHERE id in (SELECT id FROM small_view);
SELECT * FROM large ORDER BY 1, 2;
-- we should still have identical rows for next test statement, then insert a new row to large table
INSERT INTO large VALUES(14, 14);
-- delete statement with CTE
WITH all_small_view_ids AS (SELECT id FROM small_view)
DELETE FROM large WHERE id in (SELECT * FROM all_small_view_ids);
SELECT * FROM large ORDER BY 1, 2;
-- INSERT INTO views is still not supported
INSERT INTO small_view VALUES(3, 3);
DROP TABLE large;
DROP TABLE small CASCADE;
-- now, run the same modify statement tests on a partitioned table
CREATE TABLE small (id int, tenant_id int);
CREATE TABLE large_partitioned (id int, tenant_id int) partition by range(tenant_id);
CREATE TABLE large_partitioned_p1 PARTITION OF large_partitioned FOR VALUES FROM (1) TO (10);
CREATE TABLE large_partitioned_p2 PARTITION OF large_partitioned FOR VALUES FROM (10) TO (20);
CREATE TABLE large_partitioned_p3 PARTITION OF large_partitioned FOR VALUES FROM (20) TO (100);
SELECT create_distributed_table('large_partitioned','tenant_id');
SELECT create_distributed_table('small','tenant_id');
CREATE VIEW small_view AS SELECT * from small where id < 100;
\copy small FROM STDIN DELIMITER ','
250, 25
470, 13
8,2
6,3
7,4
1,2
\.
\copy large_partitioned FROM STDIN DELIMITER ','
1,2
2,3
5,4
6,5
29,15
26,32
60,51
\.
-- running modify statements "on" views is still not supported, hence below two statements will fail
UPDATE small_view SET id = 1;
DELETE FROM small_view;
UPDATE large_partitioned SET id=27 FROM small_view WHERE small_view.tenant_id=large_partitioned.tenant_id;
SELECT * FROM large_partitioned ORDER BY 1, 2;
-- we should still have identical rows for next test statements, then insert identical rows to both tables
INSERT INTO small VALUES(14, 14);
INSERT INTO large_partitioned VALUES(14, 14);
-- test on a router executable update statement
UPDATE large_partitioned SET id=28 FROM small_view WHERE small_view.id=large_partitioned.id and small_view.tenant_id=14 and large_partitioned.tenant_id=14;
SELECT * FROM large_partitioned ORDER BY 1, 2;
-- we should still have identical rows for next test statements, then insert a new row to large_partitioned table
INSERT INTO large_partitioned VALUES(14, 14);
-- delete statement on large
DELETE FROM large_partitioned WHERE tenant_id in (SELECT tenant_id FROM small_view);
SELECT * FROM large_partitioned ORDER BY 1, 2;
-- we should still have identical rows for next test statement, then insert a new row to large table
INSERT INTO large_partitioned VALUES(14, 14);
-- delete statement with CTE
WITH all_small_view_tenant_ids AS (SELECT tenant_id FROM small_view)
DELETE FROM large_partitioned WHERE tenant_id in (SELECT * FROM all_small_view_tenant_ids);
SELECT * FROM large_partitioned ORDER BY 1, 2;
DROP TABLE large_partitioned;
DROP TABLE small CASCADE;
-- perform similar tests with a little bit complicated view
-- create two tables and a view
CREATE TABLE large (id int, tenant_id int);
-- constraint id to be unique for "insert into on conflict" test
CREATE TABLE small (id int, tenant_id int, unique(tenant_id));
SELECT create_distributed_table('large','tenant_id');
SELECT create_distributed_table('small','tenant_id');
CREATE VIEW small_view AS SELECT id, tenant_id FROM (SELECT *, id*2 FROM small WHERE id < 100 ORDER BY 1,2 LIMIT 5) as foo;
\copy small FROM STDIN DELIMITER ','
250, 25
470, 13
8,5
6,3
7,4
1,2
\.
\copy large FROM STDIN DELIMITER ','
1,2
2,3
5,4
6,5
\.
-- using views in modify statements' FROM / WHERE clauses is still valid
UPDATE large SET id=20 FROM small_view WHERE small_view.id=large.id;
SELECT * FROM large order by 1, 2;
-- we should still have identical rows for next test statements, then insert new rows to both tables
INSERT INTO large VALUES(14, 14);
INSERT INTO small VALUES(14, 14);
-- using views in subqueries within modify statements is still valid
UPDATE large SET id=23 FROM (SELECT *, id*2 from small_view ORDER BY 1,2 LIMIT 5) as small_view WHERE small_view.id=large.id;
SELECT * FROM large order by 1, 2;
-- we should still have identical rows for next test statements, then insert a new row to large table
INSERT INTO large VALUES(14, 14);
-- using views in modify statements' FROM / WHERE clauses is still valid
UPDATE large SET id=27 FROM small_view WHERE small_view.tenant_id=large.tenant_id;
SELECT * FROM large ORDER BY 1, 2;
-- we should still have identical rows for next test statements, then insert a new row to large table
INSERT INTO large VALUES(14, 14);
-- test on a router executable update statement
UPDATE large SET id=28 FROM small_view WHERE small_view.id=large.id and small_view.tenant_id=14 and large.tenant_id=14;
SELECT * FROM large ORDER BY 1, 2;
-- we should still have identical rows for next test statements, then insert new rows to both tables
INSERT INTO large VALUES(14, 14);
INSERT INTO large VALUES(99, 78);
INSERT INTO small VALUES(99, 99);
-- run these tests with RETURNING clause to observe the functionality
-- print the columns from the "view" as well to test "rewrite resjunk" behaviour
UPDATE large SET id=36 FROM small_view WHERE small_view.id=large.id RETURNING large.id, large.tenant_id, small_view.tenant_id;
SELECT * FROM large ORDER BY 1, 2;
-- below statement should not update anything. so it should return empty
UPDATE large SET id=46 FROM small_view WHERE small_view.id=large.id and large.id=15 RETURNING large.id, large.tenant_id;
-- we should still have identical rows for next test statements, then insert a new row to large table
INSERT INTO large VALUES(14, 14);
-- delete statement on large
DELETE FROM large WHERE id in (SELECT id FROM small_view);
SELECT * FROM large ORDER BY 1, 2;
-- we should still have identical rows for next test statement, then insert a new row to large table
INSERT INTO large VALUES(14, 14);
-- delete statement with CTE
WITH all_small_view_ids AS (SELECT id FROM small_view)
DELETE FROM large WHERE id in (SELECT * FROM all_small_view_ids);
SELECT * FROM large ORDER BY 1, 2;
-- INSERT INTO views is still not supported
INSERT INTO small_view VALUES(3, 3);
DROP TABLE large;
DROP TABLE small CASCADE;