diff options
author | Alexander Korotkov <akorotkov@postgresql.org> | 2019-09-25 21:54:14 +0300 |
---|---|---|
committer | Alexander Korotkov <akorotkov@postgresql.org> | 2019-09-25 22:51:51 +0300 |
commit | bffe1bd68457e43925c362d8728ce3b25bdf1c94 (patch) | |
tree | d4de7be9e4e227a170a8852ab64ff2b610ec5195 /src/test/regress/sql/jsonb_jsonpath.sql | |
parent | 6dda292d4df82a9158d1acc93feecf3b84637b59 (diff) |
Implement jsonpath .datetime() method
This commit implements jsonpath .datetime() method as it's specified in
SQL/JSON standard. There are no-argument and single-argument versions of
this method. No-argument version selects first of ISO datetime formats
matching input string. Single-argument version accepts template string as
its argument.
Additionally to .datetime() method itself this commit also implements
comparison ability of resulting date and time values. There is some difficulty
because exising jsonb_path_*() functions are immutable, while comparison of
timezoned and non-timezoned types involves current timezone. At first, current
timezone could be changes in session. Moreover, timezones themselves are not
immutable and could be updated. This is why we let existing immutable functions
throw errors on such non-immutable comparison. In the same time this commit
provides jsonb_path_*_tz() functions which are stable and support operations
involving timezones. As new functions are added to the system catalog,
catversion is bumped.
Support of .datetime() method was the only blocker prevents T832 from being
marked as supported. sql_features.txt is updated correspondingly.
Extracted from original patch by Nikita Glukhov, Teodor Sigaev, Oleg Bartunov.
Heavily revised by me. Comments were adjusted by Liudmila Mantrova.
Discussion: https://postgr.es/m/fcc6fc6a-b497-f39a-923d-aa34d0c588e8%402ndQuadrant.com
Discussion: https://postgr.es/m/CAPpHfdsZgYEra_PeCLGNoXOWYx6iU-S3wF8aX0ObQUcZU%2B4XTw%40mail.gmail.com
Author: Alexander Korotkov, Nikita Glukhov, Teodor Sigaev, Oleg Bartunov, Liudmila Mantrova
Reviewed-by: Anastasia Lubennikova, Peter Eisentraut
Diffstat (limited to 'src/test/regress/sql/jsonb_jsonpath.sql')
-rw-r--r-- | src/test/regress/sql/jsonb_jsonpath.sql | 172 |
1 files changed, 172 insertions, 0 deletions
diff --git a/src/test/regress/sql/jsonb_jsonpath.sql b/src/test/regress/sql/jsonb_jsonpath.sql index ae8549d5536..246e38b9edd 100644 --- a/src/test/regress/sql/jsonb_jsonpath.sql +++ b/src/test/regress/sql/jsonb_jsonpath.sql @@ -346,6 +346,178 @@ select jsonb_path_query('[null, 1, "a\b", "a\\b", "^a\\b$"]', 'lax $[*] ? (@ lik select jsonb_path_query('[null, 1, "a\b", "a\\b", "^a\\b$"]', 'lax $[*] ? (@ like_regex "^a\\B$" flag "iq")'); select jsonb_path_query('[null, 1, "a\b", "a\\b", "^a\\b$"]', 'lax $[*] ? (@ like_regex "^a\\b$" flag "")'); +select jsonb_path_query('null', '$.datetime()'); +select jsonb_path_query('true', '$.datetime()'); +select jsonb_path_query('1', '$.datetime()'); +select jsonb_path_query('[]', '$.datetime()'); +select jsonb_path_query('[]', 'strict $.datetime()'); +select jsonb_path_query('{}', '$.datetime()'); +select jsonb_path_query('""', '$.datetime()'); +select jsonb_path_query('"12:34"', '$.datetime("aaa")'); +select jsonb_path_query('"aaaa"', '$.datetime("HH24")'); + +select jsonb '"10-03-2017"' @? '$.datetime("dd-mm-yyyy")'; +select jsonb_path_query('"10-03-2017"', '$.datetime("dd-mm-yyyy")'); +select jsonb_path_query('"10-03-2017"', '$.datetime("dd-mm-yyyy").type()'); +select jsonb_path_query('"10-03-2017 12:34"', '$.datetime("dd-mm-yyyy")'); +select jsonb_path_query('"10-03-2017 12:34"', '$.datetime("dd-mm-yyyy").type()'); + +select jsonb_path_query('"10-03-2017 12:34"', ' $.datetime("dd-mm-yyyy HH24:MI").type()'); +select jsonb_path_query('"10-03-2017 12:34 +05:20"', '$.datetime("dd-mm-yyyy HH24:MI TZH:TZM").type()'); +select jsonb_path_query('"12:34:56"', '$.datetime("HH24:MI:SS").type()'); +select jsonb_path_query('"12:34:56 +05:20"', '$.datetime("HH24:MI:SS TZH:TZM").type()'); + +set time zone '+00'; + +select jsonb_path_query('"10-03-2017 12:34"', '$.datetime("dd-mm-yyyy HH24:MI")'); +select jsonb_path_query('"10-03-2017 12:34"', '$.datetime("dd-mm-yyyy HH24:MI TZH")'); +select jsonb_path_query('"10-03-2017 12:34 +05"', '$.datetime("dd-mm-yyyy HH24:MI TZH")'); +select jsonb_path_query('"10-03-2017 12:34 -05"', '$.datetime("dd-mm-yyyy HH24:MI TZH")'); +select jsonb_path_query('"10-03-2017 12:34 +05:20"', '$.datetime("dd-mm-yyyy HH24:MI TZH:TZM")'); +select jsonb_path_query('"10-03-2017 12:34 -05:20"', '$.datetime("dd-mm-yyyy HH24:MI TZH:TZM")'); +select jsonb_path_query('"12:34"', '$.datetime("HH24:MI")'); +select jsonb_path_query('"12:34"', '$.datetime("HH24:MI TZH")'); +select jsonb_path_query('"12:34 +05"', '$.datetime("HH24:MI TZH")'); +select jsonb_path_query('"12:34 -05"', '$.datetime("HH24:MI TZH")'); +select jsonb_path_query('"12:34 +05:20"', '$.datetime("HH24:MI TZH:TZM")'); +select jsonb_path_query('"12:34 -05:20"', '$.datetime("HH24:MI TZH:TZM")'); + +set time zone '+10'; + +select jsonb_path_query('"10-03-2017 12:34"', '$.datetime("dd-mm-yyyy HH24:MI")'); +select jsonb_path_query('"10-03-2017 12:34"', '$.datetime("dd-mm-yyyy HH24:MI TZH")'); +select jsonb_path_query('"10-03-2017 12:34 +05"', '$.datetime("dd-mm-yyyy HH24:MI TZH")'); +select jsonb_path_query('"10-03-2017 12:34 -05"', '$.datetime("dd-mm-yyyy HH24:MI TZH")'); +select jsonb_path_query('"10-03-2017 12:34 +05:20"', '$.datetime("dd-mm-yyyy HH24:MI TZH:TZM")'); +select jsonb_path_query('"10-03-2017 12:34 -05:20"', '$.datetime("dd-mm-yyyy HH24:MI TZH:TZM")'); +select jsonb_path_query('"12:34"', '$.datetime("HH24:MI")'); +select jsonb_path_query('"12:34"', '$.datetime("HH24:MI TZH")'); +select jsonb_path_query('"12:34 +05"', '$.datetime("HH24:MI TZH")'); +select jsonb_path_query('"12:34 -05"', '$.datetime("HH24:MI TZH")'); +select jsonb_path_query('"12:34 +05:20"', '$.datetime("HH24:MI TZH:TZM")'); +select jsonb_path_query('"12:34 -05:20"', '$.datetime("HH24:MI TZH:TZM")'); + +set time zone default; + +select jsonb_path_query('"2017-03-10"', '$.datetime().type()'); +select jsonb_path_query('"2017-03-10"', '$.datetime()'); +select jsonb_path_query('"2017-03-10 12:34:56"', '$.datetime().type()'); +select jsonb_path_query('"2017-03-10 12:34:56"', '$.datetime()'); +select jsonb_path_query('"2017-03-10 12:34:56 +3"', '$.datetime().type()'); +select jsonb_path_query('"2017-03-10 12:34:56 +3"', '$.datetime()'); +select jsonb_path_query('"2017-03-10 12:34:56 +3:10"', '$.datetime().type()'); +select jsonb_path_query('"2017-03-10 12:34:56 +3:10"', '$.datetime()'); +select jsonb_path_query('"12:34:56"', '$.datetime().type()'); +select jsonb_path_query('"12:34:56"', '$.datetime()'); +select jsonb_path_query('"12:34:56 +3"', '$.datetime().type()'); +select jsonb_path_query('"12:34:56 +3"', '$.datetime()'); +select jsonb_path_query('"12:34:56 +3:10"', '$.datetime().type()'); +select jsonb_path_query('"12:34:56 +3:10"', '$.datetime()'); + +set time zone '+00'; + +-- date comparison +select jsonb_path_query( + '["2017-03-10", "2017-03-11", "2017-03-09", "12:34:56", "01:02:03 +04", "2017-03-10 00:00:00", "2017-03-10 12:34:56", "2017-03-10 01:02:03 +04", "2017-03-10 03:00:00 +03"]', + '$[*].datetime() ? (@ == "10.03.2017".datetime("dd.mm.yyyy"))'); +select jsonb_path_query( + '["2017-03-10", "2017-03-11", "2017-03-09", "12:34:56", "01:02:03 +04", "2017-03-10 00:00:00", "2017-03-10 12:34:56", "2017-03-10 01:02:03 +04", "2017-03-10 03:00:00 +03"]', + '$[*].datetime() ? (@ >= "10.03.2017".datetime("dd.mm.yyyy"))'); +select jsonb_path_query( + '["2017-03-10", "2017-03-11", "2017-03-09", "12:34:56", "01:02:03 +04", "2017-03-10 00:00:00", "2017-03-10 12:34:56", "2017-03-10 01:02:03 +04", "2017-03-10 03:00:00 +03"]', + '$[*].datetime() ? (@ < "10.03.2017".datetime("dd.mm.yyyy"))'); +select jsonb_path_query_tz( + '["2017-03-10", "2017-03-11", "2017-03-09", "12:34:56", "01:02:03 +04", "2017-03-10 00:00:00", "2017-03-10 12:34:56", "2017-03-10 01:02:03 +04", "2017-03-10 03:00:00 +03"]', + '$[*].datetime() ? (@ == "10.03.2017".datetime("dd.mm.yyyy"))'); +select jsonb_path_query_tz( + '["2017-03-10", "2017-03-11", "2017-03-09", "12:34:56", "01:02:03 +04", "2017-03-10 00:00:00", "2017-03-10 12:34:56", "2017-03-10 01:02:03 +04", "2017-03-10 03:00:00 +03"]', + '$[*].datetime() ? (@ >= "10.03.2017".datetime("dd.mm.yyyy"))'); +select jsonb_path_query_tz( + '["2017-03-10", "2017-03-11", "2017-03-09", "12:34:56", "01:02:03 +04", "2017-03-10 00:00:00", "2017-03-10 12:34:56", "2017-03-10 01:02:03 +04", "2017-03-10 03:00:00 +03"]', + '$[*].datetime() ? (@ < "10.03.2017".datetime("dd.mm.yyyy"))'); + +-- time comparison +select jsonb_path_query( + '["12:34:00", "12:35:00", "12:36:00", "12:35:00 +00", "12:35:00 +01", "13:35:00 +01", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +01"]', + '$[*].datetime() ? (@ == "12:35".datetime("HH24:MI"))'); +select jsonb_path_query( + '["12:34:00", "12:35:00", "12:36:00", "12:35:00 +00", "12:35:00 +01", "13:35:00 +01", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +01"]', + '$[*].datetime() ? (@ >= "12:35".datetime("HH24:MI"))'); +select jsonb_path_query( + '["12:34:00", "12:35:00", "12:36:00", "12:35:00 +00", "12:35:00 +01", "13:35:00 +01", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +01"]', + '$[*].datetime() ? (@ < "12:35".datetime("HH24:MI"))'); +select jsonb_path_query_tz( + '["12:34:00", "12:35:00", "12:36:00", "12:35:00 +00", "12:35:00 +01", "13:35:00 +01", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +01"]', + '$[*].datetime() ? (@ == "12:35".datetime("HH24:MI"))'); +select jsonb_path_query_tz( + '["12:34:00", "12:35:00", "12:36:00", "12:35:00 +00", "12:35:00 +01", "13:35:00 +01", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +01"]', + '$[*].datetime() ? (@ >= "12:35".datetime("HH24:MI"))'); +select jsonb_path_query_tz( + '["12:34:00", "12:35:00", "12:36:00", "12:35:00 +00", "12:35:00 +01", "13:35:00 +01", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +01"]', + '$[*].datetime() ? (@ < "12:35".datetime("HH24:MI"))'); + +-- timetz comparison +select jsonb_path_query( + '["12:34:00 +01", "12:35:00 +01", "12:36:00 +01", "12:35:00 +02", "12:35:00 -02", "10:35:00", "11:35:00", "12:35:00", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +1"]', + '$[*].datetime() ? (@ == "12:35 +1".datetime("HH24:MI TZH"))'); +select jsonb_path_query( + '["12:34:00 +01", "12:35:00 +01", "12:36:00 +01", "12:35:00 +02", "12:35:00 -02", "10:35:00", "11:35:00", "12:35:00", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +1"]', + '$[*].datetime() ? (@ >= "12:35 +1".datetime("HH24:MI TZH"))'); +select jsonb_path_query( + '["12:34:00 +01", "12:35:00 +01", "12:36:00 +01", "12:35:00 +02", "12:35:00 -02", "10:35:00", "11:35:00", "12:35:00", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +1"]', + '$[*].datetime() ? (@ < "12:35 +1".datetime("HH24:MI TZH"))'); +select jsonb_path_query_tz( + '["12:34:00 +01", "12:35:00 +01", "12:36:00 +01", "12:35:00 +02", "12:35:00 -02", "10:35:00", "11:35:00", "12:35:00", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +1"]', + '$[*].datetime() ? (@ == "12:35 +1".datetime("HH24:MI TZH"))'); +select jsonb_path_query_tz( + '["12:34:00 +01", "12:35:00 +01", "12:36:00 +01", "12:35:00 +02", "12:35:00 -02", "10:35:00", "11:35:00", "12:35:00", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +1"]', + '$[*].datetime() ? (@ >= "12:35 +1".datetime("HH24:MI TZH"))'); +select jsonb_path_query_tz( + '["12:34:00 +01", "12:35:00 +01", "12:36:00 +01", "12:35:00 +02", "12:35:00 -02", "10:35:00", "11:35:00", "12:35:00", "2017-03-10", "2017-03-10 12:35:00", "2017-03-10 12:35:00 +1"]', + '$[*].datetime() ? (@ < "12:35 +1".datetime("HH24:MI TZH"))'); + +-- timestamp comparison +select jsonb_path_query( + '["2017-03-10 12:34:00", "2017-03-10 12:35:00", "2017-03-10 12:36:00", "2017-03-10 12:35:00 +01", "2017-03-10 13:35:00 +01", "2017-03-10 12:35:00 -01", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]', + '$[*].datetime() ? (@ == "10.03.2017 12:35".datetime("dd.mm.yyyy HH24:MI"))'); +select jsonb_path_query( + '["2017-03-10 12:34:00", "2017-03-10 12:35:00", "2017-03-10 12:36:00", "2017-03-10 12:35:00 +01", "2017-03-10 13:35:00 +01", "2017-03-10 12:35:00 -01", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]', + '$[*].datetime() ? (@ >= "10.03.2017 12:35".datetime("dd.mm.yyyy HH24:MI"))'); +select jsonb_path_query( + '["2017-03-10 12:34:00", "2017-03-10 12:35:00", "2017-03-10 12:36:00", "2017-03-10 12:35:00 +01", "2017-03-10 13:35:00 +01", "2017-03-10 12:35:00 -01", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]', + '$[*].datetime() ? (@ < "10.03.2017 12:35".datetime("dd.mm.yyyy HH24:MI"))'); +select jsonb_path_query_tz( + '["2017-03-10 12:34:00", "2017-03-10 12:35:00", "2017-03-10 12:36:00", "2017-03-10 12:35:00 +01", "2017-03-10 13:35:00 +01", "2017-03-10 12:35:00 -01", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]', + '$[*].datetime() ? (@ == "10.03.2017 12:35".datetime("dd.mm.yyyy HH24:MI"))'); +select jsonb_path_query_tz( + '["2017-03-10 12:34:00", "2017-03-10 12:35:00", "2017-03-10 12:36:00", "2017-03-10 12:35:00 +01", "2017-03-10 13:35:00 +01", "2017-03-10 12:35:00 -01", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]', + '$[*].datetime() ? (@ >= "10.03.2017 12:35".datetime("dd.mm.yyyy HH24:MI"))'); +select jsonb_path_query_tz( + '["2017-03-10 12:34:00", "2017-03-10 12:35:00", "2017-03-10 12:36:00", "2017-03-10 12:35:00 +01", "2017-03-10 13:35:00 +01", "2017-03-10 12:35:00 -01", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]', + '$[*].datetime() ? (@ < "10.03.2017 12:35".datetime("dd.mm.yyyy HH24:MI"))'); + +-- timestamptz comparison +select jsonb_path_query( + '["2017-03-10 12:34:00 +01", "2017-03-10 12:35:00 +01", "2017-03-10 12:36:00 +01", "2017-03-10 12:35:00 +02", "2017-03-10 12:35:00 -02", "2017-03-10 10:35:00", "2017-03-10 11:35:00", "2017-03-10 12:35:00", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]', + '$[*].datetime() ? (@ == "10.03.2017 12:35 +1".datetime("dd.mm.yyyy HH24:MI TZH"))'); +select jsonb_path_query( + '["2017-03-10 12:34:00 +01", "2017-03-10 12:35:00 +01", "2017-03-10 12:36:00 +01", "2017-03-10 12:35:00 +02", "2017-03-10 12:35:00 -02", "2017-03-10 10:35:00", "2017-03-10 11:35:00", "2017-03-10 12:35:00", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]', + '$[*].datetime() ? (@ >= "10.03.2017 12:35 +1".datetime("dd.mm.yyyy HH24:MI TZH"))'); +select jsonb_path_query( + '["2017-03-10 12:34:00 +01", "2017-03-10 12:35:00 +01", "2017-03-10 12:36:00 +01", "2017-03-10 12:35:00 +02", "2017-03-10 12:35:00 -02", "2017-03-10 10:35:00", "2017-03-10 11:35:00", "2017-03-10 12:35:00", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]', + '$[*].datetime() ? (@ < "10.03.2017 12:35 +1".datetime("dd.mm.yyyy HH24:MI TZH"))'); +select jsonb_path_query_tz( + '["2017-03-10 12:34:00 +01", "2017-03-10 12:35:00 +01", "2017-03-10 12:36:00 +01", "2017-03-10 12:35:00 +02", "2017-03-10 12:35:00 -02", "2017-03-10 10:35:00", "2017-03-10 11:35:00", "2017-03-10 12:35:00", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]', + '$[*].datetime() ? (@ == "10.03.2017 12:35 +1".datetime("dd.mm.yyyy HH24:MI TZH"))'); +select jsonb_path_query_tz( + '["2017-03-10 12:34:00 +01", "2017-03-10 12:35:00 +01", "2017-03-10 12:36:00 +01", "2017-03-10 12:35:00 +02", "2017-03-10 12:35:00 -02", "2017-03-10 10:35:00", "2017-03-10 11:35:00", "2017-03-10 12:35:00", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]', + '$[*].datetime() ? (@ >= "10.03.2017 12:35 +1".datetime("dd.mm.yyyy HH24:MI TZH"))'); +select jsonb_path_query_tz( + '["2017-03-10 12:34:00 +01", "2017-03-10 12:35:00 +01", "2017-03-10 12:36:00 +01", "2017-03-10 12:35:00 +02", "2017-03-10 12:35:00 -02", "2017-03-10 10:35:00", "2017-03-10 11:35:00", "2017-03-10 12:35:00", "2017-03-10", "2017-03-11", "12:34:56", "12:34:56 +01"]', + '$[*].datetime() ? (@ < "10.03.2017 12:35 +1".datetime("dd.mm.yyyy HH24:MI TZH"))'); + +set time zone default; + -- jsonpath operators SELECT jsonb_path_query('[{"a": 1}, {"a": 2}]', '$[*]'); |