Skip to content

Commit

Permalink
Merge #97515
Browse files Browse the repository at this point in the history
97515: sql: allow stars inside view definitions r=DrewKimball,rharding6373 a=knz

First commit from #97544.
Fixes #10028.

Release note (sql change): It is now possible to use `*` inside CREATE VIEW. The list of columns is expanded at the time the view is created, so that new columns added after the view was defined are not included in the view. This behavior is the same as PostgreSQL.

Co-authored-by: Raphael 'kena' Poss <knz@thaumogen.net>
  • Loading branch information
craig[bot] and knz committed Feb 23, 2023
2 parents 3a1564a + d59c96f commit 821ffce
Show file tree
Hide file tree
Showing 11 changed files with 311 additions and 75 deletions.
6 changes: 3 additions & 3 deletions pkg/ccl/backupccl/backup_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -5312,7 +5312,7 @@ func TestBackupRestoreSequencesInViews(t *testing.T) {
sqlDB.CheckQueryResults(t, `SELECT * FROM d.v`, [][]string{{"2"}})
sqlDB.CheckQueryResults(t, `SHOW CREATE VIEW d.v`, [][]string{{
"d.public.v", "CREATE VIEW public.v (\n\tk\n) AS " +
"SELECT k FROM (SELECT nextval('public.s2'::REGCLASS) AS k)",
"SELECT k FROM (SELECT nextval('public.s2'::REGCLASS) AS k) AS \"?subquery1?\"",
}})

// Test that references are still tracked.
Expand All @@ -5338,7 +5338,7 @@ func TestBackupRestoreSequencesInViews(t *testing.T) {
sqlDB.Exec(t, `RESTORE TABLE s, v FROM 'nodelocal://0/test/'`)
sqlDB.CheckQueryResults(t, `SHOW CREATE VIEW d.v`, [][]string{{
"d.public.v", "CREATE VIEW public.v (\n\tk\n) AS " +
"(SELECT k FROM (SELECT nextval('public.s'::REGCLASS) AS k))",
"(SELECT k FROM (SELECT nextval('public.s'::REGCLASS) AS k) AS \"?subquery1?\")",
}})

// Check that v is not corrupted.
Expand All @@ -5348,7 +5348,7 @@ func TestBackupRestoreSequencesInViews(t *testing.T) {
sqlDB.Exec(t, `ALTER SEQUENCE s RENAME TO s2`)
sqlDB.CheckQueryResults(t, `SHOW CREATE VIEW d.v`, [][]string{{
"d.public.v", "CREATE VIEW public.v (\n\tk\n) AS " +
"(SELECT k FROM (SELECT nextval('public.s2'::REGCLASS) AS k))",
"(SELECT k FROM (SELECT nextval('public.s2'::REGCLASS) AS k) AS \"?subquery1?\")",
}})
sqlDB.CheckQueryResults(t, `SELECT * FROM v`, [][]string{{"2"}})

Expand Down
5 changes: 4 additions & 1 deletion pkg/sql/logictest/testdata/logic_test/sequences_regclass
Original file line number Diff line number Diff line change
Expand Up @@ -430,7 +430,10 @@ SHOW CREATE VIEW v2
----
v2 CREATE VIEW public.v2 (
currval
) AS SELECT currval FROM (SELECT currval('public.view_seq'::REGCLASS) FROM test.public.t3)
) AS SELECT
currval
FROM
(SELECT currval('public.view_seq'::REGCLASS) FROM test.public.t3) AS "?subquery1?"

# Union containing sequences.
statement ok
Expand Down
42 changes: 30 additions & 12 deletions pkg/sql/logictest/testdata/logic_test/udf_star
Original file line number Diff line number Diff line change
Expand Up @@ -18,7 +18,7 @@ $$
SELECT * FROM (SELECT a FROM (SELECT * FROM t_onecol) AS foo) AS bar;
$$ LANGUAGE SQL;

statement error pq: unimplemented: unaliased subquery inside a function definition
statement ok
CREATE FUNCTION f_subquery_unaliased() RETURNS INT AS
$$
SELECT * FROM (SELECT a FROM (SELECT * FROM t_onecol));
Expand Down Expand Up @@ -68,8 +68,8 @@ $$
SELECT word FROM (SELECT (pg_get_keywords()).* ORDER BY word LIMIT 1) AS foo;
$$ LANGUAGE SQL;

statement error pq: unimplemented: unaliased subquery inside a function definition
CREATE FUNCTION f_ambiguous() RETURNS INT AS
statement ok
CREATE FUNCTION f_anon_subqueries() RETURNS INT AS
$$
SELECT * FROM (SELECT a FROM t_onecol) JOIN (SELECT a FROM t_twocol) ON true;
SELECT 1;
Expand All @@ -88,15 +88,18 @@ FROM pg_catalog.pg_proc WHERE proname LIKE 'f\_%' ORDER BY oid;
----
100108 f_unqualified_onecol SELECT t_onecol.a FROM test.public.t_onecol;
100109 f_subquery SELECT bar.a FROM (SELECT a FROM (SELECT t_onecol.a FROM test.public.t_onecol) AS foo) AS bar;
100110 f_unqualified_twocol SELECT t_twocol.a, t_twocol.b FROM test.public.t_twocol;
100111 f_allcolsel SELECT t_twocol.a, t_twocol.b FROM test.public.t_twocol;
100112 f_allcolsel_alias SELECT t1.a, t1.b FROM test.public.t_twocol AS t1, test.public.t_twocol AS t2 WHERE t1.a = t2.a;
100113 f_tuplestar SELECT t_twocol.a, t_twocol.b FROM test.public.t_twocol;
100114 f_unqualified_multicol SELECT t_onecol.a, a FROM test.public.t_onecol;
100110 f_subquery_unaliased SELECT "?subquery1?".a FROM (SELECT a FROM (SELECT t_onecol.a FROM test.public.t_onecol) AS "?subquery2?") AS "?subquery1?";
100111 f_unqualified_twocol SELECT t_twocol.a, t_twocol.b FROM test.public.t_twocol;
100112 f_allcolsel SELECT t_twocol.a, t_twocol.b FROM test.public.t_twocol;
100113 f_allcolsel_alias SELECT t1.a, t1.b FROM test.public.t_twocol AS t1, test.public.t_twocol AS t2 WHERE t1.a = t2.a;
100114 f_tuplestar SELECT t_twocol.a, t_twocol.b FROM test.public.t_twocol;
100115 f_unqualified_multicol SELECT t_onecol.a, a FROM test.public.t_onecol;
SELECT 1;
100115 f_unqualified_doublestar SELECT t_onecol.a, t_onecol.a FROM test.public.t_onecol;
100116 f_unqualified_doublestar SELECT t_onecol.a, t_onecol.a FROM test.public.t_onecol;
SELECT 1;
100117 f_exprstar SELECT word FROM (SELECT (pg_get_keywords()).word, (pg_get_keywords()).catcode, (pg_get_keywords()).catdesc ORDER BY word LIMIT 1) AS foo;
100118 f_anon_subqueries SELECT "?subquery1?".a, "?subquery2?".a FROM (SELECT a FROM test.public.t_onecol) AS "?subquery1?" JOIN (SELECT a FROM test.public.t_twocol) AS "?subquery2?" ON true;
SELECT 1;
100116 f_exprstar SELECT word FROM (SELECT (pg_get_keywords()).word, (pg_get_keywords()).catcode, (pg_get_keywords()).catdesc ORDER BY word LIMIT 1) AS foo;


query TT
Expand Down Expand Up @@ -211,16 +214,31 @@ statement ok
DROP FUNCTION f_tuplestar;
DROP FUNCTION f_allcolsel_alias;

# Dropping a column using CASCADE is ok.
# Dropping a column using CASCADE is ok,
# although the legacy schema changer has troubles with it,
# see: https://github.com/cockroachdb/cockroach/issues/97546
skipif config local-legacy-schema-changer
statement ok
ALTER TABLE t_twocol DROP COLUMN b CASCADE;

statement ok
DROP TABLE t_onecol CASCADE;

# The only remaining function should not reference the tables.
# NB: remove the skipif directive when #97546 is resolved.
skipif config local-legacy-schema-changer
query TTT
SELECT oid, proname, prosrc
FROM pg_catalog.pg_proc WHERE proname LIKE 'f\_%' ORDER BY oid;
----
100117 f_exprstar SELECT word FROM (SELECT (pg_get_keywords()).word, (pg_get_keywords()).catcode, (pg_get_keywords()).catdesc ORDER BY word LIMIT 1) AS foo;

# Remove this when #97546 is resolved.
onlyif config local-legacy-schema-changer
query TTT
SELECT oid, proname, prosrc
FROM pg_catalog.pg_proc WHERE proname LIKE 'f\_%' ORDER BY oid;
----
100116 f_exprstar SELECT word FROM (SELECT (pg_get_keywords()).word, (pg_get_keywords()).catcode, (pg_get_keywords()).catdesc ORDER BY word LIMIT 1) AS foo;
100111 f_unqualified_twocol SELECT t_twocol.a, t_twocol.b FROM test.public.t_twocol;
100112 f_allcolsel SELECT t_twocol.a, t_twocol.b FROM test.public.t_twocol;
100117 f_exprstar SELECT word FROM (SELECT (pg_get_keywords()).word, (pg_get_keywords()).catcode, (pg_get_keywords()).catdesc ORDER BY word LIMIT 1) AS foo;
Loading

0 comments on commit 821ffce

Please sign in to comment.