mirror of https://github.com/citusdata/citus.git
Add view propagation tests
parent
b8f673ca91
commit
6de95e2b14
|
@ -0,0 +1,215 @@
|
|||
-- Tests to check propagation of all view commands
|
||||
CREATE SCHEMA view_prop_schema;
|
||||
SET search_path to view_prop_schema;
|
||||
-- Check creating views depending on different types of tables
|
||||
-- and from multiple schemas
|
||||
-- Try to create view depending local table, then try to recreate it after distributing the table
|
||||
CREATE TABLE view_table_1(id int, val_1 text);
|
||||
CREATE VIEW prop_view_1 AS
|
||||
SELECT * FROM view_table_1;
|
||||
WARNING: "view prop_view_1" has dependency to "table view_table_1" that is not in Citus' metadata
|
||||
DETAIL: "view prop_view_1" will be created only locally
|
||||
HINT: Distribute "table view_table_1" first to distribute "view prop_view_1"
|
||||
SELECT create_distributed_table('view_table_1', 'id');
|
||||
create_distributed_table
|
||||
---------------------------------------------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
CREATE OR REPLACE VIEW prop_view_1 AS
|
||||
SELECT * FROM view_table_1;
|
||||
-- Try to create view depending local table, then try to recreate it after making the table reference table
|
||||
CREATE TABLE view_table_2(id int PRIMARY KEY, val_1 text);
|
||||
CREATE VIEW prop_view_2 AS
|
||||
SELECT view_table_1.id, view_table_2.val_1 FROM view_table_1 INNER JOIN view_table_2
|
||||
ON view_table_1.id = view_table_2.id;
|
||||
WARNING: "view prop_view_2" has dependency to "table view_table_2" that is not in Citus' metadata
|
||||
DETAIL: "view prop_view_2" will be created only locally
|
||||
HINT: Distribute "table view_table_2" first to distribute "view prop_view_2"
|
||||
SELECT create_reference_table('view_table_2');
|
||||
create_reference_table
|
||||
---------------------------------------------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
CREATE OR REPLACE VIEW prop_view_2 AS
|
||||
SELECT view_table_1.id, view_table_2.val_1 FROM view_table_1 INNER JOIN view_table_2
|
||||
ON view_table_1.id = view_table_2.id;
|
||||
-- Try to create view depending local table, then try to recreate it after making the table citus local table
|
||||
CREATE TABLE view_table_3(id int, val_1 text);
|
||||
CREATE VIEW prop_view_3 AS
|
||||
SELECT * FROM view_table_1 WHERE id IN
|
||||
(SELECT view_table_2.id FROM view_table_2 INNER JOIN view_table_3 ON view_table_2.id = view_table_3.id);
|
||||
WARNING: "view prop_view_3" has dependency to "table view_table_3" that is not in Citus' metadata
|
||||
DETAIL: "view prop_view_3" will be created only locally
|
||||
HINT: Distribute "table view_table_3" first to distribute "view prop_view_3"
|
||||
SELECT 1 FROM citus_add_node('localhost', :master_port, groupid=>0);
|
||||
NOTICE: Replicating reference table "view_table_2" to the node localhost:57636
|
||||
NOTICE: localhost:57636 is the coordinator and already contains metadata, skipping syncing the metadata
|
||||
?column?
|
||||
---------------------------------------------------------------------
|
||||
1
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE view_table_3
|
||||
ADD CONSTRAINT f_key_for_local_table
|
||||
FOREIGN KEY(id)
|
||||
REFERENCES view_table_2(id);
|
||||
CREATE OR REPLACE VIEW prop_view_3 AS
|
||||
SELECT * FROM view_table_1 WHERE id IN
|
||||
(SELECT view_table_2.id FROM view_table_2 INNER JOIN view_table_3 ON view_table_2.id = view_table_3.id);
|
||||
-- Try to create view depending on PG metadata table
|
||||
CREATE VIEW prop_view_4 AS
|
||||
SELECT * FROM pg_stat_activity;
|
||||
-- Try to create view depending on Citus metadata table
|
||||
CREATE VIEW prop_view_5 AS
|
||||
SELECT * FROM citus_dist_stat_activity;
|
||||
-- Try to create table depending on a local table from another schema, then try to create it again after distributing the table
|
||||
CREATE SCHEMA view_prop_schema_inner;
|
||||
SET search_path TO view_prop_schema_inner;
|
||||
CREATE TABLE view_table_4(id int, val_1 text);
|
||||
SET search_path to view_prop_schema;
|
||||
CREATE VIEW prop_view_6 AS
|
||||
SELECT vt1.id, vt4.val_1 FROM view_table_1 AS vt1
|
||||
INNER JOIN view_prop_schema_inner.view_table_4 AS vt4 ON vt1.id = vt4.id;
|
||||
WARNING: "view prop_view_6" has dependency to "table view_prop_schema_inner.view_table_4" that is not in Citus' metadata
|
||||
DETAIL: "view prop_view_6" will be created only locally
|
||||
HINT: Distribute "table view_prop_schema_inner.view_table_4" first to distribute "view prop_view_6"
|
||||
SELECT create_distributed_table('view_prop_schema_inner.view_table_4','id');
|
||||
create_distributed_table
|
||||
---------------------------------------------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
CREATE OR REPLACE VIEW prop_view_6 AS
|
||||
SELECT vt1.id, vt4.val_1 FROM view_table_1 AS vt1
|
||||
INNER JOIN view_prop_schema_inner.view_table_4 AS vt4 ON vt1.id = vt4.id;
|
||||
-- Show that all views are propagated as distributed object
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%prop_view_%';
|
||||
obj_identifier
|
||||
---------------------------------------------------------------------
|
||||
(view,"{view_prop_schema,prop_view_1}",{})
|
||||
(view,"{view_prop_schema,prop_view_2}",{})
|
||||
(view,"{view_prop_schema,prop_view_3}",{})
|
||||
(view,"{view_prop_schema,prop_view_4}",{})
|
||||
(view,"{view_prop_schema,prop_view_5}",{})
|
||||
(view,"{view_prop_schema,prop_view_6}",{})
|
||||
(6 rows)
|
||||
|
||||
-- Check creating views depending various kind of objects
|
||||
-- Tests will also check propagating dependent objects
|
||||
-- Depending on function
|
||||
SET citus.enable_ddl_propagation TO OFF;
|
||||
CREATE OR REPLACE FUNCTION func_1_for_view(param_1 int)
|
||||
RETURNS int
|
||||
LANGUAGE plpgsql AS
|
||||
$$
|
||||
BEGIN
|
||||
return param_1;
|
||||
END;
|
||||
$$;
|
||||
RESET citus.enable_ddl_propagation;
|
||||
-- Show that function will be propagated together with the view
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%func_1_for_view%';
|
||||
obj_identifier
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
CREATE VIEW prop_view_7 AS SELECT func_1_for_view(id) FROM view_table_1;
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%func_1_for_view%';
|
||||
obj_identifier
|
||||
---------------------------------------------------------------------
|
||||
(function,"{view_prop_schema,func_1_for_view}",{integer})
|
||||
(1 row)
|
||||
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%prop_view_7%';
|
||||
obj_identifier
|
||||
---------------------------------------------------------------------
|
||||
(view,"{view_prop_schema,prop_view_7}",{})
|
||||
(1 row)
|
||||
|
||||
-- Depending on type
|
||||
SET citus.enable_ddl_propagation TO OFF;
|
||||
CREATE TYPE type_for_view_prop AS ENUM ('a','b','c');
|
||||
RESET citus.enable_ddl_propagation;
|
||||
-- Show that type will be propagated together with the view
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%type_for_view_prop%';
|
||||
obj_identifier
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
CREATE VIEW prop_view_8 AS SELECT val_1::type_for_view_prop FROM view_table_1;
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%type_for_view_prop%';
|
||||
obj_identifier
|
||||
---------------------------------------------------------------------
|
||||
(type,{view_prop_schema.type_for_view_prop},{})
|
||||
(1 row)
|
||||
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%prop_view_8%';
|
||||
obj_identifier
|
||||
---------------------------------------------------------------------
|
||||
(view,"{view_prop_schema,prop_view_8}",{})
|
||||
(1 row)
|
||||
|
||||
-- Depending on another view
|
||||
CREATE TABLE view_table_5(id int);
|
||||
CREATE VIEW prop_view_9 AS SELECT * FROM view_table_5;
|
||||
WARNING: "view prop_view_9" has dependency to "table view_table_5" that is not in Citus' metadata
|
||||
DETAIL: "view prop_view_9" will be created only locally
|
||||
HINT: Distribute "table view_table_5" first to distribute "view prop_view_9"
|
||||
CREATE VIEW prop_view_10 AS SELECT * FROM prop_view_9;
|
||||
WARNING: "view prop_view_10" has dependency to "table view_table_5" that is not in Citus' metadata
|
||||
DETAIL: "view prop_view_10" will be created only locally
|
||||
HINT: Distribute "table view_table_5" first to distribute "view prop_view_10"
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%prop_view_9%';
|
||||
obj_identifier
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%prop_view_10%';
|
||||
obj_identifier
|
||||
---------------------------------------------------------------------
|
||||
(0 rows)
|
||||
|
||||
SELECT create_distributed_table('view_table_5', 'id');
|
||||
create_distributed_table
|
||||
---------------------------------------------------------------------
|
||||
|
||||
(1 row)
|
||||
|
||||
CREATE OR REPLACE VIEW prop_view_10 AS SELECT * FROM prop_view_9;
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%prop_view_9%';
|
||||
obj_identifier
|
||||
---------------------------------------------------------------------
|
||||
(view,"{view_prop_schema,prop_view_9}",{})
|
||||
(1 row)
|
||||
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%prop_view_10%';
|
||||
obj_identifier
|
||||
---------------------------------------------------------------------
|
||||
(view,"{view_prop_schema,prop_view_10}",{})
|
||||
(1 row)
|
||||
|
||||
DROP SCHEMA view_prop_schema_inner CASCADE;
|
||||
NOTICE: drop cascades to 2 other objects
|
||||
DETAIL: drop cascades to table view_prop_schema_inner.view_table_4
|
||||
drop cascades to view prop_view_6
|
||||
DROP SCHEMA view_prop_schema CASCADE;
|
||||
NOTICE: drop cascades to 17 other objects
|
||||
DETAIL: drop cascades to table view_table_1
|
||||
drop cascades to view prop_view_1
|
||||
drop cascades to table view_table_2
|
||||
drop cascades to view prop_view_2
|
||||
drop cascades to table view_table_3_1410200
|
||||
drop cascades to table view_table_2_1410199
|
||||
drop cascades to table view_table_3
|
||||
drop cascades to view prop_view_3
|
||||
drop cascades to view prop_view_4
|
||||
drop cascades to view prop_view_5
|
||||
drop cascades to function func_1_for_view(integer)
|
||||
drop cascades to view prop_view_7
|
||||
drop cascades to type type_for_view_prop
|
||||
drop cascades to view prop_view_8
|
||||
drop cascades to table view_table_5
|
||||
drop cascades to view prop_view_9
|
||||
drop cascades to view prop_view_10
|
|
@ -324,6 +324,7 @@ test: distributed_collations
|
|||
test: distributed_procedure
|
||||
test: distributed_collations_conflict
|
||||
test: function_propagation
|
||||
test: view_propagation
|
||||
test: check_mx
|
||||
|
||||
# ---------
|
||||
|
|
|
@ -0,0 +1,122 @@
|
|||
-- Tests to check propagation of all view commands
|
||||
CREATE SCHEMA view_prop_schema;
|
||||
SET search_path to view_prop_schema;
|
||||
|
||||
-- Check creating views depending on different types of tables
|
||||
-- and from multiple schemas
|
||||
|
||||
-- Try to create view depending local table, then try to recreate it after distributing the table
|
||||
CREATE TABLE view_table_1(id int, val_1 text);
|
||||
CREATE VIEW prop_view_1 AS
|
||||
SELECT * FROM view_table_1;
|
||||
|
||||
SELECT create_distributed_table('view_table_1', 'id');
|
||||
CREATE OR REPLACE VIEW prop_view_1 AS
|
||||
SELECT * FROM view_table_1;
|
||||
|
||||
-- Try to create view depending local table, then try to recreate it after making the table reference table
|
||||
CREATE TABLE view_table_2(id int PRIMARY KEY, val_1 text);
|
||||
CREATE VIEW prop_view_2 AS
|
||||
SELECT view_table_1.id, view_table_2.val_1 FROM view_table_1 INNER JOIN view_table_2
|
||||
ON view_table_1.id = view_table_2.id;
|
||||
|
||||
SELECT create_reference_table('view_table_2');
|
||||
CREATE OR REPLACE VIEW prop_view_2 AS
|
||||
SELECT view_table_1.id, view_table_2.val_1 FROM view_table_1 INNER JOIN view_table_2
|
||||
ON view_table_1.id = view_table_2.id;
|
||||
|
||||
-- Try to create view depending local table, then try to recreate it after making the table citus local table
|
||||
CREATE TABLE view_table_3(id int, val_1 text);
|
||||
CREATE VIEW prop_view_3 AS
|
||||
SELECT * FROM view_table_1 WHERE id IN
|
||||
(SELECT view_table_2.id FROM view_table_2 INNER JOIN view_table_3 ON view_table_2.id = view_table_3.id);
|
||||
|
||||
SELECT 1 FROM citus_add_node('localhost', :master_port, groupid=>0);
|
||||
|
||||
ALTER TABLE view_table_3
|
||||
ADD CONSTRAINT f_key_for_local_table
|
||||
FOREIGN KEY(id)
|
||||
REFERENCES view_table_2(id);
|
||||
|
||||
CREATE OR REPLACE VIEW prop_view_3 AS
|
||||
SELECT * FROM view_table_1 WHERE id IN
|
||||
(SELECT view_table_2.id FROM view_table_2 INNER JOIN view_table_3 ON view_table_2.id = view_table_3.id);
|
||||
|
||||
-- Try to create view depending on PG metadata table
|
||||
CREATE VIEW prop_view_4 AS
|
||||
SELECT * FROM pg_stat_activity;
|
||||
|
||||
-- Try to create view depending on Citus metadata table
|
||||
CREATE VIEW prop_view_5 AS
|
||||
SELECT * FROM citus_dist_stat_activity;
|
||||
|
||||
-- Try to create table depending on a local table from another schema, then try to create it again after distributing the table
|
||||
CREATE SCHEMA view_prop_schema_inner;
|
||||
SET search_path TO view_prop_schema_inner;
|
||||
CREATE TABLE view_table_4(id int, val_1 text);
|
||||
SET search_path to view_prop_schema;
|
||||
|
||||
CREATE VIEW prop_view_6 AS
|
||||
SELECT vt1.id, vt4.val_1 FROM view_table_1 AS vt1
|
||||
INNER JOIN view_prop_schema_inner.view_table_4 AS vt4 ON vt1.id = vt4.id;
|
||||
|
||||
SELECT create_distributed_table('view_prop_schema_inner.view_table_4','id');
|
||||
CREATE OR REPLACE VIEW prop_view_6 AS
|
||||
SELECT vt1.id, vt4.val_1 FROM view_table_1 AS vt1
|
||||
INNER JOIN view_prop_schema_inner.view_table_4 AS vt4 ON vt1.id = vt4.id;
|
||||
|
||||
-- Show that all views are propagated as distributed object
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%prop_view_%';
|
||||
|
||||
-- Check creating views depending various kind of objects
|
||||
-- Tests will also check propagating dependent objects
|
||||
|
||||
-- Depending on function
|
||||
SET citus.enable_ddl_propagation TO OFF;
|
||||
CREATE OR REPLACE FUNCTION func_1_for_view(param_1 int)
|
||||
RETURNS int
|
||||
LANGUAGE plpgsql AS
|
||||
$$
|
||||
BEGIN
|
||||
return param_1;
|
||||
END;
|
||||
$$;
|
||||
RESET citus.enable_ddl_propagation;
|
||||
|
||||
-- Show that function will be propagated together with the view
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%func_1_for_view%';
|
||||
|
||||
CREATE VIEW prop_view_7 AS SELECT func_1_for_view(id) FROM view_table_1;
|
||||
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%func_1_for_view%';
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%prop_view_7%';
|
||||
|
||||
-- Depending on type
|
||||
SET citus.enable_ddl_propagation TO OFF;
|
||||
CREATE TYPE type_for_view_prop AS ENUM ('a','b','c');
|
||||
RESET citus.enable_ddl_propagation;
|
||||
|
||||
-- Show that type will be propagated together with the view
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%type_for_view_prop%';
|
||||
|
||||
CREATE VIEW prop_view_8 AS SELECT val_1::type_for_view_prop FROM view_table_1;
|
||||
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%type_for_view_prop%';
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%prop_view_8%';
|
||||
|
||||
-- Depending on another view
|
||||
CREATE TABLE view_table_5(id int);
|
||||
CREATE VIEW prop_view_9 AS SELECT * FROM view_table_5;
|
||||
CREATE VIEW prop_view_10 AS SELECT * FROM prop_view_9;
|
||||
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%prop_view_9%';
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%prop_view_10%';
|
||||
|
||||
SELECT create_distributed_table('view_table_5', 'id');
|
||||
CREATE OR REPLACE VIEW prop_view_10 AS SELECT * FROM prop_view_9;
|
||||
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%prop_view_9%';
|
||||
SELECT * FROM (SELECT pg_identify_object_as_address(classid, objid, objsubid) as obj_identifier from pg_catalog.pg_dist_object) as obj_identifiers where obj_identifier::text like '%prop_view_10%';
|
||||
|
||||
DROP SCHEMA view_prop_schema_inner CASCADE;
|
||||
DROP SCHEMA view_prop_schema CASCADE;
|
Loading…
Reference in New Issue