You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
postgres/src/test/regress/sql/create_function_sql.sql

483 lines
15 KiB

--
-- CREATE_FUNCTION_SQL
--
-- Assorted tests using SQL-language functions
--
-- All objects made in this test are in temp_func_test schema
CREATE USER regress_unpriv_user;
CREATE SCHEMA temp_func_test;
GRANT ALL ON SCHEMA temp_func_test TO public;
SET search_path TO temp_func_test, public;
--
-- Make sanity checks on the pg_proc entries created by CREATE FUNCTION
--
--
-- ARGUMENT and RETURN TYPES
--
CREATE FUNCTION functest_A_1(text, date) RETURNS bool LANGUAGE 'sql'
AS 'SELECT $1 = ''abcd'' AND $2 > ''2001-01-01''';
CREATE FUNCTION functest_A_2(text[]) RETURNS int LANGUAGE 'sql'
AS 'SELECT $1[1]::int';
CREATE FUNCTION functest_A_3() RETURNS bool LANGUAGE 'sql'
AS 'SELECT false';
SELECT proname, prorettype::regtype, proargtypes::regtype[] FROM pg_proc
WHERE oid in ('functest_A_1'::regproc,
'functest_A_2'::regproc,
'functest_A_3'::regproc) ORDER BY proname;
SELECT functest_A_1('abcd', '2020-01-01');
SELECT functest_A_2(ARRAY['1', '2', '3']);
SELECT functest_A_3();
--
-- IMMUTABLE | STABLE | VOLATILE
--
CREATE FUNCTION functest_B_1(int) RETURNS bool LANGUAGE 'sql'
AS 'SELECT $1 > 0';
CREATE FUNCTION functest_B_2(int) RETURNS bool LANGUAGE 'sql'
IMMUTABLE AS 'SELECT $1 > 0';
CREATE FUNCTION functest_B_3(int) RETURNS bool LANGUAGE 'sql'
STABLE AS 'SELECT $1 = 0';
CREATE FUNCTION functest_B_4(int) RETURNS bool LANGUAGE 'sql'
VOLATILE AS 'SELECT $1 < 0';
SELECT proname, provolatile FROM pg_proc
WHERE oid in ('functest_B_1'::regproc,
'functest_B_2'::regproc,
'functest_B_3'::regproc,
'functest_B_4'::regproc) ORDER BY proname;
ALTER FUNCTION functest_B_2(int) VOLATILE;
ALTER FUNCTION functest_B_3(int) COST 100; -- unrelated change, no effect
SELECT proname, provolatile FROM pg_proc
WHERE oid in ('functest_B_1'::regproc,
'functest_B_2'::regproc,
'functest_B_3'::regproc,
'functest_B_4'::regproc) ORDER BY proname;
--
-- SECURITY DEFINER | INVOKER
--
8 years ago
CREATE FUNCTION functest_C_1(int) RETURNS bool LANGUAGE 'sql'
AS 'SELECT $1 > 0';
8 years ago
CREATE FUNCTION functest_C_2(int) RETURNS bool LANGUAGE 'sql'
SECURITY DEFINER AS 'SELECT $1 = 0';
8 years ago
CREATE FUNCTION functest_C_3(int) RETURNS bool LANGUAGE 'sql'
SECURITY INVOKER AS 'SELECT $1 < 0';
SELECT proname, prosecdef FROM pg_proc
8 years ago
WHERE oid in ('functest_C_1'::regproc,
'functest_C_2'::regproc,
'functest_C_3'::regproc) ORDER BY proname;
8 years ago
ALTER FUNCTION functest_C_1(int) IMMUTABLE; -- unrelated change, no effect
ALTER FUNCTION functest_C_2(int) SECURITY INVOKER;
ALTER FUNCTION functest_C_3(int) SECURITY DEFINER;
SELECT proname, prosecdef FROM pg_proc
8 years ago
WHERE oid in ('functest_C_1'::regproc,
'functest_C_2'::regproc,
'functest_C_3'::regproc) ORDER BY proname;
--
-- LEAKPROOF
--
8 years ago
CREATE FUNCTION functest_E_1(int) RETURNS bool LANGUAGE 'sql'
AS 'SELECT $1 > 100';
8 years ago
CREATE FUNCTION functest_E_2(int) RETURNS bool LANGUAGE 'sql'
LEAKPROOF AS 'SELECT $1 > 100';
SELECT proname, proleakproof FROM pg_proc
8 years ago
WHERE oid in ('functest_E_1'::regproc,
'functest_E_2'::regproc) ORDER BY proname;
8 years ago
ALTER FUNCTION functest_E_1(int) LEAKPROOF;
ALTER FUNCTION functest_E_2(int) STABLE; -- unrelated change, no effect
SELECT proname, proleakproof FROM pg_proc
8 years ago
WHERE oid in ('functest_E_1'::regproc,
'functest_E_2'::regproc) ORDER BY proname;
ALTER FUNCTION functest_E_2(int) NOT LEAKPROOF; -- remove leakproof attribute
SELECT proname, proleakproof FROM pg_proc
8 years ago
WHERE oid in ('functest_E_1'::regproc,
'functest_E_2'::regproc) ORDER BY proname;
-- it takes superuser privilege to turn on leakproof, but not to turn off
8 years ago
ALTER FUNCTION functest_E_1(int) OWNER TO regress_unpriv_user;
ALTER FUNCTION functest_E_2(int) OWNER TO regress_unpriv_user;
SET SESSION AUTHORIZATION regress_unpriv_user;
SET search_path TO temp_func_test, public;
8 years ago
ALTER FUNCTION functest_E_1(int) NOT LEAKPROOF;
ALTER FUNCTION functest_E_2(int) LEAKPROOF;
8 years ago
CREATE FUNCTION functest_E_3(int) RETURNS bool LANGUAGE 'sql'
LEAKPROOF AS 'SELECT $1 < 200'; -- fail
RESET SESSION AUTHORIZATION;
--
-- CALLED ON NULL INPUT | RETURNS NULL ON NULL INPUT | STRICT
--
8 years ago
CREATE FUNCTION functest_F_1(int) RETURNS bool LANGUAGE 'sql'
AS 'SELECT $1 > 50';
8 years ago
CREATE FUNCTION functest_F_2(int) RETURNS bool LANGUAGE 'sql'
CALLED ON NULL INPUT AS 'SELECT $1 = 50';
8 years ago
CREATE FUNCTION functest_F_3(int) RETURNS bool LANGUAGE 'sql'
RETURNS NULL ON NULL INPUT AS 'SELECT $1 < 50';
8 years ago
CREATE FUNCTION functest_F_4(int) RETURNS bool LANGUAGE 'sql'
STRICT AS 'SELECT $1 = 50';
SELECT proname, proisstrict FROM pg_proc
8 years ago
WHERE oid in ('functest_F_1'::regproc,
'functest_F_2'::regproc,
'functest_F_3'::regproc,
'functest_F_4'::regproc) ORDER BY proname;
ALTER FUNCTION functest_F_1(int) IMMUTABLE; -- unrelated change, no effect
ALTER FUNCTION functest_F_2(int) STRICT;
ALTER FUNCTION functest_F_3(int) CALLED ON NULL INPUT;
SELECT proname, proisstrict FROM pg_proc
8 years ago
WHERE oid in ('functest_F_1'::regproc,
'functest_F_2'::regproc,
'functest_F_3'::regproc,
'functest_F_4'::regproc) ORDER BY proname;
-- pg_get_functiondef tests
SELECT pg_get_functiondef('functest_A_1'::regproc);
SELECT pg_get_functiondef('functest_B_3'::regproc);
SELECT pg_get_functiondef('functest_C_3'::regproc);
SELECT pg_get_functiondef('functest_F_2'::regproc);
SQL-standard function body This adds support for writing CREATE FUNCTION and CREATE PROCEDURE statements for language SQL with a function body that conforms to the SQL standard and is portable to other implementations. Instead of the PostgreSQL-specific AS $$ string literal $$ syntax, this allows writing out the SQL statements making up the body unquoted, either as a single statement: CREATE FUNCTION add(a integer, b integer) RETURNS integer LANGUAGE SQL RETURN a + b; or as a block CREATE PROCEDURE insert_data(a integer, b integer) LANGUAGE SQL BEGIN ATOMIC INSERT INTO tbl VALUES (a); INSERT INTO tbl VALUES (b); END; The function body is parsed at function definition time and stored as expression nodes in a new pg_proc column prosqlbody. So at run time, no further parsing is required. However, this form does not support polymorphic arguments, because there is no more parse analysis done at call time. Dependencies between the function and the objects it uses are fully tracked. A new RETURN statement is introduced. This can only be used inside function bodies. Internally, it is treated much like a SELECT statement. psql needs some new intelligence to keep track of function body boundaries so that it doesn't send off statements when it sees semicolons that are inside a function body. Tested-by: Jaime Casanova <jcasanov@systemguards.com.ec> Reviewed-by: Julien Rouhaud <rjuju123@gmail.com> Discussion: https://www.postgresql.org/message-id/flat/1c11f1eb-f00c-43b7-799d-2d44132c02d7@2ndquadrant.com
4 years ago
--
-- SQL-standard body
--
CREATE FUNCTION functest_S_1(a text, b date) RETURNS boolean
LANGUAGE SQL
RETURN a = 'abcd' AND b > '2001-01-01';
CREATE FUNCTION functest_S_2(a text[]) RETURNS int
RETURN a[1]::int;
CREATE FUNCTION functest_S_3() RETURNS boolean
RETURN false;
CREATE FUNCTION functest_S_3a() RETURNS boolean
BEGIN ATOMIC
;;RETURN false;;
SQL-standard function body This adds support for writing CREATE FUNCTION and CREATE PROCEDURE statements for language SQL with a function body that conforms to the SQL standard and is portable to other implementations. Instead of the PostgreSQL-specific AS $$ string literal $$ syntax, this allows writing out the SQL statements making up the body unquoted, either as a single statement: CREATE FUNCTION add(a integer, b integer) RETURNS integer LANGUAGE SQL RETURN a + b; or as a block CREATE PROCEDURE insert_data(a integer, b integer) LANGUAGE SQL BEGIN ATOMIC INSERT INTO tbl VALUES (a); INSERT INTO tbl VALUES (b); END; The function body is parsed at function definition time and stored as expression nodes in a new pg_proc column prosqlbody. So at run time, no further parsing is required. However, this form does not support polymorphic arguments, because there is no more parse analysis done at call time. Dependencies between the function and the objects it uses are fully tracked. A new RETURN statement is introduced. This can only be used inside function bodies. Internally, it is treated much like a SELECT statement. psql needs some new intelligence to keep track of function body boundaries so that it doesn't send off statements when it sees semicolons that are inside a function body. Tested-by: Jaime Casanova <jcasanov@systemguards.com.ec> Reviewed-by: Julien Rouhaud <rjuju123@gmail.com> Discussion: https://www.postgresql.org/message-id/flat/1c11f1eb-f00c-43b7-799d-2d44132c02d7@2ndquadrant.com
4 years ago
END;
CREATE FUNCTION functest_S_10(a text, b date) RETURNS boolean
LANGUAGE SQL
BEGIN ATOMIC
SELECT a = 'abcd' AND b > '2001-01-01';
END;
CREATE FUNCTION functest_S_13() RETURNS boolean
BEGIN ATOMIC
SELECT 1;
SELECT false;
END;
-- check display of function arguments in sub-SELECT
CREATE TABLE functest1 (i int);
CREATE FUNCTION functest_S_16(a int, b int) RETURNS void
LANGUAGE SQL
BEGIN ATOMIC
INSERT INTO functest1 SELECT a + $2;
END;
SQL-standard function body This adds support for writing CREATE FUNCTION and CREATE PROCEDURE statements for language SQL with a function body that conforms to the SQL standard and is portable to other implementations. Instead of the PostgreSQL-specific AS $$ string literal $$ syntax, this allows writing out the SQL statements making up the body unquoted, either as a single statement: CREATE FUNCTION add(a integer, b integer) RETURNS integer LANGUAGE SQL RETURN a + b; or as a block CREATE PROCEDURE insert_data(a integer, b integer) LANGUAGE SQL BEGIN ATOMIC INSERT INTO tbl VALUES (a); INSERT INTO tbl VALUES (b); END; The function body is parsed at function definition time and stored as expression nodes in a new pg_proc column prosqlbody. So at run time, no further parsing is required. However, this form does not support polymorphic arguments, because there is no more parse analysis done at call time. Dependencies between the function and the objects it uses are fully tracked. A new RETURN statement is introduced. This can only be used inside function bodies. Internally, it is treated much like a SELECT statement. psql needs some new intelligence to keep track of function body boundaries so that it doesn't send off statements when it sees semicolons that are inside a function body. Tested-by: Jaime Casanova <jcasanov@systemguards.com.ec> Reviewed-by: Julien Rouhaud <rjuju123@gmail.com> Discussion: https://www.postgresql.org/message-id/flat/1c11f1eb-f00c-43b7-799d-2d44132c02d7@2ndquadrant.com
4 years ago
-- error: duplicate function body
CREATE FUNCTION functest_S_xxx(x int) RETURNS int
LANGUAGE SQL
AS $$ SELECT x * 2 $$
RETURN x * 3;
-- polymorphic arguments not allowed in this form
CREATE FUNCTION functest_S_xx(x anyarray) RETURNS anyelement
LANGUAGE SQL
RETURN x[1];
-- check reporting of parse-analysis errors
CREATE FUNCTION functest_S_xx(x date) RETURNS boolean
LANGUAGE SQL
RETURN x > 1;
SQL-standard function body This adds support for writing CREATE FUNCTION and CREATE PROCEDURE statements for language SQL with a function body that conforms to the SQL standard and is portable to other implementations. Instead of the PostgreSQL-specific AS $$ string literal $$ syntax, this allows writing out the SQL statements making up the body unquoted, either as a single statement: CREATE FUNCTION add(a integer, b integer) RETURNS integer LANGUAGE SQL RETURN a + b; or as a block CREATE PROCEDURE insert_data(a integer, b integer) LANGUAGE SQL BEGIN ATOMIC INSERT INTO tbl VALUES (a); INSERT INTO tbl VALUES (b); END; The function body is parsed at function definition time and stored as expression nodes in a new pg_proc column prosqlbody. So at run time, no further parsing is required. However, this form does not support polymorphic arguments, because there is no more parse analysis done at call time. Dependencies between the function and the objects it uses are fully tracked. A new RETURN statement is introduced. This can only be used inside function bodies. Internally, it is treated much like a SELECT statement. psql needs some new intelligence to keep track of function body boundaries so that it doesn't send off statements when it sees semicolons that are inside a function body. Tested-by: Jaime Casanova <jcasanov@systemguards.com.ec> Reviewed-by: Julien Rouhaud <rjuju123@gmail.com> Discussion: https://www.postgresql.org/message-id/flat/1c11f1eb-f00c-43b7-799d-2d44132c02d7@2ndquadrant.com
4 years ago
-- tricky parsing
CREATE FUNCTION functest_S_15(x int) RETURNS boolean
LANGUAGE SQL
BEGIN ATOMIC
select case when x % 2 = 0 then true else false end;
END;
SELECT functest_S_1('abcd', '2020-01-01');
SELECT functest_S_2(ARRAY['1', '2', '3']);
SELECT functest_S_3();
SELECT functest_S_10('abcd', '2020-01-01');
SELECT functest_S_13();
SELECT pg_get_functiondef('functest_S_1'::regproc);
SELECT pg_get_functiondef('functest_S_2'::regproc);
SELECT pg_get_functiondef('functest_S_3'::regproc);
SELECT pg_get_functiondef('functest_S_3a'::regproc);
SELECT pg_get_functiondef('functest_S_10'::regproc);
SELECT pg_get_functiondef('functest_S_13'::regproc);
SELECT pg_get_functiondef('functest_S_15'::regproc);
SELECT pg_get_functiondef('functest_S_16'::regproc);
DROP TABLE functest1 CASCADE;
SQL-standard function body This adds support for writing CREATE FUNCTION and CREATE PROCEDURE statements for language SQL with a function body that conforms to the SQL standard and is portable to other implementations. Instead of the PostgreSQL-specific AS $$ string literal $$ syntax, this allows writing out the SQL statements making up the body unquoted, either as a single statement: CREATE FUNCTION add(a integer, b integer) RETURNS integer LANGUAGE SQL RETURN a + b; or as a block CREATE PROCEDURE insert_data(a integer, b integer) LANGUAGE SQL BEGIN ATOMIC INSERT INTO tbl VALUES (a); INSERT INTO tbl VALUES (b); END; The function body is parsed at function definition time and stored as expression nodes in a new pg_proc column prosqlbody. So at run time, no further parsing is required. However, this form does not support polymorphic arguments, because there is no more parse analysis done at call time. Dependencies between the function and the objects it uses are fully tracked. A new RETURN statement is introduced. This can only be used inside function bodies. Internally, it is treated much like a SELECT statement. psql needs some new intelligence to keep track of function body boundaries so that it doesn't send off statements when it sees semicolons that are inside a function body. Tested-by: Jaime Casanova <jcasanov@systemguards.com.ec> Reviewed-by: Julien Rouhaud <rjuju123@gmail.com> Discussion: https://www.postgresql.org/message-id/flat/1c11f1eb-f00c-43b7-799d-2d44132c02d7@2ndquadrant.com
4 years ago
-- test with views
CREATE TABLE functest3 (a int);
INSERT INTO functest3 VALUES (1), (2);
CREATE VIEW functestv3 AS SELECT * FROM functest3;
CREATE FUNCTION functest_S_14() RETURNS bigint
RETURN (SELECT count(*) FROM functestv3);
SELECT functest_S_14();
DROP TABLE functest3 CASCADE;
-- information_schema tests
CREATE FUNCTION functest_IS_1(a int, b int default 1, c text default 'foo')
RETURNS int
LANGUAGE SQL
AS 'SELECT $1 + $2';
CREATE FUNCTION functest_IS_2(out a int, b int default 1)
RETURNS int
LANGUAGE SQL
AS 'SELECT $1';
CREATE FUNCTION functest_IS_3(a int default 1, out b int)
RETURNS int
LANGUAGE SQL
AS 'SELECT $1';
SELECT routine_name, ordinal_position, parameter_name, parameter_default
FROM information_schema.parameters JOIN information_schema.routines USING (specific_schema, specific_name)
WHERE routine_schema = 'temp_func_test' AND routine_name ~ '^functest_is_'
ORDER BY 1, 2;
DROP FUNCTION functest_IS_1(int, int, text), functest_IS_2(int), functest_IS_3(int);
-- routine usage views
CREATE FUNCTION functest_IS_4a() RETURNS int LANGUAGE SQL AS 'SELECT 1';
CREATE FUNCTION functest_IS_4b(x int DEFAULT functest_IS_4a()) RETURNS int LANGUAGE SQL AS 'SELECT x';
CREATE SEQUENCE functest1;
CREATE FUNCTION functest_IS_5(x int DEFAULT nextval('functest1'))
RETURNS int
LANGUAGE SQL
AS 'SELECT x';
SQL-standard function body This adds support for writing CREATE FUNCTION and CREATE PROCEDURE statements for language SQL with a function body that conforms to the SQL standard and is portable to other implementations. Instead of the PostgreSQL-specific AS $$ string literal $$ syntax, this allows writing out the SQL statements making up the body unquoted, either as a single statement: CREATE FUNCTION add(a integer, b integer) RETURNS integer LANGUAGE SQL RETURN a + b; or as a block CREATE PROCEDURE insert_data(a integer, b integer) LANGUAGE SQL BEGIN ATOMIC INSERT INTO tbl VALUES (a); INSERT INTO tbl VALUES (b); END; The function body is parsed at function definition time and stored as expression nodes in a new pg_proc column prosqlbody. So at run time, no further parsing is required. However, this form does not support polymorphic arguments, because there is no more parse analysis done at call time. Dependencies between the function and the objects it uses are fully tracked. A new RETURN statement is introduced. This can only be used inside function bodies. Internally, it is treated much like a SELECT statement. psql needs some new intelligence to keep track of function body boundaries so that it doesn't send off statements when it sees semicolons that are inside a function body. Tested-by: Jaime Casanova <jcasanov@systemguards.com.ec> Reviewed-by: Julien Rouhaud <rjuju123@gmail.com> Discussion: https://www.postgresql.org/message-id/flat/1c11f1eb-f00c-43b7-799d-2d44132c02d7@2ndquadrant.com
4 years ago
CREATE FUNCTION functest_IS_6()
RETURNS int
LANGUAGE SQL
RETURN nextval('functest1');
CREATE TABLE functest2 (a int, b int);
CREATE FUNCTION functest_IS_7()
RETURNS int
LANGUAGE SQL
RETURN (SELECT count(a) FROM functest2);
SELECT r0.routine_name, r1.routine_name
FROM information_schema.routine_routine_usage rru
JOIN information_schema.routines r0 ON r0.specific_name = rru.specific_name
JOIN information_schema.routines r1 ON r1.specific_name = rru.routine_name
WHERE r0.routine_schema = 'temp_func_test' AND
r1.routine_schema = 'temp_func_test'
ORDER BY 1, 2;
SELECT routine_name, sequence_name FROM information_schema.routine_sequence_usage
WHERE routine_schema = 'temp_func_test'
ORDER BY 1, 2;
SELECT routine_name, table_name, column_name FROM information_schema.routine_column_usage
WHERE routine_schema = 'temp_func_test'
ORDER BY 1, 2;
SELECT routine_name, table_name FROM information_schema.routine_table_usage
WHERE routine_schema = 'temp_func_test'
ORDER BY 1, 2;
DROP FUNCTION functest_IS_4a CASCADE;
DROP SEQUENCE functest1 CASCADE;
SQL-standard function body This adds support for writing CREATE FUNCTION and CREATE PROCEDURE statements for language SQL with a function body that conforms to the SQL standard and is portable to other implementations. Instead of the PostgreSQL-specific AS $$ string literal $$ syntax, this allows writing out the SQL statements making up the body unquoted, either as a single statement: CREATE FUNCTION add(a integer, b integer) RETURNS integer LANGUAGE SQL RETURN a + b; or as a block CREATE PROCEDURE insert_data(a integer, b integer) LANGUAGE SQL BEGIN ATOMIC INSERT INTO tbl VALUES (a); INSERT INTO tbl VALUES (b); END; The function body is parsed at function definition time and stored as expression nodes in a new pg_proc column prosqlbody. So at run time, no further parsing is required. However, this form does not support polymorphic arguments, because there is no more parse analysis done at call time. Dependencies between the function and the objects it uses are fully tracked. A new RETURN statement is introduced. This can only be used inside function bodies. Internally, it is treated much like a SELECT statement. psql needs some new intelligence to keep track of function body boundaries so that it doesn't send off statements when it sees semicolons that are inside a function body. Tested-by: Jaime Casanova <jcasanov@systemguards.com.ec> Reviewed-by: Julien Rouhaud <rjuju123@gmail.com> Discussion: https://www.postgresql.org/message-id/flat/1c11f1eb-f00c-43b7-799d-2d44132c02d7@2ndquadrant.com
4 years ago
DROP TABLE functest2 CASCADE;
-- overload
CREATE FUNCTION functest_B_2(bigint) RETURNS bool LANGUAGE 'sql'
IMMUTABLE AS 'SELECT $1 > 0';
DROP FUNCTION functest_b_1;
DROP FUNCTION functest_b_1; -- error, not found
DROP FUNCTION functest_b_2; -- error, ambiguous
-- CREATE OR REPLACE tests
CREATE FUNCTION functest1(a int) RETURNS int LANGUAGE SQL AS 'SELECT $1';
CREATE OR REPLACE FUNCTION functest1(a int) RETURNS int LANGUAGE SQL WINDOW AS 'SELECT $1';
CREATE OR REPLACE PROCEDURE functest1(a int) LANGUAGE SQL AS 'SELECT $1';
DROP FUNCTION functest1(a int);
Change SQL-language functions to use the plan cache. In the historical implementation of SQL functions (if they don't get inlined), we built plans for all the contained queries at first call within an outer query, and then re-used those plans for the duration of the outer query, and then forgot everything. This was not ideal, not least because the plans could not be customized to specific values of the function's parameters. Our plancache infrastructure seems mature enough to be used here. That will solve both the problem with not being able to build custom plans and the problem with not being able to share work across successive outer queries. Aside from those performance concerns, this change fixes a longstanding bugaboo with SQL functions: you could not write DDL that would affect later statements in the same function. That's mostly still true with new-style SQL functions, since the results of parse analysis are baked into the stored query trees (and protected by dependency records). But for old-style SQL functions, it will now work much as it does with PL/pgSQL functions, because we delay parse analysis and planning of each query until we're ready to run it. Some edge cases that require replanning are now handled better too; see for example the new rowsecurity test, where we now detect an RLS context change that was previously missed. One other edge-case change that might be worthy of a release note is that we now insist that a SQL function's result be generated by the physically-last query within it. Previously, if the last original query was deleted by a DO INSTEAD NOTHING rule, we'd be willing to take the result from the preceding query instead. This behavior was undocumented except in source-code comments, and it seems hard to believe that anyone's relying on it. Along the way to this feature, we needed a few infrastructure changes: * The plancache can now take either a raw parse tree or an analyzed-but-not-rewritten Query as the starting point for a CachedPlanSource. If given a Query, it is caller's responsibility that nothing will happen to invalidate that form of the query. We use this for new-style SQL functions, where what's in pg_proc is serialized Query(s) and we trust the dependency mechanism to disallow DDL that would break those. * The plancache now offers a way to invoke a post-rewrite callback to examine/modify the rewritten parse tree when it is rebuilding the parse trees after a cache invalidation. We need this because SQL functions sometimes adjust the parse tree to make its output exactly match the declared result type; if the plan gets rebuilt, that has to be re-done. * There is a new backend module utils/cache/funccache.c that abstracts the idea of caching data about a specific function usage (a particular function and set of input data types). The code in it is moved almost verbatim from PL/pgSQL, which has done that for a long time. We use that logic now for SQL-language functions too, and maybe other PLs will have use for it in the future. Author: Alexander Pyhalov <a.pyhalov@postgrespro.ru> Co-authored-by: Tom Lane <tgl@sss.pgh.pa.us> Reviewed-by: Pavel Stehule <pavel.stehule@gmail.com> Discussion: https://postgr.es/m/8216639.NyiUUSuA9g@aivenlaptop
5 months ago
-- early shutdown of set-returning functions
CREATE FUNCTION functest_srf0() RETURNS SETOF int
LANGUAGE SQL
AS $$ SELECT i FROM generate_series(1, 100) i $$;
SELECT functest_srf0() LIMIT 5;
SQL-standard function body This adds support for writing CREATE FUNCTION and CREATE PROCEDURE statements for language SQL with a function body that conforms to the SQL standard and is portable to other implementations. Instead of the PostgreSQL-specific AS $$ string literal $$ syntax, this allows writing out the SQL statements making up the body unquoted, either as a single statement: CREATE FUNCTION add(a integer, b integer) RETURNS integer LANGUAGE SQL RETURN a + b; or as a block CREATE PROCEDURE insert_data(a integer, b integer) LANGUAGE SQL BEGIN ATOMIC INSERT INTO tbl VALUES (a); INSERT INTO tbl VALUES (b); END; The function body is parsed at function definition time and stored as expression nodes in a new pg_proc column prosqlbody. So at run time, no further parsing is required. However, this form does not support polymorphic arguments, because there is no more parse analysis done at call time. Dependencies between the function and the objects it uses are fully tracked. A new RETURN statement is introduced. This can only be used inside function bodies. Internally, it is treated much like a SELECT statement. psql needs some new intelligence to keep track of function body boundaries so that it doesn't send off statements when it sees semicolons that are inside a function body. Tested-by: Jaime Casanova <jcasanov@systemguards.com.ec> Reviewed-by: Julien Rouhaud <rjuju123@gmail.com> Discussion: https://www.postgresql.org/message-id/flat/1c11f1eb-f00c-43b7-799d-2d44132c02d7@2ndquadrant.com
4 years ago
-- inlining of set-returning functions
CREATE TABLE functest3 (a int);
INSERT INTO functest3 VALUES (1), (2), (3);
SQL-standard function body This adds support for writing CREATE FUNCTION and CREATE PROCEDURE statements for language SQL with a function body that conforms to the SQL standard and is portable to other implementations. Instead of the PostgreSQL-specific AS $$ string literal $$ syntax, this allows writing out the SQL statements making up the body unquoted, either as a single statement: CREATE FUNCTION add(a integer, b integer) RETURNS integer LANGUAGE SQL RETURN a + b; or as a block CREATE PROCEDURE insert_data(a integer, b integer) LANGUAGE SQL BEGIN ATOMIC INSERT INTO tbl VALUES (a); INSERT INTO tbl VALUES (b); END; The function body is parsed at function definition time and stored as expression nodes in a new pg_proc column prosqlbody. So at run time, no further parsing is required. However, this form does not support polymorphic arguments, because there is no more parse analysis done at call time. Dependencies between the function and the objects it uses are fully tracked. A new RETURN statement is introduced. This can only be used inside function bodies. Internally, it is treated much like a SELECT statement. psql needs some new intelligence to keep track of function body boundaries so that it doesn't send off statements when it sees semicolons that are inside a function body. Tested-by: Jaime Casanova <jcasanov@systemguards.com.ec> Reviewed-by: Julien Rouhaud <rjuju123@gmail.com> Discussion: https://www.postgresql.org/message-id/flat/1c11f1eb-f00c-43b7-799d-2d44132c02d7@2ndquadrant.com
4 years ago
CREATE FUNCTION functest_sri1() RETURNS SETOF int
LANGUAGE SQL
STABLE
AS '
SELECT * FROM functest3;
SQL-standard function body This adds support for writing CREATE FUNCTION and CREATE PROCEDURE statements for language SQL with a function body that conforms to the SQL standard and is portable to other implementations. Instead of the PostgreSQL-specific AS $$ string literal $$ syntax, this allows writing out the SQL statements making up the body unquoted, either as a single statement: CREATE FUNCTION add(a integer, b integer) RETURNS integer LANGUAGE SQL RETURN a + b; or as a block CREATE PROCEDURE insert_data(a integer, b integer) LANGUAGE SQL BEGIN ATOMIC INSERT INTO tbl VALUES (a); INSERT INTO tbl VALUES (b); END; The function body is parsed at function definition time and stored as expression nodes in a new pg_proc column prosqlbody. So at run time, no further parsing is required. However, this form does not support polymorphic arguments, because there is no more parse analysis done at call time. Dependencies between the function and the objects it uses are fully tracked. A new RETURN statement is introduced. This can only be used inside function bodies. Internally, it is treated much like a SELECT statement. psql needs some new intelligence to keep track of function body boundaries so that it doesn't send off statements when it sees semicolons that are inside a function body. Tested-by: Jaime Casanova <jcasanov@systemguards.com.ec> Reviewed-by: Julien Rouhaud <rjuju123@gmail.com> Discussion: https://www.postgresql.org/message-id/flat/1c11f1eb-f00c-43b7-799d-2d44132c02d7@2ndquadrant.com
4 years ago
';
SELECT * FROM functest_sri1();
EXPLAIN (verbose, costs off) SELECT * FROM functest_sri1();
CREATE FUNCTION functest_sri2() RETURNS SETOF int
LANGUAGE SQL
STABLE
BEGIN ATOMIC
SELECT * FROM functest3;
SQL-standard function body This adds support for writing CREATE FUNCTION and CREATE PROCEDURE statements for language SQL with a function body that conforms to the SQL standard and is portable to other implementations. Instead of the PostgreSQL-specific AS $$ string literal $$ syntax, this allows writing out the SQL statements making up the body unquoted, either as a single statement: CREATE FUNCTION add(a integer, b integer) RETURNS integer LANGUAGE SQL RETURN a + b; or as a block CREATE PROCEDURE insert_data(a integer, b integer) LANGUAGE SQL BEGIN ATOMIC INSERT INTO tbl VALUES (a); INSERT INTO tbl VALUES (b); END; The function body is parsed at function definition time and stored as expression nodes in a new pg_proc column prosqlbody. So at run time, no further parsing is required. However, this form does not support polymorphic arguments, because there is no more parse analysis done at call time. Dependencies between the function and the objects it uses are fully tracked. A new RETURN statement is introduced. This can only be used inside function bodies. Internally, it is treated much like a SELECT statement. psql needs some new intelligence to keep track of function body boundaries so that it doesn't send off statements when it sees semicolons that are inside a function body. Tested-by: Jaime Casanova <jcasanov@systemguards.com.ec> Reviewed-by: Julien Rouhaud <rjuju123@gmail.com> Discussion: https://www.postgresql.org/message-id/flat/1c11f1eb-f00c-43b7-799d-2d44132c02d7@2ndquadrant.com
4 years ago
END;
SELECT * FROM functest_sri2();
EXPLAIN (verbose, costs off) SELECT * FROM functest_sri2();
DROP TABLE functest3 CASCADE;
SQL-standard function body This adds support for writing CREATE FUNCTION and CREATE PROCEDURE statements for language SQL with a function body that conforms to the SQL standard and is portable to other implementations. Instead of the PostgreSQL-specific AS $$ string literal $$ syntax, this allows writing out the SQL statements making up the body unquoted, either as a single statement: CREATE FUNCTION add(a integer, b integer) RETURNS integer LANGUAGE SQL RETURN a + b; or as a block CREATE PROCEDURE insert_data(a integer, b integer) LANGUAGE SQL BEGIN ATOMIC INSERT INTO tbl VALUES (a); INSERT INTO tbl VALUES (b); END; The function body is parsed at function definition time and stored as expression nodes in a new pg_proc column prosqlbody. So at run time, no further parsing is required. However, this form does not support polymorphic arguments, because there is no more parse analysis done at call time. Dependencies between the function and the objects it uses are fully tracked. A new RETURN statement is introduced. This can only be used inside function bodies. Internally, it is treated much like a SELECT statement. psql needs some new intelligence to keep track of function body boundaries so that it doesn't send off statements when it sees semicolons that are inside a function body. Tested-by: Jaime Casanova <jcasanov@systemguards.com.ec> Reviewed-by: Julien Rouhaud <rjuju123@gmail.com> Discussion: https://www.postgresql.org/message-id/flat/1c11f1eb-f00c-43b7-799d-2d44132c02d7@2ndquadrant.com
4 years ago
-- Check behavior of VOID-returning SQL functions
CREATE FUNCTION voidtest1(a int) RETURNS VOID LANGUAGE SQL AS
$$ SELECT a + 1 $$;
SELECT voidtest1(42);
CREATE FUNCTION voidtest2(a int, b int) RETURNS VOID LANGUAGE SQL AS
$$ SELECT voidtest1(a + b) $$;
SELECT voidtest2(11,22);
-- currently, we can inline voidtest2 but not voidtest1
EXPLAIN (verbose, costs off) SELECT voidtest2(11,22);
CREATE TEMP TABLE sometable(f1 int);
CREATE FUNCTION voidtest3(a int) RETURNS VOID LANGUAGE SQL AS
$$ INSERT INTO sometable VALUES(a + 1) $$;
SELECT voidtest3(17);
CREATE FUNCTION voidtest4(a int) RETURNS VOID LANGUAGE SQL AS
$$ INSERT INTO sometable VALUES(a - 1) RETURNING f1 $$;
SELECT voidtest4(39);
TABLE sometable;
CREATE FUNCTION voidtest5(a int) RETURNS SETOF VOID LANGUAGE SQL AS
$$ SELECT generate_series(1, a) $$ STABLE;
SELECT * FROM voidtest5(3);
Change SQL-language functions to use the plan cache. In the historical implementation of SQL functions (if they don't get inlined), we built plans for all the contained queries at first call within an outer query, and then re-used those plans for the duration of the outer query, and then forgot everything. This was not ideal, not least because the plans could not be customized to specific values of the function's parameters. Our plancache infrastructure seems mature enough to be used here. That will solve both the problem with not being able to build custom plans and the problem with not being able to share work across successive outer queries. Aside from those performance concerns, this change fixes a longstanding bugaboo with SQL functions: you could not write DDL that would affect later statements in the same function. That's mostly still true with new-style SQL functions, since the results of parse analysis are baked into the stored query trees (and protected by dependency records). But for old-style SQL functions, it will now work much as it does with PL/pgSQL functions, because we delay parse analysis and planning of each query until we're ready to run it. Some edge cases that require replanning are now handled better too; see for example the new rowsecurity test, where we now detect an RLS context change that was previously missed. One other edge-case change that might be worthy of a release note is that we now insist that a SQL function's result be generated by the physically-last query within it. Previously, if the last original query was deleted by a DO INSTEAD NOTHING rule, we'd be willing to take the result from the preceding query instead. This behavior was undocumented except in source-code comments, and it seems hard to believe that anyone's relying on it. Along the way to this feature, we needed a few infrastructure changes: * The plancache can now take either a raw parse tree or an analyzed-but-not-rewritten Query as the starting point for a CachedPlanSource. If given a Query, it is caller's responsibility that nothing will happen to invalidate that form of the query. We use this for new-style SQL functions, where what's in pg_proc is serialized Query(s) and we trust the dependency mechanism to disallow DDL that would break those. * The plancache now offers a way to invoke a post-rewrite callback to examine/modify the rewritten parse tree when it is rebuilding the parse trees after a cache invalidation. We need this because SQL functions sometimes adjust the parse tree to make its output exactly match the declared result type; if the plan gets rebuilt, that has to be re-done. * There is a new backend module utils/cache/funccache.c that abstracts the idea of caching data about a specific function usage (a particular function and set of input data types). The code in it is moved almost verbatim from PL/pgSQL, which has done that for a long time. We use that logic now for SQL-language functions too, and maybe other PLs will have use for it in the future. Author: Alexander Pyhalov <a.pyhalov@postgrespro.ru> Co-authored-by: Tom Lane <tgl@sss.pgh.pa.us> Reviewed-by: Pavel Stehule <pavel.stehule@gmail.com> Discussion: https://postgr.es/m/8216639.NyiUUSuA9g@aivenlaptop
5 months ago
-- DDL within a SQL function can now affect later statements in the function;
-- though that doesn't work if check_function_bodies is on.
SET check_function_bodies TO off;
CREATE FUNCTION create_and_insert() RETURNS VOID LANGUAGE sql AS $$
create table ddl_test (f1 int);
insert into ddl_test values (1.2);
$$;
SELECT create_and_insert();
TABLE ddl_test;
CREATE FUNCTION alter_and_insert() RETURNS VOID LANGUAGE sql AS $$
alter table ddl_test alter column f1 type numeric;
insert into ddl_test values (1.2);
$$;
SELECT alter_and_insert();
TABLE ddl_test;
RESET check_function_bodies;
-- Regression tests for bugs:
-- Check that arguments that are R/W expanded datums aren't corrupted by
-- multiple uses. This test knows that array_append() returns a R/W datum
-- and will modify a R/W array input in-place. We use SETOF to prevent
-- inlining of the SQL function.
CREATE FUNCTION double_append(anyarray, anyelement) RETURNS SETOF anyarray
LANGUAGE SQL IMMUTABLE AS
$$ SELECT array_append($1, $2) || array_append($1, $2) $$;
SELECT double_append(array_append(ARRAY[q1], q2), q3)
FROM (VALUES(1,2,3), (4,5,6)) v(q1,q2,q3);
-- Check that we can re-use a SQLFunctionCache after a run-time error.
-- This function will fail with zero-divide at run time (not plan time).
CREATE FUNCTION part_hashint4_error(value int4, seed int8) RETURNS int8
LANGUAGE SQL STRICT IMMUTABLE PARALLEL SAFE AS
$$ SELECT value + seed + random()::int/0 $$;
-- Put it into an operator class so that FmgrInfo will be cached in relcache.
CREATE OPERATOR CLASS part_test_int4_ops_bad FOR TYPE int4 USING hash AS
FUNCTION 2 part_hashint4_error(int4, int8);
CREATE TABLE pt(i int) PARTITION BY hash (i part_test_int4_ops_bad);
CREATE TABLE p1 PARTITION OF pt FOR VALUES WITH (modulus 4, remainder 0);
INSERT INTO pt VALUES (1);
INSERT INTO pt VALUES (1);
-- Things that shouldn't work:
CREATE FUNCTION test1 (int) RETURNS int LANGUAGE SQL
AS 'SELECT ''not an integer'';';
CREATE FUNCTION test1 (int) RETURNS int LANGUAGE SQL
AS 'not even SQL';
CREATE FUNCTION test1 (int) RETURNS int LANGUAGE SQL
AS 'SELECT 1, 2, 3;';
CREATE FUNCTION test1 (int) RETURNS int LANGUAGE SQL
AS 'SELECT $2;';
CREATE FUNCTION test1 (int) RETURNS int LANGUAGE SQL
AS 'a', 'b';
CREATE FUNCTION test1 (int) RETURNS int LANGUAGE SQL
AS '';
-- make sure empty-body case is handled at execution time, too
SET check_function_bodies = off;
CREATE FUNCTION test1 (anyelement) RETURNS anyarray LANGUAGE SQL
AS '';
SELECT test1(0);
RESET check_function_bodies;
-- Cleanup
DROP SCHEMA temp_func_test CASCADE;
DROP USER regress_unpriv_user;
RESET search_path;