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

expression: allow json functions to be expression index #37738

Merged
merged 7 commits into from Sep 14, 2022
Merged
Show file tree
Hide file tree
Changes from 4 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
Expand Up @@ -531,7 +531,7 @@ a
b
select @@tidb_allow_function_for_expression_index;
@@tidb_allow_function_for_expression_index
lower, md5, reverse, tidb_shard, upper, vitess_hash
json_array, json_array_append, json_array_insert, json_contains, json_contains_path, json_depth, json_extract, json_insert, json_keys, json_length, json_merge_patch, json_merge_preserve, json_object, json_pretty, json_quote, json_remove, json_replace, json_search, json_set, json_storage_size, json_type, json_unquote, json_valid, lower, md5, reverse, tidb_shard, upper, vitess_hash
CREATE TABLE `PK_S_MULTI_30_tmp` (
`COL1` double NOT NULL,
`COL2` double NOT NULL,
Expand Down
98 changes: 98 additions & 0 deletions ddl/db_integration_test.go
Expand Up @@ -2467,6 +2467,104 @@ func TestAddExpressionIndex(t *testing.T) {
})
}

func TestCreateExpressionIndexWithJSONFunction(t *testing.T) {
store := testkit.CreateMockStore(t)
tk := testkit.NewTestKit(t, store)
tk.MustExec("use test")
tk.MustExec("drop table if exists t;")
tk.MustExec("create table t(a int, b json);")
tk.MustExec("insert into t values (1, '{\"a\": 1}');")

tk.MustExec("alter table t add index idx((cast(b->'$.a' as char(255))));")
tk.MustQuery("select * from t force index(idx);").Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery("select * from t ignore index(idx);").Check(testkit.Rows("1 {\"a\": 1}"))

tk.MustExec("alter table t add index idx1((cast(b->>'$.a' as char(255))));")
tk.MustQuery("select * from t force index(idx1);").Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery("select * from t ignore index(idx1);").Check(testkit.Rows("1 {\"a\": 1}"))

tk.MustExec("alter table t add index idx2((json_type(b)));")
tk.MustQuery("select * from t force index(idx2) where json_type(b) = 'OBJECT';").Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery("select * from t ignore index(idx2) where json_type(b) = 'OBJECT';").Check(testkit.Rows("1 {\"a\": 1}"))

tk.MustGetErrCode("alter table t add index idx_wrong((b->'$.a'));", errno.ErrFunctionalIndexOnJSONOrGeometryFunction)
tk.MustGetErrCode("alter table t add index idx_wrong((b->>'$.a'));", errno.ErrFunctionalIndexOnBlob)
tk.MustGetErrCode("alter table t add index idx_wrong((json_pretty(b)));", errno.ErrFunctionalIndexOnBlob)

tk.MustExec("drop table if exists t;")
tk.MustGetErrCode("create table t(a char(255), index idx((json_quote(a))));", errno.ErrTooLongKey)
tk.MustExec("create table t(a char(40));")
tk.MustExec("insert into t values ('[1, 2, 3]')")
tk.MustExec("alter table t add index idx3((json_quote(a)));")
tk.MustQuery("select * from t force index(idx3) where json_quote(a) = '\"[1, 2, 3]\"';").Check(testkit.Rows("[1, 2, 3]"))
tk.MustQuery("select * from t ignore index(idx3) where json_quote(a) = '\"[1, 2, 3]\"';").Check(testkit.Rows("[1, 2, 3]"))

tk.MustExec("drop table if exists t;")
tk.MustExec("create table t(a int, b json);")
tk.MustGetErrCode(`alter table t add index idx_wrong((json_array(b)));`, errno.ErrFunctionalIndexOnJSONOrGeometryFunction)
Copy link
Member

Choose a reason for hiding this comment

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

Please add some success tests for these functions.

Copy link
Contributor Author

Choose a reason for hiding this comment

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

more tests are added

tk.MustGetErrCode(`alter table t add index idx_wrong((json_object('key', b)));`, errno.ErrFunctionalIndexOnJSONOrGeometryFunction)
tk.MustGetErrCode(`alter table t add index idx_wrong((json_merge_preserve(b, '{"k": "v"}')));`, errno.ErrFunctionalIndexOnJSONOrGeometryFunction)
tk.MustGetErrCode(`alter table t add index idx_wrong((json_set(b, '$.a', 'v')));`, errno.ErrFunctionalIndexOnJSONOrGeometryFunction)
tk.MustGetErrCode(`alter table t add index idx_wrong((json_insert(b, '$.a', 'v')));`, errno.ErrFunctionalIndexOnJSONOrGeometryFunction)
tk.MustGetErrCode(`alter table t add index idx_wrong((json_replace(b, '$.a', 'v')));`, errno.ErrFunctionalIndexOnJSONOrGeometryFunction)
tk.MustGetErrCode(`alter table t add index idx_wrong((json_remove(b, '$.a')));`, errno.ErrFunctionalIndexOnJSONOrGeometryFunction)
tk.MustGetErrCode(`alter table t add index idx_wrong((json_array_append(b, '$.a', 1)));`, errno.ErrFunctionalIndexOnJSONOrGeometryFunction)
tk.MustGetErrCode(`alter table t add index idx_wrong((json_merge_patch(b, '{"k": "v"}')));`, errno.ErrFunctionalIndexOnJSONOrGeometryFunction)
tk.MustGetErrCode(`alter table t add index idx_wrong((json_search(b, 'one', 'a')));`, errno.ErrFunctionalIndexOnJSONOrGeometryFunction)
tk.MustGetErrCode(`alter table t add index idx_wrong((json_keys(b)));`, errno.ErrFunctionalIndexOnJSONOrGeometryFunction)

tk.MustExec("drop table if exists t;")
tk.MustExec("create table t(a int, b json);")
tk.MustExec("insert into t values (1, '{\"a\": 1}');")
tk.MustExec(`alter table t add index idx0((json_type(json_search(b, 'one', 'a'))));`)
tk.MustExec(`alter table t add index idx1((json_type(json_array(b))));`)
tk.MustExec(`alter table t add index idx2((json_type(json_object('key', b))));`)
tk.MustExec(`alter table t add index idx3((json_type(json_merge_preserve(b, '{"k": "v"}'))));`)
tk.MustExec(`alter table t add index idx4((json_type(json_set(b, '$.a', 'v'))));`)
tk.MustExec(`alter table t add index idx5((json_type(json_insert(b, '$.a', 'v'))));`)
tk.MustExec(`alter table t add index idx6((json_type(json_replace(b, '$.a', 'v'))));`)
tk.MustExec(`alter table t add index idx7((json_type(json_remove(b, '$.a'))));`)
tk.MustExec(`alter table t add index idx8((json_type(json_array_append(b, '$.a', 1))));`)
tk.MustExec(`alter table t add index idx9((json_type(json_merge_patch(b, '{"k": "v"}'))));`)
tk.MustExec(`alter table t add index idx10((json_type(json_keys(b))));`)
tk.MustExec(`alter table t add index idx11((cast(json_quote(cast(a as char(10))) as char(64))));`)
tk.MustExec(`alter table t add index idx12((json_storage_size(b)));`)
tk.MustExec(`alter table t add index idx13((json_depth(b)));`)
tk.MustExec(`alter table t add index idx14((json_length(b)));`)

tk.MustQuery(`select * from t force index(idx0) where json_type(json_search(b, 'one', 'a')) is NULL;`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t force index(idx1) where json_type(json_array(b)) = 'ARRAY';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t force index(idx2) where json_type(json_object('key', b)) = 'OBJECT';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t force index(idx3) where json_type(json_merge_preserve(b, '{"k": "v"}')) = 'OBJECT';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t force index(idx4) where json_type(json_set(b, '$.a', 'v')) = 'OBJECT';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t force index(idx5) where json_type(json_insert(b, '$.a', 'v')) = 'OBJECT';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t force index(idx6) where json_type(json_replace(b, '$.a', 'v')) = 'OBJECT';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t force index(idx7) where json_type(json_remove(b, '$.a')) = 'OBJECT';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t force index(idx8) where json_type(json_array_append(b, '$.a', 1)) = 'OBJECT';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t force index(idx9) where json_type(json_merge_patch(b, '{"k": "v"}')) = 'OBJECT';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t force index(idx10) where json_type(json_keys(b)) = 'ARRAY';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t force index(idx11) where cast(json_quote(cast(a as char(10))) as char(64)) = '"1"';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t force index(idx12) where json_storage_size(b) > 1;`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t force index(idx13) where json_depth(b) > 0;`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t force index(idx14) where json_length(b) > 0;`).Check(testkit.Rows("1 {\"a\": 1}"))

tk.MustQuery(`select * from t ignore index(idx0) where json_type(json_search(b, 'one', 'a')) is NULL;`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t ignore index(idx1) where json_type(json_array(b)) = 'ARRAY';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t ignore index(idx2) where json_type(json_object('key', b)) = 'OBJECT';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t ignore index(idx3) where json_type(json_merge_preserve(b, '{"k": "v"}')) = 'OBJECT';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t ignore index(idx4) where json_type(json_set(b, '$.a', 'v')) = 'OBJECT';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t ignore index(idx5) where json_type(json_insert(b, '$.a', 'v')) = 'OBJECT';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t ignore index(idx6) where json_type(json_replace(b, '$.a', 'v')) = 'OBJECT';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t ignore index(idx7) where json_type(json_remove(b, '$.a')) = 'OBJECT';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t ignore index(idx8) where json_type(json_array_append(b, '$.a', 1)) = 'OBJECT';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t ignore index(idx9) where json_type(json_merge_patch(b, '{"k": "v"}')) = 'OBJECT';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t ignore index(idx10) where json_type(json_keys(b)) = 'ARRAY';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t ignore index(idx11) where cast(json_quote(cast(a as char(10))) as char(64)) = '"1"';`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t ignore index(idx12) where json_storage_size(b) > 1;`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t ignore index(idx13) where json_depth(b) > 0;`).Check(testkit.Rows("1 {\"a\": 1}"))
tk.MustQuery(`select * from t ignore index(idx14) where json_length(b) > 0;`).Check(testkit.Rows("1 {\"a\": 1}"))
}

func TestCreateExpressionIndexError(t *testing.T) {
config.UpdateGlobal(func(conf *config.Config) {
// Test for table lock.
Expand Down
2 changes: 1 addition & 1 deletion ddl/index.go
Expand Up @@ -210,7 +210,7 @@ func getIndexColumnLength(col *model.ColumnInfo, colLen int) (int, error) {
switch col.GetType() {
case mysql.TypeBit:
return (length + 7) >> 3, nil
case mysql.TypeVarchar, mysql.TypeString, mysql.TypeTinyBlob, mysql.TypeMediumBlob, mysql.TypeBlob, mysql.TypeLongBlob:
case mysql.TypeVarchar, mysql.TypeString, mysql.TypeVarString, mysql.TypeTinyBlob, mysql.TypeMediumBlob, mysql.TypeBlob, mysql.TypeLongBlob:
// Different charsets occupy different numbers of bytes on each character.
desc, err := charset.GetCharsetInfo(col.GetCharset())
if err != nil {
Expand Down
4 changes: 4 additions & 0 deletions expression/collation.go
Expand Up @@ -277,6 +277,10 @@ func deriveCollation(ctx sessionctx.Context, funcName string, args []Expression,
ec = &ExprCollation{Coer: CoercibilityCoercible, Repe: ASCII}
ec.Charset, ec.Collation = ctx.GetSessionVars().GetCharsetInfo()
return ec, nil
case ast.JSONPretty, ast.JSONQuote:
// JSON function always return utf8mb4 and utf8mb4_bin.
ec = &ExprCollation{Coer: CoercibilityCoercible, Repe: UNICODE, Charset: charset.CharsetUTF8MB4, Collation: charset.CollationUTF8MB4}
return ec, nil
}

ec = &ExprCollation{CoercibilityNumeric, ASCII, charset.CharsetBin, charset.CollationBin}
Expand Down
24 changes: 24 additions & 0 deletions sessionctx/variable/varsutil.go
Expand Up @@ -473,4 +473,28 @@ var GAFunction4ExpressionIndex = map[string]struct{}{
ast.Reverse: {},
ast.VitessHash: {},
ast.TiDBShard: {},
// JSON functions.
ast.JSONType: {},
ast.JSONExtract: {},
ast.JSONUnquote: {},
ast.JSONArray: {},
ast.JSONObject: {},
ast.JSONSet: {},
ast.JSONInsert: {},
ast.JSONReplace: {},
ast.JSONRemove: {},
ast.JSONContains: {},
ast.JSONContainsPath: {},
ast.JSONValid: {},
ast.JSONArrayAppend: {},
ast.JSONArrayInsert: {},
ast.JSONMergePatch: {},
ast.JSONMergePreserve: {},
ast.JSONPretty: {},
ast.JSONQuote: {},
ast.JSONSearch: {},
ast.JSONStorageSize: {},
ast.JSONDepth: {},
ast.JSONKeys: {},
ast.JSONLength: {},
}