From b97b4356162f495916df1612cde9df002a12deff Mon Sep 17 00:00:00 2001 From: Jason Petersen Date: Fri, 9 Jun 2017 13:50:24 -0600 Subject: [PATCH] Change table_fkeys view to use information_schema --- src/test/regress/expected/multi_extension.out | 52 ++++++++++++++---- .../regress/expected/multi_metadata_sync.out | 12 ++--- src/test/regress/sql/multi_extension.sql | 54 +++++++++++++++---- src/test/regress/sql/multi_metadata_sync.sql | 4 +- 4 files changed, 94 insertions(+), 28 deletions(-) diff --git a/src/test/regress/expected/multi_extension.out b/src/test/regress/expected/multi_extension.out index f3c83a007..5951bb727 100644 --- a/src/test/regress/expected/multi_extension.out +++ b/src/test/regress/expected/multi_extension.out @@ -198,12 +198,28 @@ ALTER EXTENSION citus UPDATE; (0 rows) \c - - - :master_port +CREATE VIEW table_fkey_cols AS +SELECT rc.constraint_name AS "name", + kcu.column_name AS "column_name", + uc_kcu.column_name AS "refd_column_name", + format('%I.%I', kcu.table_schema, kcu.table_name)::regclass::oid AS relid, + format('%I.%I', uc_kcu.table_schema, uc_kcu.table_name)::regclass::oid AS refd_relid +FROM information_schema.referential_constraints rc, + information_schema.key_column_usage kcu, + information_schema.key_column_usage uc_kcu +WHERE rc.constraint_schema = kcu.constraint_schema AND + rc.constraint_name = kcu.constraint_name AND + rc.unique_constraint_schema = uc_kcu.constraint_schema AND + rc.unique_constraint_name = uc_kcu.constraint_name; CREATE VIEW table_fkeys AS -SELECT r.conname AS "Constraint", - pg_catalog.pg_get_constraintdef(r.oid, true) AS "Definition", - conrelid AS "relid" -FROM pg_catalog.pg_constraint r -WHERE r.contype = 'f'; +SELECT name AS "Constraint", + format('FOREIGN KEY (%s) REFERENCES %s(%s)', + string_agg(DISTINCT quote_ident(column_name), ', '), + string_agg(DISTINCT refd_relid::regclass::text, ', '), + string_agg(DISTINCT quote_ident(refd_column_name), ', ')) AS "Definition", + "relid" +FROM table_fkey_cols +GROUP BY (name, relid); -- create views used to describe relations CREATE VIEW table_attrs AS SELECT a.attname AS "name", @@ -241,12 +257,28 @@ WHERE cc.constraint_schema = ccu.constraint_schema AND cc.constraint_name = ccu.constraint_name ORDER BY cc.constraint_name ASC; \c - - - :worker_1_port +CREATE VIEW table_fkey_cols AS +SELECT rc.constraint_name AS "name", + kcu.column_name AS "column_name", + uc_kcu.column_name AS "refd_column_name", + format('%I.%I', kcu.table_schema, kcu.table_name)::regclass::oid AS relid, + format('%I.%I', uc_kcu.table_schema, uc_kcu.table_name)::regclass::oid AS refd_relid +FROM information_schema.referential_constraints rc, + information_schema.key_column_usage kcu, + information_schema.key_column_usage uc_kcu +WHERE rc.constraint_schema = kcu.constraint_schema AND + rc.constraint_name = kcu.constraint_name AND + rc.unique_constraint_schema = uc_kcu.constraint_schema AND + rc.unique_constraint_name = uc_kcu.constraint_name; CREATE VIEW table_fkeys AS -SELECT r.conname AS "Constraint", - pg_catalog.pg_get_constraintdef(r.oid, true) AS "Definition", - conrelid AS "relid" -FROM pg_catalog.pg_constraint r -WHERE r.contype = 'f'; +SELECT name AS "Constraint", + format('FOREIGN KEY (%s) REFERENCES %s(%s)', + string_agg(DISTINCT quote_ident(column_name), ', '), + string_agg(DISTINCT refd_relid::regclass::text, ', '), + string_agg(DISTINCT quote_ident(refd_column_name), ', ')) AS "Definition", + "relid" +FROM table_fkey_cols +GROUP BY (name, relid); -- create views used to describe relations CREATE VIEW table_attrs AS SELECT a.attname AS "name", diff --git a/src/test/regress/expected/multi_metadata_sync.out b/src/test/regress/expected/multi_metadata_sync.out index 9bbe00ab9..b7a980009 100644 --- a/src/test/regress/expected/multi_metadata_sync.out +++ b/src/test/regress/expected/multi_metadata_sync.out @@ -684,7 +684,7 @@ SELECT * FROM pg_dist_shard_placement ORDER BY shardid, nodename, nodeport; SET citus.multi_shard_commit_protocol TO '2pc'; SET client_min_messages TO 'ERROR'; CREATE INDEX mx_index_3 ON mx_test_schema_2.mx_table_2 USING hash (col1); -CREATE UNIQUE INDEX mx_index_4 ON mx_test_schema_2.mx_table_2(col1); +ALTER TABLE mx_test_schema_2.mx_table_2 ADD CONSTRAINT mx_table_2_col1_key UNIQUE (col1); \c - - - :worker_1_port \d mx_test_schema_2.mx_index_3 Index "mx_test_schema_2.mx_index_3" @@ -693,8 +693,8 @@ Index "mx_test_schema_2.mx_index_3" col1 | integer | col1 hash, for table "mx_test_schema_2.mx_table_2" -\d mx_test_schema_2.mx_index_4 -Index "mx_test_schema_2.mx_index_4" +\d mx_test_schema_2.mx_table_2_col1_key +Index "mx_test_schema_2.mx_table_2_col1_key" Column | Type | Definition --------+---------+------------ col1 | integer | col1 @@ -749,9 +749,9 @@ REFERENCES NOT VALID; \c - - - :worker_1_port SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='mx_test_schema_1.mx_table_1'::regclass; - Constraint | Definition ---------------------+--------------------------------------------------------------------------- - mx_fk_constraint_2 | FOREIGN KEY (col1) REFERENCES mx_test_schema_2.mx_table_2(col1) NOT VALID + Constraint | Definition +--------------------+----------------------------------------------------------------- + mx_fk_constraint_2 | FOREIGN KEY (col1) REFERENCES mx_test_schema_2.mx_table_2(col1) (1 row) -- Check that mark_tables_colocated call propagates the changes to the workers diff --git a/src/test/regress/sql/multi_extension.sql b/src/test/regress/sql/multi_extension.sql index f87a743b6..a9a070baa 100644 --- a/src/test/regress/sql/multi_extension.sql +++ b/src/test/regress/sql/multi_extension.sql @@ -178,12 +178,29 @@ ALTER EXTENSION citus UPDATE; \c - - - :master_port +CREATE VIEW table_fkey_cols AS +SELECT rc.constraint_name AS "name", + kcu.column_name AS "column_name", + uc_kcu.column_name AS "refd_column_name", + format('%I.%I', kcu.table_schema, kcu.table_name)::regclass::oid AS relid, + format('%I.%I', uc_kcu.table_schema, uc_kcu.table_name)::regclass::oid AS refd_relid +FROM information_schema.referential_constraints rc, + information_schema.key_column_usage kcu, + information_schema.key_column_usage uc_kcu +WHERE rc.constraint_schema = kcu.constraint_schema AND + rc.constraint_name = kcu.constraint_name AND + rc.unique_constraint_schema = uc_kcu.constraint_schema AND + rc.unique_constraint_name = uc_kcu.constraint_name; + CREATE VIEW table_fkeys AS -SELECT r.conname AS "Constraint", - pg_catalog.pg_get_constraintdef(r.oid, true) AS "Definition", - conrelid AS "relid" -FROM pg_catalog.pg_constraint r -WHERE r.contype = 'f'; +SELECT name AS "Constraint", + format('FOREIGN KEY (%s) REFERENCES %s(%s)', + string_agg(DISTINCT quote_ident(column_name), ', '), + string_agg(DISTINCT refd_relid::regclass::text, ', '), + string_agg(DISTINCT quote_ident(refd_column_name), ', ')) AS "Definition", + "relid" +FROM table_fkey_cols +GROUP BY (name, relid); -- create views used to describe relations CREATE VIEW table_attrs AS @@ -226,12 +243,29 @@ ORDER BY cc.constraint_name ASC; \c - - - :worker_1_port +CREATE VIEW table_fkey_cols AS +SELECT rc.constraint_name AS "name", + kcu.column_name AS "column_name", + uc_kcu.column_name AS "refd_column_name", + format('%I.%I', kcu.table_schema, kcu.table_name)::regclass::oid AS relid, + format('%I.%I', uc_kcu.table_schema, uc_kcu.table_name)::regclass::oid AS refd_relid +FROM information_schema.referential_constraints rc, + information_schema.key_column_usage kcu, + information_schema.key_column_usage uc_kcu +WHERE rc.constraint_schema = kcu.constraint_schema AND + rc.constraint_name = kcu.constraint_name AND + rc.unique_constraint_schema = uc_kcu.constraint_schema AND + rc.unique_constraint_name = uc_kcu.constraint_name; + CREATE VIEW table_fkeys AS -SELECT r.conname AS "Constraint", - pg_catalog.pg_get_constraintdef(r.oid, true) AS "Definition", - conrelid AS "relid" -FROM pg_catalog.pg_constraint r -WHERE r.contype = 'f'; +SELECT name AS "Constraint", + format('FOREIGN KEY (%s) REFERENCES %s(%s)', + string_agg(DISTINCT quote_ident(column_name), ', '), + string_agg(DISTINCT refd_relid::regclass::text, ', '), + string_agg(DISTINCT quote_ident(refd_column_name), ', ')) AS "Definition", + "relid" +FROM table_fkey_cols +GROUP BY (name, relid); -- create views used to describe relations CREATE VIEW table_attrs AS diff --git a/src/test/regress/sql/multi_metadata_sync.sql b/src/test/regress/sql/multi_metadata_sync.sql index 53d3eb9ff..47dee0e22 100644 --- a/src/test/regress/sql/multi_metadata_sync.sql +++ b/src/test/regress/sql/multi_metadata_sync.sql @@ -268,10 +268,10 @@ SELECT * FROM pg_dist_shard_placement ORDER BY shardid, nodename, nodeport; SET citus.multi_shard_commit_protocol TO '2pc'; SET client_min_messages TO 'ERROR'; CREATE INDEX mx_index_3 ON mx_test_schema_2.mx_table_2 USING hash (col1); -CREATE UNIQUE INDEX mx_index_4 ON mx_test_schema_2.mx_table_2(col1); +ALTER TABLE mx_test_schema_2.mx_table_2 ADD CONSTRAINT mx_table_2_col1_key UNIQUE (col1); \c - - - :worker_1_port \d mx_test_schema_2.mx_index_3 -\d mx_test_schema_2.mx_index_4 +\d mx_test_schema_2.mx_table_2_col1_key -- Check that DROP INDEX statement is propagated \c - - - :master_port