Skip to content

Commit

Permalink
sql: add support for intervals, DATE_SUB and DATE_ADD
Browse files Browse the repository at this point in the history
Fixes src-d#663

This PR introduces a few new features:
- Correctly parsing interval expressions.
- Allow using the + and - operators to subtract from and add to
  dates. e.g. `'2019-04-10' - INTERVAL 1 DAY`.
- New `DATE_ADD` function, which is essentially the same as
  `DATE + INTERVAL`.
- New `DATE_SUB` function, which is essentially the same as
  `DATE - INTERVAL`.
- Validation rule to ensure intervals are only used in certain
  specific places, such as DATE_SUB, DATE_ADD, + and -. Using it
  anywhere else is not valid SQL, but vitess does not catch those
  errors. Plus, even if it's an expression for convenience, its
  `Eval` method is a stub and panics, so it should not be used
  unless it's in an expression that knows how to deal with intervals.

Signed-off-by: Miguel Molina <miguel@erizocosmi.co>
  • Loading branch information
erizocosmico committed Apr 11, 2019
1 parent d03de5f commit 69d26d9
Show file tree
Hide file tree
Showing 14 changed files with 1,206 additions and 22 deletions.
2 changes: 2 additions & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -68,6 +68,8 @@ We support and actively test against certain third-party clients to ensure compa
|`CONCAT_WS(sep, ...)`|Concatenate any group of fields into a single string. The first argument is the separator for the rest of the arguments. The separator is added between the strings to be concatenated. The separator can be a string, as can the rest of the arguments. If the separator is NULL, the result is NULL.|
|`CONNECTION_ID()`|Return the current connection ID.|
|`COUNT(expr)`| Returns a count of the number of non-NULL values of expr in the rows retrieved by a SELECT statement.|
|`DATE_ADD(date, interval)`|Adds the interval to the given date.|
|`DATE_SUB(date, interval)`|Subtracts the interval from the given date.|
|`DAY(date)`|Returns the day of the given date.|
|`DAYOFWEEK(date)`|Returns the day of the week of the given date.|
|`DAYOFYEAR(date)`|Returns the day of the year of the given date.|
Expand Down
7 changes: 5 additions & 2 deletions SUPPORTED.md
Original file line number Diff line number Diff line change
Expand Up @@ -50,6 +50,7 @@
- USE
- SHOW DATABASES
- SHOW WARNINGS
- INTERVALS

## Index expressions
- CREATE INDEX (an index can be created using either column names or a single arbitrary expression).
Expand All @@ -67,8 +68,8 @@
- OR

## Arithmetic expressions
- \+
- \-
- \+ (including between dates and intervals)
- \- (including between dates and intervals)
- \*
- \\
- <<
Expand Down Expand Up @@ -121,3 +122,5 @@
- SECOND
- YEAR
- NOW
- DATE_ADD
- DATE_SUB
16 changes: 16 additions & 0 deletions engine_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -877,6 +877,22 @@ var queries = []struct {
"SELECT substring(s, 1, 1), count(*) FROM mytable GROUP BY substring(s, 1, 1)",
[]sql.Row{{"f", int64(1)}, {"s", int64(1)}, {"t", int64(1)}},
},
{
"SELECT DATE_ADD('2018-05-02', INTERVAL 1 DAY)",
[]sql.Row{{time.Date(2018, time.May, 3, 0, 0, 0, 0, time.UTC)}},
},
{
"SELECT DATE_SUB('2018-05-02', INTERVAL 1 DAY)",
[]sql.Row{{time.Date(2018, time.May, 1, 0, 0, 0, 0, time.UTC)}},
},
{
"SELECT '2018-05-02' + INTERVAL 1 DAY",
[]sql.Row{{time.Date(2018, time.May, 3, 0, 0, 0, 0, time.UTC)}},
},
{
"SELECT '2018-05-02' - INTERVAL 1 DAY",
[]sql.Row{{time.Date(2018, time.May, 1, 0, 0, 0, 0, time.UTC)}},
},
}

func TestQueries(t *testing.T) {
Expand Down
38 changes: 38 additions & 0 deletions sql/analyzer/validation_rules.go
Original file line number Diff line number Diff line change
Expand Up @@ -6,6 +6,7 @@ import (
errors "gopkg.in/src-d/go-errors.v1"
"gopkg.in/src-d/go-mysql-server.v0/sql"
"gopkg.in/src-d/go-mysql-server.v0/sql/expression"
"gopkg.in/src-d/go-mysql-server.v0/sql/expression/function"
"gopkg.in/src-d/go-mysql-server.v0/sql/plan"
)

Expand All @@ -17,6 +18,7 @@ const (
validateProjectTuplesRule = "validate_project_tuples"
validateIndexCreationRule = "validate_index_creation"
validateCaseResultTypesRule = "validate_case_result_types"
validateIntervalUsageRule = "validate_interval_usage"
)

var (
Expand All @@ -43,6 +45,12 @@ var (
"expecting all case branches to return values of type %s, " +
"but found value %q of type %s on %s",
)
// ErrIntervalInvalidUse is returned when an interval expression is not
// correctly used.
ErrIntervalInvalidUse = errors.NewKind(
"invalid use of an interval, which can only be used with DATE_ADD, " +
"DATE_SUB and +/- operators to subtract from or add to a date",
)
)

// DefaultValidationRules to apply while analyzing nodes.
Expand All @@ -54,6 +62,7 @@ var DefaultValidationRules = []Rule{
{validateProjectTuplesRule, validateProjectTuples},
{validateIndexCreationRule, validateIndexCreation},
{validateCaseResultTypesRule, validateCaseResultTypes},
{validateIntervalUsageRule, validateIntervalUsage},
}

func validateIsResolved(ctx *sql.Context, a *Analyzer, n sql.Node) (sql.Node, error) {
Expand Down Expand Up @@ -243,6 +252,35 @@ func validateCaseResultTypes(ctx *sql.Context, a *Analyzer, n sql.Node) (sql.Nod
return n, nil
}

func validateIntervalUsage(ctx *sql.Context, a *Analyzer, n sql.Node) (sql.Node, error) {
var invalid bool
plan.InspectExpressions(n, func(e sql.Expression) bool {
// If it's already invalid just skip everything else.
if invalid {
return false
}

switch e := e.(type) {
case *function.DateAdd, *function.DateSub:
return false
case *expression.Arithmetic:
if e.Op == "+" || e.Op == "-" {
return false
}
case *expression.Interval:
invalid = true
}

return true
})

if invalid {
return nil, ErrIntervalInvalidUse.New()
}

return n, nil
}

func stringContains(strs []string, target string) bool {
for _, s := range strs {
if s == target {
Expand Down
124 changes: 124 additions & 0 deletions sql/analyzer/validation_rules_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -6,6 +6,7 @@ import (
"gopkg.in/src-d/go-mysql-server.v0/mem"
"gopkg.in/src-d/go-mysql-server.v0/sql"
"gopkg.in/src-d/go-mysql-server.v0/sql/expression"
"gopkg.in/src-d/go-mysql-server.v0/sql/expression/function"
"gopkg.in/src-d/go-mysql-server.v0/sql/expression/function/aggregation"
"gopkg.in/src-d/go-mysql-server.v0/sql/plan"

Expand Down Expand Up @@ -431,6 +432,129 @@ func TestValidateCaseResultTypes(t *testing.T) {
}
}

func mustFunc(e sql.Expression, err error) sql.Expression {
if err != nil {
panic(err)
}
return e
}

func TestValidateIntervalUsage(t *testing.T) {
testCases := []struct {
name string
node sql.Node
ok bool
}{
{
"date add",
plan.NewProject(
[]sql.Expression{
mustFunc(function.NewDateAdd(
expression.NewLiteral("2018-05-01", sql.Text),
expression.NewInterval(
expression.NewLiteral(int64(1), sql.Int64),
"DAY",
),
)),
},
plan.NewUnresolvedTable("dual", ""),
),
true,
},
{
"date sub",
plan.NewProject(
[]sql.Expression{
mustFunc(function.NewDateSub(
expression.NewLiteral("2018-05-01", sql.Text),
expression.NewInterval(
expression.NewLiteral(int64(1), sql.Int64),
"DAY",
),
)),
},
plan.NewUnresolvedTable("dual", ""),
),
true,
},
{
"+ op",
plan.NewProject(
[]sql.Expression{
expression.NewPlus(
expression.NewLiteral("2018-05-01", sql.Text),
expression.NewInterval(
expression.NewLiteral(int64(1), sql.Int64),
"DAY",
),
),
},
plan.NewUnresolvedTable("dual", ""),
),
true,
},
{
"- op",
plan.NewProject(
[]sql.Expression{
expression.NewMinus(
expression.NewLiteral("2018-05-01", sql.Text),
expression.NewInterval(
expression.NewLiteral(int64(1), sql.Int64),
"DAY",
),
),
},
plan.NewUnresolvedTable("dual", ""),
),
true,
},
{
"invalid",
plan.NewProject(
[]sql.Expression{
expression.NewInterval(
expression.NewLiteral(int64(1), sql.Int64),
"DAY",
),
},
plan.NewUnresolvedTable("dual", ""),
),
false,
},
{
"alias",
plan.NewProject(
[]sql.Expression{
expression.NewAlias(
expression.NewInterval(
expression.NewLiteral(int64(1), sql.Int64),
"DAY",
),
"foo",
),
},
plan.NewUnresolvedTable("dual", ""),
),
false,
},
}

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

_, err := validateIntervalUsage(sql.NewEmptyContext(), nil, tt.node)
if tt.ok {
require.NoError(err)
} else {
require.Error(err)
require.True(ErrIntervalInvalidUse.Is(err))
}
})
}
}

type dummyNode struct{ resolved bool }

func (n dummyNode) String() string { return "dummynode" }
Expand Down
Loading

0 comments on commit 69d26d9

Please sign in to comment.