On Fri, Apr 10, 2020 at 08:17:09PM -0400, Bruce Momjian wrote: > On Fri, Apr 10, 2020 at 07:21:29PM -0400, Tom Lane wrote: > > Bruce Momjian <br...@momjian.us> writes: > > > I agree with your analysis. I still want to have some mention that > > > partial indexes can be used to create single-NULL columns, which might > > > be required for compatibility with other databases. Attached is an > > > updated patch which removes the previous commit but adds a mention of > > > this. > > > > The single-null thing is probably a useful example, but please make > > it an actual separate example, or at least its own para outside the > > existing <example> sections. > > > > Also, the existing example demonstrating that seems overcomplicated; > > why not just > > > > create unique index ... (1) where (foo is null); > > I ended up using "true" since that is ony one byte; patch attached.
[ thread moved to docs] I now remember that I wrote the first IS NULL in: CREATE UNIQUE INDEX tests_target_one_null ON tests ((target IS NULL)) WHERE target IS NULL; in hope that if someone is looking for the null value in the column, the IS NULL would allow the index to be used to find it, while 1 or true would not. Also, I think the most popular use for this ability would be for multi-column indexes where you want only one NULL value for a combination of columns, e.g.: CREATE UNIQUE INDEX tests_target_one_null ON test (x, (y IS NULL)) WHERE y IS NULL; I have added that. It also hows the use of columns and expressions in the same index. Proposed patch attached. -- Bruce Momjian <br...@momjian.us> https://momjian.us EnterpriseDB https://enterprisedb.com + As you are, so once was I. As I am, so you will be. + + Ancient Roman grave inscription +
diff --git a/doc/src/sgml/indices.sgml b/doc/src/sgml/indices.sgml index 1be209a2fe..2790fb2a89 100644 --- a/doc/src/sgml/indices.sgml +++ b/doc/src/sgml/indices.sgml @@ -705,15 +705,6 @@ CREATE INDEX test1_lower_col1_idx ON test1 (lower(col1)); </programlisting> </para> - <para> - Expression indexes also allow control over the scope of unique indexes. - For example, this unique index prevents duplicate integer values from - being stored in a <type>double precision</type>-typed column: -<programlisting> -CREATE UNIQUE INDEX test1_uniq_int ON tests ((floor(double_col))) -</programlisting> - </para> - <para> If we were to declare this index <literal>UNIQUE</literal>, it would prevent creation of rows whose <literal>col1</literal> values differ only in case, @@ -956,16 +947,22 @@ CREATE UNIQUE INDEX tests_success_constraint ON tests (subject, target) successful tests and many unsuccessful ones. </para> - <para> - This index allows only one null in the indexed column by using a - partial index clause to process only null column values, and using - an expression index clause to index <literal>true</literal> instead - of <literal>null</literal>: + </example> + + <para> + This index allows only one null in the indexed column by using a + partial index clause to process only null column values, and using + an expression index clause to index <literal>true</literal> instead + of <literal>null</literal>: <programlisting> CREATE UNIQUE INDEX tests_target_one_null ON tests ((target IS NULL)) WHERE target IS NULL; </programlisting> - </para> - </example> + This index allows only one null value for each value in the first + referenced column: +<programlisting> +CREATE UNIQUE INDEX tests_combo_one_null ON tests (col1, (target IS NULL)) WHERE target IS NULL; +</programlisting> + </para> <para> Finally, a partial index can also be used to override the system's