Skip to content

Commit

Permalink
sql: allow stars inside view definitions
Browse files Browse the repository at this point in the history
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.
  • Loading branch information
knz committed Feb 22, 2023
1 parent e3c3ef3 commit 007378d
Show file tree
Hide file tree
Showing 4 changed files with 152 additions and 51 deletions.
186 changes: 144 additions & 42 deletions pkg/sql/logictest/testdata/logic_test/views
Original file line number Diff line number Diff line change
Expand Up @@ -401,68 +401,170 @@ 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 error views do not currently support \* expressions
create view s1 AS SELECT * FROM t

statement error views do not currently support \* expressions
create view s1 AS SELECT t.* FROM t
statement ok
CREATE VIEW star1 AS 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 star2 AS SELECT t.* 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 star3 AS SELECT a FROM t ORDER BY t.*

statement error views do not currently support \* expressions
create view s1 AS SELECT alias.* FROM t AS alias
statement ok
CREATE VIEW star4 AS SELECT count(1) FROM t GROUP BY t.*

statement error views do not currently support \* expressions
create view s1 AS TABLE 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 a FROM (SELECT * FROM t)
statement ok
CREATE VIEW star6 AS TABLE t

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 star7 AS SELECT a FROM (SELECT * FROM t)

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))
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 t1.*, t2.a FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a
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 t1.a, t2.* 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 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 SELECT t1.*, t2.* FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a
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 * 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 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 t1.a, t2.a FROM (SELECT * FROM t) AS t1 JOIN t AS t2 ON t1.a = t2.a
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 t1.a, t2.a FROM t AS t1 JOIN (SELECT * FROM t) AS t2 ON t1.a = t2.a
# 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.a, t2.a FROM t AS t1 JOIN t AS t2 ON t1.a IN (SELECT a FROM (SELECT * FROM t))
# 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 ok
create view s1 AS SELECT count(*) FROM t
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 ok
create view s2 AS SELECT a FROM t WHERE a IN (SELECT count(*) FROM t)
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 ok
create view s3 AS SELECT a, count(*) FROM t GROUP BY a
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 ok
create view s4 AS SELECT a, count(*) FROM t GROUP BY a HAVING a > (SELECT count(*) FROM t)
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))
star2 CREATE VIEW public.star2 (
a,
b
) AS SELECT t.a, t.b FROM test.public.t
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)
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)))
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))

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;

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
Expand Down Expand Up @@ -1121,7 +1223,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

Expand Down
6 changes: 3 additions & 3 deletions pkg/sql/opt/optbuilder/project.go
Original file line number Diff line number Diff line change
Expand Up @@ -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) {
Expand Down Expand Up @@ -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
}
}
Expand Down
7 changes: 5 additions & 2 deletions pkg/sql/opt/optbuilder/testdata/create_view
Original file line number Diff line number Diff line change
Expand Up @@ -111,11 +111,14 @@ 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 v5 AS SELECT a FROM [53 AS t]
Expand Down
4 changes: 0 additions & 4 deletions pkg/sql/opt/optbuilder/util.go
Original file line number Diff line number Diff line change
Expand Up @@ -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"
)

Expand Down Expand Up @@ -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)
Expand Down

0 comments on commit 007378d

Please sign in to comment.