PostgreSQL 10.0 preview 功能增强 - 兼容SQL:2016标准(之SQL/JSON) 道高一丈魔高一丈

本文涉及的产品
云原生数据库 PolarDB MySQL 版,Serverless 5000PCU 100GB
云原生数据库 PolarDB 分布式版,标准版 2核8GB
云数据库 RDS MySQL Serverless,0.5-2RCU 50GB
简介:

标签

PostgreSQL , 10.0 , sql:2016 , sql/json , oracle


背景

PostgreSQL 很多年前,就支持JSON类型,属于最早支持JSON类型的关系数据库。内置了两个JSON类型json与jsonb。

而Oracle从12c才开始支持JSON。

SQL标准2016中,包含了一个SQL/JSON的数据模型标准,这个标准的内容购买页面 https://www.iso.org/standard/63556.html

Oracle 12c支持的JSON与该标准非常接近(不知道是不是Oracle想用标准来后来居上呢?)

那么虽然PostgreSQL早在几年前就支持了JSON,由于oracle市场还是很大,很多用户也许会习惯ORACLE的那一套JSON用法。

PostgreSQL json, jsonb已有的生态,包括自身的用法,周边的例如pljava, pljavascript, plv8等存储过程引擎。感兴趣可以谷歌百科。

个人认为实用性已超SQL标准,但是拗不过人多。客户第一。

所以,PostgreSQL社区依旧会在10.0支持SQL:2016的SQL/JSON标准,真是道高一尺魔高一丈啊。

Hi there,  


Attached patch is an implementation of SQL/JSON data model from SQL-2016  
standard (ISO/IEC 9075-2:2016(E)), which was published 2016-12-15 and is  
available only for purchase from ISO web site (  
https://www.iso.org/standard/63556.html). Unfortunately I didn't find any  
public sources of the standard or any preview documents, but Oracle  
implementation of json support in 12c release 2 is very close (  
http://docs.oracle.com/database/122/ADJSN/json-in-oracle-database.htm),  
also we used https://livesql.oracle.com/  to understand some details.  

Postgres has already two json data types - json and jsonb and implementing  
another json data type, which strictly conforms the standard, would be not  
a good idea. Moreover, SQL standard doesn’t describe data type, but only  
data model, which “comprises SQL/JSON items and SQL/JSON sequences. The  
components of the SQL/JSON data model are:  

1) An SQL/JSON item is defined recursively as any of the following:  

a) An SQL/JSON scalar, defined as a non-null value of any of the following  
predefined (SQL) types:  

character string with character set Unicode, numeric, Boolean, or datetime.  

b) An SQL/JSON null, defined as a value that is distinct from any value of  
any SQL type.  

NOTE 122 — An SQL/JSON null is distinct from the SQL null value.  

c) An SQL/JSON array, defined as an ordered list of zero or more SQL/JSON  
items, called the SQL/JSON  

elements of the SQL/JSON array.  

d) An SQL/JSON object, defined as an unordered collection of zero or more  
SQL/JSON members….  

“  

Our jsonb corresponds to SQL/JSON with UNIQUE KEYS and implicit ordering of  
keys and our main intention was to provide support of jsonb as a most  
important and usable data type.  

We created repository for reviewing (ask for write access) -  
https://github.com/postgrespro/sqljson/tree/sqljson  


Examples of usage can be found in src/test/regress/sql/sql_json.sql  

The whole documentation about json support should be reorganized and added,  
and we plan to do this before release. We need help of community here.  

Our goal is to provide support of main features of SQL/JSON to release 10,  
as we discussed at developers meeting in Brussels (Andrew Dunstan has  
kindly agreed to review the patch).  

We had not much time to develop the complete support, because of standard  
availability), but hope all major features are here, namely, all nine  
functions as described in the standard (but see implementation notes below):  

“All manipulation (e.g., retrieval, creation, testing) of SQL/JSON items is  
performed through a number of SQL/JSON functions. There are nine such  
functions, categorized as SQL/JSON retrieval functions and SQL/JSON  
construction functions. The SQL/JSON retrieval functions are characterized  
by operating on JSON data and returning an SQL value (possibly a Boolean  
value) or a JSON value. The SQL/JSON construction functions return JSON  
data created from operations on SQL data or other JSON data.  

The SQL/JSON retrieval functions are:  

— <JSON value function>: extracts an SQL value of a predefined type from a  
JSON text.  

— <JSON query>: extracts a JSON text from a JSON text.  

— <JSON table>: converts a JSON text to an SQL table.  

— <JSON predicate>: tests whether a string value is or is not properly  
formed JSON text.  

— <JSON exists predicate>: tests whether an SQL/JSON path expression  
returns any SQL/JSON items.  

The SQL/JSON construction functions are:  

— <JSON object constructor>: generates a string that is a serialization of  
an SQL/JSON object.  

— <JSON array constructor>: generates a string that is a serialization of  
an SQL/JSON array.  

— <JSON object aggregate constructor>: generates, from an aggregation of  
SQL data, a string that is a serialization  

of an SQL/JSON object.  

— <JSON array aggregate constructor>: generates, from an aggregation of SQL  
data, a string that is a serialization  

of an SQL/JSON array.  

A JSON-returning function is an SQL/JSON construction function or  
JSON_QUERY.”  

The standard describes SQL/JSON path language, which used by SQL/JSON query  
operators to query JSON. It defines path language as string literal. We  
implemented the path language as  JSONPATH data type, since other  
approaches are not friendly to planner and executor.  

The functions and JSONPATH provide a new functionality for json support,  
namely, ability to operate (in standard specified way) with json structure  
at SQL-language level - the often requested feature by the users.  

The patch is consists of about 15000 insertions (about 5000 lines are from  
tests), passes all regression tests and doesn’t touches critical parts, so  
we hope with community help to bring it to committable state.  

Authors: Nikita Glukhov, Teodor Sigaev, Oleg Bartunov and Alexander Korotkov  

Implementation notes:  


   1.  

   We didn’t implemented ‘datetime’ support, since it’s not clear from  
   standard.  
   2.  

   JSON_OBJECT/JSON_OBJECTAGG (KEY <key> VALUE <value>, ...) doesn’t  
   implemented, only (<key>:<value>, …) and (<key> VALUE <value>, …) are  
   supported, because of  grammar conflicts with leading KEY keyword.  
   3.  

   FORMAT (JSON|JSONB))  in JSON_ARRAYAGG with subquery  doesn’t supported,  
   because of grammar conflicts with non-reserved word FORMAT.  
   4.  

   JSONPATH implemented only for  jsonb data type , so JSON_EXISTS(),  
   JSON_VALUE(), JSON_QUERY() and JSON_TABLE() doesn’t works if context item  
   is of json data type.  
   5.  

   Some methods and predicates for JSONPATH not yet implemented, for  
   example  .type(), .size(), .keyvalue(),  predicates  like_regex, starts  
   with, etc. They are not key features and we plan to make them in next  
   release.  
   6.  

   JSONPATH doesn’t support expression for index array, like [2+3 to  
   $upperbound], only simple constants like [5, 7 to 12] are supported.  
   7.  

   JSONPATH extensions to standard: .** (wildcard path accessor), .key  
   (member accessor without leading @).  
   8.  

   FORMAT JSONB extension to standard for returning jsonb - standard  
   specifies possibility of returning custom type.  
   9.  

   JSON_EXISTS(), JSON_VALUE(), JSON_QUERY() are implemented using new  
   executor node JsonExpr.  
   10.  

   JSON_TABLE() is transformed into joined subselects with JSON_VALUE() and  
   JSON_QUERY() in target list.  
   11.  

   JSON_OBJECT(), JSON_ARRAY() constructors and IS JSON predicate are  
   transformed into raw function calls.  
   12.  

   Added explicit casts bytea=>jsonb and jsonb=>bytea (for jsonb=>bytea  
   output using RETURNING bytea FORMAT JSONB and corresponding bytea=>jsonb  
   input using <jsonb_bytea_expr> FORMAT JSONB).  


Best regards,  

Oleg  

玩法

https://github.com/postgrespro/sqljson/blob/sqljson/src/test/regress/sql/sql_json.sql

这个patch的讨论,详见邮件组,本文末尾URL。

PostgreSQL社区的作风非常严谨,一个patch可能在邮件组中讨论几个月甚至几年,根据大家的意见反复的修正,patch合并到master已经非常成熟,所以PostgreSQL的稳定性也是远近闻名的。

参考

https://commitfest.postgresql.org/13/1063/

https://www.postgresql.org/message-id/flat/CAF4Au4w2x-5LTnN_bxky-mq4=WOqsGsxSpENCzHRAzSnEd8+WQ@mail.gmail.com#CAF4Au4w2x-5LTnN_bxky-mq4=WOqsGsxSpENCzHRAzSnEd8+WQ@mail.gmail.com

相关实践学习
使用PolarDB和ECS搭建门户网站
本场景主要介绍基于PolarDB和ECS实现搭建门户网站。
阿里云数据库产品家族及特性
阿里云智能数据库产品团队一直致力于不断健全产品体系,提升产品性能,打磨产品功能,从而帮助客户实现更加极致的弹性能力、具备更强的扩展能力、并利用云设施进一步降低企业成本。以云原生+分布式为核心技术抓手,打造以自研的在线事务型(OLTP)数据库Polar DB和在线分析型(OLAP)数据库Analytic DB为代表的新一代企业级云原生数据库产品体系, 结合NoSQL数据库、数据库生态工具、云原生智能化数据库管控平台,为阿里巴巴经济体以及各个行业的企业客户和开发者提供从公共云到混合云再到私有云的完整解决方案,提供基于云基础设施进行数据从处理、到存储、再到计算与分析的一体化解决方案。本节课带你了解阿里云数据库产品家族及特性。
相关文章
|
24天前
|
关系型数据库 Serverless 分布式数据库
【公测】PolarDB PostgreSQL版Serverless功能免费使用​!
【公测】PolarDB PostgreSQL版Serverless功能免费使用​,公测于2024年3月28日开始,持续三个月,公测期间可以免费使用!
|
1月前
|
Oracle 关系型数据库 分布式数据库
PolarDB常见问题之PolarDB(Oracle兼容版) 执行命令报错如何解决
PolarDB是阿里云推出的下一代关系型数据库,具有高性能、高可用性和弹性伸缩能力,适用于大规模数据处理场景。本汇总囊括了PolarDB使用中用户可能遭遇的一系列常见问题及解答,旨在为数据库管理员和开发者提供全面的问题指导,确保数据库平稳运行和优化使用体验。
|
3月前
|
存储 关系型数据库 MySQL
PolarDB优势功能
PolarDB优势功能
|
4月前
|
存储 SQL 关系型数据库
PolarDB这个sql行存和列存性能差别好大 ,为什么?
PolarDB这个sql行存和列存性能差别好大 ,为什么?
33 0
|
1月前
|
关系型数据库 分布式数据库 数据库
PolarDB PostgreSQL版:Oracle兼容的高性能数据库
PolarDB PostgreSQL版是一款高性能的数据库,具有与Oracle兼容的特性。它采用了分布式架构,可以轻松处理大量的数据,同时还支持多种数据类型和函数,具有高可用性和可扩展性。它还提供了丰富的管理工具和性能优化功能,为企业提供了可靠的数据存储和处理解决方案。PolarDB PostgreSQL版在数据库领域具有很高的竞争力,可以满足各种企业的需求。
|
1月前
|
关系型数据库 Serverless 分布式数据库
PolarDB PostgreSQL版Serverless功能上线公测啦,公测期间免费使用!
Serverless数据库能够使得数据库集群资源随客户业务负载动态弹性扩缩,将客户从复杂的业务资源评估和运维工作中解放出来。PolarDB PostgreSQL版 Serverless提供了CPU、内存、存储、网络资源的实时弹性能力,构建计算与存储分离架构下的 PolarDB PostgreSQL版产品新形态。
|
24天前
|
存储 JSON 关系型数据库
PostgreSQL Json应用场景介绍和Shared Detoast优化
PostgreSQL Json应用场景介绍和Shared Detoast优化
|
1月前
|
SQL 关系型数据库 分布式数据库
在PolarDB中,如果慢SQL导致了CPU升高,进而又产生了更多的慢SQL
【2月更文挑战第22天】在PolarDB中,如果慢SQL导致了CPU升高,进而又产生了更多的慢SQL
13 1
|
2月前
|
SQL JSON Apache
Flink SQL问题之复杂JSON解析如何解决
Apache Flink是由Apache软件基金会开发的开源流处理框架,其核心是用Java和Scala编写的分布式流数据流引擎。本合集提供有关Apache Flink相关技术、使用技巧和最佳实践的资源。
401 0
|
2月前
|
SQL 关系型数据库 分布式数据库
在PolarDB for PostgreSQL中,你可以使用LIKE运算符来实现类似的查询功能,而不是使用IF函数
在PolarDB for PostgreSQL中,你可以使用LIKE运算符来实现类似的查询功能,而不是使用IF函数
43 7

相关产品

  • 云原生数据库 PolarDB