Add num_nulls() and num_nonnulls() to count NULL arguments.
authorTom Lane <[email protected]>
Fri, 5 Feb 2016 04:03:10 +0000 (23:03 -0500)
committerTom Lane <[email protected]>
Fri, 5 Feb 2016 04:03:37 +0000 (23:03 -0500)
An example use-case is "CHECK(num_nonnulls(a,b,c) = 1)" to assert that
exactly one of a,b,c isn't NULL.  The functions are variadic, so they
can also be pressed into service to count the number of null or nonnull
elements in an array.

Marko Tiikkaja, reviewed by Pavel Stehule

doc/src/sgml/func.sgml
src/backend/utils/adt/misc.c
src/include/catalog/catversion.h
src/include/catalog/pg_proc.h
src/include/utils/builtins.h
src/test/regress/expected/misc_functions.out [new file with mode: 0644]
src/test/regress/parallel_schedule
src/test/regress/serial_schedule
src/test/regress/sql/misc_functions.sql [new file with mode: 0644]

index 139aa2b811e88f92719904f8da727c21bd0bc22d..f9eea76fd5f1646dd64b1aa2ab17bd26b7f24e1d 100644 (file)
   </sect1>
 
   <sect1 id="functions-comparison">
-   <title>Comparison Operators</title>
+   <title>Comparison Functions and Operators</title>
 
    <indexterm zone="functions-comparison">
     <primary>comparison</primary>
    </indexterm>
 
    <para>
-    The usual comparison operators are available, shown in <xref
-    linkend="functions-comparison-table">.
+    The usual comparison operators are available, as shown in <xref
+    linkend="functions-comparison-op-table">.
    </para>
 
-   <table id="functions-comparison-table">
+   <table id="functions-comparison-op-table">
     <title>Comparison Operators</title>
     <tgroup cols="2">
      <thead>
    </para>
 -->
 
+   <para>
+    Some comparison-related functions are also available, as shown in <xref
+    linkend="functions-comparison-func-table">.
+   </para>
+
+  <table id="functions-comparison-func-table">
+    <title>Comparison Functions</title>
+    <tgroup cols="4">
+     <thead>
+      <row>
+       <entry>Function</entry>
+       <entry>Description</entry>
+       <entry>Example</entry>
+       <entry>Example Result</entry>
+      </row>
+     </thead>
+     <tbody>
+      <row>
+       <entry>
+         <indexterm>
+          <primary>num_nonnulls</primary>
+         </indexterm>
+         <literal>num_nonnulls(VARIADIC "any")</literal>
+       </entry>
+       <entry>returns the number of non-NULL arguments</entry>
+       <entry><literal>num_nonnulls(1, NULL, 2)</literal></entry>
+       <entry><literal>2</literal></entry>
+      </row>
+      <row>
+       <entry>
+         <indexterm>
+          <primary>num_nulls</primary>
+         </indexterm>
+         <literal>num_nulls(VARIADIC "any")</literal>
+       </entry>
+       <entry>returns the number of NULL arguments</entry>
+       <entry><literal>num_nulls(1, NULL, 2)</literal></entry>
+       <entry><literal>1</literal></entry>
+      </row>
+     </tbody>
+    </tgroup>
+   </table>
+
   </sect1>
 
   <sect1 id="functions-math">
@@ -10389,7 +10432,7 @@ table2-mapping
   </note>
   <para>
    The standard comparison operators shown in  <xref
-   linkend="functions-comparison-table"> are available for
+   linkend="functions-comparison-op-table"> are available for
    <type>jsonb</type>, but not for <type>json</type>. They follow the
    ordering rules for B-tree operations outlined at <xref
    linkend="json-indexing">.
index 6a306f39a9b777a0b5c07bc92416add5f7dee6e3..43f36db47bb1864351e9e14e4ba168f3d7b4774d 100644 (file)
 #define atooid(x)  ((Oid) strtoul((x), NULL, 10))
 
 
+/*
+ * Common subroutine for num_nulls() and num_nonnulls().
+ * Returns TRUE if successful, FALSE if function should return NULL.
+ * If successful, total argument count and number of nulls are
+ * returned into *nargs and *nulls.
+ */
+static bool
+count_nulls(FunctionCallInfo fcinfo,
+           int32 *nargs, int32 *nulls)
+{
+   int32       count = 0;
+   int         i;
+
+   /* Did we get a VARIADIC array argument, or separate arguments? */
+   if (get_fn_expr_variadic(fcinfo->flinfo))
+   {
+       ArrayType  *arr;
+       int         ndims,
+                   nitems,
+                  *dims;
+       bits8      *bitmap;
+
+       Assert(PG_NARGS() == 1);
+
+       /*
+        * If we get a null as VARIADIC array argument, we can't say anything
+        * useful about the number of elements, so return NULL.  This behavior
+        * is consistent with other variadic functions - see concat_internal.
+        */
+       if (PG_ARGISNULL(0))
+           return false;
+
+       /*
+        * Non-null argument had better be an array.  We assume that any call
+        * context that could let get_fn_expr_variadic return true will have
+        * checked that a VARIADIC-labeled parameter actually is an array.  So
+        * it should be okay to just Assert that it's an array rather than
+        * doing a full-fledged error check.
+        */
+       Assert(OidIsValid(get_base_element_type(get_fn_expr_argtype(fcinfo->flinfo, 0))));
+
+       /* OK, safe to fetch the array value */
+       arr = PG_GETARG_ARRAYTYPE_P(0);
+
+       /* Count the array elements */
+       ndims = ARR_NDIM(arr);
+       dims = ARR_DIMS(arr);
+       nitems = ArrayGetNItems(ndims, dims);
+
+       /* Count those that are NULL */
+       bitmap = ARR_NULLBITMAP(arr);
+       if (bitmap)
+       {
+           int         bitmask = 1;
+
+           for (i = 0; i < nitems; i++)
+           {
+               if ((*bitmap & bitmask) == 0)
+                   count++;
+
+               bitmask <<= 1;
+               if (bitmask == 0x100)
+               {
+                   bitmap++;
+                   bitmask = 1;
+               }
+           }
+       }
+
+       *nargs = nitems;
+       *nulls = count;
+   }
+   else
+   {
+       /* Separate arguments, so just count 'em */
+       for (i = 0; i < PG_NARGS(); i++)
+       {
+           if (PG_ARGISNULL(i))
+               count++;
+       }
+
+       *nargs = PG_NARGS();
+       *nulls = count;
+   }
+
+   return true;
+}
+
+/*
+ * num_nulls()
+ * Count the number of NULL arguments
+ */
+Datum
+pg_num_nulls(PG_FUNCTION_ARGS)
+{
+   int32       nargs,
+               nulls;
+
+   if (!count_nulls(fcinfo, &nargs, &nulls))
+       PG_RETURN_NULL();
+
+   PG_RETURN_INT32(nulls);
+}
+
+/*
+ * num_nonnulls()
+ * Count the number of non-NULL arguments
+ */
+Datum
+pg_num_nonnulls(PG_FUNCTION_ARGS)
+{
+   int32       nargs,
+               nulls;
+
+   if (!count_nulls(fcinfo, &nargs, &nulls))
+       PG_RETURN_NULL();
+
+   PG_RETURN_INT32(nargs - nulls);
+}
+
+
 /*
  * current_database()
  * Expose the current database to the user
index 568c98f94e4653383d95de02bc5ebbb2c181820b..90992f269ebbbbd18d3db660b5d6d508b1972b1a 100644 (file)
@@ -53,6 +53,6 @@
  */
 
 /*                         yyyymmddN */
-#define CATALOG_VERSION_NO 201602031
+#define CATALOG_VERSION_NO 201602041
 
 #endif
index 5ded13e2b01edb199b32659c48d0282ca1b086a6..c6b4916f24868e95cc1057079bf1c37d1d824a7a 100644 (file)
@@ -686,6 +686,12 @@ DATA(insert OID = 422 (  hashinet         PGNSP PGUID 12 1 0 0 0 f f f f t f i s 1 0
 DESCR("hash");
 DATA(insert OID = 432 (  hash_numeric     PGNSP PGUID 12 1 0 0 0 f f f f t f i s 1 0 23 "1700" _null_ _null_ _null_ _null_ _null_ hash_numeric _null_ _null_ _null_ ));
 DESCR("hash");
+
+DATA(insert OID = 438 (  num_nulls        PGNSP PGUID 12 1 0 2276 0 f f f f f f i s 1 0 23 "2276" "{2276}" "{v}" _null_ _null_ _null_ pg_num_nulls _null_ _null_ _null_ ));
+DESCR("count the number of NULL arguments");
+DATA(insert OID = 440 (  num_nonnulls     PGNSP PGUID 12 1 0 2276 0 f f f f f f i s 1 0 23 "2276" "{2276}" "{v}" _null_ _null_ _null_ pg_num_nonnulls _null_ _null_ _null_ ));
+DESCR("count the number of non-NULL arguments");
+
 DATA(insert OID = 458 (  text_larger      PGNSP PGUID 12 1 0 0 0 f f f f t f i s 2 0 25 "25 25" _null_ _null_ _null_ _null_ _null_ text_larger _null_ _null_ _null_ ));
 DESCR("larger of two");
 DATA(insert OID = 459 (  text_smaller     PGNSP PGUID 12 1 0 0 0 f f f f t f i s 2 0 25 "25 25" _null_ _null_ _null_ _null_ _null_ text_smaller _null_ _null_ _null_ ));
index 5e8e8329b8261f7cb57116abf8ff5a3ecab26cf8..c9be32e33acddfc560a3a471b8abee0f7815db00 100644 (file)
@@ -490,6 +490,8 @@ extern Datum pg_ls_dir(PG_FUNCTION_ARGS);
 extern Datum pg_ls_dir_1arg(PG_FUNCTION_ARGS);
 
 /* misc.c */
+extern Datum pg_num_nulls(PG_FUNCTION_ARGS);
+extern Datum pg_num_nonnulls(PG_FUNCTION_ARGS);
 extern Datum current_database(PG_FUNCTION_ARGS);
 extern Datum current_query(PG_FUNCTION_ARGS);
 extern Datum pg_cancel_backend(PG_FUNCTION_ARGS);
@@ -823,7 +825,7 @@ extern Datum textoverlay_no_len(PG_FUNCTION_ARGS);
 extern Datum name_text(PG_FUNCTION_ARGS);
 extern Datum text_name(PG_FUNCTION_ARGS);
 extern int varstr_cmp(char *arg1, int len1, char *arg2, int len2, Oid collid);
-extern void    varstr_sortsupport(SortSupport ssup, Oid collid, bool bpchar);
+extern void varstr_sortsupport(SortSupport ssup, Oid collid, bool bpchar);
 extern int varstr_levenshtein(const char *source, int slen,
                   const char *target, int tlen,
                   int ins_c, int del_c, int sub_c,
diff --git a/src/test/regress/expected/misc_functions.out b/src/test/regress/expected/misc_functions.out
new file mode 100644 (file)
index 0000000..130a0e4
--- /dev/null
@@ -0,0 +1,135 @@
+--
+-- num_nulls()
+--
+SELECT num_nonnulls(NULL);
+ num_nonnulls 
+--------------
+            0
+(1 row)
+
+SELECT num_nonnulls('1');
+ num_nonnulls 
+--------------
+            1
+(1 row)
+
+SELECT num_nonnulls(NULL::text);
+ num_nonnulls 
+--------------
+            0
+(1 row)
+
+SELECT num_nonnulls(NULL::text, NULL::int);
+ num_nonnulls 
+--------------
+            0
+(1 row)
+
+SELECT num_nonnulls(1, 2, NULL::text, NULL::point, '', int8 '9', 1.0 / NULL);
+ num_nonnulls 
+--------------
+            4
+(1 row)
+
+SELECT num_nonnulls(VARIADIC '{1,2,NULL,3}'::int[]);
+ num_nonnulls 
+--------------
+            3
+(1 row)
+
+SELECT num_nonnulls(VARIADIC '{"1","2","3","4"}'::text[]);
+ num_nonnulls 
+--------------
+            4
+(1 row)
+
+SELECT num_nonnulls(VARIADIC ARRAY(SELECT CASE WHEN i <> 40 THEN i END FROM generate_series(1, 100) i));
+ num_nonnulls 
+--------------
+           99
+(1 row)
+
+SELECT num_nulls(NULL);
+ num_nulls 
+-----------
+         1
+(1 row)
+
+SELECT num_nulls('1');
+ num_nulls 
+-----------
+         0
+(1 row)
+
+SELECT num_nulls(NULL::text);
+ num_nulls 
+-----------
+         1
+(1 row)
+
+SELECT num_nulls(NULL::text, NULL::int);
+ num_nulls 
+-----------
+         2
+(1 row)
+
+SELECT num_nulls(1, 2, NULL::text, NULL::point, '', int8 '9', 1.0 / NULL);
+ num_nulls 
+-----------
+         3
+(1 row)
+
+SELECT num_nulls(VARIADIC '{1,2,NULL,3}'::int[]);
+ num_nulls 
+-----------
+         1
+(1 row)
+
+SELECT num_nulls(VARIADIC '{"1","2","3","4"}'::text[]);
+ num_nulls 
+-----------
+         0
+(1 row)
+
+SELECT num_nulls(VARIADIC ARRAY(SELECT CASE WHEN i <> 40 THEN i END FROM generate_series(1, 100) i));
+ num_nulls 
+-----------
+         1
+(1 row)
+
+-- special cases
+SELECT num_nonnulls(VARIADIC NULL::text[]);
+ num_nonnulls 
+--------------
+             
+(1 row)
+
+SELECT num_nonnulls(VARIADIC '{}'::int[]);
+ num_nonnulls 
+--------------
+            0
+(1 row)
+
+SELECT num_nulls(VARIADIC NULL::text[]);
+ num_nulls 
+-----------
+          
+(1 row)
+
+SELECT num_nulls(VARIADIC '{}'::int[]);
+ num_nulls 
+-----------
+         0
+(1 row)
+
+-- should fail, one or more arguments is required
+SELECT num_nonnulls();
+ERROR:  function num_nonnulls() does not exist
+LINE 1: SELECT num_nonnulls();
+               ^
+HINT:  No function matches the given name and argument types. You might need to add explicit type casts.
+SELECT num_nulls();
+ERROR:  function num_nulls() does not exist
+LINE 1: SELECT num_nulls();
+               ^
+HINT:  No function matches the given name and argument types. You might need to add explicit type casts.
index b1bc7c716a3365e68dc6887a15b0b7599ab98484..bec03165a73213c5e916b4eb02febe96ff67d0b0 100644 (file)
@@ -89,7 +89,7 @@ test: brin gin gist spgist privileges security_label collate matview lock replic
 # ----------
 # Another group of parallel tests
 # ----------
-test: alter_generic alter_operator misc psql async dbsize
+test: alter_generic alter_operator misc psql async dbsize misc_functions
 
 # rules cannot run concurrently with any test that creates a view
 test: rules
index ade9ef15530d442cabc669249e2acdf879394ad4..7e9b319b0f7091ccd865df2f83ed21d1a76d8a41 100644 (file)
@@ -119,6 +119,7 @@ test: misc
 test: psql
 test: async
 test: dbsize
+test: misc_functions
 test: rules
 test: select_views
 test: portals_p2
diff --git a/src/test/regress/sql/misc_functions.sql b/src/test/regress/sql/misc_functions.sql
new file mode 100644 (file)
index 0000000..1a20c1f
--- /dev/null
@@ -0,0 +1,31 @@
+--
+-- num_nulls()
+--
+
+SELECT num_nonnulls(NULL);
+SELECT num_nonnulls('1');
+SELECT num_nonnulls(NULL::text);
+SELECT num_nonnulls(NULL::text, NULL::int);
+SELECT num_nonnulls(1, 2, NULL::text, NULL::point, '', int8 '9', 1.0 / NULL);
+SELECT num_nonnulls(VARIADIC '{1,2,NULL,3}'::int[]);
+SELECT num_nonnulls(VARIADIC '{"1","2","3","4"}'::text[]);
+SELECT num_nonnulls(VARIADIC ARRAY(SELECT CASE WHEN i <> 40 THEN i END FROM generate_series(1, 100) i));
+
+SELECT num_nulls(NULL);
+SELECT num_nulls('1');
+SELECT num_nulls(NULL::text);
+SELECT num_nulls(NULL::text, NULL::int);
+SELECT num_nulls(1, 2, NULL::text, NULL::point, '', int8 '9', 1.0 / NULL);
+SELECT num_nulls(VARIADIC '{1,2,NULL,3}'::int[]);
+SELECT num_nulls(VARIADIC '{"1","2","3","4"}'::text[]);
+SELECT num_nulls(VARIADIC ARRAY(SELECT CASE WHEN i <> 40 THEN i END FROM generate_series(1, 100) i));
+
+-- special cases
+SELECT num_nonnulls(VARIADIC NULL::text[]);
+SELECT num_nonnulls(VARIADIC '{}'::int[]);
+SELECT num_nulls(VARIADIC NULL::text[]);
+SELECT num_nulls(VARIADIC '{}'::int[]);
+
+-- should fail, one or more arguments is required
+SELECT num_nonnulls();
+SELECT num_nulls();