Skip to content

Commit

Permalink
opt: resolve TupleStars in UDFs and views
Browse files Browse the repository at this point in the history
Star expressions have been allowed in UDFs since cockroachdb#95710 and in views
since cockroachdb#97515. This commit lifts a restriction that prevented table
references from being resolved as TupleStars in SELECT lists inside UDFs
and views. For example, an expression like `SELECT tbl FROM tbl` is now
allowed inside views and UDFs.

Fixes cockroachdb#104927

Release note (sql change): Table names are now allowed in SELECT lists
inside view and UDF definitions.
  • Loading branch information
mgartner committed Jun 15, 2023
1 parent ae25f4d commit afa92a0
Show file tree
Hide file tree
Showing 4 changed files with 83 additions and 24 deletions.
62 changes: 48 additions & 14 deletions pkg/sql/logictest/testdata/logic_test/udf
Original file line number Diff line number Diff line change
Expand Up @@ -2464,16 +2464,15 @@ SELECT imp(), (1,2,'a')::imp = imp(), pg_typeof(imp())
----
(1,2,a) true imp

# TODO(#90080): Allow star expressions in UDFs.
# statement ok
# CREATE FUNCTION imp_star() RETURNS imp LANGUAGE SQL AS $$
# SELECT * FROM imp
# $$
#
# query TBT
# SELECT imp_star(), (1,2,'a')::imp = imp_star(), pg_typeof(imp_star())
# ----
# (1,2,a) true imp
statement ok
CREATE FUNCTION imp_star() RETURNS imp LANGUAGE SQL AS $$
SELECT * FROM imp
$$

query TBT
SELECT imp_star(), (1,2,'a')::imp = imp_star(), pg_typeof(imp_star())
----
(1,2,a) true imp

statement ok
INSERT INTO imp VALUES (100, 200, 'z')
Expand Down Expand Up @@ -3087,10 +3086,10 @@ SELECT oid, proname, pronamespace, proowner, prolang, proleakproof, proisstrict,
FROM pg_catalog.pg_proc WHERE proname IN ('f_93314', 'f_93314_alias', 'f_93314_comp', 'f_93314_comp_t')
ORDER BY oid;
----
100272 f_93314 105 1546506610 14 false false false v 0 100271 · {} NULL SELECT i, e FROM test.public.t_93314 ORDER BY i LIMIT 1;
100274 f_93314_alias 105 1546506610 14 false false false v 0 100273 · {} NULL SELECT i, e FROM test.public.t_93314_alias ORDER BY i LIMIT 1;
100278 f_93314_comp 105 1546506610 14 false false false v 0 100275 · {} NULL SELECT (1, 2);
100279 f_93314_comp_t 105 1546506610 14 false false false v 0 100277 · {} NULL SELECT a, c FROM test.public.t_93314_comp LIMIT 1;
100273 f_93314 105 1546506610 14 false false false v 0 100272 · {} NULL SELECT i, e FROM test.public.t_93314 ORDER BY i LIMIT 1;
100275 f_93314_alias 105 1546506610 14 false false false v 0 100274 · {} NULL SELECT i, e FROM test.public.t_93314_alias ORDER BY i LIMIT 1;
100279 f_93314_comp 105 1546506610 14 false false false v 0 100276 · {} NULL SELECT (1, 2);
100280 f_93314_comp_t 105 1546506610 14 false false false v 0 100278 · {} NULL SELECT a, c FROM test.public.t_93314_comp LIMIT 1;

# Regression test for #95240. Strict UDFs that are inlined should result in NULL
# when presented with NULL arguments.
Expand Down Expand Up @@ -3459,6 +3458,8 @@ $func$;
# Regression test for #100915. Do not error when attempting to inline a UDF when
# it has a subquery argument that corresponds to a parameter that is referenced
# multiple times in the UDF body.
subtest regression_100915

statement ok
CREATE FUNCTION f100915(i INT) RETURNS BOOL STABLE LANGUAGE SQL AS $$
SELECT i = 0 OR i = 10
Expand Down Expand Up @@ -3532,3 +3533,36 @@ SELECT schema_name FROM [SHOW SCHEMAS] WHERE schema_name LIKE 'pg_temp_%';

statement error pgcode 0A000 unimplemented: cannot create UDFs under a temporary schema
CREATE FUNCTION $temp_schema_102964.f_102964 () RETURNS INT AS 'SELECT 1' LANGUAGE sql;

# Regression test for #104927. Correctly resolve table references in UDFs as
# TupleStars.
subtest regression_104927

statement ok
CREATE TABLE t104927 (
i INT,
s STRING
);
INSERT INTO t104927 VALUES (1, 'foo');

query T
SELECT json_agg(r) FROM (
SELECT i, s
FROM t104927
) AS r
----
[{"i": 1, "s": "foo"}]

statement ok
CREATE FUNCTION f104927() RETURNS TEXT LANGUAGE SQL AS $$
SELECT json_agg(r) FROM (
SELECT i, s
FROM t104927
) AS r
$$

# The output should match the output above where the query was run directly.
query T
SELECT f104927()
----
[{"i": 1, "s": "foo"}]
31 changes: 31 additions & 0 deletions pkg/sql/logictest/testdata/logic_test/views
Original file line number Diff line number Diff line change
Expand Up @@ -1869,3 +1869,34 @@ DROP VIEW cd_v1;

statement ok
DROP VIEW cd_v1 CASCADE;

# Regression test for #104927. Correctly resolve table references in views as
# TupleStars.
subtest regression_104927

statement ok
CREATE TABLE t104927 (
i INT,
s STRING
);
INSERT INTO t104927 VALUES (1, 'foo');

query T
SELECT json_agg(r) FROM (
SELECT i, s
FROM t104927
) AS r
----
[{"i": 1, "s": "foo"}]

statement ok
CREATE VIEW v104927 AS SELECT json_agg(r) FROM (
SELECT i, s
FROM t104927
) AS r

# The output should match the output above where the query was run directly.
query T
SELECT * FROM v104927
----
[{"i": 1, "s": "foo"}]
7 changes: 2 additions & 5 deletions pkg/sql/opt/optbuilder/project.go
Original file line number Diff line number Diff line change
Expand Up @@ -220,11 +220,8 @@ func (b *Builder) resolveColRef(e tree.Expr, inScope *scope) tree.TypedExpr {
_, srcMeta, _, resolveErr := inScope.FindSourceProvidingColumn(b.ctx, tree.Name(colName))
if resolveErr != nil {
// It may be a reference to a table, e.g. SELECT tbl FROM tbl.
// Attempt to resolve as a TupleStar. We do not attempt to resolve
// as a TupleStar if we are inside a view or function definition
// because views and functions do not support * expressions.
if !b.insideViewDef && !b.insideFuncDef &&
sqlerrors.IsUndefinedColumnError(resolveErr) {
// Attempt to resolve as a TupleStar.
if sqlerrors.IsUndefinedColumnError(resolveErr) {
return func() tree.TypedExpr {
defer wrapColTupleStarPanic(resolveErr)
return inScope.resolveType(columnNameAsTupleStar(colName), types.Any)
Expand Down
7 changes: 2 additions & 5 deletions pkg/sql/opt/optbuilder/scope.go
Original file line number Diff line number Diff line change
Expand Up @@ -1026,11 +1026,8 @@ func (s *scope) VisitPre(expr tree.Expr) (recurse bool, newExpr tree.Expr) {
colI, resolveErr := colinfo.ResolveColumnItem(s.builder.ctx, s, t)
if resolveErr != nil {
// It may be a reference to a table, e.g. SELECT tbl FROM tbl.
// Attempt to resolve as a TupleStar. We do not attempt to resolve
// as a TupleStar if we are inside a view or function definition
// because views and functions do not support * expressions.
if !s.builder.insideViewDef && !s.builder.insideFuncDef &&
sqlerrors.IsUndefinedColumnError(resolveErr) {
// Attempt to resolve as a TupleStar.
if sqlerrors.IsUndefinedColumnError(resolveErr) {
// Attempt to resolve as columnname.*, which allows items
// such as SELECT row_to_json(tbl_name) FROM tbl_name to work.
return func() (bool, tree.Expr) {
Expand Down

0 comments on commit afa92a0

Please sign in to comment.