On Fri, May 3, 2024 at 9:00 AM David G. Johnston <david.g.johns...@gmail.com>
wrote:

> On Fri, May 3, 2024 at 8:44 AM Tom Lane <t...@sss.pgh.pa.us> wrote:
>
>> Having said that, I reiterate my proposal that we make it a new
>>
> <sect1> under DDL, before 5.2 Default Values which is the first
>> place in ddl.sgml that assumes you have heard of nulls.
>
>
> I will go with this and remove the "Data Basics" section I wrote, leaving
> it to be just a discussion about null values.  The tutorial is the only
> section that really needs unique wording to fit in.  No matter where we
> decide to place it otherwise the core content will be the same, with maybe
> a different section preface to tie it in.
>
>
v3 Attached.

Probably at the 90% complete mark.  Minimal index entries, not as thorough
a look-about of the existing documentation as I'd like.  Probably some
wording and style choices to tweak.  Figured better to get feedback now
before I go into polish mode.  In particular, tweaking and re-running the
examples.

Yes, I am aware of my improper indentation for programlisting and screen. I
wanted to be able to use the code folding features of my editor.  Those can
be readily un-indented in the final version.

The changes to func.sgml is basically one change repeated something like 20
times with tweaks for true/false.  Plus moving the discussion regarding the
SQL specification into the new null handling section.

It took me doing this to really understand the difference between row
constructors and composite typed values, especially since array
constructors produce array typed values and the constructor is just an
unimportant implementation option while row constructors introduce
meaningfully different behaviors when used.

My plan is to have a v4 out next week, without or without a review of this
draft, but then the subsequent few weeks will probably be a bit quiet.

David J.
From bea784bd683f7e022dbfb3d72832d09fc7754913 Mon Sep 17 00:00:00 2001
From: "David G. Johnston" <david.g.johns...@gmail.com>
Date: Wed, 1 May 2024 07:45:48 -0700
Subject: [PATCH] Document NULL

---
 doc/src/sgml/ddl.sgml        |   2 +
 doc/src/sgml/filelist.sgml   |   1 +
 doc/src/sgml/func.sgml       | 268 ++++++-------
 doc/src/sgml/nullvalues.sgml | 719 +++++++++++++++++++++++++++++++++++
 4 files changed, 837 insertions(+), 153 deletions(-)
 create mode 100644 doc/src/sgml/nullvalues.sgml

diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml
index 026bfff70f..68a0fe698d 100644
--- a/doc/src/sgml/ddl.sgml
+++ b/doc/src/sgml/ddl.sgml
@@ -168,6 +168,8 @@ DROP TABLE products;
   </para>
  </sect1>
 
+ &nullvalues;
+
  <sect1 id="ddl-default">
   <title>Default Values</title>
 
diff --git a/doc/src/sgml/filelist.sgml b/doc/src/sgml/filelist.sgml
index 38ec362d8f..882752e88f 100644
--- a/doc/src/sgml/filelist.sgml
+++ b/doc/src/sgml/filelist.sgml
@@ -21,6 +21,7 @@
 <!ENTITY indices    SYSTEM "indices.sgml">
 <!ENTITY json       SYSTEM "json.sgml">
 <!ENTITY mvcc       SYSTEM "mvcc.sgml">
+<!ENTITY nullvalues SYSTEM "nullvalues.sgml">
 <!ENTITY parallel   SYSTEM "parallel.sgml">
 <!ENTITY perform    SYSTEM "perform.sgml">
 <!ENTITY queries    SYSTEM "queries.sgml">
diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 17c44bc338..98fba7742c 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -23295,7 +23295,8 @@ MERGE INTO products p
    This section describes the <acronym>SQL</acronym>-compliant subquery
    expressions available in <productname>PostgreSQL</productname>.
    All of the expression forms documented in this section return
-   Boolean (true/false) results.
+   <link linkend="nullvalues">three-valued</link> typed
+   results (true, false, or null).
   </para>
 
   <sect2 id="functions-subquery-exists">
@@ -23357,19 +23358,17 @@ WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
 
   <para>
    The right-hand side is a parenthesized
-   subquery, which must return exactly one column.  The left-hand expression
+   subquery, which must return exactly one column.  The result of <token>IN</token>
+   is <quote>false</quote> if the subquery returns no rows, otherwise the left-hand expression
    is evaluated and compared to each row of the subquery result.
-   The result of <token>IN</token> is <quote>true</quote> if any equal subquery row is found.
-   The result is <quote>false</quote> if no equal row is found (including the
-   case where the subquery returns no rows).
+   The result is <quote>true</quote> if any equal subquery row is found.
+   The result is <quote>false</quote> if no equal row is found.
   </para>
 
   <para>
-   Note that if the left-hand expression yields null, or if there are
-   no equal right-hand values and at least one right-hand row yields
-   null, the result of the <token>IN</token> construct will be null, not false.
-   This is in accordance with SQL's normal rules for Boolean combinations
-   of null values.
+   As explained in <xref linkend="nullvalues-multielement"/>, it is not possible to see
+   a <quote>false</quote> result in the presence of both rows and null values since the multiple equality
+   tests are AND'd together.
   </para>
 
   <para>
@@ -23386,21 +23385,18 @@ WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
    as described in <xref linkend="sql-syntax-row-constructors"/>.
    The right-hand side is a parenthesized
    subquery, which must return exactly as many columns as there are
-   expressions in the left-hand row.  The left-hand expressions are
+   expressions in the left-hand row.
+   The result of <token>IN</token> is <quote>false</quote> if the subquery returns no rows,
+   otherwise the left-hand expressions are
    evaluated and compared row-wise to each row of the subquery result.
-   The result of <token>IN</token> is <quote>true</quote> if any equal subquery row is found.
-   The result is <quote>false</quote> if no equal row is found (including the
-   case where the subquery returns no rows).
+   The result is <quote>true</quote> if any equal subquery row is found.
+   The result is <quote>false</quote> if no equal row is found.
   </para>
 
   <para>
-   As usual, null values in the rows are combined per
-   the normal rules of SQL Boolean expressions.  Two rows are considered
-   equal if all their corresponding members are non-null and equal; the rows
-   are unequal if any corresponding members are non-null and unequal;
-   otherwise the result of that row comparison is unknown (null).
-   If all the per-row results are either unequal or null, with at least one
-   null, then the result of <token>IN</token> is null.
+   As explained in <xref linkend="nullvalues-multielement"/>, it is not possible to see
+   a <quote>false</quote> result in the presence of both rows and null values since the multiple equality
+   tests are OR'd together.
   </para>
   </sect2>
 
@@ -23412,20 +23408,17 @@ WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
 </synopsis>
 
   <para>
-   The right-hand side is a parenthesized
-   subquery, which must return exactly one column.  The left-hand expression
-   is evaluated and compared to each row of the subquery result.
-   The result of <token>NOT IN</token> is <quote>true</quote> if only unequal subquery rows
-   are found (including the case where the subquery returns no rows).
+   The right-hand side is a parenthesized subquery, which must return exactly one column.
+   The result of <token>NOT IN</token> is <quote>true</quote> if the subquery returns no rows,
+   otherwise the left-hand expression is evaluated and compared to each row of the subquery result.
+   The result is <quote>true</quote> if only unequal subquery rows are found.
    The result is <quote>false</quote> if any equal row is found.
   </para>
 
   <para>
-   Note that if the left-hand expression yields null, or if there are
-   no equal right-hand values and at least one right-hand row yields
-   null, the result of the <token>NOT IN</token> construct will be null, not true.
-   This is in accordance with SQL's normal rules for Boolean combinations
-   of null values.
+   As explained in <xref linkend="nullvalues-multielement"/>, it is not possible to see
+   a <quote>true</quote> result in the presence of both rows and null values since the multiple inequality
+   tests are OR'd together.
   </para>
 
   <para>
@@ -23442,21 +23435,18 @@ WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
    as described in <xref linkend="sql-syntax-row-constructors"/>.
    The right-hand side is a parenthesized
    subquery, which must return exactly as many columns as there are
-   expressions in the left-hand row.  The left-hand expressions are
+   expressions in the left-hand row.
+   The result of <token>NOT IN</token> is <quote>true</quote> if the subquery returns no rows,
+   otherwise the left-hand expressions are
    evaluated and compared row-wise to each row of the subquery result.
-   The result of <token>NOT IN</token> is <quote>true</quote> if only unequal subquery rows
-   are found (including the case where the subquery returns no rows).
+   The result is <quote>true</quote> if only unequal subquery rows are found.
    The result is <quote>false</quote> if any equal row is found.
   </para>
 
   <para>
-   As usual, null values in the rows are combined per
-   the normal rules of SQL Boolean expressions.  Two rows are considered
-   equal if all their corresponding members are non-null and equal; the rows
-   are unequal if any corresponding members are non-null and unequal;
-   otherwise the result of that row comparison is unknown (null).
-   If all the per-row results are either unequal or null, with at least one
-   null, then the result of <token>NOT IN</token> is null.
+   As explained in <xref linkend="nullvalues-multielement"/>, it is not possible to see
+   a <quote>true</quote> result in the presence of both rows and null values since the multiple inequality
+   tests are OR'd together.
   </para>
   </sect2>
 
@@ -23470,13 +23460,13 @@ WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
 
   <para>
    The right-hand side is a parenthesized
-   subquery, which must return exactly one column.  The left-hand expression
+   subquery, which must return exactly one column.  The result of <token>ANY</token> is
+   <quote>false</quote> if the subquery returns no rows, otherwise the left-hand expression
    is evaluated and compared to each row of the subquery result using the
    given <replaceable>operator</replaceable>, which must yield a Boolean
    result.
-   The result of <token>ANY</token> is <quote>true</quote> if any true result is obtained.
-   The result is <quote>false</quote> if no true result is found (including the
-   case where the subquery returns no rows).
+   The result is <quote>true</quote> if any true result is obtained.
+   The result is <quote>false</quote> if no true result is found.
   </para>
 
   <para>
@@ -23485,11 +23475,10 @@ WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
   </para>
 
   <para>
-   Note that if there are no successes and at least one right-hand row yields
-   null for the operator's result, the result of the <token>ANY</token> construct
-   will be null, not false.
-   This is in accordance with SQL's normal rules for Boolean combinations
-   of null values.
+   If <replaceable>operator</replaceable> can produce null valued booleans then, as explained in
+   <xref linkend="nullvalues-multielement"/>, it is not possible to see
+   a <quote>false</quote> result in the presence of both rows and null values since the multiple equality
+   tests are AND'd together.  Note that <literal>IS DISTINCT FROM</literal> is not an operator.
   </para>
 
   <para>
@@ -23507,16 +23496,19 @@ WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
    as described in <xref linkend="sql-syntax-row-constructors"/>.
    The right-hand side is a parenthesized
    subquery, which must return exactly as many columns as there are
-   expressions in the left-hand row.  The left-hand expressions are
+   expressions in the left-hand row.  The result of <token>ANY</token> is
+   <quote>false</quote> if the subquery returns no rows, otherwise the left-hand expressions are
    evaluated and compared row-wise to each row of the subquery result,
    using the given <replaceable>operator</replaceable>.
-   The result of <token>ANY</token> is <quote>true</quote> if the comparison
-   returns true for any subquery row.
-   The result is <quote>false</quote> if the comparison returns false for every
-   subquery row (including the case where the subquery returns no
-   rows).
-   The result is NULL if no comparison with a subquery row returns true,
-   and at least one comparison returns NULL.
+   The result is <quote>true</quote> if the comparison returns true for any subquery row.
+   The result is <quote>false</quote> if the comparison returns false for every subquery row.
+  </para>
+
+  <para>
+   If <replaceable>operator</replaceable> can produce null valued booleans then, as explained in
+   <xref linkend="nullvalues-multielement"/>, it is not possible to see
+   a <quote>false</quote> result in the presence of both rows and null values since the multiple equality
+   tests are OR'd together.  Note that <literal>IS DISTINCT FROM</literal> is not an operator.
   </para>
 
   <para>
@@ -23534,15 +23526,20 @@ WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
 
   <para>
    The right-hand side is a parenthesized
-   subquery, which must return exactly one column.  The left-hand expression
+   subquery, which must return exactly one column.  The result of <token>ALL</token> is
+   <quote>true</quote> if the subquery returns no rows, otherwise the left-hand expression
    is evaluated and compared to each row of the subquery result using the
    given <replaceable>operator</replaceable>, which must yield a Boolean
    result.
-   The result of <token>ALL</token> is <quote>true</quote> if all rows yield true
-   (including the case where the subquery returns no rows).
+   The result is <quote>true</quote> if all rows yield true.
    The result is <quote>false</quote> if any false result is found.
-   The result is NULL if no comparison with a subquery row returns false,
-   and at least one comparison returns NULL.
+  </para>
+
+  <para>
+   If <replaceable>operator</replaceable> can produce null valued booleans then, as explained in
+   <xref linkend="nullvalues-multielement"/>, it is not possible to see
+   a <quote>true</quote> result in the presence of both rows and null values since the multiple equality
+   tests are AND'd together.  Note that <literal>IS DISTINCT FROM</literal> is not an operator.
   </para>
 
   <para>
@@ -23563,22 +23560,21 @@ WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
    as described in <xref linkend="sql-syntax-row-constructors"/>.
    The right-hand side is a parenthesized
    subquery, which must return exactly as many columns as there are
-   expressions in the left-hand row.  The left-hand expressions are
+   expressions in the left-hand row.  The result of <token>ALL</token> is
+   <quote>true</quote> if the subquery returns no rows, otherwise the left-hand expressions are
    evaluated and compared row-wise to each row of the subquery result,
    using the given <replaceable>operator</replaceable>.
-   The result of <token>ALL</token> is <quote>true</quote> if the comparison
-   returns true for all subquery rows (including the
-   case where the subquery returns no rows).
-   The result is <quote>false</quote> if the comparison returns false for any
-   subquery row.
-   The result is NULL if no comparison with a subquery row returns false,
-   and at least one comparison returns NULL.
+   The result is <quote>true</quote> if the comparison returns true for all subquery rows.
+   The result is <quote>false</quote> if the comparison returns false for any subquery row.
   </para>
 
   <para>
-   See <xref linkend="row-wise-comparison"/> for details about the meaning
-   of a row constructor comparison.
+   If <replaceable>operator</replaceable> can produce null valued booleans then, as explained in
+   <xref linkend="nullvalues-multielement"/>, it is not possible to see
+   a <quote>true</quote> result in the presence of both rows and null values since the multiple equality
+   tests are AND'd together.  Note that <literal>IS DISTINCT FROM</literal> is not an operator.
   </para>
+
   </sect2>
 
   <sect2 id="functions-subquery-single-row-comp">
@@ -23603,6 +23599,14 @@ WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
    compared row-wise to the single subquery result row.
   </para>
 
+  <para>
+   If <replaceable>operator</replaceable> can produce null valued booleans then, as explained in
+   <xref linkend="nullvalues-composites"/>, the result cannot be <quote>true</quote> in the
+   presence of null valued fields in either the row constructor or the subquery result row, as
+   the individual field tests are AND'd together.
+   Note that <literal>IS DISTINCT FROM</literal> is not an operator.
+  </para>
+
   <para>
    See <xref linkend="row-wise-comparison"/> for details about the meaning
    of a row constructor comparison.
@@ -23670,7 +23674,8 @@ WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
    <productname>PostgreSQL</productname> extensions; the rest are
    <acronym>SQL</acronym>-compliant.
    All of the expression forms documented in this section return
-   Boolean (true/false) results.
+   <link linkend="nullvalues">three-valued</link> boolean typed
+   results (true, false, or null).
   </para>
 
   <sect2 id="functions-comparisons-in-scalar">
@@ -23683,24 +23688,13 @@ WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
   <para>
    The right-hand side is a parenthesized list
    of expressions.  The result is <quote>true</quote> if the left-hand expression's
-   result is equal to any of the right-hand expressions.  This is a shorthand
-   notation for
-
-<synopsis>
-<replaceable>expression</replaceable> = <replaceable>value1</replaceable>
-OR
-<replaceable>expression</replaceable> = <replaceable>value2</replaceable>
-OR
-...
-</synopsis>
+   result is equal to any of the right-hand expressions.
   </para>
 
   <para>
-   Note that if the left-hand expression yields null, or if there are
-   no equal right-hand values and at least one right-hand expression yields
-   null, the result of the <token>IN</token> construct will be null, not false.
-   This is in accordance with SQL's normal rules for Boolean combinations
-   of null values.
+   As explained in <xref linkend="nullvalues-multielement"/>, it is not possible to see
+   a <quote>false</quote> result in the presence null values since the multiple equality
+   tests are OR'd together.
   </para>
   </sect2>
 
@@ -23714,35 +23708,15 @@ OR
   <para>
    The right-hand side is a parenthesized list
    of expressions.  The result is <quote>true</quote> if the left-hand expression's
-   result is unequal to all of the right-hand expressions.  This is a shorthand
-   notation for
-
-<synopsis>
-<replaceable>expression</replaceable> &lt;&gt; <replaceable>value1</replaceable>
-AND
-<replaceable>expression</replaceable> &lt;&gt; <replaceable>value2</replaceable>
-AND
-...
-</synopsis>
+   result is unequal to all of the right-hand expressions.
   </para>
 
   <para>
-   Note that if the left-hand expression yields null, or if there are
-   no equal right-hand values and at least one right-hand expression yields
-   null, the result of the <token>NOT IN</token> construct will be null, not true
-   as one might naively expect.
-   This is in accordance with SQL's normal rules for Boolean combinations
-   of null values.
+   As explained in <xref linkend="nullvalues-multielement"/>, it is not possible to see
+   a <quote>true</quote> result in the presence of null values since the multiple inequality
+   tests are OR'd together.
   </para>
 
-  <tip>
-  <para>
-   <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
-   cases.  However, null values are much more likely to trip up the novice when
-   working with <token>NOT IN</token> than when working with <token>IN</token>.
-   It is best to express your condition positively if possible.
-  </para>
-  </tip>
   </sect2>
 
   <sect2 id="functions-comparisons-any-some">
@@ -23755,30 +23729,26 @@ AND
 
   <para>
    The right-hand side is a parenthesized expression, which must yield an
-   array value.
-   The left-hand expression
+   array value. The result of <token>ANY</token> is
+   <quote>false</quote> if the array has zero element, otherwise
+   the left-hand expression
    is evaluated and compared to each element of the array using the
    given <replaceable>operator</replaceable>, which must yield a Boolean
    result.
-   The result of <token>ANY</token> is <quote>true</quote> if any true result is obtained.
-   The result is <quote>false</quote> if no true result is found (including the
-   case where the array has zero elements).
+   The result is <quote>true</quote> if any true result is obtained.
+   The result is <quote>false</quote> if no true result is found.
   </para>
 
   <para>
-   If the array expression yields a null array, the result of
-   <token>ANY</token> will be null.  If the left-hand expression yields null,
-   the result of <token>ANY</token> is ordinarily null (though a non-strict
-   comparison operator could possibly yield a different result).
-   Also, if the right-hand array contains any null elements and no true
-   comparison result is obtained, the result of <token>ANY</token>
-   will be null, not false (again, assuming a strict comparison operator).
-   This is in accordance with SQL's normal rules for Boolean combinations
-   of null values.
+   If <replaceable>operator</replaceable> can produce null valued booleans then, as explained in
+   <xref linkend="nullvalues-multielement"/>, it is not possible to see
+   a <quote>false</quote> result in the presence of both elements and null values since the multiple equality
+   tests are AND'd together.  Note that <literal>IS DISTINCT FROM</literal> is not an operator.
   </para>
 
   <para>
    <token>SOME</token> is a synonym for <token>ANY</token>.
+   <token>IN</token> is equivalent to <literal>= ANY</literal>.
   </para>
   </sect2>
 
@@ -23792,26 +23762,27 @@ AND
   <para>
    The right-hand side is a parenthesized expression, which must yield an
    array value.
-   The left-hand expression
+   The result of <token>ALL</token> is
+   <quote>true</quote> if the array has zero elements, otherwise
+   the left-hand expression
    is evaluated and compared to each element of the array using the
    given <replaceable>operator</replaceable>, which must yield a Boolean
    result.
-   The result of <token>ALL</token> is <quote>true</quote> if all comparisons yield true
-   (including the case where the array has zero elements).
+   The result is <quote>true</quote> if all comparisons yield true.
    The result is <quote>false</quote> if any false result is found.
   </para>
 
   <para>
-   If the array expression yields a null array, the result of
-   <token>ALL</token> will be null.  If the left-hand expression yields null,
-   the result of <token>ALL</token> is ordinarily null (though a non-strict
-   comparison operator could possibly yield a different result).
-   Also, if the right-hand array contains any null elements and no false
-   comparison result is obtained, the result of <token>ALL</token>
-   will be null, not true (again, assuming a strict comparison operator).
-   This is in accordance with SQL's normal rules for Boolean combinations
-   of null values.
+   If <replaceable>operator</replaceable> can produce null valued booleans then, as explained in
+   <xref linkend="nullvalues-multielement"/>, it is not possible to see
+   a <quote>true</quote> result in the presence of both elements and null values since the multiple equality
+   tests are AND'd together.  Note that <literal>IS DISTINCT FROM</literal> is not an operator.
+  </para>
+
+  <para>
+   <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
   </para>
+
   </sect2>
 
   <sect2 id="row-wise-comparison">
@@ -23896,20 +23867,11 @@ AND
 </synopsis>
 
   <para>
-   The SQL specification requires row-wise comparison to return NULL if the
-   result depends on comparing two NULL values or a NULL and a non-NULL.
-   <productname>PostgreSQL</productname> does this only when comparing the
-   results of two row constructors (as in
-   <xref linkend="row-wise-comparison"/>) or comparing a row constructor
-   to the output of a subquery (as in <xref linkend="functions-subquery"/>).
-   In other contexts where two composite-type values are compared, two
-   NULL field values are considered equal, and a NULL is considered larger
-   than a non-NULL.  This is necessary in order to have consistent sorting
-   and indexing behavior for composite types.
-  </para>
-
-  <para>
-   Each side is evaluated and they are compared row-wise.  Composite type
+   Each side is evaluated and they are compared row-wise.
+   As discussed in <xref linkend="nullvalues-multielementcomparison"/>,
+   null values are treated as being equal to other null values and greater
+   than all non-null values.
+   Composite type
    comparisons are allowed when the <replaceable>operator</replaceable> is
    <literal>=</literal>,
    <literal>&lt;&gt;</literal>,
diff --git a/doc/src/sgml/nullvalues.sgml b/doc/src/sgml/nullvalues.sgml
new file mode 100644
index 0000000000..d77235a527
--- /dev/null
+++ b/doc/src/sgml/nullvalues.sgml
@@ -0,0 +1,719 @@
+<sect1 id="nullvalues">
+ <title>Null Values</title>
+
+ <indexterm>
+  <primary>null value</primary>
+ </indexterm>
+
+ <para>
+  This section first introduces the concept of null values and then goes
+  on to explain how different parts of the system behave when provided
+  one or more null value inputs.  Examples throughout this section
+  can be executed so long as the following table and rows are created first.
+ </para>
+
+ <programlisting>
+  CREATE TABLE null_examples (
+    id bigint PRIMARY KEY,
+    value integer NULL
+  );
+  INSERT INTO null_examples
+  VALUES (1, 1), (2, NULL), (3, 4);
+ </programlisting>
+
+ <sect2 id="nullvalues-model">
+  <title>Meaning</title>
+  <para>
+   Generally a null value is assumed to mean "unknown", but other interpretations
+   are common.  A data model design may state that a null value
+   is to be used to represent "not applicable" - i.e., that a value is not
+   even possible.  The null value also takes on a literal meaning of "not found"
+   when produced as the result of an outer join.
+  </para>
+ </sect2>
+
+ <sect2 id="nullvalues-usage">
+  <title>Usage</title>
+  <para>
+   A null value, like all values, must have a data type, and is valid for all data types.
+  </para>
+  <para>
+   A null value literal is written as unquoted, case insensitive, NULL.
+   Its type is the pseudo-type unknown but can be cast to any concrete data type.
+   The <link linkend="sql-syntax-constants-generic"><literal>type 'string'</literal></link>
+   syntax, however, will not work as there is no way to express
+   the <literal>NULL</literal> using single quotes.
+  </para>
+  <para>
+  <programlisting>
+  SELECT
+    NULL,
+    pg_typeof(null),
+    pg_typeof(NuLl::text),
+    cast(null as text);
+  </programlisting>
+  <screen>
+   ?column? | pg_typeof | pg_typeof | text
+  ----------+-----------+-----------+------
+            | unknown   | text      |
+  </screen>
+  </para>
+  <para>
+   <programlisting>
+   SELECT text NULL;
+   </programlisting>
+   <screen>
+   ERROR:  column "text" does not exist
+   LINE 1: select text NUll;
+   </screen>
+  </para>
+  <para>
+   The presence of null values in the system results in three-valued logic.
+   In binary logic every outcome is either true or false.  In
+   three-valued logic unknown, represented using a null value, is
+   also an outcome.  Put a bit more formally, the
+   Law of the Excluded Middle does not hold: i.e.,
+   P OR NOT(p) != true; for all p.
+  </para>
+  <para>
+   Aspects of the system that branch based upon
+   whether a condition variable is true or false must therefore
+   decide how to behave when then input condition is a null value.
+   The remaining sub-sections summarize these decisions.
+  </para>
+  <para>
+   In there are two broad classes of such comparison tests: first determining
+   whehow a given value compares to one or more other values, and second, determining
+   how two multi-element values compare to each other.
+  </para>
+ </sect2>
+
+ <sect2 id="nullvalues-cardinalrule">
+  <title>Distinctness - Overcoming the Cardinal Rule of Null Values</title>
+  <para>
+   The cardinal rule, a given null value is never
+   <link linkend="functions-comparison-op-table">equal or unequal</link>
+   to any other non-null.
+  <programlisting>
+   SELECT
+    NULL = NULL as "N = N", NULL != NULL as "N != N",
+    1 = NULL as "1 = N", 1 != NULL as "1 != N",
+    1 = 1 as "1 = 1", 1 != 1 as "1 != 1";
+  </programlisting>
+  <screen>
+   N = N | N != N | 1 = N | 1 != N | 1 = 1 | 1 != 1
+  -------+--------+-------+--------+-------+--------
+         |        |       |        | t     | f
+  </screen>
+   However, as with many rules, there are exceptions
+   <link linkend="nullvalues-multielementcomparison">noted below</link>.  Specifically, when
+   when the two compared values are part of a larger multi-element value.
+   <programlisting>
+     select array[1,2]=array[1,null];
+    </programlisting>
+    <screen>
+      ?column?
+     ----------
+      f
+     (1 row)
+    </screen>
+  </para>
+  <para>
+   Because of this SQL specification mandated rule  checking for a null value has an
+   explicit<literal>IS NULL</literal> test,
+   and additionally there are distinctness tests
+   (e.g., <literal>IS DISTINCT</literal>, and <literal>IS TRUE</literal>)
+   that consider a null value equal to another null value and unequal
+   to any other value. These and other tests are described in
+   <xref linkend="functions-comparison-pred-table"></xref>
+   <programlisting>
+    SELECT id, value,
+     value IS NULL as "IS N",
+     value IS DISTINCT FROM id as "IS D",
+     value != id as "IS !="
+    FROM null_examples;
+   </programlisting>
+   <screen>
+    id | value | IS N | IS D | IS !=
+   ----+-------+------+------+-------
+     1 |     1 | f    | f    | f
+     2 |       | t    | t    |
+     3 |     4 | f    | t    | t
+   </screen>
+  </para>
+  <para>
+   There is also a cardinal warning: when dealing with
+   <link linkend="rowtypes">composite types</link>
+   expressions; <literal>composite IS NULL</literal>
+   and <literal>composite IS NOT NUll</literal>
+   are not the opposites of each other in the case where some,
+   but not all, of the composite's fields are null values.
+   (The case where all fields are null is indistinguishable
+   from the composite as a whole being null.)
+   Write <literal>NOT(composite IS NULL)</literal> instead.
+  <programlisting>
+   SELECT
+     c,
+     c IS NULL as "c IS N",
+     NOT(c IS NULL) as "NOT c IS N",
+     c IS NOT NULL as "c IS NOT N",
+     ROW(value, value) IS NULL as "ROW(v,v) IS N",
+     ROW(value, value) IS NOT NULL as "ROW(v,v) IS NOT N"
+   FROM null_examples AS c;
+  </programlisting>
+  <screen>
+      c   | c IS N | NOT c IS N | c IS NOT N | ROW(v,v) IS N | ROW(v,v) IS NOT N
+   -------+--------+------------+------------+---------------+-------------------
+    (1,1) | f      | t          | t          | f             | t
+    (2,)  | f      | t          | f          | t             | f
+    (3,4) | f      | t          | t          | f             | t
+  </screen>
+   See the <link linkend="nullvalues-multielement">multi-element
+   testing section</link> below for an explanation.
+  </para>
+ </sect2>
+
+ <sect2 id="nullvalues-operations">
+  <title>Null Valued Operands</title>
+  <para>
+   As a general expectation, operator invocation expressions where one of inputs
+   is a null value will result in a null valued output.
+  <programlisting>
+   SELECT
+    1 + null as "Add",
+    'text' || null as "Concatenate";
+  </programlisting>
+  <screen>
+    Add | Concatenate
+   -----+-------------
+        |
+  </screen>
+   Operators that behave otherwise should document their deviation from this norm.
+  </para>
+  <para>
+   A notable example of this is the <literal>IN</literal> operator, which
+   uses equality, not distinctness, for testing.
+   <programlisting>
+    SELECT
+     1 IN (1, null) as "In Present",
+     1 IN (2, null) as "In MIssing",
+     null IN (1, 2) as "N In Non-N",
+     null IN (null, 2) as "N In N";
+   </programlisting>
+   <screen>
+    In Present | In Missing | N In Non-N | N In N
+   ------------+------------+------------+--------
+    t          |            |            |
+   </screen>
+   This is just an extension of the multi-element testing behavior described
+   <link linkend="nullvalues-multielement">below</link>.
+  </para>
+  <para>
+   Experience shows that <literal>CASE</literal> expressions are also prone
+   to bugs since their format encourages binary logic thinking while a
+   <literal>WHEN</literal> test will not consider a null value to be a match.
+   <programlisting>
+    SELECT id, value,
+     CASE WHEN id = value THEN 'Equal' ELSE 'Not Equal' END as "Affirm",
+     CASE WHEN id != value THEN 'Not Equal' ELSE 'Equal' END as "Negate",
+     CASE WHEN value IS NULL THEN 'Null'
+          WHEN id = value THEN 'Equal'
+          ELSE 'Not Equal' END as "Safe Affirm",
+     CASE WHEN value IS NULL THEN 'Null'
+          WHEN id != value THEN 'Not Equal'
+          ELSE 'Equal' END as "Safe Negate"
+    FROM null_examples;
+   </programlisting>
+   <screen>
+    id | value |  Affirm   |  Negate   | Safe Affirm | Safe Negate
+   ----+-------+-----------+-----------+-------------+-------------
+     1 |     1 | Equal     | Equal     | Equal       | Equal
+     2 |       | Not Equal | Equal     | Null        | Null
+     3 |     4 | Not Equal | Not Equal | Not Equal   | Not Equal
+   </screen>
+  </para>
+  <para>
+   The boolean operators <literal>AND</literal> and <literal>OR</literal>
+   will ignore the null value input if the other input is sufficient to
+   to determine the outcome.
+   <programlisting>
+    SELECT
+     true OR null as "T or N",
+     false OR null as "F or N",
+     true AND null  as "T and N",
+     false AND null  as "F and N";
+   </programlisting>
+   <screen>
+     T or N | F or N | T and N | F and N
+    --------+--------+---------+---------
+     t      |        |         | f
+   </screen>
+  </para>
+ </sect2>
+
+ <sect2 id="nullvalues-composites">
+  <title>Null Valued Composite Fields</title>
+  <para>
+   When a composite type is used, a null value can be assigned to any of its fields.
+   So long as at least one field is non-null the composite value as whole exists
+   and an IS NULL test on it will return false.
+  </para>
+  <para>
+   The IS NOT NULL test on a composite performs a test the checks whether
+   all fields of the composite have non-null values.  This is not the same
+   as a non-null composite value.  Specifically, if the composite value has
+   a null valued field then both this test and the IS NULL test will return false.
+  </para>
+  <para>
+   Please read <xref linkend="composite-type-comparison"/> for a complete treatment
+   on how <productname>PostgreSQL</productname> handle row-wise comparison.  The
+   next two multi-element parts of this section discuss those comparisons in the
+   presence of null valued fields and also in terms of the SQL specification.
+  </para>
+ </sect2>
+
+ <sect2 id="nullvalues-multielement">
+  <title>Testing Multi-Element Values with Null Elements</title>
+  <para>
+   Arrays and composite types are multi-element types.  Here we also consider non-empty
+   <link linkend="functions-subquery">subquery results</link>
+   and the list of values specified in the
+   <link linkend="functions-comparisons-in-scalar">IN test</link>.
+   When a test is performed on one of these multi-element values
+   the system will iterate over each element, or pair of elements if the test is
+   <link linkend="row-wise-comparison">comparing two row constructors</link> to each other,
+   left-to-right, combining the results using the boolean operations
+   <link linkend="nullvalues-operations">discussed above</link>. For tests that
+   require an exhaustive search, (e.g., <literal>ALL</literal>, <literal>NOT IN</literal>)
+   the search effectively ends when a false result is found (<literal>AND</literal> combiners).
+   For tests that simply require a true result, (e.g., <literal>ANY</literal>,
+   <literal>IN</literal>) the search effectively ends when a true result is found
+   (<literal>OR</literal> combiners). Therefore:
+   <simplelist>
+    <member>
+     <literal>IN</literal> and <literal>ANY</literal>
+     (<literal>OR</literal>) cannot produce a false result in the presence of null, and
+    </member>
+    <member>
+     <literal>NOT IN</literal> and <literal>ALL</literal>
+     (<literal>AND</literal>) cannot produce a true result in the presence of null.
+    </member>
+   </simplelist>
+   This is because any exhaustive search will produce at least one null value result
+   that cannot be ignored.
+  </para>
+  <para>
+   The SQL specification requires that non-exhaustive
+   (e.g., <literal>IN</literal> and <literal>ANY</literal>) subquery tests
+   return false when there are no rows in the subquery result, and return true
+   for the exhaustive tests (i.e., <literal>ALL</literal>).
+  </para>
+  <para>
+   Note that the <link linkend="nullvalues-cardinalrule">cardinal warning</link>
+   noted above is just the application of this behavior to the
+   <literal>IS NULL</literal> and <literal>IS NOT NULL</literal>
+   tests, which are both exhaustive search tests guaranteed to produce at least one false result
+   when the composite has a mix of null and non-null values.
+  </para>
+  <para>
+   Note that the rules above are applied to situation with a predicate or a scalar value
+   are being compared to a multi-element value.  The rules when two multi-element values are compared
+   to each other are discussed <link linkend="nullvalues-multielementcomparison">next</link>.
+   The two row constructor comparison case included above is also noted below.
+  </para>
+ </sect2>
+
+ <sect2 id="nullvalues-multielementcomparison">
+  <title>Multi-Element Comparisons</title>
+  <para>
+   The <link linkend="nullvalues-multielement">prior section</link> discussed applying
+   a predicate or a scalar value check element-wise across a multi-element value.
+   This section discusses
+   comparing two multi-element values to each other.  As both array and composite typed values
+   can be stored within an index, and comparing two values in that context must not produce
+   a null valued result, considerations are made to adhere to the SQL specification where
+   possible while still making indexes, which the specification is silent on, functional.
+   Specifically, except when comparing two row constructors, null values are considered
+   equal to other null values and greater than all non-null values.
+  </para>
+  <para>
+   There are five pair-wise comparison situations to consider:
+   element-wise when the inputs are arrays, and row-wise when the inputs can be either
+   row constructors or composite typed values.  While these four later combinations seem similar,
+   the fact that row constructors are query literals, while composite typed values can be stored,
+   brings about important differences in how they are treated.  Please read
+   <xref linkend="composite-type-comparison"/> for a fuller treatment of this topic.  Here
+   we briefly recap the five different sitautions in the presence of null values.
+  </para>
+  <sect3 id="nullvalues-multielementcomparison-array">
+   <title>Element-wise Comparisons</title>
+   <para>
+    First,  null values within an array compare as equal to each other and greater than all
+    non-null values, regardless of whether the comparison involves
+    <link linkend="sql-syntax-array-constructors">array constructors</link> or array typed values.
+    <programlisting>
+     select array[1,2]=array[1,null], s, t, s = t, t &gt; s
+     from
+     (values (array[1,2])) sv (s),
+     (values (array[1,null::integer])) st (t);
+    </programlisting>
+    <screen>
+     ?column? |   s   |    t     | ?column? | ?column?
+    ----------+-------+----------+----------+----------
+     f        | {1,2} | {1,NULL} | f        | t
+    </screen>
+   </para>
+  </sect3>
+  <sect3 id="nullvalues-multielementcomparison-rowconstructor">
+   <title>Row-Wise Mutual Row Constructor Comparisons</title>
+   <para>
+    In this situation null values produce unknown when compared to all values.
+    <programlisting>
+     select (1,2)=(1,null), (1,null::integer)=(1,null);
+    </programlisting>
+    <screen>
+      ?column? | ?column?
+     ----------+----------
+               |
+     (1 row)
+    </screen>
+   </para>
+  </sect3>
+  <sect3 id="nullvalues-multielementcomparison-composite">
+   <title>Row-Wise Composite Involved Comparisons</title>
+   <para>
+    In these three situations null values are considered equal to each other and greater than
+    all non-null value.
+   </para>
+   <programlisting>
+    select s, t, s = t, t &lt; (1,2), t = (1,null::integer)
+    from (values ((1,2))) sv (s),
+         (values ((1,null::integer))) st (t);
+   </programlisting>
+   <screen>
+       s   |  t   | ?column? | ?column? | ?column?
+    -------+------+----------+----------+----------
+     (1,2) | (1,) | f        | f        | t
+   </screen>
+  </sect3>
+  <sect3 id="nullvalues-multielementcomparison-sqlconformance">
+   <title>SQL Conformance</title>
+   <para>
+    The SQL specification requires row-wise comparison to return NULL if the
+    result depends on comparing two NULL values or a NULL and a non-NULL.
+    <productname>PostgreSQL</productname> does this only when comparing the
+    results of two row constructors (as in
+    <xref linkend="row-wise-comparison"/>) or comparing a row constructor
+    to the output of a subquery (as in <xref linkend="functions-subquery"/>).
+   </para>
+  </sect3>
+ </sect2>
+
+ <sect2 id="nullvalues-functions">
+  <title>Null Valued Arguments in Normal Function Calls</title>
+  <para>
+   <link linkend="sql-createfunction">Function specifications</link>
+   have a "strictness" attribute that, when set to "strict"
+   (a.k.a. "null on null input") will tell the executor to return a null value for any
+   function call having at least one null valued input, without executing the
+   function.
+  </para>
+  <para>
+   Most functions, especially single argument functions, are defined with strict because without
+   non-null values to act upon they cannot produce a meaningful result.  However, for multi-argument
+   functions, especially <link linkend="xfunc-sql-variadic-functions">variadic functions</link>
+   like concatenate, null values often are simply ignored.
+   This can be different than the choice made by a binary operator performing the same function,
+   like for concatenating text, but not always, like concatenating an element onto an array.
+   <programlisting>
+    SELECT
+     lower(null::text) as "Lower",
+     left('text', null) as "Left",
+     'one' || null as "|| Text Op",
+     concat('one', null) as "concat Text Func",
+     array_append(array[1], null) as "append([], null)",
+     array[1]::integer[] || null::integer as "[] || null",
+     array[1]::integer[] || null::integer[] as "[] || null[]";
+   </programlisting>
+   <screen>
+    Lower | Left | || Text Op | concat Text Func | append([], null) | [] || null | [] || null[]
+   -------+------+------------+------------------+------------------+------------+--------------
+          |      |            | one              | {1,NULL}         | {1,NULL}   | {1}
+   </screen>
+   In short, please read the documentation for the functions you use if they may receive null inputs
+   to understand how they will behave.  Send a documentation comment pointing out any functions
+   that do not behave strictly but whose actual behavior in the presence of null valued input
+   is not described or readily inferred.
+  </para>
+ </sect2>
+
+ <sect2 id="nullvalues-aggregates">
+  <title>Null Valued Arguments in Aggregate and Window Processing</title>
+  <para>
+   When executing an aggregate or window function the state tracking
+   component will remain unchanged even if the underlying processing
+   function returns a null value, whether from being defined strict
+   or it simply returns a null value upon execution.  The aggregation
+   routine will usually ignore the null value and continue processing,
+   as demonstrated in <literal>count(value)</literal> below.
+   <programlisting>
+    SELECT
+     count(*) as "Count",
+     count(value) as "Count Value",
+     count(null_examples) as "Count Composite",
+     count(row(value, value)) as "Count Row"
+    FROM null_examples;
+   </programlisting>
+   <screen>
+    Count | Count Value | Count Composite | Count Row
+   -------+-------------+-----------------+-----------
+        3 |           2 |               3 |         3
+   </screen>
+   Notice the "Count Row" outcome, though.  While we noted in the cardinal warning
+   that a composite whose fields are all null values is indistinguishable from
+   a null value of composite type, the count aggregate does indeed distinguish them,
+   recognizing and counting the non-null composite value produced by the
+   <link linkend="sql-syntax-row-constructors">row constructor</link>
+   <literal>count(row(value, value))</literal>.
+  </para>
+ </sect2>
+
+ <sect2 id="nullvalues-filters">
+  <title>Null Values in Filters</title>
+  <para>
+   A <literal>WHERE</literal> clause that evaluates to a null value for a given row will exclude that row.
+   <programlisting>
+    SELECT id, value FROM null_examples WHERE value = 1;
+   </programlisting>
+   <screen>
+     id | value
+    ----+-------
+      1 |     1
+   </screen>
+  </para>
+ </sect2>
+
+ <sect2 id="nullvalues-constraints">
+  <title>Null Values in Constraints</title>
+  <para>
+   It is possible to define validation expressions
+   (<link linkend="ddl-constraints-check-constraints">check constraints</link>)
+   on tables that ensure only values passing those expressions are inserted.  While
+   this seems like it would behave the same as a filter, the choice here,
+   when an expression evaulates to a null value, is to allow the row to be inserted
+   - the same as a true result.
+   <programlisting>
+    BEGIN;
+    ALTER TABLE null_examples ADD CONSTRAINT value_not_1 CHECK (value != 1);
+    ROLLBACK;
+   </programlisting>
+   <screen>
+    BEGIN
+    ERROR:  check constraint "value_not_1" of relation "null_examples" is violated by some row
+    ROLLBACK
+   </screen>
+   <programlisting>
+    BEGIN;
+    ALTER TABLE null_examples ADD CONSTRAINT value_not_10 CHECK (value != 10);
+    ROLLBACK;
+   </programlisting>
+   <screen>
+    BEGIN
+    ALTER TABLE
+    ROLLBACK
+   </screen>
+   We are using a <link linkend="tutorial-transactions">transaction</link>
+   (begin and rollback) and the alter table command to add two
+   constraints to our null_examples table.  The first constraint prohibits rows with a value
+   of 1, which our row with an id of 1 violates.  Prohibiting the value 10 definitely allows
+   rows with ids 1 and 3 to exist, and since we are not told that some row violates our
+   constraint the null value in the row with id 2 is being accepted as well.
+  </para>
+  <para>
+   The <link linkend="ddl-constraints-not-null"><literal>NOT NULL</literal> column constraint</link>
+   produces the same answer as a <literal>column IS NOT NULL</literal> check constraint but is
+   more concise to write.
+  </para>
+ </sect2>
+
+ <sect2 id="nullvalues-grouping">
+  <title>Null Values When Grouping</title>
+  <para>
+   In the context of both <literal>DISTINCT</literal> and <literal>GROUP BY</literal>
+   it is necessary that all inputs resolve to being either equal to or not equal to all
+   other values.  These features use <link linkend="nullvalues-cardinalrule">distinctness</link>
+   instead of simple equality in order to handle a null value like a definite value equal to
+   another null vale and unequal to all other values.
+   <programlisting>
+    WITH vals (value) AS (VALUES (1), (NULL), (1), (2), (NULL))
+    SELECT
+     value,
+     count(*) as "Count"
+    FROM vals
+    GROUP BY value
+    ORDER BY value;
+   </programlisting>
+   <screen>
+     value | Count
+    -------+-------
+         1 |     2
+         2 |     1
+           |     2
+   </screen>
+   <programlisting>
+    WITH vals (value) AS (VALUES (1), (NULL), (1), (2), (NULL))
+    SELECT DISTINCT value FROM vals
+    ORDER BY value NULLS FIRST;
+   </programlisting>
+   <screen>
+     value
+    -------
+
+         1
+         2
+   </screen>
+  </para>
+ </sect2>
+
+ <sect2 id="nullvalues-ordering">
+  <title>Null Values When Ordering</title>
+  <para>
+   In the context of <literal>ORDER BY</literal>, distinctness rules also apply,
+   though this is insufficient since it must be determined whether or not to
+   present null values before or after all non-null values.  To handle
+   this, the <literal>ORDER BY</literal> clause will let you specify either
+   <literal>NULLS FIRST</literal> or <literal>NULLS LAST</literal>.
+   <programlisting>
+    WITH vals (value) AS (VALUES (1), (NULL), (1), (2), (NULL))
+    SELECT value FROM vals
+    ORDER BY value DESC NULLS FIRST;
+   </programlisting>
+   <screen>
+     value
+    -------
+
+
+         2
+         1
+         1
+   </screen>
+  </para>
+  <para>
+   Note that when dealing with multi-element values the comparison behavior
+   <link linkend="nullvalues-multielementcomparison">described above</link> applies,
+   if the comparison determination rests upon comparing a null value to a non-null value
+   the multi-element value with the null valued component will sort greater than the one
+   with a non-null component.
+  </para>
+ </sect2>
+
+ <sect2 id="nullvalues-indexed">
+  <title>Null Values in Indexes</title>
+  <para>
+   The uniqueness and relative ordering rules applied to null values
+   are defined when creating an index.  For the default
+   <literal>NULLS DISTINCT</literal> uniqueness, equality rules are applied.
+   Specifying <literal>NULLS NOT DISTINCT</literal> will result in
+   <literal>IS DISTINCT FROM</literal> rules being applied whereby all null
+   values are equal to each other.  This setting applies to all columns in the index.
+  </para>
+  <programlisting>
+   BEGIN;
+   CREATE UNIQUE INDEX value_nulls_distinct_implicit ON null_examples (value);
+   CREATE UNIQUE INDEX value_nulls_distinct_explicit ON null_examples (value) NULLS DISTINCT;
+   INSERT INTO null_examples VALUES (4, NULL);
+   ROLLBACK;
+  </programlisting>
+  <screen>
+   BEGIN
+   CREATE INDEX
+   CREATE INDEX
+   INSERT 0 1
+   ROLLBACK
+  </screen>
+    <programlisting>
+   BEGIN;
+   CREATE UNIQUE INDEX value_nulls_not_distinct_explicit ON null_examples (value) NULLS NOT DISTINCT;
+   INSERT INTO null_examples VALUES (4, NULL);
+   ROLLBACK;
+  </programlisting>
+  <screen>
+   BEGIN
+   CREATE INDEX
+   ERROR:  duplicate key value violates unique constraint "value_nulls_not_distinct_explicit"
+   DETAIL:  Key (value)=(null) already exists.
+   ROLLBACK
+  </screen>
+  <para>
+   For ordering, each column in the index gets its own specification of
+   direction and null value placement similar to that found in the
+   <literal>ORDER BY</literal> clause.
+  </para>
+  <para>
+   Note that when dealing with multi-element values the comparison behavior
+   <link linkend="nullvalues-multielementcomparison">described above</link> applies,
+   if the comparison determination rests upon comparing a null value to a non-null value
+   the multi-element value with the null valued component will sort greater than the one
+   with a non-null component.
+  </para>
+ </sect2>
+
+ <sect2 id="nullvalues-settings">
+  <title>Null Valued Settings</title>
+  <para>
+   There are none.  During initializion all settings are assigned a non-null value.
+  </para>
+  <para>
+   This is mostly meaningful for <link linkend="runtime-config-custom">custom settings</link>,
+   thus this section focuses on <link linkend="config-setting-sql">SQL interaction</link>.
+   Unlike settings created by extensions, custom settings can only be textual and the default
+   value for text here is the empty string.
+   <programlisting>
+    SHOW example.string;
+    BEGIN;
+    SELECT set_config('example.string', NULL, true);
+    SELECT current_setting('example.string') IS NULL AS "Setting Is Null";
+    ROLLBACK;
+    SHOW example.string;
+    RESET example.string;
+    SHOW example.string;
+   </programlisting>
+   <screen>
+    ERROR:  unrecognized configuration parameter "example.string"
+    BEGIN
+     set_config
+    ------------
+
+    (1 row)
+
+     Setting Is Null
+    -----------------
+     f
+    (1 row)
+
+    ROLLBACK
+     example.string
+    ----------------
+
+    (1 row)
+
+    RESET
+     example.string
+    ----------------
+
+    (1 row)
+   </screen>
+   Notice two important behaviors: first, even though we passed in a null value to
+   to the <literal>set_config</literal> function, the <literal>current_setting</literal>
+   function returned a non-null value, specifically the empty string.  Second, after ROLLBACK the
+   setting is still present (i.e., the error seen before creating the setting no longer appears),
+   and in fact will remain so until the session ends
+   (i.e., RESET does not restore the non-existence state.)
+  </para>
+  <para>
+    The other ways to specify settings do not have a means to specify null values,
+    a specific non-null value is required as part of the specification of the setting.
+   </para>
+ </sect2>
+
+</sect1>
-- 
2.34.1

Reply via email to