Skip to content

Commit

Permalink
sql: fix record-returning udfs when used as data source
Browse files Browse the repository at this point in the history
When record-returning UDFs (both implicit and `RECORD` return types) are
used as a data source in a query, the result should be treated as a row
with separate columns instead of a tuple, which is how UDF output is
normally treated. This PR closes this gap between CRDB and Postgres.

For example:

```
CREATE FUNCTION f() RETURNS RECORD AS
$$
  SELECT 1, 2, 3;
$$ LANGUAGE SQL

SELECT f()
    f
--------
 (1,2,3)

SELECT * FROM f() as foo(a int, b int, c int);
 a | b | c
---+---+---
 1 | 2 | 3
```

The behavior is the same for implicit record return types.

Epic: CRDB-19496
Fixes: cockroachdb#97059

Release note: None
  • Loading branch information
rharding6373 committed Mar 16, 2023
1 parent b88e0e5 commit be790d0
Show file tree
Hide file tree
Showing 13 changed files with 339 additions and 42 deletions.
172 changes: 167 additions & 5 deletions pkg/sql/logictest/testdata/logic_test/udf_record
Original file line number Diff line number Diff line change
Expand Up @@ -13,15 +13,13 @@ SELECT f_one();
----
(1)

# TODO(97059): The following query should require a column definition list.
statement ok
statement error pq: a column definition list is required for functions returning \"record\"
SELECT * FROM f_one();

# TODO(97059): The following query should produce a row, not a tuple.
query T
query I
SELECT * FROM f_one() AS foo (a INT);
----
(1)
1

statement ok
CREATE FUNCTION f_const() RETURNS RECORD AS
Expand Down Expand Up @@ -130,3 +128,167 @@ query T
SELECT f_table();
----
(1,5)

# subtest datasource

statement ok
CREATE FUNCTION f_tup() RETURNS RECORD AS
$$
SELECT ROW(1, 2, 3);
$$ LANGUAGE SQL;

query T
SELECT f_tup();
----
(1,2,3)

statement error pq: a column definition list is required for functions returning \"record\"
SELECT * FROM f_tup();

query III colnames
SELECT * FROM f_tup() as foo(a int, b int, c int);
----
a b c
1 2 3

statement ok
CREATE FUNCTION f_col() RETURNS RECORD AS
$$
SELECT 1, 2, 3;
$$ LANGUAGE SQL;

query T
SELECT f_col();
----
(1,2,3)

query III colnames
SELECT * FROM f_col() as foo(a int, b int, c int);
----
a b c
1 2 3

statement ok
CREATE TABLE t_imp (a INT PRIMARY KEY, b INT);
INSERT INTO t_imp VALUES (1, 10), (2, 4), (3, 32);

statement ok
CREATE FUNCTION f_imp() RETURNS t_imp AS
$$
SELECT * FROM t_imp ORDER BY a LIMIT 1;
$$ LANGUAGE SQL;

query II colnames
SELECT * FROM f_imp();
----
a b
1 10

statement ok
CREATE TYPE udt AS ENUM ('a', 'b', 'c');

statement ok
CREATE FUNCTION f_udt() RETURNS udt AS
$$
SELECT 'a'::udt;
$$ LANGUAGE SQL;

query T
SELECT * FROM f_udt();
----
a

statement ok
CREATE FUNCTION f_udt_record() RETURNS RECORD AS
$$
SELECT 'a'::udt;
$$ LANGUAGE SQL;

query T
SELECT * FROM f_udt() AS foo(u udt);
----
a

query II rowsort
SELECT * FROM f_setof() AS foo(a INT, b INT);
----
1 5
2 6
3 7

statement ok
CREATE FUNCTION f_setof_imp() RETURNS SETOF t_imp AS
$$
SELECT * FROM t_imp;
$$ LANGUAGE SQL;

query II rowsort
SELECT * FROM f_setof_imp()
----
1 10
2 4
3 32

statement ok
CREATE FUNCTION f_strict() RETURNS RECORD STRICT AS
$$
SELECT 1, 2, 3;
$$ LANGUAGE SQL;

query III
SELECT * FROM f_strict() AS foo(a INT, b INT, c INT);
----
1 2 3

statement ok
CREATE FUNCTION f_setof_strict() RETURNS SETOF RECORD STRICT AS
$$
SELECT * FROM t_imp;
$$ LANGUAGE SQL;

query II rowsort
SELECT * FROM f_setof_strict() AS foo(a INT, b INT);
----
1 10
2 4
3 32

statement ok
CREATE FUNCTION f_strict_arg(IN a INT, IN b INT) RETURNS RECORD STRICT AS
$$
SELECT a, b;
$$ LANGUAGE SQL;

query II colnames
SELECT * FROM f_strict_arg(1,2) AS foo(a INT, b INT);
----
a b
1 2

# TODO(harding): The result should be NULL NULL, one for each column,
# instead of NULL.
statement error pq: source "foo" has 1 columns available but 2 columns specified
SELECT * FROM f_strict_arg(NULL, 2) AS foo(a INT, b INT);

statement ok
CREATE FUNCTION f_strict_arg_setof(IN a INT, IN b INT) RETURNS SETOF RECORD STRICT AS
$$
SELECT a, b FROM generate_series(1,3);
$$ LANGUAGE SQL;

# Strict SETOF UDF with NULL input returns 0 rows.
query II colnames
SELECT * FROM f_strict_arg_setof(NULL,2) AS foo(a INT, b INT);
----
a b

statement ok
CREATE FUNCTION f_arg(IN a INT8, IN b INT8) RETURNS RECORD AS
$$
SELECT a, b;
$$ LANGUAGE SQL;

query II
SELECT * FROM f_arg(1,2) AS foo(a INT, b INT);
----
1 2
35 changes: 23 additions & 12 deletions pkg/sql/logictest/testdata/logic_test/udf_setof
Original file line number Diff line number Diff line change
Expand Up @@ -166,25 +166,36 @@ CREATE FUNCTION all_ab() RETURNS SETOF ab LANGUAGE SQL AS $$
SELECT a, b FROM ab
$$

# TODO(mgartner): This should return separate columns, not a tuple. See #97059.
query T rowsort
query II rowsort
SELECT * FROM all_ab()
----
(1,10)
(2,20)
(3,30)
(4,40)
1 10
2 20
3 30
4 40

statement ok
CREATE FUNCTION all_ab_tuple() RETURNS SETOF ab LANGUAGE SQL AS $$
SELECT (a, b) FROM ab
$$

# TODO(mgartner): This should return separate columns, not a tuple. See #97059.
query T rowsort
query II rowsort
SELECT * FROM all_ab_tuple()
----
1 10
2 20
3 30
4 40

statement ok
CREATE FUNCTION all_ab_record() RETURNS SETOF RECORD LANGUAGE SQL AS $$
SELECT a, b FROM ab
$$

query II rowsort
SELECT * FROM all_ab_tuple()
----
(1,10)
(2,20)
(3,30)
(4,40)
1 10
2 20
3 30
4 40
4 changes: 4 additions & 0 deletions pkg/sql/opt/exec/execbuilder/scalar.go
Original file line number Diff line number Diff line change
Expand Up @@ -669,6 +669,7 @@ func (b *Builder) buildExistsSubquery(
types.Bool,
false, /* enableStepping */
true, /* calledOnNullInput */
false, /* multiColOutput */
),
tree.DBoolFalse,
}, types.Bool), nil
Expand Down Expand Up @@ -753,6 +754,7 @@ func (b *Builder) buildSubquery(
subquery.Typ,
false, /* enableStepping */
true, /* calledOnNullInput */
false, /* multiColOutput */
), nil
}

Expand Down Expand Up @@ -809,6 +811,7 @@ func (b *Builder) buildSubquery(
subquery.Typ,
false, /* enableStepping */
true, /* calledOnNullInput */
false, /* multiColOutput */
), nil
}

Expand Down Expand Up @@ -891,6 +894,7 @@ func (b *Builder) buildUDF(ctx *buildScalarCtx, scalar opt.ScalarExpr) (tree.Typ
udf.Typ,
enableStepping,
udf.CalledOnNullInput,
udf.MultiColOutput,
), nil
}

Expand Down
3 changes: 3 additions & 0 deletions pkg/sql/opt/ops/scalar.opt
Original file line number Diff line number Diff line change
Expand Up @@ -1274,6 +1274,9 @@ define UDFPrivate {
# inputs are NULL. If false, the function will not be evaluated in the
# presence of NULL inputs, and will instead evaluate directly to NULL.
CalledOnNullInput bool

# MultiColOutput is true if the function may return multiple columns.
MultiColOutput bool
}

# KVOptions is a set of KVOptionItems that specify arbitrary keys and values
Expand Down
3 changes: 3 additions & 0 deletions pkg/sql/opt/optbuilder/builder.go
Original file line number Diff line number Diff line change
Expand Up @@ -133,6 +133,9 @@ type Builder struct {
// within.
insideUDF bool

// insideDataSource is true when we are processing a data source.
insideDataSource bool

// If set, we are collecting view dependencies in schemaDeps. This can only
// happen inside view/function definitions.
//
Expand Down
Loading

0 comments on commit be790d0

Please sign in to comment.