Skip to content

Commit d59c96f

Browse files
committed
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.
1 parent c5fb4a5 commit d59c96f

File tree

4 files changed

+236
-50
lines changed

4 files changed

+236
-50
lines changed

pkg/sql/logictest/testdata/logic_test/views

Lines changed: 218 additions & 41 deletions
Original file line numberDiff line numberDiff line change
@@ -4,7 +4,8 @@ statement ok
44
SET CLUSTER SETTING sql.cross_db_views.enabled = TRUE
55

66
statement ok
7-
CREATE TABLE t (a INT PRIMARY KEY, b INT)
7+
CREATE TABLE t (a INT PRIMARY KEY, b INT);
8+
CREATE TABLE u (a INT PRIMARY KEY, b INT);
89

910
let $t_id
1011
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
401402
statement ok
402403
DROP VIEW virt2
403404

404-
# Verify correct rejection of star expressions
405-
# TODO(a-robinson): Support star expressions as soon as we can (#10028)
405+
statement ok
406+
CREATE VIEW star1 AS SELECT * FROM t
407+
408+
statement ok
409+
CREATE VIEW star2 AS SELECT t.* FROM t
410+
411+
# Note: this is affected by
412+
# https://github.com/cockroachdb/cockroach/issues/97520
413+
statement ok
414+
CREATE VIEW star3 AS SELECT a FROM t ORDER BY t.*
415+
416+
# Note: this is affected by
417+
# https://github.com/cockroachdb/cockroach/issues/97520
418+
statement ok
419+
CREATE VIEW star4 AS SELECT count(1) FROM t GROUP BY t.*
420+
421+
statement ok
422+
CREATE VIEW star5 AS SELECT alias.* FROM t AS alias
406423

407-
statement error views do not currently support \* expressions
408-
create view s1 AS SELECT * FROM t
424+
statement ok
425+
CREATE VIEW star6 AS TABLE t
409426

410-
statement error views do not currently support \* expressions
411-
create view s1 AS SELECT t.* FROM t
427+
statement ok
428+
CREATE VIEW star7 AS SELECT a FROM (SELECT * FROM t)
412429

413-
statement error views do not currently support \* expressions
414-
create view s1 AS SELECT a FROM t ORDER BY t.*
430+
statement ok
431+
CREATE VIEW star8 AS SELECT a FROM t WHERE NOT a IN (SELECT a FROM (SELECT * FROM t))
415432

416-
statement error views do not currently support \* expressions
417-
create view s1 AS SELECT count(1) FROM t GROUP BY t.*
433+
statement ok
434+
CREATE VIEW star9 AS SELECT a FROM t GROUP BY a HAVING a IN (SELECT a FROM (SELECT * FROM t))
418435

419-
statement error views do not currently support \* expressions
420-
create view s1 AS SELECT alias.* FROM t AS alias
436+
# This error is the same as in postgres.
437+
statement error duplicate column name: "a"
438+
CREATE VIEW star10 AS SELECT t1.*, t2.a FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a
421439

422-
statement error views do not currently support \* expressions
423-
create view s1 AS TABLE t
440+
statement ok
441+
CREATE VIEW star10 AS SELECT t1.*, t2.a AS a2 FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a
424442

425-
statement error views do not currently support \* expressions
426-
create view s1 AS SELECT a FROM (SELECT * FROM t)
443+
# This error is the same as in postgres.
444+
statement error duplicate column name: "a"
445+
CREATE VIEW star11 AS SELECT t1.a, t2.* FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a
427446

428-
statement error views do not currently support \* expressions
429-
create view s1 AS SELECT a FROM t WHERE NOT a IN (SELECT a FROM (SELECT * FROM t))
447+
statement ok
448+
CREATE VIEW star11 AS SELECT t1.a AS a1, t2.* FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a
430449

431-
statement error views do not currently support \* expressions
432-
create view s1 AS SELECT a FROM t GROUP BY a HAVING a IN (SELECT a FROM (SELECT * FROM t))
450+
# This error is the same as in postgres.
451+
statement error duplicate column name: "a"
452+
CREATE VIEW star12 AS SELECT t1.*, t2.* FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a
433453

434-
statement error views do not currently support \* expressions
435-
create view s1 AS SELECT t1.*, t2.a FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a
454+
# This error is the same as in postgres.
455+
statement error duplicate column name: "a"
456+
CREATE VIEW star13 AS SELECT * FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a
436457

437-
statement error views do not currently support \* expressions
438-
create view s1 AS SELECT t1.a, t2.* FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a
458+
statement ok
459+
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
439460

440-
statement error views do not currently support \* expressions
441-
create view s1 AS SELECT t1.*, t2.* FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a
461+
statement ok
462+
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
442463

443-
statement error views do not currently support \* expressions
444-
create view s1 AS SELECT * FROM t AS t1 JOIN t AS t2 ON t1.a = t2.a
464+
statement ok
465+
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))
445466

446-
statement error views do not currently support \* expressions
447-
create view s1 AS SELECT t1.a, t2.a FROM (SELECT * FROM t) AS t1 JOIN t AS t2 ON t1.a = t2.a
467+
# This error is the same as in postgres.
468+
statement error duplicate column name: "a"
469+
CREATE VIEW star17 AS SELECT * FROM (SELECT a FROM t) t1 JOIN (SELECT a FROM u) t2 ON true;
448470

449-
statement error views do not currently support \* expressions
450-
create view s1 AS SELECT t1.a, t2.a FROM t AS t1 JOIN (SELECT * FROM t) AS t2 ON t1.a = t2.a
471+
# Ditto for crdb's special feature where subquery aliases can be omitted.
472+
statement error duplicate column name: "a"
473+
CREATE VIEW star17 AS SELECT * FROM (SELECT a FROM t) JOIN (SELECT a FROM u) ON true;
451474

452-
statement error views do not currently support \* expressions
453-
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))
475+
statement ok
476+
CREATE VIEW star17 AS SELECT * FROM (SELECT a FROM t) JOIN (SELECT b FROM u) ON true;
454477

455478
statement ok
456-
create view s1 AS SELECT count(*) FROM t
479+
CREATE VIEW star18 AS SELECT * FROM (SELECT * FROM (SELECT a FROM t));
457480

458481
statement ok
459-
create view s2 AS SELECT a FROM t WHERE a IN (SELECT count(*) FROM t)
482+
CREATE VIEW star19 AS SELECT a FROM (SELECT * FROM (SELECT a FROM t));
460483

461484
statement ok
462-
create view s3 AS SELECT a, count(*) FROM t GROUP BY a
485+
CREATE VIEW star20 AS SELECT ARRAY[z.*]::STRING FROM (SELECT * FROM (SELECT a FROM t), (SELECT a FROM t)) AS z
463486

464487
statement ok
465-
create view s4 AS SELECT a, count(*) FROM t GROUP BY a HAVING a > (SELECT count(*) FROM t)
488+
ALTER TABLE t ADD COLUMN c INT
489+
490+
statement error cannot drop column "b" because view "star1" depends on it
491+
ALTER TABLE t DROP COLUMN b
492+
493+
# See: https://github.com/cockroachdb/cockroach/issues/10083
494+
statement error cannot rename column "b" because view "star1" depends on it
495+
ALTER TABLE t RENAME COLUMN b TO d
496+
497+
query TT
498+
SELECT descriptor_name, create_statement FROM crdb_internal.create_statements WHERE descriptor_name LIKE 'star%' ORDER BY 1
499+
----
500+
star1 CREATE VIEW public.star1 (
501+
a,
502+
b
503+
) AS SELECT t.a, t.b FROM test.public.t
504+
star10 CREATE VIEW public.star10 (
505+
a,
506+
b,
507+
a2
508+
) 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
509+
star11 CREATE VIEW public.star11 (
510+
a1,
511+
a,
512+
b
513+
) 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
514+
star14 CREATE VIEW public.star14 (
515+
a,
516+
a2
517+
) AS SELECT
518+
t1.a, t2.a AS a2
519+
FROM
520+
(SELECT t.a, t.b FROM test.public.t) AS t1 JOIN test.public.t AS t2 ON t1.a = t2.a
521+
star15 CREATE VIEW public.star15 (
522+
a,
523+
a2
524+
) AS SELECT
525+
t1.a, t2.a AS a2
526+
FROM
527+
test.public.t AS t1 JOIN (SELECT t.a, t.b FROM test.public.t) AS t2 ON t1.a = t2.a
528+
star16 CREATE VIEW public.star16 (
529+
a,
530+
a2
531+
) AS SELECT
532+
t1.a, t2.a AS a2
533+
FROM
534+
test.public.t AS t1
535+
JOIN test.public.t AS t2 ON
536+
t1.a IN (SELECT a FROM (SELECT t.a, t.b FROM test.public.t) AS "?subquery1?")
537+
star17 CREATE VIEW public.star17 (
538+
a,
539+
b
540+
) AS SELECT
541+
"?subquery1?".a, "?subquery2?".b
542+
FROM
543+
(SELECT a FROM test.public.t) AS "?subquery1?"
544+
JOIN (SELECT b FROM test.public.u) AS "?subquery2?" ON true
545+
star18 CREATE VIEW public.star18 (
546+
a
547+
) AS SELECT
548+
"?subquery1?".a
549+
FROM
550+
(SELECT "?subquery2?".a FROM (SELECT a FROM test.public.t) AS "?subquery2?")
551+
AS "?subquery1?"
552+
star19 CREATE VIEW public.star19 (
553+
a
554+
) AS SELECT
555+
a
556+
FROM
557+
(SELECT "?subquery2?".a FROM (SELECT a FROM test.public.t) AS "?subquery2?")
558+
AS "?subquery1?"
559+
star2 CREATE VIEW public.star2 (
560+
a,
561+
b
562+
) AS SELECT t.a, t.b FROM test.public.t
563+
star20 CREATE VIEW public.star20 (
564+
"array"
565+
) AS SELECT
566+
ARRAY[z.*]::STRING
567+
FROM
568+
(
569+
SELECT
570+
"?subquery1?".a, "?subquery2?".a
571+
FROM
572+
(SELECT a FROM test.public.t) AS "?subquery1?",
573+
(SELECT a FROM test.public.t) AS "?subquery2?"
574+
)
575+
AS z
576+
star3 CREATE VIEW public.star3 (
577+
a
578+
) AS SELECT a FROM test.public.t ORDER BY t.*
579+
star4 CREATE VIEW public.star4 (
580+
count
581+
) AS SELECT count(1:::INT8) FROM test.public.t GROUP BY t.*
582+
star5 CREATE VIEW public.star5 (
583+
a,
584+
b
585+
) AS SELECT alias.a, alias.b FROM test.public.t AS alias
586+
star6 CREATE VIEW public.star6 (
587+
a,
588+
b
589+
) AS TABLE test.public.t
590+
star7 CREATE VIEW public.star7 (
591+
a
592+
) AS SELECT a FROM (SELECT t.a, t.b FROM test.public.t) AS "?subquery1?"
593+
star8 CREATE VIEW public.star8 (
594+
a
595+
) AS SELECT
596+
a
597+
FROM
598+
test.public.t
599+
WHERE
600+
NOT (a IN (SELECT a FROM (SELECT t.a, t.b FROM test.public.t) AS "?subquery1?"))
601+
star9 CREATE VIEW public.star9 (
602+
a
603+
) AS SELECT
604+
a
605+
FROM
606+
test.public.t
607+
GROUP BY
608+
a
609+
HAVING
610+
a IN (SELECT a FROM (SELECT t.a, t.b FROM test.public.t) AS "?subquery1?")
611+
612+
statement ok
613+
DROP VIEW star1;
614+
DROP VIEW star2;
615+
DROP VIEW star3;
616+
DROP VIEW star4;
617+
DROP VIEW star5;
618+
DROP VIEW star6;
619+
DROP VIEW star7;
620+
DROP VIEW star8;
621+
DROP VIEW star9;
622+
DROP VIEW star10;
623+
DROP VIEW star11;
624+
DROP VIEW star14;
625+
DROP VIEW star15;
626+
DROP VIEW star16;
627+
DROP VIEW star17;
628+
DROP VIEW star18;
629+
DROP VIEW star19;
630+
DROP VIEW star20;
631+
632+
statement ok
633+
CREATE VIEW s1 AS SELECT count(*) FROM t
634+
635+
statement ok
636+
CREATE VIEW s2 AS SELECT a FROM t WHERE a IN (SELECT count(*) FROM t)
637+
638+
statement ok
639+
CREATE VIEW s3 AS SELECT a, count(*) FROM t GROUP BY a
640+
641+
statement ok
642+
CREATE VIEW s4 AS SELECT a, count(*) FROM t GROUP BY a HAVING a > (SELECT count(*) FROM t)
466643

467644
statement ok
468645
DROP VIEW s4
@@ -477,7 +654,7 @@ statement ok
477654
DROP VIEW s1
478655

479656
statement ok
480-
DROP TABLE t
657+
DROP TABLE t; DROP TABLE u
481658

482659
# Check for memory leak (#10466)
483660
statement ok
@@ -1121,7 +1298,7 @@ CREATE VIEW v7_dep AS (SELECT i FROM t6@idx WHERE k < 'a'::typ6)
11211298
statement error cannot drop type "typ6" because other objects \(\[db2.public.t6 db2.public.v7_dep\]\) still depend on it
11221299
DROP TYPE typ6
11231300

1124-
# Test we can create views from various data sources.
1301+
# Test we can CREATE VIEWs from various data sources.
11251302
statement ok
11261303
CREATE SEQUENCE s
11271304

pkg/sql/opt/optbuilder/project.go

Lines changed: 3 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -148,7 +148,7 @@ func (b *Builder) analyzeSelectList(
148148
}
149149

150150
aliases, exprs := b.expandStar(e.Expr, inScope)
151-
if b.insideFuncDef {
151+
if b.insideFuncDef || b.insideViewDef {
152152
expanded = true
153153
for _, expr := range exprs {
154154
switch col := expr.(type) {
@@ -187,11 +187,11 @@ func (b *Builder) analyzeSelectList(
187187
}
188188
alias := b.getColName(e)
189189
outScope.addColumn(scopeColName(tree.Name(alias)), texpr)
190-
if b.insideFuncDef && !expanded {
190+
if (b.insideViewDef || b.insideFuncDef) && !expanded {
191191
expansions = append(expansions, e)
192192
}
193193
}
194-
if b.insideFuncDef {
194+
if b.insideFuncDef || b.insideViewDef {
195195
*selects = expansions
196196
}
197197
}

pkg/sql/opt/optbuilder/testdata/create_view

Lines changed: 15 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -111,11 +111,24 @@ CREATE VIEW v3 (x) AS SELECT a, b FROM ab
111111
----
112112
error (42601): CREATE VIEW specifies 1 column name, but data source has 2 columns
113113

114-
# Verify that we disallow * in view definitions (#10028).
115114
build
116115
CREATE VIEW v4 AS SELECT * FROM ab
117116
----
118-
error (0A000): unimplemented: views do not currently support * expressions
117+
create-view t.public.v4
118+
├── SELECT ab.a, ab.b FROM t.public.ab
119+
├── columns: a:1 b:2
120+
└── dependencies
121+
└── ab [columns: a b]
122+
123+
build
124+
CREATE VIEW v4 AS SELECT ARRAY[z.*]::STRING FROM (SELECT * FROM (SELECT * FROM ab), (SELECT * FROM ab)) AS z
125+
----
126+
create-view t.public.v4
127+
├── 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
128+
├── columns: array:9
129+
└── dependencies
130+
├── ab [columns: a b]
131+
└── ab [columns: a b]
119132

120133
build
121134
CREATE VIEW v5 AS SELECT a FROM [53 AS t]

pkg/sql/opt/optbuilder/util.go

Lines changed: 0 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -23,7 +23,6 @@ import (
2323
"github.com/cockroachdb/cockroach/pkg/sql/sem/tree"
2424
"github.com/cockroachdb/cockroach/pkg/sql/sqlerrors"
2525
"github.com/cockroachdb/cockroach/pkg/sql/types"
26-
"github.com/cockroachdb/cockroach/pkg/util/errorutil/unimplemented"
2726
"github.com/cockroachdb/errors"
2827
)
2928

@@ -61,9 +60,6 @@ func getTypedExprs(exprs []tree.Expr) []tree.TypedExpr {
6160
func (b *Builder) expandStar(
6261
expr tree.Expr, inScope *scope,
6362
) (aliases []string, exprs []tree.TypedExpr) {
64-
if b.insideViewDef {
65-
panic(unimplemented.NewWithIssue(10028, "views do not currently support * expressions"))
66-
}
6763
switch t := expr.(type) {
6864
case *tree.TupleStar:
6965
texpr := inScope.resolveType(t.Expr, types.Any)

0 commit comments

Comments
 (0)