-
-
Notifications
You must be signed in to change notification settings - Fork 205
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
Add the EXISTS Operator for Select Where Filters #572
Merged
Merged
Changes from all commits
Commits
Show all changes
11 commits
Select commit
Hold shift + click to select a range
3c402c4
kinda works
VinaiRachakonda 0d21785
better implementation
VinaiRachakonda d6bf830
format repo
VinaiRachakonda 7b200df
cleanup
VinaiRachakonda e60b8e8
try something else
VinaiRachakonda f73b90b
Merge branch 'master' into vinai/exists-operator
VinaiRachakonda 1f544a7
get rid of ctx
VinaiRachakonda ba18abe
add tests and edit typo
VinaiRachakonda 4c0f4c5
add tests for exists expressiona and add hasResults func
VinaiRachakonda 3e89180
add cache
VinaiRachakonda 85aec08
close the iterator
VinaiRachakonda File filter
Filter by extension
Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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 | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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)) | ||
}) | ||
} | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Need a test of the EXISTS expression not in the filter
i.e.
SELECT EXISTS (SELECT NULL from dual);