Skip to content

Commit

Permalink
sql: support returning results from procedures with output parameters
Browse files Browse the repository at this point in the history
This commit teaches the execution to return a single row from procedures
with output parameters. Whenever a procedure has any output parameters,
it's expected to return a single tuple elements from which form the
result row of the procedure call. Additionally, this commit adjusts the
logic to skip evaluation of OUT argument expressions (to match
postgres) and ignore them from passing into the udf call.

It also extends the logic test framework a bit to add a mode that
asserts that the output of a query is empty (procedures with no output
parameters don't return any rows).

Release note (sql change): OUT and INOUT parameter classes are now
supported in stored procedures.
  • Loading branch information
yuzefovich committed Mar 23, 2024
1 parent 3ee65b4 commit 6406f4e
Show file tree
Hide file tree
Showing 8 changed files with 415 additions and 64 deletions.
143 changes: 140 additions & 3 deletions pkg/ccl/logictestccl/testdata/logic_test/procedure_params
Original file line number Diff line number Diff line change
Expand Up @@ -20,12 +20,30 @@ CALL p(1, 2, 3);
statement ok
CREATE PROCEDURE p(IN param1 FLOAT, OUT param2 FLOAT) AS $$ BEGIN SELECT param1 INTO param2; END; $$ LANGUAGE PLpgSQL;

query I colnames
CALL p(1, 2);
----
param2
1

query R colnames
CALL p(1.1, 2.2);
----
param2
1.1

statement error pgcode 42723 function "p" already exists with same argument types
CREATE PROCEDURE p(OUT param1 INT, IN param2 INT) AS $$ BEGIN SELECT param2 INTO param1; END; $$ LANGUAGE PLpgSQL;

statement ok
CREATE OR REPLACE PROCEDURE p(OUT param2 INT, IN param1 INT) AS $$ BEGIN SELECT param1 INTO param2; END; $$ LANGUAGE PLpgSQL;

query I colnames
CALL p(1, 2);
----
param2
2

statement error pgcode 42723 function "p" already exists with same argument types
CREATE PROCEDURE p(OUT param1 INT, IN param2 INT, OUT param3 INT) AS $$
BEGIN
Expand All @@ -36,6 +54,12 @@ END; $$ LANGUAGE PLpgSQL;
statement ok
CREATE PROCEDURE p(OUT param1 INT, IN param2 INT, IN param3 INT) AS $$ BEGIN SELECT param2 + param3 INTO param1; END; $$ LANGUAGE PLpgSQL;

query I colnames
CALL p(1, 2, 3);
----
param1
5

statement error pgcode 42723 function "p" already exists with same argument types
CREATE PROCEDURE p(INOUT param1 INT, IN param2 INT) AS $$ BEGIN SELECT param1 + param2 INTO param1; END; $$ LANGUAGE PLpgSQL;

Expand Down Expand Up @@ -68,6 +92,12 @@ DROP PROCEDURE p(INT, INT, INT);
statement ok
DROP PROCEDURE p(INT, INT);

query III colnames
CALL p(-1, -2, -3);
----
param1 param2 param3
1 2 3

statement ok
CREATE PROCEDURE p(OUT param1 INT, IN param2 INT, IN param3 INT) AS $$ BEGIN SELECT param2 + param3 INTO param1; END; $$ LANGUAGE PLpgSQL;

Expand All @@ -93,6 +123,35 @@ DROP PROCEDURE p;
statement ok
CREATE PROCEDURE p(OUT param INT) AS $$ BEGIN SELECT 1 INTO param; END $$ LANGUAGE PLpgSQL;

statement error pgcode 42883 procedure p\(\) does not exist
CALL p();

query I colnames
CALL p(NULL);
----
param
1

# Argument expressions for OUT parameters shouldn't be evaluated.
query I colnames
CALL p(1 // 0);
----
param
1

statement ok
DROP PROCEDURE p;

statement ok
CREATE PROCEDURE p(IN INT, INOUT INT) AS $$ BEGIN END $$ LANGUAGE PLpgSQL;

# Argument expressions for IN and INOUT parameters are evaluated.
statement error pgcode 22012 division by zero
CALL p(1 // 0, 1)

statement error pgcode 22012 division by zero
CALL p(1, 1 // 0)

statement ok
DROP PROCEDURE p;

Expand All @@ -104,6 +163,12 @@ BEGIN
SELECT 3 INTO param3;
END $$ LANGUAGE PLpgSQL;

query II colnames
CALL p(-1, -2, NULL);
----
param2 param3
2 3

statement ok
DROP PROCEDURE p;

Expand All @@ -128,7 +193,7 @@ DROP PROCEDURE p(OUT INT);
statement ok
CREATE PROCEDURE p(OUT param1 INT, OUT param2 INT) AS $$ BEGIN SELECT 1 INTO param2; END $$ LANGUAGE PLpgSQL;

statement error pq: procedure p\(int\) does not exist
statement error pgcode 42883 pq: procedure p\(int\) does not exist
DROP PROCEDURE p(INT);

statement ok
Expand Down Expand Up @@ -157,12 +222,29 @@ BEGIN
END
$$ LANGUAGE PLpgSQL;

query II colnames
CALL p(3, NULL);
----
param1 param2
3 2

query II noticetrace
CALL p(3, NULL);
----
NOTICE: 2

statement ok
DROP PROCEDURE p;

statement ok
CREATE PROCEDURE p(INOUT param1 INT, OUT param2 INT) AS $$ BEGIN SELECT 3 INTO param1; END $$ LANGUAGE PLpgSQL;

query II colnames
CALL p(1, NULL);
----
param1 param2
3 NULL

statement ok
CREATE OR REPLACE PROCEDURE p(INOUT param1 INT, OUT param2 INT) AS $$
BEGIN
Expand All @@ -174,6 +256,19 @@ BEGIN
END
$$ LANGUAGE PLpgSQL;

query II colnames
CALL p(1, NULL);
----
param1 param2
3 4

query II noticetrace
CALL p(1, NULL);
----
NOTICE: 1 <NULL>
NOTICE: 3 <NULL>
NOTICE: 3 4

statement ok
DROP PROCEDURE p;

Expand All @@ -185,6 +280,12 @@ BEGIN
END
$$ LANGUAGE PLpgSQL;

query II colnames
CALL p(3, NULL);
----
param1 param2
1 2

statement ok
DROP PROCEDURE p;

Expand Down Expand Up @@ -216,7 +317,7 @@ DROP PROCEDURE p(OUT INT);
statement ok
CREATE PROCEDURE p(OUT param1 INT, OUT param2 INT) AS $$ BEGIN SELECT 1 INTO param2; END $$ LANGUAGE PLpgSQL;

statement error pq: procedure p\(int\) does not exist
statement error pgcode 42883 pq: procedure p\(int\) does not exist
DROP PROCEDURE p(INT);

statement ok
Expand Down Expand Up @@ -296,6 +397,12 @@ CREATE PROCEDURE p_same_name(IN a INT, OUT a INT) AS $$ BEGIN RETURN a; END $$ L
statement ok
CREATE PROCEDURE p_names(IN param_in INT, OUT param_out INT) AS $$ BEGIN SELECT param_in INTO param_out; END $$ LANGUAGE PLpgSQL;

query I colnames
CALL p_names(1, NULL);
----
param_out
1

statement error pgcode 42601 RETURN cannot have a parameter in a procedure
CREATE PROCEDURE p_in_int(IN param INT) AS $$ BEGIN RETURN param; END; $$ LANGUAGE PLpgSQL;

Expand Down Expand Up @@ -347,6 +454,12 @@ subtest default_parameter_names
statement ok
CREATE PROCEDURE p_default_names(OUT INT, OUT param2 INT, IN INT, OUT INT) AS $$ BEGIN param2 = 2; END; $$ LANGUAGE PLpgSQL;

query III colnames
CALL p_default_names(NULL, NULL, 3, NULL);
----
column1 param2 column3
NULL 2 NULL

# However, attempting to access the parameter by the default names is invalid.
statement error pgcode 42601 pq: \"column1\" is not a known variable
CREATE OR REPLACE PROCEDURE p_default_names(OUT INT, OUT param2 INT, IN INT, OUT INT) AS $$ BEGIN SELECT 1 INTO column1; END; $$ LANGUAGE PLpgSQL;
Expand All @@ -371,6 +484,12 @@ CREATE PROCEDURE public.p_default_names(OUT INT8, OUT param2 INT8, IN INT8, OUT
END;
$$

query III colnames
CALL p_default_names(NULL, NULL, 3, NULL);
----
column1 param2 column3
NULL NULL 3

# Then we can omit the default OUT parameter name again (but still cannot use it
# in the body).
statement error pgcode 42601 pq: \"column3\" is not a known variable
Expand All @@ -390,6 +509,12 @@ CREATE PROCEDURE public.p_default_names(OUT INT8, OUT param2 INT8, IN INT8, OUT
END;
$$

query III colnames
CALL p_default_names(NULL, NULL, 3, NULL);
----
column1 param2 column3
NULL 2 NULL

# Introducing the IN parameter name is ok.
statement ok
CREATE OR REPLACE PROCEDURE p_default_names(OUT INT, OUT param2 INT, IN in_param INT, OUT INT) AS $$ BEGIN SELECT in_param INTO param2; END; $$ LANGUAGE PLpgSQL;
Expand All @@ -405,8 +530,14 @@ CREATE PROCEDURE public.p_default_names(OUT INT8, OUT param2 INT8, IN in_param I
END;
$$

query III colnames
CALL p_default_names(NULL, NULL, 3, NULL);
----
column1 param2 column3
NULL 3 NULL

# But then the IN parameter name cannot be changed anymore.
statement error cannot change name of input parameter "in_param"
statement error pgcode 42P13 cannot change name of input parameter "in_param"
CREATE OR REPLACE PROCEDURE p_default_names(OUT INT, OUT param2 INT, IN in_param_new INT, OUT INT) AS $$ BEGIN SELECT in_param_new INTO param2; END; $$ LANGUAGE PLpgSQL;

subtest end
Expand All @@ -416,3 +547,9 @@ CREATE TYPE typ AS (a INT, b INT);

statement ok
CREATE PROCEDURE p_udt(OUT param typ) AS $$ BEGIN param := (1, 2); END $$ LANGUAGE PLpgSQL;

query T colnames
CALL p_udt(NULL);
----
param
(1,2)
32 changes: 23 additions & 9 deletions pkg/sql/logictest/logic.go
Original file line number Diff line number Diff line change
Expand Up @@ -345,6 +345,9 @@ import (
// Runs the query that follows and expects an error
// that matches the given regexp.
//
// - query empty
// Runs the query that follows and verifies that no rows are produced.
//
// - awaitquery <name>
// Completes a pending query with the provided name, validating its
// results as expected per the given options to "query ... async ... <label>".
Expand Down Expand Up @@ -906,7 +909,9 @@ type logicQuery struct {
sorter logicSorter
// noSort is true if the nosort option was explicitly provided in the test.
noSort bool
// expectedErr and expectedErrCode are as in logicStatement.
// empty indicates whether the result is expected to be empty (i.e. 0 rows
// returned).
empty bool

// if set, the results are cross-checked against previous queries with the
// same label.
Expand Down Expand Up @@ -2665,14 +2670,19 @@ func (t *logicTest) processSubtest(
} else if len(fields) < 2 {
return errors.Errorf("%s: invalid test statement: %s", query.pos, s.Text())
} else {
// Parse "query <type-string> <options> <label>"
query.colTypes = fields[1]
if *Bigtest {
// bigtests put each expected value on its own line.
query.valsPerLine = 1
// Parse "query empty"
if len(fields) == 2 && fields[1] == "empty" {
query.empty = true
} else {
// Otherwise, expect number of values to match expected type count.
query.valsPerLine = len(query.colTypes)
// Parse "query <type-string> <options> <label>"
query.colTypes = fields[1]
if *Bigtest {
// bigtests put each expected value on its own line.
query.valsPerLine = 1
} else {
// Otherwise, expect number of values to match expected type count.
query.valsPerLine = len(query.colTypes)
}
}

if len(fields) >= 3 {
Expand Down Expand Up @@ -3581,7 +3591,7 @@ func (t *logicTest) finishExecQuery(query logicQuery, rows *gosql.Rows, err erro
if err != nil {
return err
}
if len(query.colTypes) != len(cols) {
if len(query.colTypes) != len(cols) && !query.empty {
return fmt.Errorf("%s: expected %d columns, but found %d",
query.pos, len(query.colTypes), len(cols))
}
Expand Down Expand Up @@ -3722,6 +3732,10 @@ func (t *logicTest) finishExecQuery(query logicQuery, rows *gosql.Rows, err erro
}
}

if query.empty && rowCount != 0 {
return errors.Newf("expected empty result, found %d rows\n%v", rowCount, actualResults)
}

if rowCount > 1 && !allDuplicateRows && query.sorter == nil && !query.noSort &&
!query.kvtrace && !orderRE.MatchString(query.sql) && !explainRE.MatchString(query.sql) &&
!showTraceRE.MatchString(query.sql) {
Expand Down

0 comments on commit 6406f4e

Please sign in to comment.