Skip to content

Commit

Permalink
Add the EXISTS Operator for Select Where Filters (#572)
Browse files Browse the repository at this point in the history
EXISTS expression and where filter
  • Loading branch information
Vinai Rachakonda committed Sep 28, 2021
1 parent 915c224 commit 88a5e4a
Show file tree
Hide file tree
Showing 7 changed files with 316 additions and 16 deletions.
37 changes: 21 additions & 16 deletions enginetest/memory_engine_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -124,30 +124,35 @@ func TestSingleScript(t *testing.T) {
{
Name: "Issue #499",
SetUpScript: []string{
"CREATE TABLE test (time TIMESTAMP, value DOUBLE);",
`INSERT INTO test VALUES
("2021-07-04 10:00:00", 1.0),
("2021-07-03 10:00:00", 2.0),
("2021-07-02 10:00:00", 3.0),
("2021-07-01 10:00:00", 4.0);`,
"CREATE TABLE test (pk int primary key);",
`INSERT INTO test values (1),(2);`,
`CREATE TABLE t2 (pk int)`,
`INSERT INTO t2 VALUES (NULL)`,
},
Assertions: []enginetest.ScriptTestAssertion{
{
Query: `SELECT
UNIX_TIMESTAMP(time) DIV 60 * 60 AS "time",
avg(value) AS "value"
FROM test
GROUP BY 1
ORDER BY UNIX_TIMESTAMP(time) DIV 60 * 60`,
Query: `SELECT * FROM test WHERE EXISTS (SELECT pk FROM t2)`,
Expected: []sql.Row{
{1625133600, 4.0},
{1625220000, 3.0},
{1625306400, 2.0},
{1625392800, 1.0},
{1},
{2},
},
},
},
},
{
Name: "Issue #499",
SetUpScript: []string{
"CREATE TABLE test2 (pk int primary key);",
`INSERT INTO test2 values (1),(2);`,
`CREATE TABLE t2 (pk int)`,
},
Assertions: []enginetest.ScriptTestAssertion{
{
Query: `SELECT * FROM test2 WHERE EXISTS (SELECT pk FROM t2)`,
Expected: []sql.Row{},
},
},
},
}

for _, test := range scripts {
Expand Down
48 changes: 48 additions & 0 deletions enginetest/queries.go
Original file line number Diff line number Diff line change
Expand Up @@ -5284,6 +5284,50 @@ var QueryTests = []QueryTest{
{time.Date(2020, 1, 1, 16, 0, 0, 0, time.UTC)},
},
},
{
Query: `SELECT 1 from dual WHERE EXISTS (SELECT 1 from dual);`,
Expected: []sql.Row{
{1},
},
},
{
Query: `SELECT 1 from dual WHERE EXISTS (SELECT NULL from dual);`,
Expected: []sql.Row{
{1},
},
},
{
Query: `SELECT * FROM two_pk WHERE EXISTS (SELECT pk FROM one_pk WHERE pk > 4)`,
Expected: []sql.Row{},
},
{
Query: `SELECT 2 + 2 WHERE NOT EXISTS (SELECT pk FROM one_pk WHERE pk > 4)`,
Expected: []sql.Row{{4}},
},
{
Query: `SELECT distinct pk1 FROM two_pk WHERE EXISTS (SELECT pk from one_pk where pk <= two_pk.pk1)`,
Expected: []sql.Row{{0}, {1}},
},
{
Query: `select pk from one_pk where exists (SELECT pk1 FROM two_pk);`,
Expected: []sql.Row{{0}, {1}, {2}, {3}},
},
{
Query: `SELECT EXISTS (SELECT NULL from dual);`,
Expected: []sql.Row{{true}},
},
{
Query: `SELECT NOT EXISTS (SELECT NULL FROM dual)`,
Expected: []sql.Row{{false}},
},
{
Query: `select exists (SELECT pk1 FROM two_pk);`,
Expected: []sql.Row{{true}},
},
{
Query: `SELECT EXISTS (SELECT pk FROM one_pk WHERE pk > 4)`,
Expected: []sql.Row{{false}},
},
}

var KeylessQueries = []QueryTest{
Expand Down Expand Up @@ -6471,6 +6515,10 @@ var errorQueries = []QueryErrorTest{
Query: "select ((4,5),((1,2),3)) = ((1,2),(4,5)) from dual",
ExpectedErr: sql.ErrInvalidOperandColumns,
},
{
Query: "SELECT (2, 2)=1 FROM dual where exists (SELECT 1 FROM dual)",
ExpectedErr: sql.ErrInvalidOperandColumns,
},
}

// WriteQueryTest is a query test for INSERT, UPDATE, etc. statements. It has a query to run and a select query to
Expand Down
15 changes: 15 additions & 0 deletions enginetest/script_queries.go
Original file line number Diff line number Diff line change
Expand Up @@ -1170,6 +1170,21 @@ var ScriptTests = []ScriptTest{
},
},
},
{
Name: "Slightly more complex example for the Exists Clause",
SetUpScript: []string{
"create table store(store_id int, item_id int, primary key (store_id, item_id))",
"create table items(item_id int primary key, price int)",
"insert into store values (0, 1), (0,2),(0,3),(1,2),(1,4),(2,1)",
"insert into items values (1, 10), (2, 20), (3, 30),(4,40)",
},
Assertions: []ScriptTestAssertion{
{
Query: "SELECT * from store WHERE EXISTS (SELECT price from items where price > 10 and store.item_id = items.item_id)",
Expected: []sql.Row{{0, 2}, {0, 3}, {1, 2}, {1, 4}},
},
},
},
}

var CreateCheckConstraintsScripts = []ScriptTest{
Expand Down
7 changes: 7 additions & 0 deletions sql/parse/parse.go
Original file line number Diff line number Diff line change
Expand Up @@ -2436,6 +2436,13 @@ func ExprToExpression(ctx *sql.Context, e sqlparser.Expr) (sql.Expression, error
return nil, err
}
return expression.NewUnresolvedFunction("values", false, nil, col), nil
case *sqlparser.ExistsExpr:
subqueryExp, err := ExprToExpression(ctx, v.Subquery)
if err != nil {
return nil, err
}

return plan.NewExistsSubquery(subqueryExp), nil
}
}

Expand Down
85 changes: 85 additions & 0 deletions sql/plan/existssubquery.go
Original file line number Diff line number Diff line change
@@ -0,0 +1,85 @@
// Copyright 2020-2021 Dolthub, Inc.
//
// Licensed under the Apache License, Version 2.0 (the "License");
// you may not use this file except in compliance with the License.
// You may obtain a copy of the License at
//
// http://www.apache.org/licenses/LICENSE-2.0
//
// Unless required by applicable law or agreed to in writing, software
// distributed under the License is distributed on an "AS IS" BASIS,
// WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
// See the License for the specific language governing permissions and
// limitations under the License.

package plan

import (
"fmt"

"github.com/dolthub/go-mysql-server/sql"
"github.com/dolthub/go-mysql-server/sql/expression"
)

// ExistsSubquery is an expression that checks that a subquery returns a non-empty result set. It's in the plan package,
// instead of the expression package, because Subquery is itself in the plan package (because it functions more like a
// plan node than an expression in its evaluation).
type ExistsSubquery struct {
subquery expression.UnaryExpression
}

var _ sql.Expression = (*ExistsSubquery)(nil)

//NewExistsSubquery created an ExistsSubquery expression.
func NewExistsSubquery(query sql.Expression) *ExistsSubquery {
return &ExistsSubquery{expression.UnaryExpression{Child: query}}
}

// Eval implements the Expression interface.
func (e *ExistsSubquery) Eval(ctx *sql.Context, row sql.Row) (interface{}, error) {
subquery, ok := e.subquery.Child.(*Subquery)
if !ok {
return nil, fmt.Errorf("error: exists operator should only work with a subquery")
}

hasResultRow, err := subquery.HasResultRow(ctx, row)
if err != nil {
return nil, err
}

return hasResultRow, nil
}

// WithChildren implements the Expression interface.
func (e *ExistsSubquery) WithChildren(children ...sql.Expression) (sql.Expression, error) {
if len(children) != 1 {
return nil, sql.ErrInvalidChildrenNumber.New(e, len(children), 1)
}

return NewExistsSubquery(children[0]), nil
}

// Resolved implements the Expression interface.
func (e *ExistsSubquery) Resolved() bool {
return e.subquery.Resolved()
}

// IsNullable implements the Expression interface.
func (e *ExistsSubquery) IsNullable() bool {
return false
}

// Children implements the Expression interface.
func (e *ExistsSubquery) Children() []sql.Expression {
return []sql.Expression{e.subquery.Child}
}

// String implements the Expression interface.
func (e *ExistsSubquery) String() string {
return fmt.Sprintf("EXISTS %s", e.subquery)
}

// Type implements the Expression interface.
func (e *ExistsSubquery) Type() sql.Type {
return sql.Boolean
}
99 changes: 99 additions & 0 deletions sql/plan/existssubquery_test.go
Original file line number Diff line number Diff line change
@@ -0,0 +1,99 @@
// Copyright 2020-2021 Dolthub, Inc.
//
// Licensed under the Apache License, Version 2.0 (the "License");
// you may not use this file except in compliance with the License.
// You may obtain a copy of the License at
//
// http://www.apache.org/licenses/LICENSE-2.0
//
// Unless required by applicable law or agreed to in writing, software
// distributed under the License is distributed on an "AS IS" BASIS,
// WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
// See the License for the specific language governing permissions and
// limitations under the License.

package plan_test

import (
"testing"

"github.com/stretchr/testify/require"

"github.com/dolthub/go-mysql-server/memory"
"github.com/dolthub/go-mysql-server/sql"
"github.com/dolthub/go-mysql-server/sql/expression"
"github.com/dolthub/go-mysql-server/sql/plan"
)

func TestExistsSubquery(t *testing.T) {
ctx := sql.NewEmptyContext()
table := memory.NewTable("foo", sql.Schema{
{Name: "t", Source: "foo", Type: sql.Text},
})

require.NoError(t, table.Insert(ctx, sql.Row{"one"}))
require.NoError(t, table.Insert(ctx, sql.Row{"two"}))
require.NoError(t, table.Insert(ctx, sql.Row{"three"}))

emptyTable := memory.NewTable("empty", sql.Schema{
{Name: "t", Source: "empty", Type: sql.Int64},
})

project := func(expr sql.Expression, tbl *memory.Table) sql.Node {
return plan.NewProject([]sql.Expression{
expr,
}, plan.NewResolvedTable(tbl, nil, nil))
}

testCases := []struct {
name string
subquery sql.Node
row sql.Row
result interface{}
}{
{
"Null returns as true",
project(
expression.NewGetField(1, sql.Text, "foo", false), table,
),
sql.NewRow(nil),
true,
},
{
"Non NULL evaluates as true",
project(
expression.NewGetField(1, sql.Text, "foo", false), table,
),
sql.NewRow("four"),
true,
},
{
"Empty Set Passes",
project(
expression.NewGetField(1, sql.Text, "foo", false), emptyTable,
),
sql.NewRow(),
false,
},
}

for _, tt := range testCases {
t.Run(tt.name, func(t *testing.T) {
require := require.New(t)

result, err := plan.NewExistsSubquery(
plan.NewSubquery(tt.subquery, ""),
).Eval(sql.NewEmptyContext(), tt.row)
require.NoError(err)
require.Equal(tt.result, result)

// Test Not Exists
result, err = expression.NewNot(plan.NewExistsSubquery(
plan.NewSubquery(tt.subquery, ""),
)).Eval(sql.NewEmptyContext(), tt.row)

require.NoError(err)
require.Equal(tt.result, !result.(bool))
})
}
}
41 changes: 41 additions & 0 deletions sql/plan/subquery.go
Original file line number Diff line number Diff line change
Expand Up @@ -316,6 +316,47 @@ func (s *Subquery) HashMultiple(ctx *sql.Context, row sql.Row) (sql.KeyValueCach
return cache, putAllRows(cache, result)
}

// HasResultRow returns whether the subquery has a result set > 0.
func (s *Subquery) HasResultRow(ctx *sql.Context, row sql.Row) (bool, error) {
// First check if the query was cached.
s.cacheMu.Lock()
cached := s.resultsCached
s.cacheMu.Unlock()

if cached {
return len(s.cache) > 0, nil
}

// Any source of rows, as well as any node that alters the schema of its children, needs to be wrapped so that its
// result rows are prepended with the scope row.
q, err := TransformUp(s.Query, prependRowInPlan(row))
if err != nil {
return false, err
}

iter, err := q.RowIter(ctx, row)
if err != nil {
return false, err
}

// Call the iterator once and see if it has a row. If io.EOF is received return false.
_, err = iter.Next()
if err == io.EOF {
return false, nil
}

if err != nil {
return false, err
}

err = iter.Close(ctx)
if err != nil {
return false, err
}

return true, nil
}

func putAllRows(cache sql.KeyValueCache, vals []interface{}) error {
for _, val := range vals {
rowKey, err := sql.HashOf(sql.NewRow(val))
Expand Down

0 comments on commit 88a5e4a

Please sign in to comment.