diff --git a/src/backend/distributed/commands/function.c b/src/backend/distributed/commands/function.c index 13ec391d2..f7bc29c34 100644 --- a/src/backend/distributed/commands/function.c +++ b/src/backend/distributed/commands/function.c @@ -80,6 +80,7 @@ static void EnsureSequentialModeForFunctionDDL(void); static void TriggerSyncMetadataToPrimaryNodes(void); static bool ShouldPropagateCreateFunction(CreateFunctionStmt *stmt); static bool ShouldPropagateAlterFunction(const ObjectAddress *address); +static bool ShouldAddFunctionSignature(FunctionParameterMode mode); static ObjectAddress FunctionToObjectAddress(ObjectType objectType, ObjectWithArgs *objectWithArgs, bool missing_ok); @@ -1328,7 +1329,11 @@ CreateFunctionStmtObjectAddress(Node *node, bool missing_ok) FunctionParameter *funcParam = NULL; foreach_ptr(funcParam, stmt->parameters) { - objectWithArgs->objargs = lappend(objectWithArgs->objargs, funcParam->argType); + if (ShouldAddFunctionSignature(funcParam->mode)) + { + objectWithArgs->objargs = lappend(objectWithArgs->objargs, + funcParam->argType); + } } return FunctionToObjectAddress(objectType, objectWithArgs, missing_ok); @@ -1885,8 +1890,7 @@ ObjectWithArgsFromOid(Oid funcOid) for (int i = 0; i < numargs; i++) { - if (argModes == NULL || - argModes[i] != PROARGMODE_OUT || argModes[i] != PROARGMODE_TABLE) + if (argModes == NULL || ShouldAddFunctionSignature(argModes[i])) { objargs = lappend(objargs, makeTypeNameFromOid(argTypes[i], -1)); } @@ -1899,6 +1903,35 @@ ObjectWithArgsFromOid(Oid funcOid) } +/* + * ShouldAddFunctionSignature takes a FunctionParameterMode and returns true if it should + * be included in the function signature. Returns false otherwise. + */ +static bool +ShouldAddFunctionSignature(FunctionParameterMode mode) +{ + /* only input parameters should be added to the generated signature */ + switch (mode) + { + case FUNC_PARAM_IN: + case FUNC_PARAM_INOUT: + case FUNC_PARAM_VARIADIC: + { + return true; + } + + case FUNC_PARAM_OUT: + case FUNC_PARAM_TABLE: + { + return false; + } + + default: + return true; + } +} + + /* * FunctionToObjectAddress returns the ObjectAddress of a Function or Procedure based on * its type and ObjectWithArgs describing the Function/Procedure. If missing_ok is set to diff --git a/src/backend/distributed/worker/worker_create_or_replace.c b/src/backend/distributed/worker/worker_create_or_replace.c index 2bb34ea8c..c067abc11 100644 --- a/src/backend/distributed/worker/worker_create_or_replace.c +++ b/src/backend/distributed/worker/worker_create_or_replace.c @@ -61,7 +61,7 @@ WrapCreateOrReplace(const char *sql) * have this functionality or where their implementation is not sufficient. * * Besides checking if an object of said name exists it tries to compare the object to be - * created with the one in the local catalog. If there is a difference the on in the local + * created with the one in the local catalog. If there is a difference the one in the local * catalog will be renamed after which the statement can be executed on this worker to * create the object. * diff --git a/src/test/regress/expected/distributed_functions.out b/src/test/regress/expected/distributed_functions.out index 23b06782e..637441b46 100644 --- a/src/test/regress/expected/distributed_functions.out +++ b/src/test/regress/expected/distributed_functions.out @@ -610,7 +610,7 @@ SELECT create_distributed_function('eq_with_param_names(macaddr, macaddr)', dist -- show that we are able to propagate objects with multiple item on address arrays SELECT * FROM (SELECT unnest(master_metadata_snapshot()) as metadata_command order by 1) as innerResult WHERE metadata_command like '%distributed_object_data%'; - metadata_command + metadata_command --------------------------------------------------------------------- WITH distributed_object_data(typetext, objnames, objargs, distargumentindex, colocationid) AS (VALUES ('type', ARRAY['public.usage_access_type']::text[], ARRAY[]::text[], -1, 0), ('type', ARRAY['function_tests.dup_result']::text[], ARRAY[]::text[], -1, 0), ('function', ARRAY['public', 'usage_access_func']::text[], ARRAY['public.usage_access_type', 'integer[]']::text[], -1, 0), ('function', ARRAY['public', 'usage_access_func_third']::text[], ARRAY['integer', 'integer[]']::text[], 0, 50), ('function', ARRAY['function_tests', 'notice']::text[], ARRAY['pg_catalog.text']::text[], -1, 0), ('function', ARRAY['function_tests', 'dup']::text[], ARRAY['pg_catalog.macaddr']::text[], 0, 52), ('function', ARRAY['function_tests', 'eq_with_param_names']::text[], ARRAY['pg_catalog.macaddr', 'pg_catalog.macaddr']::text[], 0, 52), ('function', ARRAY['function_tests', 'eq_mi''xed_param_names']::text[], ARRAY['pg_catalog.macaddr', 'pg_catalog.macaddr']::text[], -1, 0), ('function', ARRAY['function_tests', 'agg_sfunc']::text[], ARRAY['integer', 'integer']::text[], -1, 0), ('function', ARRAY['function_tests', 'agg_invfunc']::text[], ARRAY['integer', 'integer']::text[], -1, 0), ('function', ARRAY['function_tests', 'agg_finalfunc']::text[], ARRAY['integer', 'integer']::text[], -1, 0), ('aggregate', ARRAY['function_tests', 'my_rank']::text[], ARRAY['pg_catalog."any"']::text[], -1, 0), ('function', ARRAY['function_tests', 'agg_names_sfunc']::text[], ARRAY['function_tests.dup_result', 'function_tests.dup_result', 'function_tests.dup_result']::text[], -1, 0), ('function', ARRAY['function_tests', 'agg_names_finalfunc']::text[], ARRAY['function_tests.dup_result']::text[], -1, 0), ('aggregate', ARRAY['function_tests', 'agg_names']::text[], ARRAY['function_tests.dup_result', 'function_tests.dup_result']::text[], -1, 0), ('sequence', ARRAY['public', 'user_defined_seq']::text[], ARRAY[]::text[], -1, 0), ('role', ARRAY['postgres']::text[], ARRAY[]::text[], -1, 0), ('database', ARRAY['regression']::text[], ARRAY[]::text[], -1, 0), ('schema', ARRAY['public']::text[], ARRAY[]::text[], -1, 0), ('schema', ARRAY['mx_testing_schema']::text[], ARRAY[]::text[], -1, 0), ('schema', ARRAY['mx_testing_schema_2']::text[], ARRAY[]::text[], -1, 0), ('schema', ARRAY['mx_test_schema_1']::text[], ARRAY[]::text[], -1, 0), ('schema', ARRAY['mx_test_schema_2']::text[], ARRAY[]::text[], -1, 0), ('schema', ARRAY['schema_colocation']::text[], ARRAY[]::text[], -1, 0), ('schema', ARRAY['function_tests']::text[], ARRAY[]::text[], -1, 0), ('schema', ARRAY['function_tests2']::text[], ARRAY[]::text[], -1, 0), ('extension', ARRAY['plpgsql']::text[], ARRAY[]::text[], -1, 0)) SELECT citus_internal_add_object_metadata(typetext, objnames, objargs, distargumentindex::int, colocationid::int) FROM distributed_object_data; (1 row) @@ -829,6 +829,266 @@ SELECT * FROM test ORDER BY id; (2 rows) DROP TABLE test; +-- verify that recreating distributed functions with TABLE params gets propagated to workers +CREATE OR REPLACE FUNCTION func_with_return_table(int) +RETURNS TABLE (date date) +LANGUAGE plpgsql AS $$ +BEGIN + RETURN query SELECT '2011-01-01'::date; +END; +$$; +SELECT create_distributed_function('func_with_return_table(int)'); + create_distributed_function +--------------------------------------------------------------------- + +(1 row) + +CREATE OR REPLACE FUNCTION func_with_return_table(int) +RETURNS TABLE (date date) +LANGUAGE plpgsql AS $$ +BEGIN + RETURN query SELECT '2011-01-02'::date; +END; +$$; +SELECT count(*) FROM + (SELECT result FROM + run_command_on_workers($$select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc) from pg_proc where proname = 'func_with_return_table';$$) + UNION select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc)::text from pg_proc where proname = 'func_with_return_table') + as test; + count +--------------------------------------------------------------------- + 1 +(1 row) + +-- verify that recreating distributed functions with OUT params gets propagated to workers +CREATE OR REPLACE FUNCTION func_with_out_param(a int, out b int) + RETURNS int +LANGUAGE sql AS $$ select 1; $$; +SELECT create_distributed_function('func_with_out_param(int)'); + create_distributed_function +--------------------------------------------------------------------- + +(1 row) + +SET client_min_messages TO ERROR; +CREATE ROLE r1; +SELECT 1 FROM run_command_on_workers($$CREATE ROLE r1;$$); + ?column? +--------------------------------------------------------------------- + 1 + 1 +(2 rows) + +GRANT EXECUTE ON FUNCTION func_with_out_param TO r1; +SELECT 1 FROM run_command_on_workers($$GRANT EXECUTE ON FUNCTION func_with_out_param TO r1;$$); + ?column? +--------------------------------------------------------------------- + 1 + 1 +(2 rows) + +RESET client_min_messages; +CREATE OR REPLACE FUNCTION func_with_out_param(a int, out b int) + RETURNS int +LANGUAGE sql AS $$ select 2; $$; +SELECT count(*) FROM + (SELECT result FROM + run_command_on_workers($$select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc, pg_proc.proowner) from pg_proc where proname = 'func_with_out_param';$$) + UNION select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc, pg_proc.proowner)::text from pg_proc where proname = 'func_with_out_param') + as test; + count +--------------------------------------------------------------------- + 1 +(1 row) + +-- verify that recreating distributed functions with INOUT params gets propagated to workers +CREATE OR REPLACE FUNCTION func_with_inout_param(a int, inout b int) + RETURNS int +LANGUAGE sql AS $$ select 1; $$; +-- this should error out +SELECT create_distributed_function('func_with_inout_param(int)'); +ERROR: function "func_with_inout_param(int)" does not exist +-- this should work +SELECT create_distributed_function('func_with_inout_param(int,int)'); + create_distributed_function +--------------------------------------------------------------------- + +(1 row) + +CREATE OR REPLACE FUNCTION func_with_inout_param(a int, inout b int) + RETURNS int +LANGUAGE sql AS $$ select 2; $$; +SELECT count(*) FROM + (SELECT result FROM + run_command_on_workers($$select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc) from pg_proc where proname = 'func_with_inout_param';$$) + UNION select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc)::text from pg_proc where proname = 'func_with_inout_param') + as test; + count +--------------------------------------------------------------------- + 1 +(1 row) + +-- verify that recreating distributed functions with VARIADIC params gets propagated to workers +CREATE OR REPLACE FUNCTION func_with_variadic_param(a int, variadic b int[]) + RETURNS int +LANGUAGE sql AS $$ select 1; $$; +-- this should work +SELECT create_distributed_function('func_with_variadic_param(int,int[])'); + create_distributed_function +--------------------------------------------------------------------- + +(1 row) + +CREATE OR REPLACE FUNCTION func_with_variadic_param(a int, variadic b int[]) + RETURNS int +LANGUAGE sql AS $$ select 2; $$; +SELECT count(*) FROM + (SELECT result FROM + run_command_on_workers($$select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc) from pg_proc where proname = 'func_with_variadic_param';$$) + UNION select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc)::text from pg_proc where proname = 'func_with_variadic_param') + as test; + count +--------------------------------------------------------------------- + 1 +(1 row) + +-- verify that recreating distributed functions returning setof records gets propagated to workers +CREATE OR REPLACE FUNCTION func_returning_setof_int(IN parm1 date, IN parm2 interval) + RETURNS SETOF integer AS +$BODY$ +BEGIN + RETURN QUERY + SELECT 1; +END; +$BODY$ + LANGUAGE plpgsql VOLATILE + COST 100; +SELECT create_distributed_function('func_returning_setof_int(date,interval)'); + create_distributed_function +--------------------------------------------------------------------- + +(1 row) + +CREATE OR REPLACE FUNCTION func_returning_setof_int(IN parm1 date, IN parm2 interval) + RETURNS SETOF integer AS +$BODY$ +BEGIN + RETURN QUERY + SELECT 2; + +END; +$BODY$ + LANGUAGE plpgsql VOLATILE + COST 100; +SELECT count(*) FROM + (SELECT result FROM + run_command_on_workers($$select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc) from pg_proc where proname = 'func_returning_setof_int';$$) + UNION select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc)::text from pg_proc where proname = 'func_returning_setof_int') + as test; + count +--------------------------------------------------------------------- + 1 +(1 row) + +-- verify that recreating distributed functions with variadic param returning setof records gets propagated to workers +CREATE OR REPLACE FUNCTION func_returning_setof_int_with_variadic_param(IN parm1 date, VARIADIC parm2 int[]) + RETURNS SETOF integer AS +$BODY$ +BEGIN + RETURN QUERY + SELECT 1; +END; +$BODY$ + LANGUAGE plpgsql VOLATILE + COST 100; +SELECT create_distributed_function('func_returning_setof_int_with_variadic_param(date,int[])'); + create_distributed_function +--------------------------------------------------------------------- + +(1 row) + +CREATE OR REPLACE FUNCTION func_returning_setof_int_with_variadic_param(IN parm1 date, VARIADIC parm2 int[]) + RETURNS SETOF integer AS +$BODY$ +BEGIN + RETURN QUERY + SELECT 2; +END; +$BODY$ + LANGUAGE plpgsql VOLATILE + COST 100; +SELECT count(*) FROM + (SELECT result FROM + run_command_on_workers($$select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc) from pg_proc where proname = 'func_returning_setof_int_with_variadic_param';$$) + UNION select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc)::text from pg_proc where proname = 'func_returning_setof_int_with_variadic_param') + as test; + count +--------------------------------------------------------------------- + 1 +(1 row) + +-- verify that recreating distributed procedures with out params gets propagated to workers +CREATE OR REPLACE PROCEDURE proc_with_variadic_param(IN parm1 date, VARIADIC parm2 int[]) + LANGUAGE SQL +AS $$ + SELECT 1; +$$; +-- this should error out +SELECT create_distributed_function('proc_with_variadic_param(date)'); +ERROR: function "proc_with_variadic_param(date)" does not exist +-- this should work +SELECT create_distributed_function('proc_with_variadic_param(date,int[])'); + create_distributed_function +--------------------------------------------------------------------- + +(1 row) + +CREATE OR REPLACE PROCEDURE proc_with_variadic_param(IN parm1 date, VARIADIC parm2 int[]) + LANGUAGE SQL +AS $$ + SELECT 2; +$$; +SELECT count(*) FROM + (SELECT result FROM + run_command_on_workers($$select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc) from pg_proc where proname = 'proc_with_variadic_param';$$) + UNION select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc)::text from pg_proc where proname = 'proc_with_variadic_param') + as test; + count +--------------------------------------------------------------------- + 1 +(1 row) + +-- verify that recreating distributed procedures with INOUT param gets propagated to workers +CREATE OR REPLACE PROCEDURE proc_with_inout_param(IN parm1 date, INOUT parm2 int) + LANGUAGE SQL +AS $$ + SELECT 1; +$$; +-- this should error out +SELECT create_distributed_function('proc_with_inout_param(date)'); +ERROR: function "proc_with_inout_param(date)" does not exist +-- this should work +SELECT create_distributed_function('proc_with_inout_param(date,int)'); + create_distributed_function +--------------------------------------------------------------------- + +(1 row) + +CREATE OR REPLACE PROCEDURE proc_with_inout_param(IN parm1 date, INOUT parm2 int) + LANGUAGE SQL +AS $$ + SELECT 2; +$$; +SELECT count(*) FROM + (SELECT result FROM + run_command_on_workers($$select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc) from pg_proc where proname = 'proc_with_inout_param';$$) + UNION select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc)::text from pg_proc where proname = 'proc_with_inout_param') + as test; + count +--------------------------------------------------------------------- + 1 +(1 row) + SET client_min_messages TO error; -- suppress cascading objects dropping DROP SCHEMA function_tests CASCADE; DROP SCHEMA function_tests2 CASCADE; diff --git a/src/test/regress/expected/distributed_functions_conflict.out b/src/test/regress/expected/distributed_functions_conflict.out index 995668e64..537da8c4e 100644 --- a/src/test/regress/expected/distributed_functions_conflict.out +++ b/src/test/regress/expected/distributed_functions_conflict.out @@ -139,6 +139,27 @@ SELECT worker_create_or_replace_object('CREATE AGGREGATE proc_conflict.existing_ f (1 row) +-- test worker_create_or_replace_object with a function that returns table +CREATE OR REPLACE FUNCTION func_with_return_table(int) +RETURNS TABLE (date date) +LANGUAGE plpgsql AS $$ +BEGIN + RETURN query SELECT '2011-01-01'::date; +END; +$$; +SELECT worker_create_or_replace_object('CREATE OR REPLACE FUNCTION func_with_return_table(int) RETURNS TABLE (date date) LANGUAGE plpgsql AS $$ BEGIN RETURN query SELECT ''2011-01-01''::date; END; $$;'); + worker_create_or_replace_object +--------------------------------------------------------------------- + t +(1 row) + +-- verify that a backup function is created +SELECT COUNT(*)=2 FROM pg_proc WHERE proname LIKE 'func_with_return_table%'; + ?column? +--------------------------------------------------------------------- + t +(1 row) + -- hide cascades SET client_min_messages TO error; DROP SCHEMA proc_conflict CASCADE; diff --git a/src/test/regress/expected/pg14.out b/src/test/regress/expected/pg14.out index e5257c5a0..cbdd70e05 100644 --- a/src/test/regress/expected/pg14.out +++ b/src/test/regress/expected/pg14.out @@ -1221,5 +1221,54 @@ select * from nummultirange_test natural join nummultirange_test2 order by nmr; {[1.1,2.2)} (7 rows) +-- verify that recreating distributed procedures with OUT param gets propagated to workers +CREATE OR REPLACE PROCEDURE proc_with_out_param(IN parm1 date, OUT parm2 int) + LANGUAGE SQL +AS $$ + SELECT 1; +$$; +-- this should error out +SELECT create_distributed_function('proc_with_out_param(date,int)'); +ERROR: function "proc_with_out_param(date,int)" does not exist +-- this should work +SELECT create_distributed_function('proc_with_out_param(date)'); + create_distributed_function +--------------------------------------------------------------------- + +(1 row) + +SET client_min_messages TO ERROR; +CREATE ROLE r1; +SELECT 1 FROM run_command_on_workers($$CREATE ROLE r1;$$); + ?column? +--------------------------------------------------------------------- + 1 + 1 +(2 rows) + +GRANT EXECUTE ON PROCEDURE proc_with_out_param TO r1; +SELECT 1 FROM run_command_on_workers($$GRANT EXECUTE ON PROCEDURE proc_with_out_param TO r1;$$); + ?column? +--------------------------------------------------------------------- + 1 + 1 +(2 rows) + +RESET client_min_messages; +CREATE OR REPLACE PROCEDURE proc_with_out_param(IN parm1 date, OUT parm2 int) + LANGUAGE SQL +AS $$ + SELECT 2; +$$; +SELECT count(*) FROM + (SELECT result FROM + run_command_on_workers($$select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc, pg_proc.proowner) from pg_proc where proname = 'proc_with_out_param';$$) + UNION select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc, pg_proc.proowner)::text from pg_proc where proname = 'proc_with_out_param') + as test; + count +--------------------------------------------------------------------- + 1 +(1 row) + set client_min_messages to error; drop schema pg14 cascade; diff --git a/src/test/regress/sql/distributed_functions.sql b/src/test/regress/sql/distributed_functions.sql index 8444344ee..c33ae5893 100644 --- a/src/test/regress/sql/distributed_functions.sql +++ b/src/test/regress/sql/distributed_functions.sql @@ -482,6 +482,204 @@ SELECT * FROM test ORDER BY id; DROP TABLE test; +-- verify that recreating distributed functions with TABLE params gets propagated to workers +CREATE OR REPLACE FUNCTION func_with_return_table(int) +RETURNS TABLE (date date) +LANGUAGE plpgsql AS $$ +BEGIN + RETURN query SELECT '2011-01-01'::date; +END; +$$; + +SELECT create_distributed_function('func_with_return_table(int)'); + +CREATE OR REPLACE FUNCTION func_with_return_table(int) +RETURNS TABLE (date date) +LANGUAGE plpgsql AS $$ +BEGIN + RETURN query SELECT '2011-01-02'::date; +END; +$$; + +SELECT count(*) FROM + (SELECT result FROM + run_command_on_workers($$select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc) from pg_proc where proname = 'func_with_return_table';$$) + UNION select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc)::text from pg_proc where proname = 'func_with_return_table') + as test; + +-- verify that recreating distributed functions with OUT params gets propagated to workers +CREATE OR REPLACE FUNCTION func_with_out_param(a int, out b int) + RETURNS int +LANGUAGE sql AS $$ select 1; $$; + +SELECT create_distributed_function('func_with_out_param(int)'); + +SET client_min_messages TO ERROR; +CREATE ROLE r1; +SELECT 1 FROM run_command_on_workers($$CREATE ROLE r1;$$); +GRANT EXECUTE ON FUNCTION func_with_out_param TO r1; +SELECT 1 FROM run_command_on_workers($$GRANT EXECUTE ON FUNCTION func_with_out_param TO r1;$$); +RESET client_min_messages; + +CREATE OR REPLACE FUNCTION func_with_out_param(a int, out b int) + RETURNS int +LANGUAGE sql AS $$ select 2; $$; + +SELECT count(*) FROM + (SELECT result FROM + run_command_on_workers($$select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc, pg_proc.proowner) from pg_proc where proname = 'func_with_out_param';$$) + UNION select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc, pg_proc.proowner)::text from pg_proc where proname = 'func_with_out_param') + as test; + +-- verify that recreating distributed functions with INOUT params gets propagated to workers +CREATE OR REPLACE FUNCTION func_with_inout_param(a int, inout b int) + RETURNS int +LANGUAGE sql AS $$ select 1; $$; + +-- this should error out +SELECT create_distributed_function('func_with_inout_param(int)'); +-- this should work +SELECT create_distributed_function('func_with_inout_param(int,int)'); + +CREATE OR REPLACE FUNCTION func_with_inout_param(a int, inout b int) + RETURNS int +LANGUAGE sql AS $$ select 2; $$; + +SELECT count(*) FROM + (SELECT result FROM + run_command_on_workers($$select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc) from pg_proc where proname = 'func_with_inout_param';$$) + UNION select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc)::text from pg_proc where proname = 'func_with_inout_param') + as test; + +-- verify that recreating distributed functions with VARIADIC params gets propagated to workers +CREATE OR REPLACE FUNCTION func_with_variadic_param(a int, variadic b int[]) + RETURNS int +LANGUAGE sql AS $$ select 1; $$; + +-- this should work +SELECT create_distributed_function('func_with_variadic_param(int,int[])'); + +CREATE OR REPLACE FUNCTION func_with_variadic_param(a int, variadic b int[]) + RETURNS int +LANGUAGE sql AS $$ select 2; $$; + +SELECT count(*) FROM + (SELECT result FROM + run_command_on_workers($$select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc) from pg_proc where proname = 'func_with_variadic_param';$$) + UNION select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc)::text from pg_proc where proname = 'func_with_variadic_param') + as test; + +-- verify that recreating distributed functions returning setof records gets propagated to workers +CREATE OR REPLACE FUNCTION func_returning_setof_int(IN parm1 date, IN parm2 interval) + RETURNS SETOF integer AS +$BODY$ +BEGIN + RETURN QUERY + SELECT 1; +END; +$BODY$ + LANGUAGE plpgsql VOLATILE + COST 100; + +SELECT create_distributed_function('func_returning_setof_int(date,interval)'); + +CREATE OR REPLACE FUNCTION func_returning_setof_int(IN parm1 date, IN parm2 interval) + RETURNS SETOF integer AS +$BODY$ +BEGIN + RETURN QUERY + SELECT 2; + +END; +$BODY$ + LANGUAGE plpgsql VOLATILE + COST 100; + +SELECT count(*) FROM + (SELECT result FROM + run_command_on_workers($$select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc) from pg_proc where proname = 'func_returning_setof_int';$$) + UNION select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc)::text from pg_proc where proname = 'func_returning_setof_int') + as test; + +-- verify that recreating distributed functions with variadic param returning setof records gets propagated to workers +CREATE OR REPLACE FUNCTION func_returning_setof_int_with_variadic_param(IN parm1 date, VARIADIC parm2 int[]) + RETURNS SETOF integer AS +$BODY$ +BEGIN + RETURN QUERY + SELECT 1; +END; +$BODY$ + LANGUAGE plpgsql VOLATILE + COST 100; + +SELECT create_distributed_function('func_returning_setof_int_with_variadic_param(date,int[])'); + +CREATE OR REPLACE FUNCTION func_returning_setof_int_with_variadic_param(IN parm1 date, VARIADIC parm2 int[]) + RETURNS SETOF integer AS +$BODY$ +BEGIN + RETURN QUERY + SELECT 2; +END; +$BODY$ + LANGUAGE plpgsql VOLATILE + COST 100; + +SELECT count(*) FROM + (SELECT result FROM + run_command_on_workers($$select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc) from pg_proc where proname = 'func_returning_setof_int_with_variadic_param';$$) + UNION select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc)::text from pg_proc where proname = 'func_returning_setof_int_with_variadic_param') + as test; + +-- verify that recreating distributed procedures with out params gets propagated to workers +CREATE OR REPLACE PROCEDURE proc_with_variadic_param(IN parm1 date, VARIADIC parm2 int[]) + LANGUAGE SQL +AS $$ + SELECT 1; +$$; + +-- this should error out +SELECT create_distributed_function('proc_with_variadic_param(date)'); +-- this should work +SELECT create_distributed_function('proc_with_variadic_param(date,int[])'); + +CREATE OR REPLACE PROCEDURE proc_with_variadic_param(IN parm1 date, VARIADIC parm2 int[]) + LANGUAGE SQL +AS $$ + SELECT 2; +$$; + +SELECT count(*) FROM + (SELECT result FROM + run_command_on_workers($$select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc) from pg_proc where proname = 'proc_with_variadic_param';$$) + UNION select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc)::text from pg_proc where proname = 'proc_with_variadic_param') + as test; + +-- verify that recreating distributed procedures with INOUT param gets propagated to workers +CREATE OR REPLACE PROCEDURE proc_with_inout_param(IN parm1 date, INOUT parm2 int) + LANGUAGE SQL +AS $$ + SELECT 1; +$$; + +-- this should error out +SELECT create_distributed_function('proc_with_inout_param(date)'); +-- this should work +SELECT create_distributed_function('proc_with_inout_param(date,int)'); + +CREATE OR REPLACE PROCEDURE proc_with_inout_param(IN parm1 date, INOUT parm2 int) + LANGUAGE SQL +AS $$ + SELECT 2; +$$; + +SELECT count(*) FROM + (SELECT result FROM + run_command_on_workers($$select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc) from pg_proc where proname = 'proc_with_inout_param';$$) + UNION select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc)::text from pg_proc where proname = 'proc_with_inout_param') + as test; + SET client_min_messages TO error; -- suppress cascading objects dropping DROP SCHEMA function_tests CASCADE; DROP SCHEMA function_tests2 CASCADE; diff --git a/src/test/regress/sql/distributed_functions_conflict.sql b/src/test/regress/sql/distributed_functions_conflict.sql index f4fdeddd0..ebbb6c6aa 100644 --- a/src/test/regress/sql/distributed_functions_conflict.sql +++ b/src/test/regress/sql/distributed_functions_conflict.sql @@ -115,6 +115,20 @@ $$ LANGUAGE plpgsql STRICT IMMUTABLE; SELECT worker_create_or_replace_object('CREATE AGGREGATE proc_conflict.existing_agg(integer) (STYPE = integer,SFUNC = proc_conflict.existing_func2)'); SELECT worker_create_or_replace_object('CREATE AGGREGATE proc_conflict.existing_agg(integer) (STYPE = integer,SFUNC = proc_conflict.existing_func2)'); +-- test worker_create_or_replace_object with a function that returns table +CREATE OR REPLACE FUNCTION func_with_return_table(int) +RETURNS TABLE (date date) +LANGUAGE plpgsql AS $$ +BEGIN + RETURN query SELECT '2011-01-01'::date; +END; +$$; + +SELECT worker_create_or_replace_object('CREATE OR REPLACE FUNCTION func_with_return_table(int) RETURNS TABLE (date date) LANGUAGE plpgsql AS $$ BEGIN RETURN query SELECT ''2011-01-01''::date; END; $$;'); + +-- verify that a backup function is created +SELECT COUNT(*)=2 FROM pg_proc WHERE proname LIKE 'func_with_return_table%'; + -- hide cascades SET client_min_messages TO error; DROP SCHEMA proc_conflict CASCADE; diff --git a/src/test/regress/sql/pg14.sql b/src/test/regress/sql/pg14.sql index 7998d33f1..8bc422f5d 100644 --- a/src/test/regress/sql/pg14.sql +++ b/src/test/regress/sql/pg14.sql @@ -609,5 +609,36 @@ set enable_hashjoin=f; set enable_mergejoin=f; select * from nummultirange_test natural join nummultirange_test2 order by nmr; +-- verify that recreating distributed procedures with OUT param gets propagated to workers +CREATE OR REPLACE PROCEDURE proc_with_out_param(IN parm1 date, OUT parm2 int) + LANGUAGE SQL +AS $$ + SELECT 1; +$$; + +-- this should error out +SELECT create_distributed_function('proc_with_out_param(date,int)'); +-- this should work +SELECT create_distributed_function('proc_with_out_param(date)'); + +SET client_min_messages TO ERROR; +CREATE ROLE r1; +SELECT 1 FROM run_command_on_workers($$CREATE ROLE r1;$$); +GRANT EXECUTE ON PROCEDURE proc_with_out_param TO r1; +SELECT 1 FROM run_command_on_workers($$GRANT EXECUTE ON PROCEDURE proc_with_out_param TO r1;$$); +RESET client_min_messages; + +CREATE OR REPLACE PROCEDURE proc_with_out_param(IN parm1 date, OUT parm2 int) + LANGUAGE SQL +AS $$ + SELECT 2; +$$; + +SELECT count(*) FROM + (SELECT result FROM + run_command_on_workers($$select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc, pg_proc.proowner) from pg_proc where proname = 'proc_with_out_param';$$) + UNION select row(pg_proc.pronargs, pg_proc.proargtypes, pg_proc.prosrc, pg_proc.proowner)::text from pg_proc where proname = 'proc_with_out_param') + as test; + set client_min_messages to error; drop schema pg14 cascade;