summaryrefslogtreecommitdiff
path: root/mysql-test/suite/json/t/json_table.test
blob: 4b0293f6bea705908cc3273d9113b6a9c3c18ead (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
--source include/have_sequence.inc

select * from json_table('[{"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}]', '$[*]' COLUMNS( a INT PATH '$.a')) as tt;

select * from JSON_TABLE( '[ {"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3}]', '$[*]' COLUMNS( a INT PATH '$.a', NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'))) as jt;

SELECT *  FROM   JSON_TABLE( '[ {"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3}]', '$[*]' COLUMNS( a INT PATH '$.a', NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'), NESTED PATH '$.b[*]' COLUMNS (c INT PATH '$') ) ) jt;

create table t1 (id varchar(5), json varchar(1024));
insert into t1 values ('j1', '[{"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}]');
insert into t1 values ('j2', '[{"a": 3, "b": [11,111]}, {"a": 4, "b": [22,222]}, {"a": 5, "b": [22,222]}]');
select id, json, a from t1, json_table(t1.json, '$[*]' COLUMNS(js_id FOR ORDINALITY, a INT PATH '$.a')) as tt;
select * from t1, JSON_TABLE(t1.json, '$[*]' COLUMNS(js_id FOR ORDINALITY, a INT PATH '$.a', NESTED PATH '$.b[*]' COLUMNS (l_js_id FOR ORDINALITY, b INT PATH '$'))) as jt;
--error ER_BAD_FIELD_ERROR
select * from t1, JSON_TABLE(t1.no_field, '$[*]' COLUMNS(js_id FOR ORDINALITY, a INT PATH '$.a', NESTED PATH '$.b[*]' COLUMNS (l_js_id FOR ORDINALITY, b INT PATH '$'))) as jt;

--error ER_DUP_FIELDNAME
select * from t1, JSON_TABLE(t1.no_field, '$[*]' COLUMNS(js_id FOR ORDINALITY, a INT PATH '$.a', NESTED PATH '$.b[*]' COLUMNS (l_js_id FOR ORDINALITY, a INT PATH '$'))) as jt;

DROP TABLE t1;

create table t1 (item_name varchar(32), item_props varchar(1024));
insert into t1 values ('Laptop', '{"color": "black", "price": 1000}');
insert into t1 values ('Jeans',  '{"color": "blue", "price": 50}');

select * from t1 left join json_table(t1.item_props,'$' columns( color varchar(100) path '$.color')) as T on 1;

--error ER_WRONG_OUTER_JOIN
select * from t1 right join json_table(t1.item_props,'$' columns( color varchar(100) path '$.color')) as T on 1;

DROP TABLE t1;

select * from JSON_TABLE( '[ {"xa": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3}]', '$[*]' COLUMNS( a INT PATH '$.a' default '101' on empty, NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'))) as jt;

select * from JSON_TABLE( '[ {"xa": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3}]', '$[*]' COLUMNS( a INT PATH '$.a' default '202' on error, NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'))) as jt;

select * from JSON_TABLE( '[ {"a": [1, 2], "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3}]', '$[*]' COLUMNS( a INT PATH '$.a' default '101' on empty, NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'))) as jt;

select * from JSON_TABLE( '[ {"a": [1, 2], "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3}]', '$[*]' COLUMNS( a INT PATH '$.a' default '202' on error default '101' on empty, NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'))) as jt;

--error ER_JSON_SYNTAX
select * from JSON_TABLE( '[{"a": [1, 2], "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3} xx YY]', '$[*]' COLUMNS( a INT PATH '$.a' default '202' on error default '101' on empty, NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'))) as jt;

--error ER_JSON_TABLE_ERROR_ON_FIELD
select * from JSON_TABLE( '[{"a": [1, 2], "b": [11,111]}, {"a": 2, "b": [22,222]}, {"a":3}]', '$[*]' COLUMNS( a INT PATH '$.a' error on error default '101' on empty, NESTED PATH '$.b[*]' COLUMNS (b INT PATH '$'))) as jt;

#
# MDEV-22290 JSON_TABLE: Decimal type with M equal D causes Assertion
#    `scale <= precision' failure
#
select * from json_table('{"a":0}',"$" columns(a decimal(1,1) path '$.a')) foo;


#
# MDEV-22291 JSON_TABLE: SELECT from json_table does not work without default database
#
connect (con1,localhost,root,,);
select a from json_table('{"a":0}',"$" columns(a for ordinality)) foo;
connection default;
disconnect con1;

create table t1 (
      color varchar(32),
        price int
    );
insert into t1 values ("red", 100), ("blue", 50);
insert into t1 select * from t1;
insert into t1 select * from t1;

set @save_optimizer_switch=@@optimizer_switch;
set optimizer_switch='firstmatch=off';
select * from 
  json_table('[{"color": "blue", "price": 50},
                     {"color": "red", "price": 100}]',
                                  '$[*]' columns( color varchar(100) path '$.color',
                                                              price text path '$.price'
                                                                                      )
                                               ) as T
  where
    T.color in (select color from t1 where t1.price=T.price);
set @@optimizer_switch=@save_optimizer_switch;

drop table t1;

select * from
json_table(' [ {"color": "blue", "sizes": [1,2,3,4],  "prices" : [10,20]},
               {"color": "red",  "sizes": [10,11,12,13,14],  "prices" : [100,200,300]} ]',
    '$[*]' columns(
      color varchar(4) path '$.color',
      seq0 for ordinality,
      nested path '$.sizes[*]'
      columns (seq1 for ordinality,
        size int path '$'),
      nested path '$.prices[*]'
      columns (seq2 for ordinality,
        price int path '$')
      )
    ) as T;


select * from   json_table('[{"color": "blue", "price": 50},
    {"color": "red", "price": 100},
    {"color": "rojo", "price": 10.0},
    {"color": "blanco", "price": 11.0}]',
    '$[*]' columns( color varchar(100) path '$.color',
      price text path '$.price', seq for ordinality)) as T order by color desc;

create view v as select * from json_table('{"as":"b", "x":123}',"$" columns(a varchar(8) path '$.a' default '-' on empty, x int path '$.x')) x;
select * from v;
show create table v;
drop view v;

--error ER_PARSE_ERROR
select * from json_table('{"as":"b", "x":123}',
        "$" columns(a varchar(8) path '$.a' default '-' on empty null on error null on empty, x int path '$.x')) x;

select * from json_table('{"a":"foo","b":"bar"}', '$'
      columns (v varchar(20) path '$.*')) as jt;

select * from json_table('{"a":"foo","b":"bar"}', '$'
      columns (v varchar(20) path '$.*' default '-' on error)) as jt;

select * from json_table('{"b":"bar"}', '$'
      columns (v varchar(20) path '$.*' default '-' on error)) as jt;

create table t1 (a varchar(100));
insert into t1 values ('1');
--error ER_NONUNIQ_TABLE
select * from t1 as T, json_table(T.a, '$[*]' columns(color varchar(100) path '$.nonexistent', seq for ordinality)) as T;

drop table t1;

prepare s from 'select * from
json_table(?,
    \'$[*]\' columns( color varchar(100) path \'$.color\',
      price text path \'$.price\',
      seq for ordinality)) as T
order by color desc; ';

execute s using '[{"color": "red", "price":1}, {"color":"brown", "price":2}]';
deallocate prepare s;

create view v2 as select * from   json_table('[{"co\\\\lor": "blue", "price": 50}]',              '$[*]' columns( color varchar(100) path '$.co\\\\lor')              ) as T;
select * from v2;
drop view v2;

explain format=json select * from
  json_table('[{"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}]', '$[*]' COLUMNS( a INT PATH '$.a')) as tt;
explain select * from
  json_table('[{"a": 1, "b": [11,111]}, {"a": 2, "b": [22,222]}]', '$[*]' COLUMNS( a INT PATH '$.a')) as tt;

create view v1 as select * from
  json_table('[{"color": "blue", "price": 50}]',
             '$[*]' columns(color text path '$.nonexistent',
              seq for ordinality)) as `ALIAS NOT QUOTED`;
select * from v1;
drop view v1;
create view v1 as select * from
  json_table('[{"color": "blue", "price": 50},
               {"color": "red", "price": 100}]',
               '$[*]' columns(
                   color text path "$.QUOTES \" HERE \"",
                   color1 text path '$.QUOTES " HERE "',
                   color2 text path "$.QUOTES ' HERE '",
                   seq for ordinality)) as T;
select * from v1;
drop view v1;

CREATE TABLE t1 (x INT);
INSERT INTO t1 VALUES (1), (2), (3);
--error ER_BAD_FIELD_ERROR
SELECT t1.x*2 m, jt.* FROM t1,
       JSON_TABLE(m, '$[*]' COLUMNS (i INT PATH '$')) jt;
DROP TABLE t1;

--error ER_UNKNOWN_TABLE
select *  from   json_table(JS3.size, '$' columns (size INT PATH '$.size')) as JS1,   json_table(JS1.size, '$' columns (size INT PATH '$.size')) as JS2,   json_table(JS1.size, '$' columns (size INT PATH '$.size')) as JS3 where  1;

create table t1 (json varchar(100) character set utf8);
insert into t1 values ('{"value":"АБВ"}');
create table tj1 as 
select T.value
  from t1, json_table(t1.json, '$' columns (value varchar(32) PATH '$.value')) T;
show create table tj1;
drop table t1;
drop table tj1;

CREATE TABLE t1(id INT, f1 JSON);
INSERT INTO t1 VALUES
 (1, '{\"1\": 1}'),
 (2, '{\"1\": 2}'),
 (3, '{\"1\": 3}'),
 (4, '{\"1\": 4}'),
 (5, '{\"1\": 5}'),
 (6, '{\"1\": 6}');
ANALYZE TABLE t1;

--error ER_UNKNOWN_TABLE
SELECT * FROM JSON_TABLE(tt3.f1, "$" COLUMNS (id FOR ORDINALITY)) AS tbl STRAIGHT_JOIN t1 AS tt3;
--error ER_BAD_FIELD_ERROR
SELECT * FROM t1 as jj1,
  (SELECT tt2.*
   FROM
      t1 as tt2,
      JSON_TABLE(tt3.f1, "$" COLUMNS (id FOR ORDINALITY)) AS tbl
      STRAIGHT_JOIN
      t1 AS tt3
   ) dt
ORDER BY 1,3 LIMIT 10;

drop table t1;

select collation(x) from 
    JSON_TABLE('["abc"]', '$[*]' COLUMNS (x VARCHAR(10) CHARSET latin1 PATH '$')) tbl;

SELECT * FROM  JSON_TABLE('{"x":1, "y":2}', _utf8mb4'$' COLUMNS (NESTED PATH _utf8mb4'$.x'
  COLUMNS(y INT PATH _utf8mb4'$.y' DEFAULT _utf8mb4'1' ON EMPTY DEFAULT _utf8mb4'2' ON ERROR))) jt;

select * from json_table(
'{"name":"t-shirt", "colors": ["yellow", "blue"],"sizes":  ["small", "medium", "large"]}', 
 '$' columns(name varchar(32) path '$.name',
             nested path '$.colors[*]' columns (
               color varchar(32) path '$',
               nested path '$.sizes[*]' columns (
                 size varchar(32) path '$' 
)))) as t;

SELECT x, length(x) FROM
  JSON_TABLE('{}', '$' COLUMNS (x VARCHAR(10) PATH '$.x' DEFAULT 'abcdefg' ON EMPTY)) jt;

# check how conversion works for JSON NULL, TRUE and FALSE

select * from
  json_table('[{"a":"aa"}, {"b":null}]', '$[*]'
      columns (col1 int path '$.b' default '456' on empty)) as tt;

select * from
  json_table('[{"a":"aa"}, {"b":true}]', '$[*]'
      columns (col1 int path '$.b' default '456' on empty)) as tt;

select * from
  json_table('[{"a":"aa"}, {"b":false}]', '$[*]'
      columns (col1 int path '$.b' default '456' on empty)) as tt;

select * from
  json_table('[{"a":"aa"}, {"b":null}]', '$[*]'
      columns (col1 varchar(100) path '$.b' default '456' on empty)) as tt;

select * from
  json_table('[{"a":"aa"}, {"b":true}]', '$[*]'
      columns (col1 varchar(100) path '$.b' default '456' on empty)) as tt;

select * from
  json_table('[{"a":"aa"}, {"b":false}]', '$[*]'
      columns (col1 varchar(100) path '$.b' default '456' on empty)) as tt;


select * from
  json_table( '[{"a":"asd"}, {"a":123}, {"a":[]}, {"a":{}} ]', '$[*]'
      columns (id for ordinality,
        intcol int path '$.a' default '1234' on empty default '5678' on error)
      ) as tt;

SELECT COUNT(*) FROM JSON_TABLE('[1, 2]', '$[*]' COLUMNS( I INT PATH '$')) tt;

create table t1 (a int);
insert into t1 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
create table t2 (js json, b int);
insert into t2 select '[1,2,3]',A.a from t1 A, t1 B;

explain select * from t1,
    (select * from t2, json_table(t2.js, '$[*]' columns (o for ordinality)) as jt) as TT2
    where 1;

drop table t1, t2;

CREATE TABLE t1 (x INT);
INSERT INTO t1 VALUES (1);
CREATE TABLE t2 (j JSON);
INSERT INTO t2 (j) VALUES ('[1,2,3]');
--sorted_result
SELECT * FROM t1 RIGHT JOIN
  (SELECT o FROM t2, JSON_TABLE(j, '$[*]' COLUMNS (o FOR ORDINALITY)) AS jt) AS t3 ON (t3.o = t1.x);
DROP TABLE t1, t2;

create table t20 (a int not null);
create table t21 (a int not null primary key, js varchar(100));
insert into t20 values (1),(2);
insert into t21 values (1, '{"a":100}');

explain select t20.a, jt1.ab
  from t20 left join t21 on t20.a=t21.a
    join JSON_TABLE(t21.js,'$' COLUMNS (ab INT PATH '$.a')) AS jt1;

drop table t20, t21;

select * from
json_table(
'[
  {"name": "X",
    "colors":["blue"], "sizes": [1,2,3,4],  "prices" : [10,20]},
  {"name": "Y",
    "colors":["red"], "sizes": [10,11],  "prices" : [100,200,300]}
]',
'$[*]' columns
(
  seq0 for ordinality,
  name varchar(4) path '$.name',
  nested path '$.colors[*]' columns (
    seq1 for ordinality,
    color text path '$'
  ),
  nested path '$.sizes[*]' columns (
    seq2 for ordinality,
    size int path '$'
  ),
  nested path '$.prices[*]' columns (
    seq3 for ordinality,
    price int path '$'
  )
)
) as T order by seq0, name;

# MDEV-25140 Success of query execution depends on the outcome of previous queries.
--error ER_JSON_TABLE_ALIAS_REQUIRED
select * from json_table('[]', '$' COLUMNS(x FOR ORDINALITY));
select min(x) from json_table('[]', '$' COLUMNS(x FOR ORDINALITY)) a;

--echo #
--echo # Test for the problem with 
--echo #   - Cross-outer-join dependency
--echo #   - dead-end join prefix
--echo #   - join order pruning
--echo #

create table t20 (a int not null);
create table t21 (a int not null primary key, js varchar(100));

insert into t20 select seq from seq_1_to_100;
insert into t21 select a, '{"a":100}' from t20;

create table t31(a int);
create table t32(b int);
insert into t31 values (1);
insert into t32 values (1);

explain
select
  t20.a, jt1.ab
from
  t20
  left join t21 on t20.a=t21.a
  join
  (t31 left join (t32 join JSON_TABLE(t21.js,'$' COLUMNS (ab INT PATH '$.a')) AS jt1) on t31.a<3);

drop table t20,t21,t31,t32;

--echo #
--echo # MDEV-25142: JSON_TABLE: CREATE VIEW involving EXISTS PATH ends up with invalid frm
--echo #
--disable_warnings
drop view if exists v1;
--enable_warnings

CREATE VIEW v1 AS SELECT * FROM JSON_TABLE('[]', '$' COLUMNS (f INT EXISTS PATH '$')) a ;
show create view v1;
drop view v1;

--echo #
--echo # MDEV-25145: JSON_TABLE: Assertion `fixed == 1' failed in Item_load_file::val_str on 2nd execution of PS	
--echo #
PREPARE stmt FROM "SELECT * FROM (SELECT * FROM JSON_TABLE(LOAD_FILE('x'), '$' COLUMNS (a FOR ORDINALITY)) AS t) AS sq";
EXECUTE stmt;
EXECUTE stmt;

--echo #
--echo # MDEV-JSON_TABLE: Server crashes in handler::print_error / hton_name upon ERROR ON EMPTY
--echo #
--error ER_JSON_TABLE_ERROR_ON_FIELD
SELECT a, b FROM JSON_TABLE('[]', '$' COLUMNS (a FOR ORDINALITY, b INT PATH '$[*]' ERROR ON EMPTY)) AS t ORDER BY a;

--echo #
--echo # MDEV-25151 JSON_TABLE: Unexpectedly padded values in a PATH column.
--echo #
SET @old_character_set_connection= @@character_set_connection;
SET @@character_set_connection= utf8;
select hex(a), b from json_table('["foo","bar"]','$[*]' columns (a char(3) path '$', b for ordinality)) t;
SET @@character_set_connection= @old_character_set_connection;

--echo #
--echo # MDEV-25183 JSON_TABLE: CREATE VIEW involving NESTED PATH ends up with invalid frm
--echo #
CREATE VIEW v AS SELECT * FROM JSON_TABLE('{}', '$' COLUMNS(NESTED PATH '$**.*' COLUMNS(a FOR ORDINALITY), b VARCHAR(8) PATH '$')) AS jt;
SHOW CREATE VIEW v;
SELECT * FROM v;
DROP VIEW v;

--echo #
--echo # MDEV-25178 JSON_TABLE: ASAN use-after-poison in my_fill_8bit / Json_table_column::On_response::respond
--echo #
SELECT * FROM JSON_TABLE('{}', '$' COLUMNS(a CHAR(100) PATH '$' DEFAULT "0" ON ERROR)) AS jt;

--echo #
--echo # MDEV-25188 JSON_TABLE: ASAN use-after-poison in Field_long::reset / Table_function_json_table::setup or malloc(): invalid size.
--echo #
SELECT * FROM JSON_TABLE(CONVERT('{"x":1}' USING utf8mb4), '$' COLUMNS(a INT PATH '$', b CHAR(64) PATH '$.*', c INT EXISTS PATH '$**.*')) AS jt;

--echo #
--echo # 25192 JSON_TABLE: ASAN use-after-poison in field_conv_memcpy / Create_tmp_table::finalize upon query with derived table.
--echo #
SET NAMES utf8;
SELECT * FROM ( SELECT * FROM JSON_TABLE('{}', '$' COLUMNS( a BINARY(12) PATH '$.*', b VARCHAR(40) PATH '$[*]', c VARCHAR(8) PATH '$**.*')) AS jt ) AS sq;
SET NAMES default;

--echo #
--echo # MDEV-25189 JSON_TABLE: Assertion `l_offset >= 0 && table->s->rec_buff_length - l_offset > 0' failed upon CREATE .. SELECT.
--echo #
SET NAMES utf8;
CREATE TABLE t1 AS SELECT * FROM JSON_TABLE('{}', '$' COLUMNS(a CHAR(16) PATH '$.*', b TIMESTAMP PATH '$**.*')) AS jt;
DROP TABLE t1;
SET NAMES default;


--echo #
--echo # MDEV-25230 SON_TABLE: CREATE VIEW with 2nd level NESTED PATH ends up with invalid frm, Assertion `m_status == DA_ERROR || m_status == DA_OK || m_status == DA_OK_BULK' failed.
--echo #

CREATE VIEW v AS SELECT * FROM JSON_TABLE('{}', '$' COLUMNS(NESTED PATH '$' COLUMNS(NESTED PATH '$.*' COLUMNS(o FOR ORDINALITY)))) AS jt;
SELECT * FROM v;
SHOW CREATE VIEW v;
DROP VIEW v;

--echo #
--echo # MDEV-25229 JSON_TABLE: Server crashes in hton_name upon MATCH .. AGAINST.
--echo #

--error ER_TABLE_CANT_HANDLE_FT
SELECT val, MATCH(val) AGAINST( 'MariaDB') FROM JSON_TABLE('{"db":"xx"}', '$' COLUMNS(val VARCHAR(32) PATH '$**.*')) AS jt;

--echo #
--echo # MDEV-25138 JSON_TABLE: A space between JSON_TABLE and opening bracket causes syntax error
--echo #
select * from json_table ('{}', '$' COLUMNS(x FOR ORDINALITY)) a;
create table json_table(id int);
insert into json_table values (1), (2), (3);
select * from json_table;
drop table json_table;

--echo #
--echo # End of 10.6 tests
--echo #