Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

sql: add support for subqueries with ANY/SOME/ALL operations #18094

Merged
merged 6 commits into from
Sep 6, 2017
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
360 changes: 360 additions & 0 deletions pkg/sql/logictest/testdata/logic_test/suboperators
Original file line number Diff line number Diff line change
@@ -0,0 +1,360 @@
# LogicTest: default parallel-stmts distsql

statement ok
CREATE TABLE abc (a INT, b INT, C INT)

statement ok
INSERT INTO abc VALUES (1, 10, 100), (2, 20, 200), (3, 30, 300)

# ANY/SOME with arrays.

query B
SELECT 1 = ANY(ARRAY[1, 2])
----
true

query B
SELECT 1 = SOME(ARRAY[1, 2])
----
true

query B
SELECT 1 = ANY(ARRAY[3, 4])
----
false

query B
SELECT 1 < ANY(ARRAY[0, 5])
----
true

query B
SELECT 1 < ANY(ARRAY[0, 1])
----
false

query B
SELECT 1 = ANY(ARRAY[1.0, 1.1])
----
true

query B
SELECT 1 < ANY(ARRAY[1.0, 1.1])
----
true

query B
SELECT 1 = ANY(ARRAY[1, NULL])
----
true

query T
SELECT 1 = ANY(ARRAY[2, NULL])
----
NULL

query T
SELECT 1 = ANY(ARRAY[NULL, NULL])
----
NULL

query B
SELECT 1 = ANY(ARRAY[1,2] || 3)
----
true

query B
SELECT 1 = ANY(ARRAY[2,3] || 1)
----
true

query B
SELECT 1 = ANY(ARRAY[2,3] || 4)
----
false

query III
SELECT * FROM abc WHERE a = ANY(ARRAY[1,3]) ORDER BY a
----
1 10 100
3 30 300

query III
SELECT * FROM abc WHERE a = ANY(ARRAY[4, 5])
----

query III
SELECT * FROM abc WHERE a = ANY(ARRAY[1, NULL])
----
1 10 100

query III
SELECT * FROM abc WHERE a = ANY(ARRAY[4, NULL])
----

query III
SELECT * FROM abc WHERE a = ANY(ARRAY[NULL, NULL])
----

query error unsupported comparison operator: 1 = ANY \(ARRAY\['foo', 'bar'\]\)
SELECT 1 = ANY(ARRAY['foo', 'bar'])

query error unsupported comparison operator: <int> = ANY <string\[\]>
SELECT 1 = ANY(ARRAY['foo'] || 'bar')

# ANY/SOME with subqueries.

query B
SELECT 1 = ANY(SELECT * FROM generate_series(1,3))
----
true

query B
SELECT 1 = ANY(SELECT * FROM generate_series(2,4))
----
false

query B
SELECT 1 < ANY(SELECT * FROM generate_series(1,3))
----
true

query B
SELECT 1 < ANY(SELECT * FROM generate_series(0,1))
----
false

query B
SELECT 1 = ANY(SELECT * FROM unnest(ARRAY[1.0, 1.1]))
----
true

query B
SELECT 1 < ANY(SELECT * FROM unnest(ARRAY[1.0, 1.1]))
----
true

query B
SELECT 1 = ANY(SELECT * FROM unnest(ARRAY[1.0001, 2]))
----
false

query B
SELECT 1 = ANY(SELECT * FROM unnest(ARRAY[1, NULL]))
----
true

query T
SELECT 1 = ANY(SELECT * FROM unnest(ARRAY[2, NULL]))
----
NULL

query T
SELECT 1 = ANY(SELECT * FROM unnest(ARRAY[NULL, NULL]))
----
NULL

query III
SELECT * FROM abc WHERE a = ANY(SELECT a FROM abc WHERE b = 10)
----
1 10 100

query III
SELECT * FROM abc WHERE a < ANY(SELECT a FROM abc WHERE b = 30) ORDER BY a
----
1 10 100
2 20 200

query III
SELECT * FROM abc WHERE a > ANY(SELECT a FROM abc WHERE b = 30)
----

query III
SELECT * FROM abc WHERE a = ANY(SELECT * FROM unnest(ARRAY[1, NULL]))
----
1 10 100

query III
SELECT * FROM abc WHERE a = ANY(SELECT * FROM unnest(ARRAY[4, NULL]))
----

query III
SELECT * FROM abc WHERE a = ANY(SELECT * FROM unnest(ARRAY[NULL, NULL]))
----

query error unsupported comparison operator: <int> = ANY <tuple\{string\}>
SELECT 1 = ANY(SELECT * FROM unnest(ARRAY['foo', 'bar']))

# ALL with arrays.

query B
SELECT 1 = ALL(ARRAY[1, 1, 1.0])
----
true

query B
SELECT 1 = ALL(ARRAY[1, 1.001, 1.0])
----
false

query B
SELECT 5 > ALL(ARRAY[1, 2, 3])
----
true

query B
SELECT 5 > ALL(ARRAY[6, 7, 8])
----
false

query B
SELECT 5 > ALL(ARRAY[4, 6, 7])
----
false

query B
SELECT 1 = ALL(ARRAY[2, NULL])
----
false

query T
SELECT 1 = ALL(ARRAY[1, NULL])
----
NULL

query T
SELECT 1 = ALL(ARRAY[NULL, NULL])
----
NULL

query B
SELECT 5 > ALL(ARRAY[1, 2] || 3)
----
true

query B
SELECT 5 > ALL(ARRAY[6, 7] || 8)
----
false

query III
SELECT * FROM abc WHERE a > ALL(ARRAY[0, 1]) ORDER BY a
----
2 20 200
3 30 300

query III
SELECT * FROM abc WHERE a > ALL(ARRAY[1, 4])
----

query III
SELECT * FROM abc WHERE a > ALL(ARRAY[1, NULL])
----

query III
SELECT * FROM abc WHERE a > ALL(ARRAY[NULL, NULL])
----

query error unsupported comparison operator: 1 = ALL \(ARRAY\['foo', 'bar'\]\)
SELECT 1 = ALL(ARRAY['foo', 'bar'])

query error unsupported comparison operator: <int> = ALL <string\[\]>
SELECT 1 = ALL(ARRAY['foo'] || 'bar')

# ALL with subqueries.

query B
SELECT 1 = ALL(SELECT * FROM unnest(ARRAY[1,1,1]))
----
true

query B
SELECT 1 = ALL(SELECT * FROM unnest(ARRAY[1,2,3]))
----
false

query B
SELECT 1 < ALL(SELECT * FROM generate_series(2,5))
----
true

query B
SELECT 1 < ALL(SELECT * FROM generate_series(1,3))
----
false

query B
SELECT 1 = ALL(SELECT * FROM unnest(ARRAY[2, NULL]))
----
false

query T
SELECT 1 = ALL(SELECT * FROM unnest(ARRAY[1, NULL]))
----
NULL

query T
SELECT 1 = ALL(SELECT * FROM unnest(ARRAY[NULL, NULL]))
----
NULL

query III
SELECT * FROM abc WHERE a < ALL(SELECT b FROM abc) ORDER BY a
----
1 10 100
2 20 200
3 30 300

query III
SELECT * FROM abc WHERE a < ALL(SELECT a FROM abc WHERE a >= 2)
----
1 10 100

query III
SELECT * FROM abc WHERE a < ALL(SELECT a FROM abc)
----

query III
SELECT * FROM abc WHERE a > ALL(SELECT * FROM unnest(ARRAY[1, NULL]))
----

query III
SELECT * FROM abc WHERE a > ALL(SELECT * FROM unnest(ARRAY[NULL, NULL]))
----

query error unsupported comparison operator: <int> = ALL <tuple\{string\}>
SELECT 1 = ALL(SELECT * FROM unnest(ARRAY['foo', 'bar']))

# ANY/ALL with tuples.

query B
SELECT 1 = ANY (1, 2, 3)
----
true

query B
SELECT 1 = ANY (2, 3, 4)
----
false

query error incompatible tuple element type: decimal
SELECT 1 = ANY (1, 1.1)

query B
SELECT 1::decimal = ANY (1, 1.1)
----
true

query error incompatible tuple element type: decimal
SELECT 1 = ANY (1.0, 1.1)

query B
SELECT 1::decimal = ANY (1.0, 1.1)
----
true

query error could not parse \"hello\" as type int
SELECT 1 = ANY (1, 'hello', 3)

query error unsupported comparison operator: <int> = ANY <tuple{}>
SELECT 1 = ANY ROW()
14 changes: 14 additions & 0 deletions pkg/sql/parser/datum.go
Original file line number Diff line number Diff line change
Expand Up @@ -1750,6 +1750,20 @@ func NewDTupleWithCap(c int) *DTuple {
return &DTuple{D: make(Datums, 0, c)}
}

// AsDTuple attempts to retrieve a *DTuple from an Expr, returning a *DTuple and
// a flag signifying whether the assertion was successful. The function should
// be used instead of direct type assertions wherever a *DTuple wrapped by a
// *DOidWrapper is possible.
func AsDTuple(e Expr) (*DTuple, bool) {
switch t := e.(type) {
case *DTuple:
return t, true
case *DOidWrapper:
return AsDTuple(t.Wrapped)
}
return nil, false
}

// ResolvedType implements the TypedExpr interface.
func (d *DTuple) ResolvedType() Type {
typ := make(TTuple, len(d.D))
Expand Down
Loading