From 5189b3ba8ca15c357a10e20d4babb53f52002a8c Mon Sep 17 00:00:00 2001 From: rharding6373 Date: Thu, 4 May 2023 13:19:19 -0700 Subject: [PATCH] sql: add upsert tests for udfs This PR adds logic tests for UPSERTs in UDF bodies. Epic: CRDB-19255 Informs: #87289 Release note: None --- .../tests/3node-tenant/generated_test.go | 7 + .../logictest/testdata/logic_test/udf_insert | 4 +- .../logictest/testdata/logic_test/udf_upsert | 189 ++++++++++++++++++ .../tests/fakedist-disk/generated_test.go | 7 + .../tests/fakedist-vec-off/generated_test.go | 7 + .../tests/fakedist/generated_test.go | 7 + .../generated_test.go | 7 + .../local-mixed-22.2-23.1/generated_test.go | 7 + .../tests/local-vec-off/generated_test.go | 7 + .../logictest/tests/local/generated_test.go | 7 + pkg/sql/opt/optbuilder/create_function.go | 9 +- 11 files changed, 252 insertions(+), 6 deletions(-) create mode 100644 pkg/sql/logictest/testdata/logic_test/udf_upsert diff --git a/pkg/ccl/logictestccl/tests/3node-tenant/generated_test.go b/pkg/ccl/logictestccl/tests/3node-tenant/generated_test.go index b852e9a6c0f0..a52ba8d560ff 100644 --- a/pkg/ccl/logictestccl/tests/3node-tenant/generated_test.go +++ b/pkg/ccl/logictestccl/tests/3node-tenant/generated_test.go @@ -2145,6 +2145,13 @@ func TestTenantLogic_udf_update( runLogicTest(t, "udf_update") } +func TestTenantLogic_udf_upsert( + t *testing.T, +) { + defer leaktest.AfterTest(t)() + runLogicTest(t, "udf_upsert") +} + func TestTenantLogic_udf_volatility_check( t *testing.T, ) { diff --git a/pkg/sql/logictest/testdata/logic_test/udf_insert b/pkg/sql/logictest/testdata/logic_test/udf_insert index 145b8b8b6061..09f6e484e9bd 100644 --- a/pkg/sql/logictest/testdata/logic_test/udf_insert +++ b/pkg/sql/logictest/testdata/logic_test/udf_insert @@ -1,8 +1,8 @@ statement ok CREATE TABLE t (a INT PRIMARY KEY, b INT DEFAULT 0); -statement ok -CREATE FUNCTION f_should_err() RETURNS RECORD AS +statement error pq: return type mismatch in function declared to return record\nDETAIL: Function's final statement must be SELECT or INSERT/UPDATE/DELETE RETURNING. +CREATE FUNCTION f_err() RETURNS RECORD AS $$ INSERT INTO t VALUES (1,2); $$ LANGUAGE SQL; diff --git a/pkg/sql/logictest/testdata/logic_test/udf_upsert b/pkg/sql/logictest/testdata/logic_test/udf_upsert new file mode 100644 index 000000000000..2adc557446b5 --- /dev/null +++ b/pkg/sql/logictest/testdata/logic_test/udf_upsert @@ -0,0 +1,189 @@ +subtest on_conflict_do_nothing + +statement ok +CREATE TABLE t_ocdn (a INT PRIMARY KEY, b INT UNIQUE, c INT); + +statement ok +CREATE FUNCTION f_ocdn(i INT, j INT, k INT) RETURNS RECORD AS +$$ + INSERT INTO t_ocdn VALUES (i, j, k) ON CONFLICT DO NOTHING RETURNING *; +$$ LANGUAGE SQL; + +query T +SELECT f_ocdn(1,1,1); +---- +(1,1,1) + +query T +SELECT f_ocdn(1,1,1); +---- +NULL + +query T +SELECT f_ocdn(2,1,1); +---- +NULL + +query T +SELECT f_ocdn(1,2,1); +---- +NULL + +statement error pq: multiple modification subqueries of the same table \"t_ocdn\" are not supported +SELECT f_ocdn(1,1,1), f_ocdn(3,2,2), f_ocdn(6,6,2), f_ocdn(2,1,1); + +statement ok +CREATE FUNCTION f_ocdn_2vals(i INT, j INT, k INT, m INT, n INT, o INT) RETURNS RECORD AS +$$ + INSERT INTO t_ocdn VALUES (i, j, k), (m,n,o) ON CONFLICT DO NOTHING RETURNING *; +$$ LANGUAGE SQL; + +statement ok +SELECT f_ocdn_2vals(5,5,5,5,5,5); + +query III +SELECT * FROM t_ocdn; +---- +1 1 1 +5 5 5 + +statement error pq: multiple modification subqueries of the same table \"t_ocdn\" are not supported +CREATE FUNCTION f_err(i INT, j INT, k INT, m INT, n INT, o INT) RETURNS RECORD AS +$$ + INSERT INTO t_ocdn VALUES (i, j, k) ON CONFLICT DO NOTHING; + INSERT INTO t_ocdn VALUES (m, n, o) ON CONFLICT DO NOTHING; + SELECT * FROM t_ocdn WHERE t.a=i OR t.a=m; +$$ LANGUAGE SQL; + +subtest on_conflict_do_update + +statement ok +CREATE TABLE t_ocdu (a INT PRIMARY KEY, b INT UNIQUE, c INT); + +statement ok +CREATE FUNCTION f_ocdu(i INT, j INT, k INT) RETURNS RECORD AS +$$ + INSERT INTO t_ocdu VALUES (i, j, k) ON CONFLICT (a) DO UPDATE SET b = j, c = t_ocdu.c + 1 RETURNING *; +$$ LANGUAGE SQL; + +query T +SELECT f_ocdu(1,1,1); +---- +(1,1,1) + +query T +SELECT f_ocdu(1,1,8); +---- +(1,1,2) + +query T +SELECT f_ocdu(1,4,6); +---- +(1,4,3) + +statement error pq: duplicate key value violates unique constraint \"t_ocdu_b_key\" +SELECT f_ocdu(2,4,6); + + +subtest upsert + +statement ok +CREATE TABLE t_upsert (a INT PRIMARY KEY, b INT); + + +statement ok +CREATE FUNCTION f_upsert(i INT, j INT) RETURNS RECORD AS +$$ + UPSERT INTO t_upsert VALUES (i, j) RETURNING *; +$$ LANGUAGE SQL; + +query T +SELECT f_upsert(1,1); +---- +(1,1) + +query T +SELECT f_upsert(1,4); +---- +(1,4) + +statement ok +CREATE FUNCTION f_upsert_2vals(i INT, j INT, m INT, n INT) RETURNS SETOF RECORD AS +$$ + UPSERT INTO t_upsert VALUES (i, j), (m, n) RETURNING *; +$$ LANGUAGE SQL; + +query T +SELECT f_upsert_2vals(1,9,2,8); +---- +(1,9) +(2,8) + + +subtest constraints + +statement ok +CREATE TABLE t_check1(a INT NULL CHECK(a IS NOT NULL), b CHAR(4) CHECK(length(b) < 4)); + +statement ok +CREATE FUNCTION f_check_null() RETURNS RECORD AS +$$ + UPSERT INTO t_check1(a) VALUES (NULL) RETURNING *; +$$ LANGUAGE SQL; + +statement error failed to satisfy CHECK constraint +SELECT f_check_null(); + +statement ok +CREATE FUNCTION f_check_len() RETURNS RECORD AS +$$ + UPSERT INTO t_check1(b) VALUES ('abcd') RETURNING *; +$$ LANGUAGE SQL; + +statement error failed to satisfy CHECK constraint +SELECT f_check_len() + +statement ok +CREATE FUNCTION f_check_vals(i INT, j CHAR(4)) RETURNS RECORD AS +$$ + UPSERT INTO t_check1(b,a) VALUES (j,i) RETURNING *; +$$ LANGUAGE SQL; + +statement error failed to satisfy CHECK constraint +SELECT f_check_vals(NULL, 'ab'); + +statement error failed to satisfy CHECK constraint +SELECT f_check_vals(3, 'abcd'); + +statement ok +CREATE TABLE t_check2(a INT NOT NULL CHECK(a IS NOT NULL), b CHAR(3) CHECK(length(b) < 4)); + +statement ok +CREATE FUNCTION f_check_colerr_null() RETURNS RECORD AS +$$ + UPSERT INTO t_check2(a) VALUES (NULL) RETURNING *; +$$ LANGUAGE SQL; + +statement error null value in column "a" violates not-null constraint +SELECT f_check_colerr_null(); + +statement ok +CREATE FUNCTION f_check_colerr_len() RETURNS RECORD AS +$$ + UPSERT INTO t_check2(b) VALUES ('abcd') RETURNING *; +$$ LANGUAGE SQL; + +statement error value too long for type CHAR\(3\) +SELECT f_check_colerr_len() + +statement ok +CREATE FUNCTION f_check_colerr_vals(i INT, j CHAR(4)) RETURNS RECORD AS +$$ + UPSERT INTO t_check2(a,b) VALUES (i,j) RETURNING *; +$$ LANGUAGE SQL; + +statement error null value in column "a" violates not-null constraint +SELECT f_check_colerr_vals(NULL, 'ab') + +statement error value too long for type CHAR\(3\) +SELECT f_check_colerr_vals(NULL, 'abcd') diff --git a/pkg/sql/logictest/tests/fakedist-disk/generated_test.go b/pkg/sql/logictest/tests/fakedist-disk/generated_test.go index fe48285c96f7..4866f9fc5d9a 100644 --- a/pkg/sql/logictest/tests/fakedist-disk/generated_test.go +++ b/pkg/sql/logictest/tests/fakedist-disk/generated_test.go @@ -2109,6 +2109,13 @@ func TestLogic_udf_update( runLogicTest(t, "udf_update") } +func TestLogic_udf_upsert( + t *testing.T, +) { + defer leaktest.AfterTest(t)() + runLogicTest(t, "udf_upsert") +} + func TestLogic_udf_volatility_check( t *testing.T, ) { diff --git a/pkg/sql/logictest/tests/fakedist-vec-off/generated_test.go b/pkg/sql/logictest/tests/fakedist-vec-off/generated_test.go index c87e38f41fb4..cbd116f0b8d9 100644 --- a/pkg/sql/logictest/tests/fakedist-vec-off/generated_test.go +++ b/pkg/sql/logictest/tests/fakedist-vec-off/generated_test.go @@ -2116,6 +2116,13 @@ func TestLogic_udf_update( runLogicTest(t, "udf_update") } +func TestLogic_udf_upsert( + t *testing.T, +) { + defer leaktest.AfterTest(t)() + runLogicTest(t, "udf_upsert") +} + func TestLogic_udf_volatility_check( t *testing.T, ) { diff --git a/pkg/sql/logictest/tests/fakedist/generated_test.go b/pkg/sql/logictest/tests/fakedist/generated_test.go index 84624d198aa8..5f27762cc964 100644 --- a/pkg/sql/logictest/tests/fakedist/generated_test.go +++ b/pkg/sql/logictest/tests/fakedist/generated_test.go @@ -2130,6 +2130,13 @@ func TestLogic_udf_update( runLogicTest(t, "udf_update") } +func TestLogic_udf_upsert( + t *testing.T, +) { + defer leaktest.AfterTest(t)() + runLogicTest(t, "udf_upsert") +} + func TestLogic_udf_volatility_check( t *testing.T, ) { diff --git a/pkg/sql/logictest/tests/local-legacy-schema-changer/generated_test.go b/pkg/sql/logictest/tests/local-legacy-schema-changer/generated_test.go index 4669d9e17134..8b2247d82e89 100644 --- a/pkg/sql/logictest/tests/local-legacy-schema-changer/generated_test.go +++ b/pkg/sql/logictest/tests/local-legacy-schema-changer/generated_test.go @@ -2102,6 +2102,13 @@ func TestLogic_udf_update( runLogicTest(t, "udf_update") } +func TestLogic_udf_upsert( + t *testing.T, +) { + defer leaktest.AfterTest(t)() + runLogicTest(t, "udf_upsert") +} + func TestLogic_udf_volatility_check( t *testing.T, ) { diff --git a/pkg/sql/logictest/tests/local-mixed-22.2-23.1/generated_test.go b/pkg/sql/logictest/tests/local-mixed-22.2-23.1/generated_test.go index 85862347a08a..0f83bea8b9ed 100644 --- a/pkg/sql/logictest/tests/local-mixed-22.2-23.1/generated_test.go +++ b/pkg/sql/logictest/tests/local-mixed-22.2-23.1/generated_test.go @@ -2067,6 +2067,13 @@ func TestLogic_udf_update( runLogicTest(t, "udf_update") } +func TestLogic_udf_upsert( + t *testing.T, +) { + defer leaktest.AfterTest(t)() + runLogicTest(t, "udf_upsert") +} + func TestLogic_udf_volatility_check( t *testing.T, ) { diff --git a/pkg/sql/logictest/tests/local-vec-off/generated_test.go b/pkg/sql/logictest/tests/local-vec-off/generated_test.go index bfa265f35e40..0f3faedf8c9b 100644 --- a/pkg/sql/logictest/tests/local-vec-off/generated_test.go +++ b/pkg/sql/logictest/tests/local-vec-off/generated_test.go @@ -2130,6 +2130,13 @@ func TestLogic_udf_update( runLogicTest(t, "udf_update") } +func TestLogic_udf_upsert( + t *testing.T, +) { + defer leaktest.AfterTest(t)() + runLogicTest(t, "udf_upsert") +} + func TestLogic_udf_volatility_check( t *testing.T, ) { diff --git a/pkg/sql/logictest/tests/local/generated_test.go b/pkg/sql/logictest/tests/local/generated_test.go index 202b05902cda..cfbecac6f6f3 100644 --- a/pkg/sql/logictest/tests/local/generated_test.go +++ b/pkg/sql/logictest/tests/local/generated_test.go @@ -2326,6 +2326,13 @@ func TestLogic_udf_update( runLogicTest(t, "udf_update") } +func TestLogic_udf_upsert( + t *testing.T, +) { + defer leaktest.AfterTest(t)() + runLogicTest(t, "udf_upsert") +} + func TestLogic_udf_volatility_check( t *testing.T, ) { diff --git a/pkg/sql/opt/optbuilder/create_function.go b/pkg/sql/opt/optbuilder/create_function.go index af5df96de26d..72697c5e6fbf 100644 --- a/pkg/sql/opt/optbuilder/create_function.go +++ b/pkg/sql/opt/optbuilder/create_function.go @@ -239,10 +239,6 @@ func validateReturnType(expected *types.T, cols []scopeColumn) error { if expected.Equivalent(types.Void) { return nil } - // If return type is RECORD, any column types are valid. - if types.IsRecordType(expected) { - return nil - } if len(cols) == 0 { return pgerror.WithCandidateCode( @@ -254,6 +250,11 @@ func validateReturnType(expected *types.T, cols []scopeColumn) error { ) } + // If return type is RECORD, any column types are valid. + if types.IsRecordType(expected) { + return nil + } + if len(cols) == 1 { if !expected.Equivalent(cols[0].typ) && !cast.ValidCast(cols[0].typ, expected, cast.ContextAssignment) {