Skip to content

Commit

Permalink
Copy PL/pgSQL regression tests in Makefile
Browse files Browse the repository at this point in the history
  • Loading branch information
msepga committed Oct 31, 2024
1 parent 0c69451 commit 7fb9821
Show file tree
Hide file tree
Showing 10 changed files with 338 additions and 3 deletions.
2 changes: 2 additions & 0 deletions Makefile
Original file line number Diff line number Diff line change
Expand Up @@ -171,7 +171,9 @@ extract_source: $(PGDIR)
sed -i "" '$(shell echo 's/\#define PG_VERSION_NUM .*/#define PG_VERSION_NUM $(PG_VERSION_NUM)/')' pg_query.h
# Copy regress SQL files so we can use them in tests
rm -f ./test/sql/postgres_regress/*.sql
rm -f ./test/sql/plpgsql_regress/*.sql
cp $(PGDIR)/src/test/regress/sql/*.sql ./test/sql/postgres_regress/
cp $(PGDIR)/src/pl/plpgsql/src/sql/*.sql ./test/sql/plpgsql_regress/

.c.o:
@$(ECHO) compiling $(<)
Expand Down
2 changes: 2 additions & 0 deletions test/deparse.c
Original file line number Diff line number Diff line change
Expand Up @@ -417,7 +417,9 @@ const char* plpgsqlRegressFilenames[] =
"plpgsql_cache.sql",
"plpgsql_call.sql",
"plpgsql_control.sql",
"plpgsql_copy.sql",
"plpgsql_domain.sql",
"plpgsql_misc.sql",
"plpgsql_record.sql",
"plpgsql_simple.sql",
"plpgsql_transaction.sql",
Expand Down
148 changes: 148 additions & 0 deletions test/sql/plpgsql_regress/plpgsql_call.sql
Original file line number Diff line number Diff line change
Expand Up @@ -38,6 +38,24 @@ CALL test_proc3(55);
SELECT * FROM test1;


-- Check that plan revalidation doesn't prevent setting transaction properties
-- (bug #18059). This test must include the first temp-object creation in
-- this script, or it won't exercise the bug scenario. Hence we put it early.
CREATE PROCEDURE test_proc3a()
LANGUAGE plpgsql
AS $$
BEGIN
COMMIT;
SET TRANSACTION ISOLATION LEVEL REPEATABLE READ;
RAISE NOTICE 'done';
END;
$$;

CALL test_proc3a();
CREATE TEMP TABLE tt1(f1 int);
CALL test_proc3a();


-- nested CALL
TRUNCATE TABLE test1;

Expand Down Expand Up @@ -112,6 +130,18 @@ END;
$$;


DO
LANGUAGE plpgsql
$$
DECLARE
x constant int := 3;
y int := 4;
BEGIN
CALL test_proc6(2, x, y); -- error because x is constant
END;
$$;


DO
LANGUAGE plpgsql
$$
Expand Down Expand Up @@ -345,6 +375,36 @@ BEGIN
END
$$;

-- polymorphic OUT arguments

CREATE PROCEDURE test_proc12(a anyelement, OUT b anyelement, OUT c anyarray)
LANGUAGE plpgsql
AS $$
BEGIN
RAISE NOTICE 'a: %', a;
b := a;
c := array[a];
END;
$$;

DO $$
DECLARE _a int; _b int; _c int[];
BEGIN
_a := 10;
CALL test_proc12(_a, _b, _c);
RAISE NOTICE '_a: %, _b: %, _c: %', _a, _b, _c;
END
$$;

DO $$
DECLARE _a int; _b int; _c text[];
BEGIN
_a := 10;
CALL test_proc12(_a, _b, _c); -- error
RAISE NOTICE '_a: %, _b: %, _c: %', _a, _b, _c;
END
$$;


-- transition variable assignment

Expand Down Expand Up @@ -424,3 +484,91 @@ BEGIN
RAISE NOTICE '%', v_Text;
END;
$$;


-- check that we detect change of dependencies in CALL
-- atomic and non-atomic call sites used to do this differently, so check both

CREATE PROCEDURE inner_p (f1 int)
AS $$
BEGIN
RAISE NOTICE 'inner_p(%)', f1;
END
$$ LANGUAGE plpgsql;

CREATE FUNCTION f(int) RETURNS int AS $$ SELECT $1 + 1 $$ LANGUAGE sql;

CREATE PROCEDURE outer_p (f1 int)
AS $$
BEGIN
RAISE NOTICE 'outer_p(%)', f1;
CALL inner_p(f(f1));
END
$$ LANGUAGE plpgsql;

CREATE FUNCTION outer_f (f1 int) RETURNS void
AS $$
BEGIN
RAISE NOTICE 'outer_f(%)', f1;
CALL inner_p(f(f1));
END
$$ LANGUAGE plpgsql;

CALL outer_p(42);
SELECT outer_f(42);

DROP FUNCTION f(int);
CREATE FUNCTION f(int) RETURNS int AS $$ SELECT $1 + 2 $$ LANGUAGE sql;

CALL outer_p(42);
SELECT outer_f(42);

-- Check that stable functions in CALL see the correct snapshot

CREATE TABLE t_test (x int);
INSERT INTO t_test VALUES (0);

CREATE FUNCTION f_get_x () RETURNS int
AS $$
DECLARE l_result int;
BEGIN
SELECT x INTO l_result FROM t_test;
RETURN l_result;
END
$$ LANGUAGE plpgsql STABLE;

CREATE PROCEDURE f_print_x (x int)
AS $$
BEGIN
RAISE NOTICE 'f_print_x(%)', x;
END
$$ LANGUAGE plpgsql;

-- test in non-atomic context
DO $$
BEGIN
UPDATE t_test SET x = x + 1;
RAISE NOTICE 'f_get_x(%)', f_get_x();
CALL f_print_x(f_get_x());
UPDATE t_test SET x = x + 1;
RAISE NOTICE 'f_get_x(%)', f_get_x();
CALL f_print_x(f_get_x());
ROLLBACK;
END
$$;

-- test in atomic context
BEGIN;

DO $$
BEGIN
UPDATE t_test SET x = x + 1;
RAISE NOTICE 'f_get_x(%)', f_get_x();
CALL f_print_x(f_get_x());
UPDATE t_test SET x = x + 1;
RAISE NOTICE 'f_get_x(%)', f_get_x();
CALL f_print_x(f_get_x());
END
$$;

ROLLBACK;
14 changes: 14 additions & 0 deletions test/sql/plpgsql_regress/plpgsql_control.sql
Original file line number Diff line number Diff line change
Expand Up @@ -486,3 +486,17 @@ select case_test(1);
select case_test(2);
select case_test(12);
select case_test(13);

-- test line comment between WHEN and THEN
create or replace function case_comment(int) returns text as $$
begin
case $1
when 1 -- comment before THEN
then return 'one';
else
return 'other';
end case;
end;
$$ language plpgsql immutable;

select case_comment(1);
58 changes: 58 additions & 0 deletions test/sql/plpgsql_regress/plpgsql_copy.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,58 @@
-- directory paths are passed to us in environment variables
\getenv abs_srcdir PG_ABS_SRCDIR
\getenv abs_builddir PG_ABS_BUILDDIR

-- set up file names to use
\set srcfilename :abs_srcdir '/data/copy1.data'
\set destfilename :abs_builddir '/results/copy1.data'

CREATE TABLE copy1 (a int, b float);

-- COPY TO/FROM not authorized from client.
DO LANGUAGE plpgsql $$
BEGIN
COPY copy1 TO stdout;
END;
$$;
DO LANGUAGE plpgsql $$
BEGIN
COPY copy1 FROM stdin;
END;
$$;
DO LANGUAGE plpgsql $$
BEGIN
EXECUTE 'COPY copy1 TO stdout';
END;
$$;
DO LANGUAGE plpgsql $$
BEGIN
EXECUTE 'COPY copy1 FROM stdin';
END;
$$;

-- Valid cases
-- COPY FROM
\set dobody 'BEGIN COPY copy1 FROM ' :'srcfilename' '; END'
DO LANGUAGE plpgsql :'dobody';
SELECT * FROM copy1 ORDER BY 1;
TRUNCATE copy1;
\set cmd 'COPY copy1 FROM ' :'srcfilename'
\set dobody 'BEGIN EXECUTE ' :'cmd' '; END'
DO LANGUAGE plpgsql :'dobody';
SELECT * FROM copy1 ORDER BY 1;

-- COPY TO
-- Copy the data externally once, then process it back to the table.
\set dobody 'BEGIN COPY copy1 TO ' :'destfilename' '; END'
DO LANGUAGE plpgsql :'dobody';
TRUNCATE copy1;
\set dobody 'BEGIN COPY copy1 FROM ' :'destfilename' '; END'
DO LANGUAGE plpgsql :'dobody';

\set cmd 'COPY copy1 FROM ' :'destfilename'
\set dobody 'BEGIN EXECUTE ' :'cmd' '; END'
DO LANGUAGE plpgsql :'dobody';

SELECT * FROM copy1 ORDER BY 1;

DROP TABLE copy1;
39 changes: 39 additions & 0 deletions test/sql/plpgsql_regress/plpgsql_misc.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,39 @@
--
-- Miscellaneous topics
--

-- Verify that we can parse new-style CREATE FUNCTION/PROCEDURE
do
$$
declare procedure int; -- check we still recognize non-keywords as vars
begin
create function test1() returns int
begin atomic
select 2 + 2;
end;
create or replace procedure test2(x int)
begin atomic
select x + 2;
end;
end
$$;

\sf test1
\sf test2

-- Test %TYPE and %ROWTYPE error cases
create table misc_table(f1 int);

do $$ declare x foo%type; begin end $$;
do $$ declare x notice%type; begin end $$; -- covers unreserved-keyword case
do $$ declare x foo.bar%type; begin end $$;
do $$ declare x foo.bar.baz%type; begin end $$;
do $$ declare x public.foo.bar%type; begin end $$;
do $$ declare x public.misc_table.zed%type; begin end $$;

do $$ declare x foo%rowtype; begin end $$;
do $$ declare x notice%rowtype; begin end $$; -- covers unreserved-keyword case
do $$ declare x foo.bar%rowtype; begin end $$;
do $$ declare x foo.bar.baz%rowtype; begin end $$;
do $$ declare x public.foo%rowtype; begin end $$;
do $$ declare x public.misc_table%rowtype; begin end $$;
51 changes: 51 additions & 0 deletions test/sql/plpgsql_regress/plpgsql_record.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,6 +3,7 @@
--

create type two_int4s as (f1 int4, f2 int4);
create type more_int4s as (f0 text, f1 int4, f2 int4);
create type two_int8s as (q1 int8, q2 int8);
create type nested_int8s as (c1 two_int8s, c2 two_int8s);

Expand Down Expand Up @@ -198,6 +199,46 @@ begin
raise notice 'r1.nosuchfield = %', r1.nosuchfield;
end$$;

-- check %type with block-qualified variable names
do $$
<<blk>>
declare
v int;
r two_int8s;
v1 v%type;
v2 blk.v%type;
r1 r%type;
r2 blk.r%type;
begin
raise notice '%', pg_typeof(v1);
raise notice '%', pg_typeof(v2);
raise notice '%', pg_typeof(r1);
raise notice '%', pg_typeof(r2);
end$$;

-- check that type record can be passed through %type
do $$
declare r1 record;
r2 r1%type;
begin
r2 := row(1,2);
raise notice 'r2 = %', r2;
r2 := row(3,4,5);
raise notice 'r2 = %', r2;
end$$;

-- arrays of record are not supported at the moment
do $$
declare r1 record[];
begin
end$$;

do $$
declare r1 record;
r2 r1%type[];
begin
end$$;

-- check repeated assignments to composite fields
create table some_table (id int, data text);

Expand Down Expand Up @@ -257,13 +298,23 @@ create function getf1(x record) returns int language plpgsql as
$$ begin return x.f1; end $$;
select getf1(1);
select getf1(row(1,2));
select getf1(row(1,2)::two_int4s);
select getf1(row('foo',123,456)::more_int4s);
-- the context stack is different when debug_discard_caches
-- is set, so suppress context output
\set SHOW_CONTEXT never
select getf1(row(1,2)::two_int8s);
\set SHOW_CONTEXT errors
select getf1(row(1,2));

-- this seemingly-equivalent case behaves a bit differently,
-- because the core parser's handling of $N symbols is simplistic
create function getf2(record) returns int language plpgsql as
$$ begin return $1.f2; end $$;
select getf2(row(1,2)); -- ideally would work, but does not
select getf2(row(1,2)::two_int4s);
select getf2(row('foo',123,456)::more_int4s);

-- check behavior when assignment to FOR-loop variable requires coercion
do $$
declare r two_int8s;
Expand Down
Loading

0 comments on commit 7fb9821

Please sign in to comment.