From a0e8f9eb645f4f359560fdd4a3d7ec88a52af291 Mon Sep 17 00:00:00 2001 From: Burak Yucesoy Date: Fri, 1 Jul 2016 12:56:50 +0300 Subject: [PATCH] Always schema-prefix worker queries Fixes #215 Fixes #267 Fixes #502 Fixes #556 Fixes #557 Fixes #560 Fixes #568 Fixes #623 Fixes #624 With this change we schema-prefix table names, operator names and composite types. --- .../distributed/master/master_node_protocol.c | 13 + src/backend/distributed/utils/ruleutils_94.c | 22 +- src/backend/distributed/utils/ruleutils_95.c | 21 +- .../expected/multi_fdw_master_protocol.out | 6 +- .../expected/multi_generate_ddl_commands.out | 62 +-- .../expected/multi_master_protocol.out | 8 +- .../regress/expected/multi_modifications.out | 4 +- .../regress/expected/multi_schema_support.out | 472 +++++++++++++++++- src/test/regress/pg_regress_multi.pl | 16 +- src/test/regress/sql/multi_schema_support.sql | 366 +++++++++++++- 10 files changed, 923 insertions(+), 67 deletions(-) diff --git a/src/backend/distributed/master/master_node_protocol.c b/src/backend/distributed/master/master_node_protocol.c index 075fcb83f..27d3b58a4 100644 --- a/src/backend/distributed/master/master_node_protocol.c +++ b/src/backend/distributed/master/master_node_protocol.c @@ -557,6 +557,16 @@ GetTableDDLEvents(Oid relationId) int scanKeyCount = 1; HeapTuple heapTuple = NULL; + /* + * Set search_path to NIL so that all objects outside of pg_catalog will be + * schema-prefixed. pg_catalog will be added automatically when we call + * PushOverrideSearchPath(), since we set addCatalog to true; + */ + OverrideSearchPath *overridePath = GetOverrideSearchPath(CurrentMemoryContext); + overridePath->schemas = NIL; + overridePath->addCatalog = true; + PushOverrideSearchPath(overridePath); + /* if foreign table, fetch extension and server definitions */ tableType = get_rel_relkind(relationId); if (tableType == RELKIND_FOREIGN_TABLE) @@ -666,6 +676,9 @@ GetTableDDLEvents(Oid relationId) systable_endscan(scanDescriptor); heap_close(pgIndex, AccessShareLock); + /* revert back to original search_path */ + PopOverrideSearchPath(); + return tableDDLEventList; } diff --git a/src/backend/distributed/utils/ruleutils_94.c b/src/backend/distributed/utils/ruleutils_94.c index 7dc0edcb1..87c4e6c3b 100644 --- a/src/backend/distributed/utils/ruleutils_94.c +++ b/src/backend/distributed/utils/ruleutils_94.c @@ -1731,6 +1731,8 @@ get_query_def_extended(Query *query, StringInfo buf, List *parentnamespace, deparse_context context; deparse_namespace dpns; + OverrideSearchPath *overridePath = NULL; + /* Guard against excessively long or deeply-nested queries */ CHECK_FOR_INTERRUPTS(); check_stack_depth(); @@ -1746,6 +1748,16 @@ get_query_def_extended(Query *query, StringInfo buf, List *parentnamespace, */ AcquireRewriteLocks(query, false, false); + /* + * Set search_path to NIL so that all objects outside of pg_catalog will be + * schema-prefixed. pg_catalog will be added automatically when we call + * PushOverrideSearchPath(), since we set addCatalog to true; + */ + overridePath = GetOverrideSearchPath(CurrentMemoryContext); + overridePath->schemas = NIL; + overridePath->addCatalog = true; + PushOverrideSearchPath(overridePath); + context.buf = buf; context.namespaces = lcons(&dpns, list_copy(parentnamespace)); context.windowClause = NIL; @@ -1791,6 +1803,9 @@ get_query_def_extended(Query *query, StringInfo buf, List *parentnamespace, query->commandType); break; } + + /* revert back to original search_path */ + PopOverrideSearchPath(); } /* ---------- @@ -6395,14 +6410,17 @@ generate_relation_or_shard_name(Oid relid, Oid distrelid, int64 shardid, if (relid == distrelid) { - /* XXX: this is where we would--but don't yet--handle schema-prefixing */ relname = get_relation_name(relid); if (shardid > 0) { + Oid schemaOid = get_rel_namespace(relid); + char *schemaName = get_namespace_name(schemaOid); + AppendShardIdToName(&relname, shardid); - relname = (char *) quote_identifier(relname); + relname = quote_qualified_identifier(schemaName, relname); + } } else diff --git a/src/backend/distributed/utils/ruleutils_95.c b/src/backend/distributed/utils/ruleutils_95.c index ee68f1e3a..5e5cf5e13 100644 --- a/src/backend/distributed/utils/ruleutils_95.c +++ b/src/backend/distributed/utils/ruleutils_95.c @@ -1838,6 +1838,8 @@ get_query_def_extended(Query *query, StringInfo buf, List *parentnamespace, deparse_context context; deparse_namespace dpns; + OverrideSearchPath *overridePath = NULL; + /* Guard against excessively long or deeply-nested queries */ CHECK_FOR_INTERRUPTS(); check_stack_depth(); @@ -1853,6 +1855,16 @@ get_query_def_extended(Query *query, StringInfo buf, List *parentnamespace, */ AcquireRewriteLocks(query, false, false); + /* + * Set search_path to NIL so that all objects outside of pg_catalog will be + * schema-prefixed. pg_catalog will be added automatically when we call + * PushOverrideSearchPath(), since we set addCatalog to true; + */ + overridePath = GetOverrideSearchPath(CurrentMemoryContext); + overridePath->schemas = NIL; + overridePath->addCatalog = true; + PushOverrideSearchPath(overridePath); + context.buf = buf; context.namespaces = lcons(&dpns, list_copy(parentnamespace)); context.windowClause = NIL; @@ -1899,6 +1911,9 @@ get_query_def_extended(Query *query, StringInfo buf, List *parentnamespace, query->commandType); break; } + + /* revert back to original search_path */ + PopOverrideSearchPath(); } /* ---------- @@ -6975,14 +6990,16 @@ generate_relation_or_shard_name(Oid relid, Oid distrelid, int64 shardid, if (relid == distrelid) { - /* XXX: this is where we would--but don't yet--handle schema-prefixing */ relname = get_relation_name(relid); if (shardid > 0) { + Oid schemaOid = get_rel_namespace(relid); + char *schemaName = get_namespace_name(schemaOid); + AppendShardIdToName(&relname, shardid); - relname = (char *) quote_identifier(relname); + relname = quote_qualified_identifier(schemaName, relname); } } else diff --git a/src/test/regress/expected/multi_fdw_master_protocol.out b/src/test/regress/expected/multi_fdw_master_protocol.out index 8fb73ac13..b5f732522 100644 --- a/src/test/regress/expected/multi_fdw_master_protocol.out +++ b/src/test/regress/expected/multi_fdw_master_protocol.out @@ -12,11 +12,11 @@ SELECT part_storage_type, part_key, part_replica_count, part_max_size, (1 row) SELECT * FROM master_get_table_ddl_events('lineitem'); - master_get_table_ddl_events ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + master_get_table_ddl_events +----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- CREATE EXTENSION IF NOT EXISTS file_fdw WITH SCHEMA public CREATE SERVER file_server FOREIGN DATA WRAPPER file_fdw - CREATE FOREIGN TABLE lineitem (l_orderkey bigint NOT NULL, l_partkey integer NOT NULL, l_suppkey integer NOT NULL, l_linenumber integer NOT NULL, l_quantity numeric(15,2) NOT NULL, l_extendedprice numeric(15,2) NOT NULL, l_discount numeric(15,2) NOT NULL, l_tax numeric(15,2) NOT NULL, l_returnflag character(1) NOT NULL, l_linestatus character(1) NOT NULL, l_shipdate date NOT NULL, l_commitdate date NOT NULL, l_receiptdate date NOT NULL, l_shipinstruct character(25) NOT NULL, l_shipmode character(10) NOT NULL, l_comment character varying(44) NOT NULL) SERVER file_server OPTIONS (format 'text', filename '', delimiter '|', "null" '') + CREATE FOREIGN TABLE public.lineitem (l_orderkey bigint NOT NULL, l_partkey integer NOT NULL, l_suppkey integer NOT NULL, l_linenumber integer NOT NULL, l_quantity numeric(15,2) NOT NULL, l_extendedprice numeric(15,2) NOT NULL, l_discount numeric(15,2) NOT NULL, l_tax numeric(15,2) NOT NULL, l_returnflag character(1) NOT NULL, l_linestatus character(1) NOT NULL, l_shipdate date NOT NULL, l_commitdate date NOT NULL, l_receiptdate date NOT NULL, l_shipinstruct character(25) NOT NULL, l_shipmode character(10) NOT NULL, l_comment character varying(44) NOT NULL) SERVER file_server OPTIONS (format 'text', filename '', delimiter '|', "null" '') (3 rows) SELECT * FROM master_get_new_shardid(); diff --git a/src/test/regress/expected/multi_generate_ddl_commands.out b/src/test/regress/expected/multi_generate_ddl_commands.out index bb929e533..b1dbf198e 100644 --- a/src/test/regress/expected/multi_generate_ddl_commands.out +++ b/src/test/regress/expected/multi_generate_ddl_commands.out @@ -17,9 +17,9 @@ CREATE TABLE simple_table ( id bigint ); SELECT table_ddl_command_array('simple_table'); - table_ddl_command_array ----------------------------------------------------------------------------- - {"CREATE TABLE simple_table (first_name text, last_name text, id bigint)"} + table_ddl_command_array +----------------------------------------------------------------------------------- + {"CREATE TABLE public.simple_table (first_name text, last_name text, id bigint)"} (1 row) -- ensure not-null constraints are propagated @@ -28,9 +28,9 @@ CREATE TABLE not_null_table ( id bigint not null ); SELECT table_ddl_command_array('not_null_table'); - table_ddl_command_array ------------------------------------------------------------------ - {"CREATE TABLE not_null_table (city text, id bigint NOT NULL)"} + table_ddl_command_array +------------------------------------------------------------------------ + {"CREATE TABLE public.not_null_table (city text, id bigint NOT NULL)"} (1 row) -- ensure tables not in search path are schema-prefixed @@ -50,9 +50,9 @@ CREATE TABLE column_constraint_table ( age int CONSTRAINT non_negative_age CHECK (age >= 0) ); SELECT table_ddl_command_array('column_constraint_table'); - table_ddl_command_array ---------------------------------------------------------------------------------------------------------------------------------------- - {"CREATE TABLE column_constraint_table (first_name text, last_name text, age integer, CONSTRAINT non_negative_age CHECK (age >= 0))"} + table_ddl_command_array +---------------------------------------------------------------------------------------------------------------------------------------------- + {"CREATE TABLE public.column_constraint_table (first_name text, last_name text, age integer, CONSTRAINT non_negative_age CHECK (age >= 0))"} (1 row) -- including table constraints @@ -63,9 +63,9 @@ CREATE TABLE table_constraint_table ( CONSTRAINT bids_ordered CHECK (min_bid > max_bid) ); SELECT table_ddl_command_array('table_constraint_table'); - table_ddl_command_array ---------------------------------------------------------------------------------------------------------------------------------------------------------------------- - {"CREATE TABLE table_constraint_table (bid_item_id bigint, min_bid numeric NOT NULL, max_bid numeric NOT NULL, CONSTRAINT bids_ordered CHECK (min_bid > max_bid))"} + table_ddl_command_array +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {"CREATE TABLE public.table_constraint_table (bid_item_id bigint, min_bid numeric NOT NULL, max_bid numeric NOT NULL, CONSTRAINT bids_ordered CHECK (min_bid > max_bid))"} (1 row) -- default values are supported @@ -74,9 +74,9 @@ CREATE TABLE default_value_table ( price decimal default 0.00 ); SELECT table_ddl_command_array('default_value_table'); - table_ddl_command_array ------------------------------------------------------------------------------- - {"CREATE TABLE default_value_table (name text, price numeric DEFAULT 0.00)"} + table_ddl_command_array +------------------------------------------------------------------------------------- + {"CREATE TABLE public.default_value_table (name text, price numeric DEFAULT 0.00)"} (1 row) -- of course primary keys work... @@ -86,9 +86,9 @@ CREATE TABLE pkey_table ( id bigint PRIMARY KEY ); SELECT table_ddl_command_array('pkey_table'); - table_ddl_command_array -------------------------------------------------------------------------------------------------------------------------------------------------------------------- - {"CREATE TABLE pkey_table (first_name text, last_name text, id bigint NOT NULL)","ALTER TABLE public.pkey_table ADD CONSTRAINT pkey_table_pkey PRIMARY KEY (id)"} + table_ddl_command_array +-------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {"CREATE TABLE public.pkey_table (first_name text, last_name text, id bigint NOT NULL)","ALTER TABLE public.pkey_table ADD CONSTRAINT pkey_table_pkey PRIMARY KEY (id)"} (1 row) -- as do unique indexes... @@ -97,9 +97,9 @@ CREATE TABLE unique_table ( username text UNIQUE not null ); SELECT table_ddl_command_array('unique_table'); - table_ddl_command_array ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- - {"CREATE TABLE unique_table (user_id bigint NOT NULL, username text NOT NULL)","ALTER TABLE public.unique_table ADD CONSTRAINT unique_table_username_key UNIQUE (username)"} + table_ddl_command_array +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {"CREATE TABLE public.unique_table (user_id bigint NOT NULL, username text NOT NULL)","ALTER TABLE public.unique_table ADD CONSTRAINT unique_table_username_key UNIQUE (username)"} (1 row) -- and indexes used for clustering @@ -110,9 +110,9 @@ CREATE TABLE clustered_table ( CREATE INDEX clustered_time_idx ON clustered_table (received_at); CLUSTER clustered_table USING clustered_time_idx; SELECT table_ddl_command_array('clustered_table'); - table_ddl_command_array ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- - {"CREATE TABLE clustered_table (data json NOT NULL, received_at timestamp without time zone NOT NULL)","CREATE INDEX clustered_time_idx ON clustered_table USING btree (received_at)","ALTER TABLE clustered_table CLUSTER ON clustered_time_idx"} + table_ddl_command_array +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {"CREATE TABLE public.clustered_table (data json NOT NULL, received_at timestamp without time zone NOT NULL)","CREATE INDEX clustered_time_idx ON public.clustered_table USING btree (received_at)","ALTER TABLE public.clustered_table CLUSTER ON clustered_time_idx"} (1 row) -- fiddly things like storage type and statistics also work @@ -129,9 +129,9 @@ ALTER TABLE fiddly_table ALTER traceroute SET STORAGE EXTERNAL, ALTER ip_addr SET STATISTICS 500; SELECT table_ddl_command_array('fiddly_table'); - table_ddl_command_array -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- - {"CREATE TABLE fiddly_table (hostname character(255) NOT NULL, os character(255) NOT NULL, ip_addr inet NOT NULL, traceroute text NOT NULL)","ALTER TABLE ONLY fiddly_table ALTER COLUMN hostname SET STORAGE PLAIN, ALTER COLUMN os SET STORAGE MAIN, ALTER COLUMN ip_addr SET STORAGE EXTENDED, ALTER COLUMN ip_addr SET STATISTICS 500, ALTER COLUMN traceroute SET STORAGE EXTERNAL"} + table_ddl_command_array +--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {"CREATE TABLE public.fiddly_table (hostname character(255) NOT NULL, os character(255) NOT NULL, ip_addr inet NOT NULL, traceroute text NOT NULL)","ALTER TABLE ONLY public.fiddly_table ALTER COLUMN hostname SET STORAGE PLAIN, ALTER COLUMN os SET STORAGE MAIN, ALTER COLUMN ip_addr SET STORAGE EXTENDED, ALTER COLUMN ip_addr SET STATISTICS 500, ALTER COLUMN traceroute SET STORAGE EXTERNAL"} (1 row) -- test foreign tables using fake FDW @@ -141,15 +141,15 @@ CREATE FOREIGN TABLE foreign_table ( ) SERVER fake_fdw_server OPTIONS (encoding 'utf-8', compression 'true'); SELECT table_ddl_command_array('foreign_table'); NOTICE: foreign-data wrapper "fake_fdw" does not have an extension defined - table_ddl_command_array -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- - {"CREATE SERVER fake_fdw_server FOREIGN DATA WRAPPER fake_fdw","CREATE FOREIGN TABLE foreign_table (id bigint NOT NULL, full_name text DEFAULT ''::text NOT NULL) SERVER fake_fdw_server OPTIONS (encoding 'utf-8', compression 'true')"} + table_ddl_command_array +-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + {"CREATE SERVER fake_fdw_server FOREIGN DATA WRAPPER fake_fdw","CREATE FOREIGN TABLE public.foreign_table (id bigint NOT NULL, full_name text DEFAULT ''::text NOT NULL) SERVER fake_fdw_server OPTIONS (encoding 'utf-8', compression 'true')"} (1 row) -- propagating views is not supported CREATE VIEW local_view AS SELECT * FROM simple_table; SELECT table_ddl_command_array('local_view'); -ERROR: local_view is not a regular or foreign table +ERROR: public.local_view is not a regular or foreign table -- clean up DROP VIEW IF EXISTS local_view; DROP FOREIGN TABLE IF EXISTS foreign_table; diff --git a/src/test/regress/expected/multi_master_protocol.out b/src/test/regress/expected/multi_master_protocol.out index b000b15af..36d6238d9 100644 --- a/src/test/regress/expected/multi_master_protocol.out +++ b/src/test/regress/expected/multi_master_protocol.out @@ -12,10 +12,10 @@ SELECT part_storage_type, part_key, part_replica_count, part_max_size, (1 row) SELECT * FROM master_get_table_ddl_events('lineitem'); - master_get_table_ddl_events ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- - CREATE TABLE lineitem (l_orderkey bigint NOT NULL, l_partkey integer NOT NULL, l_suppkey integer NOT NULL, l_linenumber integer NOT NULL, l_quantity numeric(15,2) NOT NULL, l_extendedprice numeric(15,2) NOT NULL, l_discount numeric(15,2) NOT NULL, l_tax numeric(15,2) NOT NULL, l_returnflag character(1) NOT NULL, l_linestatus character(1) NOT NULL, l_shipdate date NOT NULL, l_commitdate date NOT NULL, l_receiptdate date NOT NULL, l_shipinstruct character(25) NOT NULL, l_shipmode character(10) NOT NULL, l_comment character varying(44) NOT NULL) - CREATE INDEX lineitem_time_index ON lineitem USING btree (l_shipdate) + master_get_table_ddl_events +----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + CREATE TABLE public.lineitem (l_orderkey bigint NOT NULL, l_partkey integer NOT NULL, l_suppkey integer NOT NULL, l_linenumber integer NOT NULL, l_quantity numeric(15,2) NOT NULL, l_extendedprice numeric(15,2) NOT NULL, l_discount numeric(15,2) NOT NULL, l_tax numeric(15,2) NOT NULL, l_returnflag character(1) NOT NULL, l_linestatus character(1) NOT NULL, l_shipdate date NOT NULL, l_commitdate date NOT NULL, l_receiptdate date NOT NULL, l_shipinstruct character(25) NOT NULL, l_shipmode character(10) NOT NULL, l_comment character varying(44) NOT NULL) + CREATE INDEX lineitem_time_index ON public.lineitem USING btree (l_shipdate) ALTER TABLE public.lineitem ADD CONSTRAINT lineitem_pkey PRIMARY KEY (l_orderkey, l_linenumber) (3 rows) diff --git a/src/test/regress/expected/multi_modifications.out b/src/test/regress/expected/multi_modifications.out index 9e7bf8399..f6a9dd0b2 100644 --- a/src/test/regress/expected/multi_modifications.out +++ b/src/test/regress/expected/multi_modifications.out @@ -335,7 +335,7 @@ ALTER TABLE limit_orders_750000 RENAME TO renamed_orders; \c - - - :master_port -- Fourth: Perform an INSERT on the remaining node INSERT INTO limit_orders VALUES (276, 'ADR', 140, '2007-07-02 16:32:15', 'sell', 43.67); -WARNING: relation "limit_orders_750000" does not exist +WARNING: relation "public.limit_orders_750000" does not exist CONTEXT: while executing command on localhost:57638 -- Last: Verify the insert worked but the deleted placement is now unhealthy SELECT count(*) FROM limit_orders WHERE id = 276; @@ -366,7 +366,7 @@ ALTER TABLE limit_orders_750000 RENAME TO renamed_orders; \c - - - :master_port -- Fourth: Perform an INSERT on the remaining node INSERT INTO limit_orders VALUES (276, 'ADR', 140, '2007-07-02 16:32:15', 'sell', 43.67); -WARNING: relation "limit_orders_750000" does not exist +WARNING: relation "public.limit_orders_750000" does not exist CONTEXT: while executing command on localhost:57637 ERROR: could not modify any active placements -- Last: Verify worker is still healthy diff --git a/src/test/regress/expected/multi_schema_support.out b/src/test/regress/expected/multi_schema_support.out index 0c106e613..4e4df3d39 100644 --- a/src/test/regress/expected/multi_schema_support.out +++ b/src/test/regress/expected/multi_schema_support.out @@ -3,10 +3,19 @@ -- ALTER SEQUENCE pg_catalog.pg_dist_shardid_seq RESTART 1190000; ALTER SEQUENCE pg_catalog.pg_dist_jobid_seq RESTART 1190000; --- test master_append_table_to_shard with schema +-- create schema to test schema support CREATE SCHEMA test_schema_support; NOTICE: Citus partially supports CREATE SCHEMA for distributed databases DETAIL: schema usage in joins and in some UDFs provided by Citus are not supported yet +-- test master_append_table_to_shard with schema +-- create local table to append +CREATE TABLE public.nation_local( + n_nationkey integer not null, + n_name char(25) not null, + n_regionkey integer not null, + n_comment varchar(152) +); +\COPY public.nation_local FROM STDIN with delimiter '|'; CREATE TABLE test_schema_support.nation_append( n_nationkey integer not null, n_name char(25) not null, @@ -25,14 +34,6 @@ SELECT master_create_empty_shard('test_schema_support.nation_append'); 1190000 (1 row) --- create table to append -CREATE TABLE public.nation_local( - n_nationkey integer not null, - n_name char(25) not null, - n_regionkey integer not null, - n_comment varchar(152) -); -\COPY public.nation_local FROM STDIN with delimiter '|'; -- append table to shard SELECT master_append_table_to_shard(1190000, 'public.nation_local', 'localhost', :master_port); master_append_table_to_shard @@ -78,7 +79,7 @@ SELECT COUNT(*) FROM test_schema_support."nation._'append"; 6 (1 row) --- test with search_path is set +-- test master_append_table_to_shard with schema with search_path is set SET search_path TO test_schema_support; SELECT master_append_table_to_shard(1190000, 'public.nation_local', 'localhost', :master_port); master_append_table_to_shard @@ -107,3 +108,454 @@ SELECT COUNT(*) FROM "nation._'append"; 12 (1 row) +-- test shard creation on append(by data loading) and hash distributed(with UDF) tables +-- when search_path is set +SET search_path TO test_schema_support; +-- create shard with COPY on append distributed table +CREATE TABLE nation_append_search_path( + n_nationkey integer not null, + n_name char(25) not null, + n_regionkey integer not null, + n_comment varchar(152) +); +SELECT master_create_distributed_table('nation_append_search_path', 'n_nationkey', 'append'); + master_create_distributed_table +--------------------------------- + +(1 row) + +\COPY nation_append_search_path FROM STDIN with delimiter '|'; +-- create shard with master_create_worker_shards +CREATE TABLE test_schema_support.nation_hash( + n_nationkey integer not null, + n_name char(25) not null, + n_regionkey integer not null, + n_comment varchar(152) +); +SELECT master_create_distributed_table('test_schema_support.nation_hash', 'n_nationkey', 'hash'); + master_create_distributed_table +--------------------------------- + +(1 row) + +SELECT master_create_worker_shards('test_schema_support.nation_hash', 4, 1); + master_create_worker_shards +----------------------------- + +(1 row) + +-- test cursors +SET search_path TO public; +BEGIN; +DECLARE test_cursor CURSOR FOR + SELECT * + FROM test_schema_support.nation_append + WHERE n_nationkey = 1; +FETCH test_cursor; + n_nationkey | n_name | n_regionkey | n_comment +-------------+---------------------------+-------------+------------------------------------------------------------------------------ + 1 | ARGENTINA | 1 | al foxes promise slyly according to the regular accounts. bold requests alon +(1 row) + +END; +-- test with search_path is set +SET search_path TO test_schema_support; +BEGIN; +DECLARE test_cursor CURSOR FOR + SELECT * + FROM nation_append + WHERE n_nationkey = 1; +FETCH test_cursor; + n_nationkey | n_name | n_regionkey | n_comment +-------------+---------------------------+-------------+------------------------------------------------------------------------------ + 1 | ARGENTINA | 1 | al foxes promise slyly according to the regular accounts. bold requests alon +(1 row) + +END; +-- test inserting to table in different schema +SET search_path TO public; +INSERT INTO test_schema_support.nation_hash(n_nationkey, n_name, n_regionkey) VALUES (6, 'FRANCE', 3); +-- verify insertion +SELECT * FROM test_schema_support.nation_hash WHERE n_nationkey = 6; + n_nationkey | n_name | n_regionkey | n_comment +-------------+---------------------------+-------------+----------- + 6 | FRANCE | 3 | +(1 row) + +-- test with search_path is set +SET search_path TO test_schema_support; +INSERT INTO nation_hash(n_nationkey, n_name, n_regionkey) VALUES (7, 'GERMANY', 3); +-- verify insertion +SELECT * FROM nation_hash WHERE n_nationkey = 7; + n_nationkey | n_name | n_regionkey | n_comment +-------------+---------------------------+-------------+----------- + 7 | GERMANY | 3 | +(1 row) + +-- test UDFs with schemas +SET search_path TO public; +\COPY test_schema_support.nation_hash FROM STDIN with delimiter '|'; +-- create UDF in master node +CREATE OR REPLACE FUNCTION dummyFunction(theValue integer) + RETURNS text AS +$$ +DECLARE + strresult text; +BEGIN + RETURN theValue * 3 / 2 + 1; +END; +$$ +LANGUAGE 'plpgsql' IMMUTABLE; +-- create UDF in worker node 1 +\c - - - :worker_1_port +CREATE OR REPLACE FUNCTION dummyFunction(theValue integer) + RETURNS text AS +$$ +DECLARE + strresult text; +BEGIN + RETURN theValue * 3 / 2 + 1; +END; +$$ +LANGUAGE 'plpgsql' IMMUTABLE; +-- create UDF in worker node 2 +\c - - - :worker_2_port +CREATE OR REPLACE FUNCTION dummyFunction(theValue integer) + RETURNS text AS +$$ +DECLARE + strresult text; +BEGIN + RETURN theValue * 3 / 2 + 1; +END; +$$ +LANGUAGE 'plpgsql' IMMUTABLE; +\c - - - :master_port +-- UDF in public, table in a schema other than public, search_path is not set +SELECT dummyFunction(n_nationkey) FROM test_schema_support.nation_hash GROUP BY 1 ORDER BY 1; + dummyfunction +--------------- + 1 + 10 + 11 + 2 + 4 + 5 + 7 + 8 +(8 rows) + +-- UDF in public, table in a schema other than public, search_path is set +SET search_path TO test_schema_support; +SELECT public.dummyFunction(n_nationkey) FROM test_schema_support.nation_hash GROUP BY 1 ORDER BY 1; + dummyfunction +--------------- + 1 + 10 + 11 + 2 + 4 + 5 + 7 + 8 +(8 rows) + +-- create UDF in master node in schema +SET search_path TO test_schema_support; +CREATE OR REPLACE FUNCTION dummyFunction2(theValue integer) + RETURNS text AS +$$ +DECLARE + strresult text; +BEGIN + RETURN theValue * 3 / 2 + 1; +END; +$$ +LANGUAGE 'plpgsql' IMMUTABLE; +-- create UDF in worker node 1 in schema +\c - - - :worker_1_port +SET search_path TO test_schema_support; +CREATE OR REPLACE FUNCTION dummyFunction2(theValue integer) + RETURNS text AS +$$ +DECLARE + strresult text; +BEGIN + RETURN theValue * 3 / 2 + 1; +END; +$$ +LANGUAGE 'plpgsql' IMMUTABLE; +-- create UDF in worker node 2 in schema +\c - - - :worker_2_port +SET search_path TO test_schema_support; +CREATE OR REPLACE FUNCTION dummyFunction2(theValue integer) + RETURNS text AS +$$ +DECLARE + strresult text; +BEGIN + RETURN theValue * 3 / 2 + 1; +END; +$$ +LANGUAGE 'plpgsql' IMMUTABLE; +\c - - - :master_port +-- UDF in schema, table in a schema other than public, search_path is not set +SET search_path TO public; +SELECT test_schema_support.dummyFunction2(n_nationkey) FROM test_schema_support.nation_hash GROUP BY 1 ORDER BY 1; + dummyfunction2 +---------------- + 1 + 10 + 11 + 2 + 4 + 5 + 7 + 8 +(8 rows) + +-- UDF in schema, table in a schema other than public, search_path is set +SET search_path TO test_schema_support; +SELECT dummyFunction2(n_nationkey) FROM nation_hash GROUP BY 1 ORDER BY 1; + dummyfunction2 +---------------- + 1 + 10 + 11 + 2 + 4 + 5 + 7 + 8 +(8 rows) + +-- test operators with schema +SET search_path TO public; +-- create operator in master +CREATE OPERATOR test_schema_support.=== ( + LEFTARG = int, + RIGHTARG = int, + PROCEDURE = int4eq, + COMMUTATOR = ===, + NEGATOR = !==, + HASHES, MERGES +); +-- create operator in worker node 1 +\c - - - :worker_1_port +CREATE OPERATOR test_schema_support.=== ( + LEFTARG = int, + RIGHTARG = int, + PROCEDURE = int4eq, + COMMUTATOR = ===, + NEGATOR = !==, + HASHES, MERGES +); +-- create operator in worker node 2 +\c - - - :worker_2_port +CREATE OPERATOR test_schema_support.=== ( + LEFTARG = int, + RIGHTARG = int, + PROCEDURE = int4eq, + COMMUTATOR = ===, + NEGATOR = !==, + HASHES, MERGES +); +\c - - - :master_port +-- test with search_path is not set +SELECT * FROM test_schema_support.nation_hash WHERE n_nationkey OPERATOR(test_schema_support.===) 1; + n_nationkey | n_name | n_regionkey | n_comment +-------------+---------------------------+-------------+------------------------------------------------------------------------------ + 1 | ARGENTINA | 1 | al foxes promise slyly according to the regular accounts. bold requests alon +(1 row) + +-- test with search_path is set +SET search_path TO test_schema_support; +SELECT * FROM nation_hash WHERE n_nationkey OPERATOR(===) 1; + n_nationkey | n_name | n_regionkey | n_comment +-------------+---------------------------+-------------+------------------------------------------------------------------------------ + 1 | ARGENTINA | 1 | al foxes promise slyly according to the regular accounts. bold requests alon +(1 row) + +-- test with master_modify_multiple_shards +SET search_path TO public; +SELECT master_modify_multiple_shards('UPDATE test_schema_support.nation_hash SET n_regionkey = n_regionkey + 1'); + master_modify_multiple_shards +------------------------------- + 8 +(1 row) + +--verify master_modify_multiple_shards +SELECT * FROM test_schema_support.nation_hash; + n_nationkey | n_name | n_regionkey | n_comment +-------------+---------------------------+-------------+------------------------------------------------------------------------------------------------------------- + 1 | ARGENTINA | 2 | al foxes promise slyly according to the regular accounts. bold requests alon + 5 | ETHIOPIA | 1 | ven packages wake quickly. regu + 7 | GERMANY | 4 | + 0 | ALGERIA | 1 | haggle. carefully final deposits detect slyly agai + 3 | CANADA | 2 | eas hang ironic, silent packages. slyly regular packages are furiously over the tithes. fluffily bold + 4 | EGYPT | 5 | y above the carefully unusual theodolites. final dugouts are quickly across the furiously regular d + 6 | FRANCE | 4 | + 2 | BRAZIL | 2 | y alongside of the pending deposits. carefully special packages are about the ironic forges. slyly special +(8 rows) + +--test with search_path is set +SET search_path TO test_schema_support; +SELECT master_modify_multiple_shards('UPDATE nation_hash SET n_regionkey = n_regionkey + 1'); + master_modify_multiple_shards +------------------------------- + 8 +(1 row) + +--verify master_modify_multiple_shards +SELECT * FROM nation_hash; + n_nationkey | n_name | n_regionkey | n_comment +-------------+---------------------------+-------------+------------------------------------------------------------------------------------------------------------- + 1 | ARGENTINA | 3 | al foxes promise slyly according to the regular accounts. bold requests alon + 5 | ETHIOPIA | 2 | ven packages wake quickly. regu + 7 | GERMANY | 5 | + 0 | ALGERIA | 2 | haggle. carefully final deposits detect slyly agai + 3 | CANADA | 3 | eas hang ironic, silent packages. slyly regular packages are furiously over the tithes. fluffily bold + 4 | EGYPT | 6 | y above the carefully unusual theodolites. final dugouts are quickly across the furiously regular d + 6 | FRANCE | 5 | + 2 | BRAZIL | 3 | y alongside of the pending deposits. carefully special packages are about the ironic forges. slyly special +(8 rows) + +--test COLLATION with schema +SET search_path TO public; +CREATE COLLATION test_schema_support.english FROM "en_US"; +-- create COLLATION in worker node 1 in schema +\c - - - :worker_1_port +CREATE COLLATION test_schema_support.english FROM "en_US"; +-- create COLLATION in worker node 2 in schema +\c - - - :worker_2_port +CREATE COLLATION test_schema_support.english FROM "en_US"; +\c - - - :master_port +CREATE TABLE test_schema_support.nation_hash_collation( + n_nationkey integer not null, + n_name char(25) not null COLLATE test_schema_support.english, + n_regionkey integer not null, + n_comment varchar(152) +); +SELECT master_create_distributed_table('test_schema_support.nation_hash_collation', 'n_nationkey', 'hash'); + master_create_distributed_table +--------------------------------- + +(1 row) + +SELECT master_create_worker_shards('test_schema_support.nation_hash_collation', 4, 1); + master_create_worker_shards +----------------------------- + +(1 row) + +\COPY test_schema_support.nation_hash_collation FROM STDIN with delimiter '|'; +SELECT * FROM test_schema_support.nation_hash_collation; + n_nationkey | n_name | n_regionkey | n_comment +-------------+---------------------------+-------------+------------------------------------------------------------------------------------------------------------- + 1 | ARGENTINA | 1 | al foxes promise slyly according to the regular accounts. bold requests alon + 5 | ETHIOPIA | 0 | ven packages wake quickly. regu + 0 | ALGERIA | 0 | haggle. carefully final deposits detect slyly agai + 3 | CANADA | 1 | eas hang ironic, silent packages. slyly regular packages are furiously over the tithes. fluffily bold + 4 | EGYPT | 4 | y above the carefully unusual theodolites. final dugouts are quickly across the furiously regular d + 2 | BRAZIL | 1 | y alongside of the pending deposits. carefully special packages are about the ironic forges. slyly special +(6 rows) + +SELECT n_comment FROM test_schema_support.nation_hash_collation ORDER BY n_comment COLLATE test_schema_support.english; + n_comment +------------------------------------------------------------------------------------------------------------- + al foxes promise slyly according to the regular accounts. bold requests alon + eas hang ironic, silent packages. slyly regular packages are furiously over the tithes. fluffily bold + haggle. carefully final deposits detect slyly agai + ven packages wake quickly. regu + y above the carefully unusual theodolites. final dugouts are quickly across the furiously regular d + y alongside of the pending deposits. carefully special packages are about the ironic forges. slyly special +(6 rows) + +--test with search_path is set +SET search_path TO test_schema_support; +CREATE TABLE nation_hash_collation_search_path( + n_nationkey integer not null, + n_name char(25) not null COLLATE english, + n_regionkey integer not null, + n_comment varchar(152) +); +SELECT master_create_distributed_table('nation_hash_collation_search_path', 'n_nationkey', 'hash'); + master_create_distributed_table +--------------------------------- + +(1 row) + +SELECT master_create_worker_shards('nation_hash_collation_search_path', 4, 1); + master_create_worker_shards +----------------------------- + +(1 row) + +\COPY nation_hash_collation_search_path FROM STDIN with delimiter '|'; +SELECT * FROM nation_hash_collation_search_path; + n_nationkey | n_name | n_regionkey | n_comment +-------------+---------------------------+-------------+------------------------------------------------------------------------------------------------------------- + 1 | ARGENTINA | 1 | al foxes promise slyly according to the regular accounts. bold requests alon + 5 | ETHIOPIA | 0 | ven packages wake quickly. regu + 0 | ALGERIA | 0 | haggle. carefully final deposits detect slyly agai + 3 | CANADA | 1 | eas hang ironic, silent packages. slyly regular packages are furiously over the tithes. fluffily bold + 4 | EGYPT | 4 | y above the carefully unusual theodolites. final dugouts are quickly across the furiously regular d + 2 | BRAZIL | 1 | y alongside of the pending deposits. carefully special packages are about the ironic forges. slyly special +(6 rows) + +SELECT n_comment FROM nation_hash_collation_search_path ORDER BY n_comment COLLATE english; + n_comment +------------------------------------------------------------------------------------------------------------- + al foxes promise slyly according to the regular accounts. bold requests alon + eas hang ironic, silent packages. slyly regular packages are furiously over the tithes. fluffily bold + haggle. carefully final deposits detect slyly agai + ven packages wake quickly. regu + y above the carefully unusual theodolites. final dugouts are quickly across the furiously regular d + y alongside of the pending deposits. carefully special packages are about the ironic forges. slyly special +(6 rows) + +--test composite types with schema +SET search_path TO public; +CREATE TYPE test_schema_support.new_composite_type as (key1 text, key2 text); +-- create type in worker node 1 in schema +\c - - - :worker_1_port +CREATE TYPE test_schema_support.new_composite_type as (key1 text, key2 text); +-- create type in worker node 2 in schema +\c - - - :worker_2_port +CREATE TYPE test_schema_support.new_composite_type as (key1 text, key2 text); +\c - - - :master_port +CREATE TABLE test_schema_support.nation_hash_composite_types( + n_nationkey integer not null, + n_name char(25) not null, + n_regionkey integer not null, + n_comment varchar(152), + test_col test_schema_support.new_composite_type +); +SELECT master_create_distributed_table('test_schema_support.nation_hash_composite_types', 'n_nationkey', 'hash'); + master_create_distributed_table +--------------------------------- + +(1 row) + +SELECT master_create_worker_shards('test_schema_support.nation_hash_composite_types', 4, 1); + master_create_worker_shards +----------------------------- + +(1 row) + +-- insert some data to verify composite type queries +\COPY test_schema_support.nation_hash_composite_types FROM STDIN with delimiter '|'; +SELECT * FROM test_schema_support.nation_hash_composite_types WHERE test_col = '(a,a)'::test_schema_support.new_composite_type; + n_nationkey | n_name | n_regionkey | n_comment | test_col +-------------+---------------------------+-------------+-----------------------------------------------------+---------- + 0 | ALGERIA | 0 | haggle. carefully final deposits detect slyly agai | (a,a) +(1 row) + +--test with search_path is set +SET search_path TO test_schema_support; +SELECT * FROM nation_hash_composite_types WHERE test_col = '(a,a)'::new_composite_type; + n_nationkey | n_name | n_regionkey | n_comment | test_col +-------------+---------------------------+-------------+-----------------------------------------------------+---------- + 0 | ALGERIA | 0 | haggle. carefully final deposits detect slyly agai | (a,a) +(1 row) + diff --git a/src/test/regress/pg_regress_multi.pl b/src/test/regress/pg_regress_multi.pl index 34c833c6e..b2587f185 100644 --- a/src/test/regress/pg_regress_multi.pl +++ b/src/test/regress/pg_regress_multi.pl @@ -45,6 +45,7 @@ my %dataTypes = (); my %fdws = (); my %fdwServers = (); my %functions = (); +my %operators = (); GetOptions( 'bindir=s' => \$bindir, @@ -112,7 +113,12 @@ for my $option (@userPgOptions) 'bug_status', ' ENUM (\'new\', \'open\', \'closed\')'); # define functions as signature->definition -%functions = ('fake_fdw_handler()', 'fdw_handler AS \'citus\' LANGUAGE C STRICT;'); +%functions = ('fake_fdw_handler()', 'fdw_handler AS \'citus\' LANGUAGE C STRICT;', + 'equal_test_composite_type_function(test_composite_type, test_composite_type)', + 'boolean AS \'select $1.i = $2.i AND $1.i2 = $2.i2;\' LANGUAGE SQL IMMUTABLE RETURNS NULL ON NULL INPUT;'); + + +%operators = ('=', '(LEFTARG = test_composite_type, RIGHTARG = test_composite_type, PROCEDURE = equal_test_composite_type_function, HASHES)'); #define fdws as name->handler name %fdws = ('fake_fdw', 'fake_fdw_handler'); @@ -257,6 +263,14 @@ for my $port (@workerPorts) or die "Could not create FUNCTION $function on worker"; } + foreach my $operator (keys %operators) + { + system("$bindir/psql", + ('-h', $host, '-p', $port, '-U', $user, "regression", + '-c', "CREATE OPERATOR $operator $operators{$operator};")) == 0 + or die "Could not create OPERATOR $operator on worker"; + } + foreach my $fdw (keys %fdws) { system("$bindir/psql", diff --git a/src/test/regress/sql/multi_schema_support.sql b/src/test/regress/sql/multi_schema_support.sql index 1e20b38e4..518fe255b 100644 --- a/src/test/regress/sql/multi_schema_support.sql +++ b/src/test/regress/sql/multi_schema_support.sql @@ -5,20 +5,12 @@ ALTER SEQUENCE pg_catalog.pg_dist_shardid_seq RESTART 1190000; ALTER SEQUENCE pg_catalog.pg_dist_jobid_seq RESTART 1190000; --- test master_append_table_to_shard with schema +-- create schema to test schema support CREATE SCHEMA test_schema_support; -CREATE TABLE test_schema_support.nation_append( - n_nationkey integer not null, - n_name char(25) not null, - n_regionkey integer not null, - n_comment varchar(152) -); -SELECT master_create_distributed_table('test_schema_support.nation_append', 'n_nationkey', 'append'); -SELECT master_create_empty_shard('test_schema_support.nation_append'); - --- create table to append +-- test master_append_table_to_shard with schema +-- create local table to append CREATE TABLE public.nation_local( n_nationkey integer not null, n_name char(25) not null, @@ -35,6 +27,15 @@ CREATE TABLE public.nation_local( 5|ETHIOPIA|0|ven packages wake quickly. regu \. +CREATE TABLE test_schema_support.nation_append( + n_nationkey integer not null, + n_name char(25) not null, + n_regionkey integer not null, + n_comment varchar(152) +); +SELECT master_create_distributed_table('test_schema_support.nation_append', 'n_nationkey', 'append'); +SELECT master_create_empty_shard('test_schema_support.nation_append'); + -- append table to shard SELECT master_append_table_to_shard(1190000, 'public.nation_local', 'localhost', :master_port); @@ -56,7 +57,7 @@ SELECT master_append_table_to_shard(1190001, 'nation_local', 'localhost', :maste -- verify table actually appended to shard SELECT COUNT(*) FROM test_schema_support."nation._'append"; --- test with search_path is set +-- test master_append_table_to_shard with schema with search_path is set SET search_path TO test_schema_support; SELECT master_append_table_to_shard(1190000, 'public.nation_local', 'localhost', :master_port); @@ -69,3 +70,344 @@ SELECT master_append_table_to_shard(1190001, 'nation_local', 'localhost', :maste -- verify table actually appended to shard SELECT COUNT(*) FROM "nation._'append"; + + +-- test shard creation on append(by data loading) and hash distributed(with UDF) tables +-- when search_path is set +SET search_path TO test_schema_support; + +-- create shard with COPY on append distributed table +CREATE TABLE nation_append_search_path( + n_nationkey integer not null, + n_name char(25) not null, + n_regionkey integer not null, + n_comment varchar(152) +); +SELECT master_create_distributed_table('nation_append_search_path', 'n_nationkey', 'append'); + +\COPY nation_append_search_path FROM STDIN with delimiter '|'; +0|ALGERIA|0| haggle. carefully final deposits detect slyly agai +1|ARGENTINA|1|al foxes promise slyly according to the regular accounts. bold requests alon +2|BRAZIL|1|y alongside of the pending deposits. carefully special packages are about the ironic forges. slyly special +3|CANADA|1|eas hang ironic, silent packages. slyly regular packages are furiously over the tithes. fluffily bold +4|EGYPT|4|y above the carefully unusual theodolites. final dugouts are quickly across the furiously regular d +5|ETHIOPIA|0|ven packages wake quickly. regu +\. + +-- create shard with master_create_worker_shards +CREATE TABLE test_schema_support.nation_hash( + n_nationkey integer not null, + n_name char(25) not null, + n_regionkey integer not null, + n_comment varchar(152) +); +SELECT master_create_distributed_table('test_schema_support.nation_hash', 'n_nationkey', 'hash'); +SELECT master_create_worker_shards('test_schema_support.nation_hash', 4, 1); + + +-- test cursors +SET search_path TO public; +BEGIN; +DECLARE test_cursor CURSOR FOR + SELECT * + FROM test_schema_support.nation_append + WHERE n_nationkey = 1; +FETCH test_cursor; +END; + +-- test with search_path is set +SET search_path TO test_schema_support; +BEGIN; +DECLARE test_cursor CURSOR FOR + SELECT * + FROM nation_append + WHERE n_nationkey = 1; +FETCH test_cursor; +END; + + +-- test inserting to table in different schema +SET search_path TO public; + +INSERT INTO test_schema_support.nation_hash(n_nationkey, n_name, n_regionkey) VALUES (6, 'FRANCE', 3); + +-- verify insertion +SELECT * FROM test_schema_support.nation_hash WHERE n_nationkey = 6; + +-- test with search_path is set +SET search_path TO test_schema_support; + +INSERT INTO nation_hash(n_nationkey, n_name, n_regionkey) VALUES (7, 'GERMANY', 3); + +-- verify insertion +SELECT * FROM nation_hash WHERE n_nationkey = 7; + + +-- test UDFs with schemas +SET search_path TO public; + +\COPY test_schema_support.nation_hash FROM STDIN with delimiter '|'; +0|ALGERIA|0| haggle. carefully final deposits detect slyly agai +1|ARGENTINA|1|al foxes promise slyly according to the regular accounts. bold requests alon +2|BRAZIL|1|y alongside of the pending deposits. carefully special packages are about the ironic forges. slyly special +3|CANADA|1|eas hang ironic, silent packages. slyly regular packages are furiously over the tithes. fluffily bold +4|EGYPT|4|y above the carefully unusual theodolites. final dugouts are quickly across the furiously regular d +5|ETHIOPIA|0|ven packages wake quickly. regu +\. + +-- create UDF in master node +CREATE OR REPLACE FUNCTION dummyFunction(theValue integer) + RETURNS text AS +$$ +DECLARE + strresult text; +BEGIN + RETURN theValue * 3 / 2 + 1; +END; +$$ +LANGUAGE 'plpgsql' IMMUTABLE; + +-- create UDF in worker node 1 +\c - - - :worker_1_port +CREATE OR REPLACE FUNCTION dummyFunction(theValue integer) + RETURNS text AS +$$ +DECLARE + strresult text; +BEGIN + RETURN theValue * 3 / 2 + 1; +END; +$$ +LANGUAGE 'plpgsql' IMMUTABLE; + +-- create UDF in worker node 2 +\c - - - :worker_2_port +CREATE OR REPLACE FUNCTION dummyFunction(theValue integer) + RETURNS text AS +$$ +DECLARE + strresult text; +BEGIN + RETURN theValue * 3 / 2 + 1; +END; +$$ +LANGUAGE 'plpgsql' IMMUTABLE; + +\c - - - :master_port + +-- UDF in public, table in a schema other than public, search_path is not set +SELECT dummyFunction(n_nationkey) FROM test_schema_support.nation_hash GROUP BY 1 ORDER BY 1; + +-- UDF in public, table in a schema other than public, search_path is set +SET search_path TO test_schema_support; +SELECT public.dummyFunction(n_nationkey) FROM test_schema_support.nation_hash GROUP BY 1 ORDER BY 1; + +-- create UDF in master node in schema +SET search_path TO test_schema_support; +CREATE OR REPLACE FUNCTION dummyFunction2(theValue integer) + RETURNS text AS +$$ +DECLARE + strresult text; +BEGIN + RETURN theValue * 3 / 2 + 1; +END; +$$ +LANGUAGE 'plpgsql' IMMUTABLE; + +-- create UDF in worker node 1 in schema +\c - - - :worker_1_port +SET search_path TO test_schema_support; +CREATE OR REPLACE FUNCTION dummyFunction2(theValue integer) + RETURNS text AS +$$ +DECLARE + strresult text; +BEGIN + RETURN theValue * 3 / 2 + 1; +END; +$$ +LANGUAGE 'plpgsql' IMMUTABLE; + +-- create UDF in worker node 2 in schema +\c - - - :worker_2_port +SET search_path TO test_schema_support; +CREATE OR REPLACE FUNCTION dummyFunction2(theValue integer) + RETURNS text AS +$$ +DECLARE + strresult text; +BEGIN + RETURN theValue * 3 / 2 + 1; +END; +$$ +LANGUAGE 'plpgsql' IMMUTABLE; + +\c - - - :master_port + +-- UDF in schema, table in a schema other than public, search_path is not set +SET search_path TO public; +SELECT test_schema_support.dummyFunction2(n_nationkey) FROM test_schema_support.nation_hash GROUP BY 1 ORDER BY 1; + +-- UDF in schema, table in a schema other than public, search_path is set +SET search_path TO test_schema_support; +SELECT dummyFunction2(n_nationkey) FROM nation_hash GROUP BY 1 ORDER BY 1; + + +-- test operators with schema +SET search_path TO public; + +-- create operator in master +CREATE OPERATOR test_schema_support.=== ( + LEFTARG = int, + RIGHTARG = int, + PROCEDURE = int4eq, + COMMUTATOR = ===, + NEGATOR = !==, + HASHES, MERGES +); + +-- create operator in worker node 1 +\c - - - :worker_1_port +CREATE OPERATOR test_schema_support.=== ( + LEFTARG = int, + RIGHTARG = int, + PROCEDURE = int4eq, + COMMUTATOR = ===, + NEGATOR = !==, + HASHES, MERGES +); + +-- create operator in worker node 2 +\c - - - :worker_2_port +CREATE OPERATOR test_schema_support.=== ( + LEFTARG = int, + RIGHTARG = int, + PROCEDURE = int4eq, + COMMUTATOR = ===, + NEGATOR = !==, + HASHES, MERGES +); + +\c - - - :master_port + +-- test with search_path is not set +SELECT * FROM test_schema_support.nation_hash WHERE n_nationkey OPERATOR(test_schema_support.===) 1; + +-- test with search_path is set +SET search_path TO test_schema_support; +SELECT * FROM nation_hash WHERE n_nationkey OPERATOR(===) 1; + + +-- test with master_modify_multiple_shards +SET search_path TO public; +SELECT master_modify_multiple_shards('UPDATE test_schema_support.nation_hash SET n_regionkey = n_regionkey + 1'); + +--verify master_modify_multiple_shards +SELECT * FROM test_schema_support.nation_hash; + +--test with search_path is set +SET search_path TO test_schema_support; +SELECT master_modify_multiple_shards('UPDATE nation_hash SET n_regionkey = n_regionkey + 1'); + +--verify master_modify_multiple_shards +SELECT * FROM nation_hash; + + +--test COLLATION with schema +SET search_path TO public; +CREATE COLLATION test_schema_support.english FROM "en_US"; + +-- create COLLATION in worker node 1 in schema +\c - - - :worker_1_port +CREATE COLLATION test_schema_support.english FROM "en_US"; + +-- create COLLATION in worker node 2 in schema +\c - - - :worker_2_port +CREATE COLLATION test_schema_support.english FROM "en_US"; + +\c - - - :master_port + +CREATE TABLE test_schema_support.nation_hash_collation( + n_nationkey integer not null, + n_name char(25) not null COLLATE test_schema_support.english, + n_regionkey integer not null, + n_comment varchar(152) +); +SELECT master_create_distributed_table('test_schema_support.nation_hash_collation', 'n_nationkey', 'hash'); +SELECT master_create_worker_shards('test_schema_support.nation_hash_collation', 4, 1); + +\COPY test_schema_support.nation_hash_collation FROM STDIN with delimiter '|'; +0|ALGERIA|0| haggle. carefully final deposits detect slyly agai +1|ARGENTINA|1|al foxes promise slyly according to the regular accounts. bold requests alon +2|BRAZIL|1|y alongside of the pending deposits. carefully special packages are about the ironic forges. slyly special +3|CANADA|1|eas hang ironic, silent packages. slyly regular packages are furiously over the tithes. fluffily bold +4|EGYPT|4|y above the carefully unusual theodolites. final dugouts are quickly across the furiously regular d +5|ETHIOPIA|0|ven packages wake quickly. regu +\. + +SELECT * FROM test_schema_support.nation_hash_collation; +SELECT n_comment FROM test_schema_support.nation_hash_collation ORDER BY n_comment COLLATE test_schema_support.english; + +--test with search_path is set +SET search_path TO test_schema_support; +CREATE TABLE nation_hash_collation_search_path( + n_nationkey integer not null, + n_name char(25) not null COLLATE english, + n_regionkey integer not null, + n_comment varchar(152) +); +SELECT master_create_distributed_table('nation_hash_collation_search_path', 'n_nationkey', 'hash'); +SELECT master_create_worker_shards('nation_hash_collation_search_path', 4, 1); + +\COPY nation_hash_collation_search_path FROM STDIN with delimiter '|'; +0|ALGERIA|0| haggle. carefully final deposits detect slyly agai +1|ARGENTINA|1|al foxes promise slyly according to the regular accounts. bold requests alon +2|BRAZIL|1|y alongside of the pending deposits. carefully special packages are about the ironic forges. slyly special +3|CANADA|1|eas hang ironic, silent packages. slyly regular packages are furiously over the tithes. fluffily bold +4|EGYPT|4|y above the carefully unusual theodolites. final dugouts are quickly across the furiously regular d +5|ETHIOPIA|0|ven packages wake quickly. regu +\. + +SELECT * FROM nation_hash_collation_search_path; +SELECT n_comment FROM nation_hash_collation_search_path ORDER BY n_comment COLLATE english; + +--test composite types with schema +SET search_path TO public; +CREATE TYPE test_schema_support.new_composite_type as (key1 text, key2 text); + +-- create type in worker node 1 in schema +\c - - - :worker_1_port +CREATE TYPE test_schema_support.new_composite_type as (key1 text, key2 text); + +-- create type in worker node 2 in schema +\c - - - :worker_2_port +CREATE TYPE test_schema_support.new_composite_type as (key1 text, key2 text); + +\c - - - :master_port +CREATE TABLE test_schema_support.nation_hash_composite_types( + n_nationkey integer not null, + n_name char(25) not null, + n_regionkey integer not null, + n_comment varchar(152), + test_col test_schema_support.new_composite_type +); +SELECT master_create_distributed_table('test_schema_support.nation_hash_composite_types', 'n_nationkey', 'hash'); +SELECT master_create_worker_shards('test_schema_support.nation_hash_composite_types', 4, 1); + +-- insert some data to verify composite type queries +\COPY test_schema_support.nation_hash_composite_types FROM STDIN with delimiter '|'; +0|ALGERIA|0| haggle. carefully final deposits detect slyly agai|(a,a) +1|ARGENTINA|1|al foxes promise slyly according to the regular accounts. bold requests alon|(a,b) +2|BRAZIL|1|y alongside of the pending deposits. carefully special packages are about the ironic forges. slyly special |(a,c) +3|CANADA|1|eas hang ironic, silent packages. slyly regular packages are furiously over the tithes. fluffily bold|(a,d) +4|EGYPT|4|y above the carefully unusual theodolites. final dugouts are quickly across the furiously regular d|(a,e) +5|ETHIOPIA|0|ven packages wake quickly. regu|(a,f) +\. + +SELECT * FROM test_schema_support.nation_hash_composite_types WHERE test_col = '(a,a)'::test_schema_support.new_composite_type; + +--test with search_path is set +SET search_path TO test_schema_support; +SELECT * FROM nation_hash_composite_types WHERE test_col = '(a,a)'::new_composite_type; +