1 <!-- doc/src/sgml/features.sgml -->
3 <appendix id=
"features">
4 <title>SQL Conformance
</title>
7 This section attempts to outline to what extent
8 <productname>PostgreSQL
</productname> conforms to the current SQL
9 standard. The following information is not a full statement of
10 conformance, but it presents the main topics in as much detail as is
11 both reasonable and useful for users.
15 The formal name of the SQL standard is ISO/IEC
9075 <quote>Database
16 Language SQL
</quote>. A revised version of the standard is released
17 from time to time; the most recent update appearing in
2023.
18 The
2023 version is referred to as ISO/IEC
9075:
2023, or simply as SQL:
2023.
19 The versions prior to that were SQL:
2016, SQL:
2011, SQL:
2008, SQL:
2006, SQL:
2003,
20 SQL:
1999, and SQL-
92. Each version
21 replaces the previous one, so claims of conformance to earlier
22 versions have no official merit.
23 <productname>PostgreSQL
</productname> development aims for
24 conformance with the latest official version of the standard where
25 such conformance does not contradict traditional features or common
26 sense. Many of the features required by the SQL
27 standard are supported, though sometimes with slightly differing
28 syntax or function. Further moves towards conformance can be
33 <acronym>SQL-
92</acronym> defined three feature sets for
34 conformance: Entry, Intermediate, and Full. Most database
35 management systems claiming
<acronym>SQL
</acronym> standard
36 conformance were conforming at only the Entry level, since the
37 entire set of features in the Intermediate and Full levels was
38 either too voluminous or in conflict with legacy behaviors.
42 Starting with
<acronym>SQL:
1999</acronym>, the SQL standard defines
43 a large set of individual features rather than the ineffectively
44 broad three levels found in
<acronym>SQL-
92</acronym>. A large
45 subset of these features represents the
<quote>Core
</quote>
46 features, which every conforming SQL implementation must supply.
47 The rest of the features are purely optional.
51 The standard is split into a number of parts, each also known by a shorthand
55 <listitem><para>ISO/IEC
9075-
1 Framework (SQL/Framework)
</para><indexterm><primary>SQL/Framework
</primary></indexterm></listitem>
56 <listitem><para>ISO/IEC
9075-
2 Foundation (SQL/Foundation)
</para><indexterm><primary>SQL/Foundation
</primary></indexterm></listitem>
57 <listitem><para>ISO/IEC
9075-
3 Call Level Interface (SQL/CLI)
</para><indexterm><primary>SQL/CLI
</primary></indexterm></listitem>
58 <listitem><para>ISO/IEC
9075-
4 Persistent Stored Modules (SQL/PSM)
</para><indexterm><primary>SQL/PSM
</primary></indexterm></listitem>
59 <listitem><para>ISO/IEC
9075-
9 Management of External Data (SQL/MED)
</para><indexterm><primary>SQL/MED
</primary></indexterm></listitem>
60 <listitem><para>ISO/IEC
9075-
10 Object Language Bindings (SQL/OLB)
</para><indexterm><primary>SQL/OLB
</primary></indexterm></listitem>
61 <listitem><para>ISO/IEC
9075-
11 Information and Definition Schemas (SQL/Schemata)
</para><indexterm><primary>SQL/Schemata
</primary></indexterm></listitem>
62 <listitem><para>ISO/IEC
9075-
13 Routines and Types using the Java Language (SQL/JRT)
</para><indexterm><primary>SQL/JRT
</primary></indexterm></listitem>
63 <listitem><para>ISO/IEC
9075-
14 XML-related specifications (SQL/XML)
</para><indexterm><primary>SQL/XML
</primary></indexterm></listitem>
64 <listitem><para>ISO/IEC
9075-
15 Multi-dimensional arrays (SQL/MDA)
</para><indexterm><primary>SQL/MDA
</primary></indexterm></listitem>
65 <listitem><para>ISO/IEC
9075-
16 Property Graph Queries (SQL/PGQ)
</para><indexterm><primary>SQL/PGQ
</primary></indexterm></listitem>
68 Note that some part numbers are not (or no longer) used.
72 The
<productname>PostgreSQL
</productname> core covers parts
1,
2,
9,
73 11, and
14. Part
3 is covered by the ODBC driver, and part
13 is
74 covered by the PL/Java plug-in, but exact conformance is currently
75 not being verified for these components. There are currently no
76 implementations of parts
4,
10,
15, and
16
77 for
<productname>PostgreSQL
</productname>.
81 PostgreSQL supports most of the major features of SQL:
2023. Out of
82 177 mandatory features required for full Core conformance,
83 PostgreSQL conforms to at least
170. In addition, there is a long
84 list of supported optional features. It might be worth noting that at
85 the time of writing, no current version of any database management
86 system claims full conformance to Core SQL:
2023.
90 In the following two sections, we provide a list of those features
91 that
<productname>PostgreSQL
</productname> supports, followed by a
92 list of the features defined in
<acronym>SQL:
2023</acronym> which
93 are not yet supported in
<productname>PostgreSQL
</productname>.
94 Both of these lists are approximate: There might be minor details that
95 are nonconforming for a feature that is listed as supported, and
96 large parts of an unsupported feature might in fact be implemented.
97 The main body of the documentation always contains the most accurate
98 information about what does and does not work.
103 Feature codes containing a hyphen are subfeatures. Therefore, if a
104 particular subfeature is not supported, the main feature is listed
105 as unsupported even if some other subfeatures are supported.
109 <sect1 id=
"features-sql-standard">
110 <title>Supported Features
</title>
115 <colspec colname=
"col1" colwidth=
"1.5*"/>
116 <colspec colname=
"col2" colwidth=
"1*"/>
117 <colspec colname=
"col3" colwidth=
"7*"/>
118 <colspec colname=
"col4" colwidth=
"3*"/>
121 <entry>Identifier
</entry>
123 <entry>Description
</entry>
124 <entry>Comment
</entry>
135 <sect1 id=
"unsupported-features-sql-standard">
136 <title>Unsupported Features
</title>
139 The following features defined in
<acronym>SQL:
2023</acronym> are not
140 implemented in this release of
141 <productname>PostgreSQL
</productname>. In a few cases, equivalent
142 functionality is available.
146 <colspec colname=
"col1" colwidth=
"1.5*"/>
147 <colspec colname=
"col2" colwidth=
"1*"/>
148 <colspec colname=
"col3" colwidth=
"7*"/>
149 <colspec colname=
"col4" colwidth=
"3*"/>
152 <entry>Identifier
</entry>
154 <entry>Description
</entry>
155 <entry>Comment
</entry>
159 &features-unsupported;
166 <sect1 id=
"xml-limits-conformance">
167 <title>XML Limits and Conformance to SQL/XML
</title>
170 <primary>SQL/XML
</primary>
171 <secondary>limits and conformance
</secondary>
175 Significant revisions to the XML-related specifications in ISO/IEC
9075-
14
176 (SQL/XML) were introduced with SQL:
2006.
177 <productname>PostgreSQL
</productname>'s implementation of the XML data
178 type and related functions largely follows the earlier
2003 edition,
179 with some borrowing from later editions. In particular:
183 Where the current standard provides a family of XML data types
184 to hold
<quote>document
</quote> or
<quote>content
</quote> in
185 untyped or XML Schema-typed variants, and a type
186 <type>XML(SEQUENCE)
</type> to hold arbitrary pieces of XML content,
187 <productname>PostgreSQL
</productname> provides the single
188 <type>xml
</type> type, which can hold
<quote>document
</quote> or
189 <quote>content
</quote>. There is no equivalent of the
190 standard's
<quote>sequence
</quote> type.
196 <productname>PostgreSQL
</productname> provides two functions
197 introduced in SQL:
2006, but in variants that use the XPath
1.0
198 language, rather than XML Query as specified for them in the
205 <productname>PostgreSQL
</productname> does not support the
206 <literal>RETURNING CONTENT
</literal> or
<literal>RETURNING SEQUENCE
</literal>
207 clauses, functions which are defined to have these in the specification
208 are implicitly returning content.
215 This section presents some of the resulting differences you may encounter.
218 <sect2 id=
"functions-xml-limits-xpath1">
219 <title>Queries Are Restricted to XPath
1.0</title>
222 The
<productname>PostgreSQL
</productname>-specific functions
223 <function>xpath()
</function> and
<function>xpath_exists()
</function>
224 query XML documents using the XPath language.
225 <productname>PostgreSQL
</productname> also provides XPath-only variants
226 of the standard functions
<function>XMLEXISTS
</function> and
227 <function>XMLTABLE
</function>, which officially use
228 the XQuery language. For all of these functions,
229 <productname>PostgreSQL
</productname> relies on the
230 <application>libxml2
</application> library, which provides only XPath
1.0.
234 There is a strong connection between the XQuery language and XPath
235 versions
2.0 and later: any expression that is syntactically valid and
236 executes successfully in both produces the same result (with a minor
237 exception for expressions containing numeric character references or
238 predefined entity references, which XQuery replaces with the
239 corresponding character while XPath leaves them alone). But there is
240 no such connection between these languages and XPath
1.0; it was an
241 earlier language and differs in many respects.
245 There are two categories of limitation to keep in mind: the restriction
246 from XQuery to XPath for the functions specified in the SQL standard, and
247 the restriction of XPath to version
1.0 for both the standard and the
248 <productname>PostgreSQL
</productname>-specific functions.
251 <sect3 id=
"functions-xml-limits-xpath1-xquery-restriction">
252 <title>Restriction of XQuery to XPath
</title>
255 Features of XQuery beyond those of XPath include:
260 XQuery expressions can construct and return new XML nodes, in
261 addition to all possible XPath values. XPath can create and return
262 values of the atomic types (numbers, strings, and so on) but can
263 only return XML nodes that were already present in documents
264 supplied as input to the expression.
270 XQuery has control constructs for iteration, sorting, and grouping.
276 XQuery allows declaration and use of local functions.
283 Recent XPath versions begin to offer capabilities overlapping with
284 these (such as functional-style
<function>for-each
</function> and
285 <function>sort
</function>, anonymous functions, and
286 <function>parse-xml
</function> to create a node from a string),
287 but such features were not available before XPath
3.0.
291 <sect3 id=
"xml-xpath-1-specifics">
292 <title>Restriction of XPath to
1.0</title>
295 For developers familiar with XQuery and XPath
2.0 or later, XPath
1.0
296 presents a number of differences to contend with:
301 The fundamental type of an XQuery/XPath expression, the
302 <type>sequence
</type>, which can contain XML nodes, atomic values,
303 or both, does not exist in XPath
1.0. A
1.0 expression can only
304 produce a node-set (containing zero or more XML nodes), or a single
311 Unlike an XQuery/XPath sequence, which can contain any desired
312 items in any desired order, an XPath
1.0 node-set has no
313 guaranteed order and, like any set, does not allow multiple
314 appearances of the same item.
317 The
<application>libxml2
</application> library does seem to
318 always return node-sets to
<productname>PostgreSQL
</productname>
319 with their members in the same relative order they had in the
320 input document. Its documentation does not commit to this
321 behavior, and an XPath
1.0 expression cannot control it.
329 While XQuery/XPath provides all of the types defined in XML Schema
330 and many operators and functions over those types, XPath
1.0 has only
331 node-sets and the three atomic types
<type>boolean
</type>,
332 <type>double
</type>, and
<type>string
</type>.
338 XPath
1.0 has no conditional operator. An XQuery/XPath expression
339 such as
<literal>if ( hat ) then hat/@size else
"no hat"</literal>
340 has no XPath
1.0 equivalent.
346 XPath
1.0 has no ordering comparison operator for strings. Both
347 <literal>"cat" < "dog"</literal> and
348 <literal>"cat" > "dog"</literal> are false, because each is a
349 numeric comparison of two
<literal>NaN
</literal>s. In contrast,
350 <literal>=
</literal> and
<literal>!=
</literal> do compare the strings
357 XPath
1.0 blurs the distinction between
358 <firstterm>value comparisons
</firstterm> and
359 <firstterm>general comparisons
</firstterm> as XQuery/XPath define
360 them. Both
<literal>sale/@hatsize =
7</literal> and
361 <literal>sale/@customer =
"alice"</literal> are existentially
362 quantified comparisons, true if there is
363 any
<literal>sale
</literal> with the given value for the
364 attribute, but
<literal>sale/@taxable = false()
</literal> is a
365 value comparison to the
366 <firstterm>effective boolean value
</firstterm> of a whole node-set.
367 It is true only if no
<literal>sale
</literal> has
368 a
<literal>taxable
</literal> attribute at all.
374 In the XQuery/XPath data model, a
<firstterm>document
375 node
</firstterm> can have either document form (i.e., exactly one
376 top-level element, with only comments and processing instructions
377 outside of it) or content form (with those constraints
378 relaxed). Its equivalent in XPath
1.0, the
379 <firstterm>root node
</firstterm>, can only be in document form.
380 This is part of the reason an
<type>xml
</type> value passed as the
381 context item to any
<productname>PostgreSQL
</productname>
382 XPath-based function must be in document form.
389 The differences highlighted here are not all of them. In XQuery and
390 the
2.0 and later versions of XPath, there is an XPath
1.0 compatibility
391 mode, and the W3C lists of
392 <ulink url='https://www.w3.org/TR/
2010/REC-xpath-functions-
20101214/#xpath1-compatibility'
>function library changes
</ulink>
394 <ulink url='https://www.w3.org/TR/xpath20/#id-backwards-compatibility'
>language changes
</ulink>
395 applied in that mode offer a more complete (but still not exhaustive)
396 account of the differences. The compatibility mode cannot make the
397 later languages exactly equivalent to XPath
1.0.
401 <sect3 id=
"functions-xml-limits-casts">
402 <title>Mappings between SQL and XML Data Types and Values
</title>
405 In SQL:
2006 and later, both directions of conversion between standard SQL
406 data types and the XML Schema types are specified precisely. However, the
407 rules are expressed using the types and semantics of XQuery/XPath, and
408 have no direct application to the different data model of XPath
1.0.
412 When
<productname>PostgreSQL
</productname> maps SQL data values to XML
413 (as in
<function>xmlelement
</function>), or XML to SQL (as in the output
414 columns of
<function>xmltable
</function>), except for a few cases
415 treated specially,
<productname>PostgreSQL
</productname> simply assumes
416 that the XML data type's XPath
1.0 string form will be valid as the
417 text-input form of the SQL datatype, and conversely. This rule has the
418 virtue of simplicity while producing, for many data types, results similar
419 to the mappings specified in the standard.
423 Where interoperability with other systems is a concern, for some data
424 types, it may be necessary to use data type formatting functions (such
425 as those in
<xref linkend=
"functions-formatting"/>) explicitly to
426 produce the standard mappings.
431 <sect2 id=
"functions-xml-limits-postgresql">
432 <title>Incidental Limits of the Implementation
</title>
435 This section concerns limits that are not inherent in the
436 <application>libxml2
</application> library, but apply to the current
437 implementation in
<productname>PostgreSQL
</productname>.
440 <sect3 id=
"functions-xml-limits-postgresql-by-value-only">
441 <title>Only
<literal>BY VALUE
</literal> Passing Mechanism Is Supported
</title>
444 The SQL standard defines two
<firstterm>passing mechanisms
</firstterm>
445 that apply when passing an XML argument from SQL to an XML function or
446 receiving a result:
<literal>BY REF
</literal>, in which a particular XML
447 value retains its node identity, and
<literal>BY VALUE
</literal>, in which
448 the content of the XML is passed but node identity is not preserved. A
449 mechanism can be specified before a list of parameters, as the default
450 mechanism for all of them, or after any parameter, to override the
455 To illustrate the difference, if
456 <replaceable>x
</replaceable> is an XML value, these two queries in
457 an SQL:
2006 environment would produce true and false, respectively:
460 SELECT XMLQUERY('$a is $b' PASSING BY REF
<replaceable>x
</replaceable> AS a,
<replaceable>x
</replaceable> AS b NULL ON EMPTY);
461 SELECT XMLQUERY('$a is $b' PASSING BY VALUE
<replaceable>x
</replaceable> AS a,
<replaceable>x
</replaceable> AS b NULL ON EMPTY);
466 <productname>PostgreSQL
</productname> will accept
467 <literal>BY VALUE
</literal> or
<literal>BY REF
</literal> in an
468 <function>XMLEXISTS
</function> or
<function>XMLTABLE
</function>
469 construct, but it ignores them. The
<type>xml
</type> data type holds
470 a character-string serialized representation, so there is no node
471 identity to preserve, and passing is always effectively
<literal>BY
476 <sect3 id=
"functions-xml-limits-postgresql-named-parameters">
477 <title>Cannot Pass Named Parameters to Queries
</title>
480 The XPath-based functions support passing one parameter to serve as the
481 XPath expression's context item, but do not support passing additional
482 values to be available to the expression as named parameters.
486 <sect3 id=
"functions-xml-limits-postgresql-no-xml-sequence">
487 <title>No
<type>XML(SEQUENCE)
</type> Type
</title>
490 The
<productname>PostgreSQL
</productname> <type>xml
</type> data type
491 can only hold a value in
<literal>DOCUMENT
</literal>
492 or
<literal>CONTENT
</literal> form. An XQuery/XPath expression
493 context item must be a single XML node or atomic value, but XPath
1.0
494 further restricts it to be only an XML node, and has no node type
495 allowing
<literal>CONTENT
</literal>. The upshot is that a
496 well-formed
<literal>DOCUMENT
</literal> is the only form of XML value
497 that
<productname>PostgreSQL
</productname> can supply as an XPath