Skip to content

Commit

Permalink
sql: fix UDF with VOID return type
Browse files Browse the repository at this point in the history
Functions with VOID returns types should be allowed to produce any
number of columns of any type from their last statement. Prior to this
commit, a calling UDF with a VOID return type would error if the last
statement in the UDF did not produce a value of type VOID. This commit
fixes this minor bug.

Fixes #108297

Release note (bug fix): The last SQL statement in a user-defined
function with a VOID return type can now produce any number of columns
of any type. This bug was present since UDFs were introduced in version
22.2.
  • Loading branch information
mgartner committed Aug 7, 2023
1 parent cdf6d15 commit aab7109
Show file tree
Hide file tree
Showing 3 changed files with 106 additions and 2 deletions.
45 changes: 45 additions & 0 deletions pkg/sql/logictest/testdata/logic_test/udf_regressions
Original file line number Diff line number Diff line change
Expand Up @@ -580,3 +580,48 @@ statement error pgcode 22P02 invalid input value for enum e105259: "foo"
SELECT f()

subtest end


# Regression test for #108297. UDFs with VOID return types should succeed when
# the last statement returns columns of any type.
subtest regression_108297

statement ok
CREATE OR REPLACE FUNCTION f108297() RETURNS VOID LANGUAGE SQL AS 'SELECT 1'

query T
SELECT f108297()
----
NULL

statement ok
CREATE OR REPLACE FUNCTION f108297() RETURNS VOID LANGUAGE SQL AS $$
SELECT 1, 'foo', NULL
$$

query T
SELECT f108297()
----
NULL

statement ok
CREATE SEQUENCE s108297

statement ok
CREATE OR REPLACE FUNCTION f108297() RETURNS VOID LANGUAGE SQL AS $$
SELECT nextval('s108297')
$$

query T
SELECT f108297()
----
NULL

# Invoking the UDF above should have increment s108297 to 1, so calling nextval
# again should yield 2.
query I
SELECT nextval('s108297')
----
2

subtest end
18 changes: 18 additions & 0 deletions pkg/sql/opt/optbuilder/scalar.go
Original file line number Diff line number Diff line change
Expand Up @@ -24,6 +24,7 @@ import (
"github.com/cockroachdb/cockroach/pkg/sql/opt/props"
"github.com/cockroachdb/cockroach/pkg/sql/opt/props/physical"
"github.com/cockroachdb/cockroach/pkg/sql/parser"
"github.com/cockroachdb/cockroach/pkg/sql/parser/statements"
"github.com/cockroachdb/cockroach/pkg/sql/pgwire/pgcode"
"github.com/cockroachdb/cockroach/pkg/sql/pgwire/pgerror"
plpgsql "github.com/cockroachdb/cockroach/pkg/sql/plpgsql/parser"
Expand Down Expand Up @@ -728,6 +729,21 @@ func (b *Builder) buildUDF(
if err != nil {
panic(err)
}
// Add a VALUES (NULL) statement if the return type of the function is
// VOID. We cant simply project NULL from the last statement because all
// column would be pruned and the contents of last statement would not
// be executed.
// TODO(mgartner): This will add some planning overhead for every
// invocation of the function. Is there a more efficient way to do this?
if rtyp.Family() == types.VoidFamily {
stmts = append(stmts, statements.Statement[tree.Statement]{
AST: &tree.Select{
Select: &tree.ValuesClause{
Rows: []tree.Exprs{{tree.DNull}},
},
},
})
}
body = make([]memo.RelExpr, len(stmts))
bodyProps = make([]*physical.Required, len(stmts))

Expand All @@ -750,6 +766,8 @@ func (b *Builder) buildUDF(
if err != nil {
panic(err)
}
// TODO(#108298): Figure out how to handle PLpgSQL functions with VOID
// return types.
var plBuilder plpgsqlBuilder
plBuilder.init(b, colRefs, o.Types.(tree.ParamTypes), stmt.AST, rtyp)
stmtScope := plBuilder.build(stmt.AST, bodyScope)
Expand Down
45 changes: 43 additions & 2 deletions pkg/sql/opt/optbuilder/testdata/udf
Original file line number Diff line number Diff line change
Expand Up @@ -1031,6 +1031,47 @@ project
└── variable: s:2


# --------------------------------------------------
# UDFs with VOID return type.
# --------------------------------------------------

exec-ddl
CREATE FUNCTION retvoid(i INT) RETURNS VOID LANGUAGE SQL AS 'SELECT i'
----

build format=show-scalars
SELECT retvoid(1)
----
project
├── columns: retvoid:5
├── values
│ └── tuple
└── projections
└── udf: retvoid [as=retvoid:5]
├── args
│ └── const: 1
├── params: i:1
└── body
├── project
│ ├── columns: i:2
│ ├── values
│ │ └── tuple
│ └── projections
│ └── variable: i:1 [as=i:2]
└── project
├── columns: column4:4
├── limit
│ ├── columns: column1:3
│ ├── values
│ │ ├── columns: column1:3
│ │ └── tuple
│ │ └── null
│ └── const: 1
└── projections
└── assignment-cast: VOID [as=column4:4]
└── variable: column1:3


# --------------------------------------------------
# UDFs that are STRICT/RETURNS NULL ON NULL INPUT.
# --------------------------------------------------
Expand Down Expand Up @@ -1699,11 +1740,11 @@ build set=enable_multiple_modifications_of_table=true
SELECT upd_ups(1, 2, 3)
----
project
├── columns: upd_ups:27
├── columns: upd_ups:29
├── values
│ └── ()
└── projections
└── upd_ups(1, 2, 3) [as=upd_ups:27]
└── upd_ups(1, 2, 3) [as=upd_ups:29]

exec-ddl
CREATE FUNCTION ups2(a1 INT, b1 INT, c1 INT, a2 INT, b2 INT, c2 INT) RETURNS BOOL LANGUAGE SQL AS $$
Expand Down

0 comments on commit aab7109

Please sign in to comment.