From c5fb4a5301aa7de52bd3836861ca5ad839b2e866 Mon Sep 17 00:00:00 2001 From: Raphael 'kena' Poss Date: Thu, 23 Feb 2023 05:14:40 +0100 Subject: [PATCH 1/2] sql/opt: support anonymous subqueries in CREATE FUNCTION Release note (bug fix): CockroachDB now supports using subqueries in UDFs without an AS clause, for consistency with the syntax supported outside of UDFs. (Subqueries without an AS clause is a CRDB-specific extension.) --- pkg/ccl/backupccl/backup_test.go | 6 +-- .../testdata/logic_test/sequences_regclass | 5 ++- .../logictest/testdata/logic_test/udf_star | 42 +++++++++++++------ pkg/sql/logictest/testdata/logic_test/views | 2 +- pkg/sql/opt/optbuilder/builder.go | 4 ++ pkg/sql/opt/optbuilder/select.go | 26 +++++++++--- .../opt/optbuilder/testdata/create_function | 11 +++++ pkg/sql/opt/optbuilder/testdata/create_view | 2 +- pkg/sql/table_test.go | 2 +- 9 files changed, 75 insertions(+), 25 deletions(-) diff --git a/pkg/ccl/backupccl/backup_test.go b/pkg/ccl/backupccl/backup_test.go index 7d61e0476a44..9512a3e90e8e 100644 --- a/pkg/ccl/backupccl/backup_test.go +++ b/pkg/ccl/backupccl/backup_test.go @@ -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. @@ -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. @@ -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"}}) diff --git a/pkg/sql/logictest/testdata/logic_test/sequences_regclass b/pkg/sql/logictest/testdata/logic_test/sequences_regclass index 413d599f44ac..ae2fad250195 100644 --- a/pkg/sql/logictest/testdata/logic_test/sequences_regclass +++ b/pkg/sql/logictest/testdata/logic_test/sequences_regclass @@ -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 diff --git a/pkg/sql/logictest/testdata/logic_test/udf_star b/pkg/sql/logictest/testdata/logic_test/udf_star index e8bc1e7fc047..fe08e9cbe8de 100644 --- a/pkg/sql/logictest/testdata/logic_test/udf_star +++ b/pkg/sql/logictest/testdata/logic_test/udf_star @@ -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)); @@ -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; @@ -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 @@ -211,7 +214,10 @@ 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; @@ -219,8 +225,20 @@ 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; diff --git a/pkg/sql/logictest/testdata/logic_test/views b/pkg/sql/logictest/testdata/logic_test/views index 8c35a3ad6736..2b79a298635c 100644 --- a/pkg/sql/logictest/testdata/logic_test/views +++ b/pkg/sql/logictest/testdata/logic_test/views @@ -1185,7 +1185,7 @@ SHOW CREATE VIEW v12 ---- v12 CREATE VIEW public.v12 ( k - ) AS (SELECT k FROM (SELECT 'a':::db2.public.view_type_new AS k)) + ) AS (SELECT k FROM (SELECT 'a':::db2.public.view_type_new AS k) AS "?subquery1?") query T SELECT * FROM v12 diff --git a/pkg/sql/opt/optbuilder/builder.go b/pkg/sql/opt/optbuilder/builder.go index 4acf004a4943..794ab1cf96f2 100644 --- a/pkg/sql/opt/optbuilder/builder.go +++ b/pkg/sql/opt/optbuilder/builder.go @@ -153,6 +153,10 @@ type Builder struct { // (without ON CONFLICT) or false otherwise. All mutated tables will have an // entry in the map. areAllTableMutationsSimpleInserts map[cat.StableID]bool + + // subqueryNameIdx helps generate unique subquery names during star + // expansion. + subqueryNameIdx int } // New creates a new Builder structure initialized with the given diff --git a/pkg/sql/opt/optbuilder/select.go b/pkg/sql/opt/optbuilder/select.go index 88d198aee02f..1b0dde6e90aa 100644 --- a/pkg/sql/opt/optbuilder/select.go +++ b/pkg/sql/opt/optbuilder/select.go @@ -12,6 +12,7 @@ package optbuilder import ( "context" + "fmt" "github.com/cockroachdb/cockroach/pkg/server/telemetry" "github.com/cockroachdb/cockroach/pkg/sql/catalog/colinfo" @@ -58,16 +59,29 @@ func (b *Builder) buildDataSource( telemetry.Inc(sqltelemetry.IndexHintSelectUseCounter) indexFlags = source.IndexFlags } + + if source.As.Alias == "" { + // The alias is an empty string. If we are in a view or UDF + // definition, we are also expanding stars and for this we need + // to ensure all unnamed subqueries have a name. (unnamed + // subqueries are a CRDB extension, so the behavior in that case + // can be CRDB-specific.) + // + // We do not perform this name assignment in the common case + // (everything else besides CREATE VIEW/FUNCTION) so as to save + // the cost of the string alloc / name propagation. + if _, ok := source.Expr.(*tree.Subquery); ok && (b.insideFuncDef || b.insideViewDef) { + b.subqueryNameIdx++ + // The structure of this name is analogous to the auto-generated + // names for anonymous scalar expressions. + source.As.Alias = tree.Name(fmt.Sprintf("?subquery%d?", b.subqueryNameIdx)) + } + } + if source.As.Alias != "" { inScope = inScope.push() inScope.alias = &source.As locking = locking.filter(source.As.Alias) - } else if b.insideFuncDef { - // TODO(96375): Allow non-aliased subexpressions in UDFs after ambiguous - // columns can be correctly identified. - if _, ok := source.Expr.(*tree.Subquery); ok { - panic(unimplemented.New("user-defined functions", "unaliased subquery inside a function definition")) - } } outScope = b.buildDataSource(source.Expr, indexFlags, locking, inScope) diff --git a/pkg/sql/opt/optbuilder/testdata/create_function b/pkg/sql/opt/optbuilder/testdata/create_function index 6d17e4731778..d0b607ef956e 100644 --- a/pkg/sql/opt/optbuilder/testdata/create_function +++ b/pkg/sql/opt/optbuilder/testdata/create_function @@ -118,6 +118,17 @@ create-function └── dependencies └── ab [columns: a b] +build +CREATE FUNCTION f() RETURNS ab LANGUAGE SQL AS $$ SELECT * FROM (SELECT * from ab) $$ +---- +create-function + ├── CREATE FUNCTION f() + │ RETURNS ab + │ LANGUAGE SQL + │ AS $$SELECT "?subquery1?".a, "?subquery1?".b FROM (SELECT ab.a, ab.b FROM t.public.ab) AS "?subquery1?";$$ + └── dependencies + └── ab [columns: a b] + build CREATE FUNCTION f() RETURNS INT LANGUAGE SQL BEGIN ATOMIC SELECT 1; END; ---- diff --git a/pkg/sql/opt/optbuilder/testdata/create_view b/pkg/sql/opt/optbuilder/testdata/create_view index 981e0bbce715..14b44d394051 100644 --- a/pkg/sql/opt/optbuilder/testdata/create_view +++ b/pkg/sql/opt/optbuilder/testdata/create_view @@ -258,7 +258,7 @@ build CREATE VIEW v16 AS SELECT a FROM (SELECT a,b FROM ab); ---- create-view t.public.v16 - ├── SELECT a FROM (SELECT a, b FROM t.public.ab) + ├── SELECT a FROM (SELECT a, b FROM t.public.ab) AS "?subquery1?" ├── columns: a:1 └── dependencies └── ab [columns: a b] diff --git a/pkg/sql/table_test.go b/pkg/sql/table_test.go index ae9b102e41d6..82a3266b14d7 100644 --- a/pkg/sql/table_test.go +++ b/pkg/sql/table_test.go @@ -586,7 +586,7 @@ func TestSerializedUDTsInView(t *testing.T) { // Test when a UDT is used in various parts of a view (subquery, CTE, etc.). { "SELECT k FROM (SELECT 'hello'::greeting AS k)", - `(SELECT k FROM (SELECT b'\x80':::@$OID AS k))`, + `(SELECT k FROM (SELECT b'\x80':::@$OID AS k) AS "?subquery1?")`, }, { "WITH w AS (SELECT 'hello':::greeting AS k) SELECT k FROM w", From d59c96f8c30c604e9e78cfaf74bf8b251ee0091f Mon Sep 17 00:00:00 2001 From: Raphael 'kena' Poss Date: Wed, 22 Feb 2023 21:44:42 +0100 Subject: [PATCH 2/2] sql: allow stars inside view definitions 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. --- pkg/sql/logictest/testdata/logic_test/views | 259 ++++++++++++++++---- pkg/sql/opt/optbuilder/project.go | 6 +- pkg/sql/opt/optbuilder/testdata/create_view | 17 +- pkg/sql/opt/optbuilder/util.go | 4 - 4 files changed, 236 insertions(+), 50 deletions(-) diff --git a/pkg/sql/logictest/testdata/logic_test/views b/pkg/sql/logictest/testdata/logic_test/views index 2b79a298635c..70aee8011e28 100644 --- a/pkg/sql/logictest/testdata/logic_test/views +++ b/pkg/sql/logictest/testdata/logic_test/views @@ -4,7 +4,8 @@ statement ok SET CLUSTER SETTING sql.cross_db_views.enabled = TRUE statement ok -CREATE TABLE t (a INT PRIMARY KEY, b INT) +CREATE TABLE t (a INT PRIMARY KEY, b INT); +CREATE TABLE u (a INT PRIMARY KEY, b INT); let $t_id SELECT id FROM system.namespace WHERE name='t' @@ -401,68 +402,244 @@ CREATE VIEW virt2 AS SELECT range_id, lease_holder FROM crdb_internal.ranges statement ok DROP VIEW virt2 -# Verify correct rejection of star expressions -# TODO(a-robinson): Support star expressions as soon as we can (#10028) +statement ok +CREATE VIEW star1 AS SELECT * FROM t + +statement ok +CREATE VIEW star2 AS SELECT t.* FROM t + +# Note: this is affected by +# https://github.com/cockroachdb/cockroach/issues/97520 +statement ok +CREATE VIEW star3 AS SELECT a FROM t ORDER BY t.* + +# Note: this is affected by +# https://github.com/cockroachdb/cockroach/issues/97520 +statement ok +CREATE VIEW star4 AS SELECT count(1) FROM t GROUP BY t.* + +statement ok +CREATE VIEW star5 AS SELECT alias.* FROM t AS alias -statement error views do not currently support \* expressions -create view s1 AS SELECT * FROM t +statement ok +CREATE VIEW star6 AS TABLE t -statement error views do not currently support \* expressions -create view s1 AS SELECT t.* FROM t +statement ok +CREATE VIEW star7 AS SELECT a FROM (SELECT * FROM t) -statement error views do not currently support \* expressions -create view s1 AS SELECT a FROM t ORDER BY t.* +statement ok +CREATE VIEW star8 AS SELECT a FROM t WHERE NOT a IN (SELECT a FROM (SELECT * FROM t)) -statement error views do not currently support \* expressions -create view s1 AS SELECT count(1) FROM t GROUP BY t.* +statement ok +CREATE VIEW star9 AS SELECT a FROM t GROUP BY a HAVING a IN (SELECT a FROM (SELECT * FROM t)) -statement error views do not currently support \* expressions -create view s1 AS SELECT alias.* FROM t AS alias +# This error is the same as in postgres. +statement error duplicate column name: "a" +CREATE VIEW star10 AS SELECT t1.*, t2.a FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a -statement error views do not currently support \* expressions -create view s1 AS TABLE t +statement ok +CREATE VIEW star10 AS SELECT t1.*, t2.a AS a2 FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a -statement error views do not currently support \* expressions -create view s1 AS SELECT a FROM (SELECT * FROM t) +# This error is the same as in postgres. +statement error duplicate column name: "a" +CREATE VIEW star11 AS SELECT t1.a, t2.* FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a -statement error views do not currently support \* expressions -create view s1 AS SELECT a FROM t WHERE NOT a IN (SELECT a FROM (SELECT * FROM t)) +statement ok +CREATE VIEW star11 AS SELECT t1.a AS a1, t2.* FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a -statement error views do not currently support \* expressions -create view s1 AS SELECT a FROM t GROUP BY a HAVING a IN (SELECT a FROM (SELECT * FROM t)) +# This error is the same as in postgres. +statement error duplicate column name: "a" +CREATE VIEW star12 AS SELECT t1.*, t2.* FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a -statement error views do not currently support \* expressions -create view s1 AS SELECT t1.*, t2.a FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a +# This error is the same as in postgres. +statement error duplicate column name: "a" +CREATE VIEW star13 AS SELECT * FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a -statement error views do not currently support \* expressions -create view s1 AS SELECT t1.a, t2.* FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a +statement ok +CREATE VIEW star14 AS SELECT t1.a, t2.a AS a2 FROM (SELECT * FROM t) AS t1 JOIN t AS t2 ON t1.a = t2.a -statement error views do not currently support \* expressions -create view s1 AS SELECT t1.*, t2.* FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a +statement ok +CREATE VIEW star15 AS SELECT t1.a, t2.a AS a2 FROM t AS t1 JOIN (SELECT * FROM t) AS t2 ON t1.a = t2.a -statement error views do not currently support \* expressions -create view s1 AS SELECT * FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a +statement ok +CREATE VIEW star16 AS SELECT t1.a, t2.a AS a2 FROM t AS t1 JOIN t AS t2 ON t1.a IN (SELECT a FROM (SELECT * FROM t)) -statement error views do not currently support \* expressions -create view s1 AS SELECT t1.a, t2.a FROM (SELECT * FROM t) AS t1 JOIN t AS t2 ON t1.a = t2.a +# This error is the same as in postgres. +statement error duplicate column name: "a" +CREATE VIEW star17 AS SELECT * FROM (SELECT a FROM t) t1 JOIN (SELECT a FROM u) t2 ON true; -statement error views do not currently support \* expressions -create view s1 AS SELECT t1.a, t2.a FROM t AS t1 JOIN (SELECT * FROM t) AS t2 ON t1.a = t2.a +# Ditto for crdb's special feature where subquery aliases can be omitted. +statement error duplicate column name: "a" +CREATE VIEW star17 AS SELECT * FROM (SELECT a FROM t) JOIN (SELECT a FROM u) ON true; -statement error views do not currently support \* expressions -create view s1 AS SELECT t1.a, t2.a FROM t AS t1 JOIN t AS t2 ON t1.a IN (SELECT a FROM (SELECT * FROM t)) +statement ok +CREATE VIEW star17 AS SELECT * FROM (SELECT a FROM t) JOIN (SELECT b FROM u) ON true; statement ok -create view s1 AS SELECT count(*) FROM t +CREATE VIEW star18 AS SELECT * FROM (SELECT * FROM (SELECT a FROM t)); statement ok -create view s2 AS SELECT a FROM t WHERE a IN (SELECT count(*) FROM t) +CREATE VIEW star19 AS SELECT a FROM (SELECT * FROM (SELECT a FROM t)); statement ok -create view s3 AS SELECT a, count(*) FROM t GROUP BY a +CREATE VIEW star20 AS SELECT ARRAY[z.*]::STRING FROM (SELECT * FROM (SELECT a FROM t), (SELECT a FROM t)) AS z statement ok -create view s4 AS SELECT a, count(*) FROM t GROUP BY a HAVING a > (SELECT count(*) FROM t) +ALTER TABLE t ADD COLUMN c INT + +statement error cannot drop column "b" because view "star1" depends on it +ALTER TABLE t DROP COLUMN b + +# See: https://github.com/cockroachdb/cockroach/issues/10083 +statement error cannot rename column "b" because view "star1" depends on it +ALTER TABLE t RENAME COLUMN b TO d + +query TT +SELECT descriptor_name, create_statement FROM crdb_internal.create_statements WHERE descriptor_name LIKE 'star%' ORDER BY 1 +---- +star1 CREATE VIEW public.star1 ( + a, + b + ) AS SELECT t.a, t.b FROM test.public.t +star10 CREATE VIEW public.star10 ( + a, + b, + a2 + ) AS SELECT t1.a, t1.b, t2.a AS a2 FROM test.public.t AS t1 JOIN test.public.t AS t2 ON t1.a = t2.a +star11 CREATE VIEW public.star11 ( + a1, + a, + b + ) AS SELECT t1.a AS a1, t2.a, t2.b FROM test.public.t AS t1 JOIN test.public.t AS t2 ON t1.a = t2.a +star14 CREATE VIEW public.star14 ( + a, + a2 + ) AS SELECT + t1.a, t2.a AS a2 + FROM + (SELECT t.a, t.b FROM test.public.t) AS t1 JOIN test.public.t AS t2 ON t1.a = t2.a +star15 CREATE VIEW public.star15 ( + a, + a2 + ) AS SELECT + t1.a, t2.a AS a2 + FROM + test.public.t AS t1 JOIN (SELECT t.a, t.b FROM test.public.t) AS t2 ON t1.a = t2.a +star16 CREATE VIEW public.star16 ( + a, + a2 + ) AS SELECT + t1.a, t2.a AS a2 + FROM + test.public.t AS t1 + JOIN test.public.t AS t2 ON + t1.a IN (SELECT a FROM (SELECT t.a, t.b FROM test.public.t) AS "?subquery1?") +star17 CREATE VIEW public.star17 ( + a, + b + ) AS SELECT + "?subquery1?".a, "?subquery2?".b + FROM + (SELECT a FROM test.public.t) AS "?subquery1?" + JOIN (SELECT b FROM test.public.u) AS "?subquery2?" ON true +star18 CREATE VIEW public.star18 ( + a + ) AS SELECT + "?subquery1?".a + FROM + (SELECT "?subquery2?".a FROM (SELECT a FROM test.public.t) AS "?subquery2?") + AS "?subquery1?" +star19 CREATE VIEW public.star19 ( + a + ) AS SELECT + a + FROM + (SELECT "?subquery2?".a FROM (SELECT a FROM test.public.t) AS "?subquery2?") + AS "?subquery1?" +star2 CREATE VIEW public.star2 ( + a, + b + ) AS SELECT t.a, t.b FROM test.public.t +star20 CREATE VIEW public.star20 ( + "array" + ) AS SELECT + ARRAY[z.*]::STRING + FROM + ( + SELECT + "?subquery1?".a, "?subquery2?".a + FROM + (SELECT a FROM test.public.t) AS "?subquery1?", + (SELECT a FROM test.public.t) AS "?subquery2?" + ) + AS z +star3 CREATE VIEW public.star3 ( + a + ) AS SELECT a FROM test.public.t ORDER BY t.* +star4 CREATE VIEW public.star4 ( + count + ) AS SELECT count(1:::INT8) FROM test.public.t GROUP BY t.* +star5 CREATE VIEW public.star5 ( + a, + b + ) AS SELECT alias.a, alias.b FROM test.public.t AS alias +star6 CREATE VIEW public.star6 ( + a, + b + ) AS TABLE test.public.t +star7 CREATE VIEW public.star7 ( + a + ) AS SELECT a FROM (SELECT t.a, t.b FROM test.public.t) AS "?subquery1?" +star8 CREATE VIEW public.star8 ( + a + ) AS SELECT + a + FROM + test.public.t + WHERE + NOT (a IN (SELECT a FROM (SELECT t.a, t.b FROM test.public.t) AS "?subquery1?")) +star9 CREATE VIEW public.star9 ( + a + ) AS SELECT + a + FROM + test.public.t + GROUP BY + a + HAVING + a IN (SELECT a FROM (SELECT t.a, t.b FROM test.public.t) AS "?subquery1?") + +statement ok +DROP VIEW star1; +DROP VIEW star2; +DROP VIEW star3; +DROP VIEW star4; +DROP VIEW star5; +DROP VIEW star6; +DROP VIEW star7; +DROP VIEW star8; +DROP VIEW star9; +DROP VIEW star10; +DROP VIEW star11; +DROP VIEW star14; +DROP VIEW star15; +DROP VIEW star16; +DROP VIEW star17; +DROP VIEW star18; +DROP VIEW star19; +DROP VIEW star20; + +statement ok +CREATE VIEW s1 AS SELECT count(*) FROM t + +statement ok +CREATE VIEW s2 AS SELECT a FROM t WHERE a IN (SELECT count(*) FROM t) + +statement ok +CREATE VIEW s3 AS SELECT a, count(*) FROM t GROUP BY a + +statement ok +CREATE VIEW s4 AS SELECT a, count(*) FROM t GROUP BY a HAVING a > (SELECT count(*) FROM t) statement ok DROP VIEW s4 @@ -477,7 +654,7 @@ statement ok DROP VIEW s1 statement ok -DROP TABLE t +DROP TABLE t; DROP TABLE u # Check for memory leak (#10466) statement ok @@ -1121,7 +1298,7 @@ CREATE VIEW v7_dep AS (SELECT i FROM t6@idx WHERE k < 'a'::typ6) statement error cannot drop type "typ6" because other objects \(\[db2.public.t6 db2.public.v7_dep\]\) still depend on it DROP TYPE typ6 -# Test we can create views from various data sources. +# Test we can CREATE VIEWs from various data sources. statement ok CREATE SEQUENCE s diff --git a/pkg/sql/opt/optbuilder/project.go b/pkg/sql/opt/optbuilder/project.go index a925f9e2e8a2..72d9b43e0dd2 100644 --- a/pkg/sql/opt/optbuilder/project.go +++ b/pkg/sql/opt/optbuilder/project.go @@ -148,7 +148,7 @@ func (b *Builder) analyzeSelectList( } aliases, exprs := b.expandStar(e.Expr, inScope) - if b.insideFuncDef { + if b.insideFuncDef || b.insideViewDef { expanded = true for _, expr := range exprs { switch col := expr.(type) { @@ -187,11 +187,11 @@ func (b *Builder) analyzeSelectList( } alias := b.getColName(e) outScope.addColumn(scopeColName(tree.Name(alias)), texpr) - if b.insideFuncDef && !expanded { + if (b.insideViewDef || b.insideFuncDef) && !expanded { expansions = append(expansions, e) } } - if b.insideFuncDef { + if b.insideFuncDef || b.insideViewDef { *selects = expansions } } diff --git a/pkg/sql/opt/optbuilder/testdata/create_view b/pkg/sql/opt/optbuilder/testdata/create_view index 14b44d394051..63a114986b42 100644 --- a/pkg/sql/opt/optbuilder/testdata/create_view +++ b/pkg/sql/opt/optbuilder/testdata/create_view @@ -111,11 +111,24 @@ CREATE VIEW v3 (x) AS SELECT a, b FROM ab ---- error (42601): CREATE VIEW specifies 1 column name, but data source has 2 columns -# Verify that we disallow * in view definitions (#10028). build CREATE VIEW v4 AS SELECT * FROM ab ---- -error (0A000): unimplemented: views do not currently support * expressions +create-view t.public.v4 + ├── SELECT ab.a, ab.b FROM t.public.ab + ├── columns: a:1 b:2 + └── dependencies + └── ab [columns: a b] + +build +CREATE VIEW v4 AS SELECT ARRAY[z.*]::STRING FROM (SELECT * FROM (SELECT * FROM ab), (SELECT * FROM ab)) AS z +---- +create-view t.public.v4 + ├── SELECT ARRAY[z.*]::STRING FROM (SELECT "?subquery1?".a, "?subquery1?".b, "?subquery2?".a, "?subquery2?".b FROM (SELECT ab.a, ab.b FROM t.public.ab) AS "?subquery1?", (SELECT ab.a, ab.b FROM t.public.ab) AS "?subquery2?") AS z + ├── columns: array:9 + └── dependencies + ├── ab [columns: a b] + └── ab [columns: a b] build CREATE VIEW v5 AS SELECT a FROM [53 AS t] diff --git a/pkg/sql/opt/optbuilder/util.go b/pkg/sql/opt/optbuilder/util.go index c210674d376c..b9755b7a66e9 100644 --- a/pkg/sql/opt/optbuilder/util.go +++ b/pkg/sql/opt/optbuilder/util.go @@ -23,7 +23,6 @@ import ( "github.com/cockroachdb/cockroach/pkg/sql/sem/tree" "github.com/cockroachdb/cockroach/pkg/sql/sqlerrors" "github.com/cockroachdb/cockroach/pkg/sql/types" - "github.com/cockroachdb/cockroach/pkg/util/errorutil/unimplemented" "github.com/cockroachdb/errors" ) @@ -61,9 +60,6 @@ func getTypedExprs(exprs []tree.Expr) []tree.TypedExpr { func (b *Builder) expandStar( expr tree.Expr, inScope *scope, ) (aliases []string, exprs []tree.TypedExpr) { - if b.insideViewDef { - panic(unimplemented.NewWithIssue(10028, "views do not currently support * expressions")) - } switch t := expr.(type) { case *tree.TupleStar: texpr := inScope.resolveType(t.Expr, types.Any)