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

Add support for json_contains_path() #1929

Merged
merged 5 commits into from Aug 9, 2023
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.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
58 changes: 58 additions & 0 deletions enginetest/queries/json_scripts.go
Expand Up @@ -566,4 +566,62 @@ var JsonScripts = []ScriptTest{
},
},
},
{
Name: "json_contains_path returns true if the path exists",
SetUpScript: []string{
`create table t (pk int primary key, col1 json);`,
`insert into t values (1, '{"a": 1}');`,
`insert into t values (2, '{"a": 1, "b": 2, "c": {"d": 4}}');`,
`insert into t values (3, '{"w": 1, "x": 2, "c": {"d": 4}}');`,
`insert into t values (4, '{}');`,
`insert into t values (5, null);`,
},

Assertions: []ScriptTestAssertion{
{
Query: "select pk, json_contains_path(col1, 'one', '$.a') from t order by pk;",
Expected: []sql.Row{
{1, true},
{2, true},
{3, false},
{4, false},
{5, nil},
},
},
{
Query: "select pk, json_contains_path(col1, 'one', '$.a', '$.x', '$.c.d') from t order by pk;",
Expected: []sql.Row{
{1, true},
{2, true},
{3, true},
{4, false},
{5, nil},
},
},
{
Query: "select pk, json_contains_path(col1, 'all', '$.a', '$.x') from t order by pk;",
Expected: []sql.Row{
{1, false},
{2, false},
{3, false},
{4, false},
{5, nil},
},
},
{
Query: "select pk, json_contains_path(col1, 'all', '$.c.d', '$.x') from t order by pk;",
Expected: []sql.Row{
{1, false},
{2, false},
{3, true},
{4, false},
{5, nil},
},
},
{
Query: "select pk, json_contains_path(col1, 'other', '$.c.d', '$.x') from t order by pk;",
ExpectedErrStr: "The oneOrAll argument to json_contains_path may take these values: 'one' or 'all'",
},
},
},
}
1 change: 0 additions & 1 deletion sql/expression/function/json_contains.go
Expand Up @@ -90,7 +90,6 @@ func (j *JSONContains) Resolved() bool {
return false
}
}

return true
}

Expand Down
172 changes: 172 additions & 0 deletions sql/expression/function/json_contains_path.go
@@ -0,0 +1,172 @@
// Copyright 2023 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 function

import (
"fmt"
"strings"

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

// JSON_CONTAINS_PATH(json_doc, one_or_all, path[, path] ...)
//
// JSONContainsPath Returns 0 or 1 to indicate whether a JSON document contains data at a given path or paths. Returns
// NULL if any argument is NULL. An error occurs if the json_doc argument is not a valid JSON document, any path
// argument is not a valid path expression, or one_or_all is not 'one' or 'all'. To check for a specific value at a
// path, use JSON_CONTAINS() instead.
//
// The return value is 0 if no specified path exists within the document. Otherwise, the return value depends on the
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Maybe lead with this? Seems like the important part

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

The NULL behavior seems like a footnote. Not sure JSON_CONTAINS comment needs to be here, but if keeping I'd also put after main explanation.

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I wasn't going the docs because this is lifted from the link below. I'm happy to re-write it if you think that's better.

// one_or_all argument:
// - 'one': 1 if at least one path exists within the document, 0 otherwise.
// - 'all': 1 if all paths exist within the document, 0 otherwise.
//
// https://dev.mysql.com/doc/refman/8.0/en/json-search-functions.html#function_json-contains-path
//
// Above is the documentation from MySQL's documentation. Minor Nit - the observed behavior for NULL
// paths is that if a NULL path is found before the search can terminate, then NULL is returned.
type JSONContainsPath struct {
doc sql.Expression
all sql.Expression
paths []sql.Expression
}

func (j JSONContainsPath) Eval(ctx *sql.Context, row sql.Row) (interface{}, error) {
target, err := getSearchableJSONVal(ctx, row, j.doc)
if err != nil || target == nil {
return nil, err
}

oneOrAll, err := j.all.Eval(ctx, row)
if err != nil || oneOrAll == nil {
return nil, err
}
oneOrAll, _, err = types.LongText.Convert(oneOrAll)
if err != nil {
return nil, err
}
if !strings.EqualFold(oneOrAll.(string), "one") && !strings.EqualFold(oneOrAll.(string), "all") {
return nil, fmt.Errorf("The oneOrAll argument to json_contains_path may take these values: 'one' or 'all'")
}
findAllPaths := strings.EqualFold(oneOrAll.(string), "all")

// MySQL Behavior differs from their docs. The docs say that if any path is NULL, the result is NULL. However,
// they only return NULL when they search far enough to find one, so we match that behavior.
for _, path := range j.paths {
path, err := path.Eval(ctx, row)
if err != nil || path == nil {
return nil, err
}

path, _, err = types.LongText.Convert(path)
if err != nil {
return nil, err
}

result, err := target.Extract(ctx, path.(string))
if err != nil {
return nil, err
}

if result == nil && findAllPaths {
return false, nil
}
if result != nil && !findAllPaths {
return true, nil
}
}

// If we got this far, then we had no reason to terminate the search. For all, that means they all matched.
// For one, that means none matched. The result is the value of findAllPaths.
return findAllPaths, nil
}

func (j JSONContainsPath) Resolved() bool {
for _, child := range j.Children() {
if child != nil && !child.Resolved() {
return false
}
}
return true
}

func (j JSONContainsPath) String() string {
children := j.Children()
var parts = make([]string, len(children))

for i, c := range children {
parts[i] = c.String()
}
return fmt.Sprintf("%s(%s)", j.FunctionName(), strings.Join(parts, ","))
}

func (j JSONContainsPath) Type() sql.Type {
return types.Boolean
}

func (j JSONContainsPath) IsNullable() bool {
for _, path := range j.paths {
if path.IsNullable() {
return true
}
}
if j.all.IsNullable() {
return true
}
return j.doc.IsNullable()
}
func (j JSONContainsPath) Children() []sql.Expression {
answer := make([]sql.Expression, 0, len(j.paths)+2)

answer = append(answer, j.doc)
answer = append(answer, j.all)
answer = append(answer, j.paths...)

return answer
}

func (j JSONContainsPath) WithChildren(children ...sql.Expression) (sql.Expression, error) {
if len(j.Children()) != len(children) {
return nil, fmt.Errorf("json_contains_path did not receive the correct amount of args")
}
return NewJSONContainsPath(children...)
}

var _ sql.FunctionExpression = JSONContainsPath{}

// NewJSONContainsPath creates a new JSONContainsPath function.
func NewJSONContainsPath(args ...sql.Expression) (sql.Expression, error) {
if len(args) < 3 {
return nil, sql.ErrInvalidArgumentNumber.New("JSON_CONTAINS_PATH", "3 or more", len(args))
}

return &JSONContainsPath{args[0], args[1], args[2:]}, nil
}

// FunctionName implements sql.FunctionExpression
func (j JSONContainsPath) FunctionName() string {
return "json_contains_path"
}

// Description implements sql.FunctionExpression
func (j JSONContainsPath) Description() string {
return "returns whether JSON document contains any data at path."
}

// IsUnsupported implements sql.UnsupportedFunctionStub
func (j JSONContainsPath) IsUnsupported() bool {
return false
}
114 changes: 114 additions & 0 deletions sql/expression/function/json_contains_path_test.go
@@ -0,0 +1,114 @@
// Copyright 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 function

import (
"testing"

"github.com/pkg/errors"
"github.com/stretchr/testify/require"

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

func TestJSONContainsPath(t *testing.T) {
// Verify arg count 3 or more.
_, err := NewJSONContainsPath()
require.Error(t, err)

_, err = NewJSONContainsPath(
expression.NewGetField(0, types.JSON, "arg1", false),
)
require.Error(t, err)

_, err = NewJSONContainsPath(
expression.NewGetField(0, types.JSON, "arg1", false),
expression.NewGetField(1, types.LongText, "arg2", false),
)
require.Error(t, err)

// setup call expressions for calling with 1, 2, and 3 paths.
onePath, err := NewJSONContainsPath(
expression.NewGetField(0, types.JSON, "arg1", false),
expression.NewGetField(1, types.LongText, "arg2", false),
expression.NewGetField(2, types.LongText, "arg3", false),
)
require.NoError(t, err)

twoPath, err := NewJSONContainsPath(
expression.NewGetField(0, types.JSON, "arg1", false),
expression.NewGetField(1, types.LongText, "arg2", false),
expression.NewGetField(2, types.LongText, "arg3", false),
expression.NewGetField(3, types.LongText, "arg4", false),
)
require.NoError(t, err)

threePath, err := NewJSONContainsPath(
expression.NewGetField(0, types.JSON, "arg1", false),
expression.NewGetField(1, types.LongText, "arg2", false),
expression.NewGetField(2, types.LongText, "arg3", false),
expression.NewGetField(3, types.LongText, "arg4", false),
expression.NewGetField(4, types.LongText, "arg5", false),
)
require.NoError(t, err)

testCases := []struct {
fCall sql.Expression
input sql.Row
expected interface{}
err error
}{
{onePath, sql.Row{`{"a": 1, "b": 2, "c": {"d": 4}}`, `oNe`, `$.a`}, true, nil},
{onePath, sql.Row{`{"a": 1, "b": 2, "c": {"d": 4}}`, `one`, `$.e`}, false, nil},
{onePath, sql.Row{`{"a": 1, "b": 2, "c": {"d": 4}}`, `all`, `$.e`}, false, nil},
{onePath, sql.Row{`{"a": 1, "b": 2, "c": {"d": 4}}`, `All`, `$.c.d`}, true, nil},

{twoPath, sql.Row{`{"a": 1, "b": 2, "c": {"d": 4}}`, `one`, `$.a`, `$.e`}, true, nil},
{twoPath, sql.Row{`{"a": 1, "b": 2, "c": {"d": 4}}`, `ALL`, `$.a`, `$.e`}, false, nil},

{twoPath, sql.Row{`{"a": 1, "b": 2, "c": {"d": {"e" : 42}}}`, `all`, `$.a`, `$.c.d.e`}, true, nil},
{threePath, sql.Row{`{"a": 1, "b": 2, "c": {"d": {"e" : 42}}}`, `all`, `$.a`, `$.c.d.e`, `$.x`}, false, nil},
{threePath, sql.Row{`{"a": 1, "b": 2, "c": {"d": {"e" : 42}}}`, `one`, `$.a`, `$.c.d.e`, `$.x`}, true, nil},

// NULL inputs. Any NULL should result in NULL output.
{onePath, sql.Row{nil, `one`, `$.a`}, nil, nil},
{onePath, sql.Row{`{"a": 1}`, nil, `$.a`}, nil, nil},
{twoPath, sql.Row{`{"a": 1}`, `one`, `$.a`, nil}, true, nil}, // Match MySQL behavior, not docs.
{twoPath, sql.Row{`{"a": 1}`, `one`, nil, `$.a`}, nil, nil},
{twoPath, sql.Row{`{"a": 1}`, "all", `$.x`, nil}, false, nil}, // Match MySQL behavior, not docs.
{twoPath, sql.Row{`{"a": 1}`, `all`, `$.a`, nil}, nil, nil},

// Error cases
{onePath, sql.Row{`{"a": 1}`, `None`, `$.a`}, nil, errors.New("The oneOrAll argument to json_contains_path may take these values: 'one' or 'all'")},
{onePath, sql.Row{`{"a": 1`, `One`, `$.a`}, nil, errors.New(`Invalid JSON text: {"a": 1`)},
{threePath, sql.Row{`{"a": 1, "b": 2, "c": {"d": {"e" : 42}}}`, `one`, 42, `$.c.d.e`, `$.x`}, nil, errors.New(`should start with '$'`)},
}

for _, testcase := range testCases {
t.Run(testcase.fCall.String(), func(t *testing.T) {
require := require.New(t)
result, err := testcase.fCall.Eval(sql.NewEmptyContext(), testcase.input)
if testcase.err == nil {
require.NoError(err)
} else {
require.Equal(err.Error(), testcase.err.Error())
}

require.Equal(testcase.expected, result)
})
}
}