Skip to content

Commit

Permalink
Support BETWEEN in the evalengine (#12150)
Browse files Browse the repository at this point in the history
* add translation for between comparisons in the evalengine

Signed-off-by: Andres Taylor <[email protected]>

* add end to end test

Signed-off-by: Andres Taylor <[email protected]>

* add support for NOT BETWEEN

Signed-off-by: Andres Taylor <[email protected]>

* fix translation of NOT BETWEEN

Signed-off-by: Andres Taylor <[email protected]>

* assert no matter the order of the results

Signed-off-by: Andres Taylor <[email protected]>

Signed-off-by: Andres Taylor <[email protected]>
  • Loading branch information
systay authored Jan 26, 2023
1 parent ee30456 commit 47feece
Show file tree
Hide file tree
Showing 4 changed files with 104 additions and 0 deletions.
17 changes: 17 additions & 0 deletions go/test/endtoend/vtgate/queries/misc/misc_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -185,3 +185,20 @@ func TestCast(t *testing.T) {
mcmp.AssertMatches("select cast('3.2' as double)", `[[FLOAT64(3.2)]]`)
mcmp.AssertMatches("select cast('3.2' as unsigned)", `[[UINT64(3)]]`)
}

func TestOuterJoinWithPredicate(t *testing.T) {
mcmp, closer := start(t)
defer closer()

// This test uses a predicate on the outer side.
// These can't be pushed down to MySQL and have
// to be evaluated on the vtgate, so we are checking
// that evalengine handles the predicate correctly

mcmp.Exec("insert into t1(id1, id2) values (0,0), (1,10), (2,20), (3,30), (4,40)")

mcmp.AssertMatchesNoOrder("select A.id1, B.id2 from t1 as A left join t1 as B on A.id1*10 = B.id2 WHERE B.id2 BETWEEN 20 AND 30",
`[[INT64(2) INT64(20)] [INT64(3) INT64(30)]]`)
mcmp.AssertMatchesNoOrder("select A.id1, B.id2 from t1 as A left join t1 as B on A.id1*10 = B.id2 WHERE B.id2 NOT BETWEEN 20 AND 30",
`[[INT64(0) INT64(0)] [INT64(1) INT64(10)] [INT64(4) INT64(40)]]`)
}
25 changes: 25 additions & 0 deletions go/vt/vtgate/evalengine/translate.go
Original file line number Diff line number Diff line change
Expand Up @@ -570,6 +570,29 @@ func translateCaseExpr(node *sqlparser.CaseExpr, lookup TranslationLookup) (Expr
return &result, nil
}

func translateBetweenExpr(node *sqlparser.BetweenExpr, lookup TranslationLookup) (Expr, error) {
// x BETWEEN a AND b => x >= a AND x <= b
from := &sqlparser.ComparisonExpr{
Operator: sqlparser.GreaterEqualOp,
Left: node.Left,
Right: node.From,
}
to := &sqlparser.ComparisonExpr{
Operator: sqlparser.LessEqualOp,
Left: node.Left,
Right: node.To,
}

if !node.IsBetween {
// x NOT BETWEEN a AND b => x < a OR x > b
from.Operator = sqlparser.LessThanOp
to.Operator = sqlparser.GreaterThanOp
return translateExpr(&sqlparser.OrExpr{Left: from, Right: to}, lookup)
}

return translateExpr(sqlparser.AndExpressions(from, to), lookup)
}

func translateExprNotSupported(e sqlparser.Expr) error {
return vterrors.Errorf(vtrpcpb.Code_UNIMPLEMENTED, "%s: %s", ErrTranslateExprNotSupported, sqlparser.String(e))
}
Expand Down Expand Up @@ -629,6 +652,8 @@ func translateExpr(e sqlparser.Expr, lookup TranslationLookup) (Expr, error) {
return translateConvertUsingExpr(node, lookup)
case *sqlparser.CaseExpr:
return translateCaseExpr(node, lookup)
case *sqlparser.BetweenExpr:
return translateBetweenExpr(node, lookup)
default:
return nil, translateExprNotSupported(e)
}
Expand Down
3 changes: 3 additions & 0 deletions go/vt/vtgate/evalengine/translate_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -104,6 +104,9 @@ func TestTranslateSimplification(t *testing.T) {
{"ifnull(null, 23)", ok(`CASE WHEN NULL IS NULL THEN INT64(23) ELSE NULL`), ok(`INT64(23)`)},
{"nullif(1, 1)", ok(`CASE WHEN INT64(1) = INT64(1) THEN NULL ELSE INT64(1)`), ok(`NULL`)},
{"nullif(1, 2)", ok(`CASE WHEN INT64(1) = INT64(2) THEN NULL ELSE INT64(1)`), ok(`INT64(1)`)},
{"12 between 5 and 20", ok("(INT64(12) >= INT64(5)) AND (INT64(12) <= INT64(20))"), ok(`INT64(1)`)},
{"12 not between 5 and 20", ok("(INT64(12) < INT64(5)) OR (INT64(12) > INT64(20))"), ok(`INT64(0)`)},
{"2 not between 5 and 20", ok("(INT64(2) < INT64(5)) OR (INT64(2) > INT64(20))"), ok(`INT64(1)`)},
}

for _, tc := range testCases {
Expand Down
59 changes: 59 additions & 0 deletions go/vt/vtgate/planbuilder/testdata/from_cases.json
Original file line number Diff line number Diff line change
Expand Up @@ -6284,5 +6284,64 @@
"user.user_extra"
]
}
},
{
"comment": "left join where clauses #3 - assert that we can evaluate BETWEEN with the evalengine",
"query": "select user.id from user left join user_extra on user.col = user_extra.col where user_extra.col between 10 and 20",
"plan": {
"QueryType": "SELECT",
"Original": "select user.id from user left join user_extra on user.col = user_extra.col where user_extra.col between 10 and 20",
"Instructions": {
"OperatorType": "SimpleProjection",
"Columns": [
1
],
"Inputs": [
{
"OperatorType": "Filter",
"Predicate": "user_extra.col between 10 and 20",
"Inputs": [
{
"OperatorType": "Join",
"Variant": "LeftJoin",
"JoinColumnIndexes": "R:0,L:1",
"JoinVars": {
"user_col": 0
},
"TableName": "`user`_user_extra",
"Inputs": [
{
"OperatorType": "Route",
"Variant": "Scatter",
"Keyspace": {
"Name": "user",
"Sharded": true
},
"FieldQuery": "select `user`.col, `user`.id from `user` where 1 != 1",
"Query": "select `user`.col, `user`.id from `user`",
"Table": "`user`"
},
{
"OperatorType": "Route",
"Variant": "Scatter",
"Keyspace": {
"Name": "user",
"Sharded": true
},
"FieldQuery": "select user_extra.col from user_extra where 1 != 1",
"Query": "select user_extra.col from user_extra where user_extra.col = :user_col",
"Table": "user_extra"
}
]
}
]
}
]
},
"TablesUsed": [
"user.user",
"user.user_extra"
]
}
}
]

0 comments on commit 47feece

Please sign in to comment.