mirror of
https://github.com/postgres/postgres.git
synced 2025-04-27 22:56:53 +03:00
Add num_nulls() and num_nonnulls() to count NULL arguments.
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
This commit is contained in:
parent
d0cd7bda97
commit
6819514fca
@ -182,7 +182,7 @@
|
||||
</sect1>
|
||||
|
||||
<sect1 id="functions-comparison">
|
||||
<title>Comparison Operators</title>
|
||||
<title>Comparison Functions and Operators</title>
|
||||
|
||||
<indexterm zone="functions-comparison">
|
||||
<primary>comparison</primary>
|
||||
@ -190,11 +190,11 @@
|
||||
</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>
|
||||
@ -437,6 +437,49 @@
|
||||
</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">.
|
||||
|
@ -44,6 +44,127 @@
|
||||
#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
|
||||
|
@ -53,6 +53,6 @@
|
||||
*/
|
||||
|
||||
/* yyyymmddN */
|
||||
#define CATALOG_VERSION_NO 201602031
|
||||
#define CATALOG_VERSION_NO 201602041
|
||||
|
||||
#endif
|
||||
|
@ -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_ ));
|
||||
|
@ -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);
|
||||
|
135
src/test/regress/expected/misc_functions.out
Normal file
135
src/test/regress/expected/misc_functions.out
Normal file
@ -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.
|
@ -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
|
||||
|
@ -119,6 +119,7 @@ test: misc
|
||||
test: psql
|
||||
test: async
|
||||
test: dbsize
|
||||
test: misc_functions
|
||||
test: rules
|
||||
test: select_views
|
||||
test: portals_p2
|
||||
|
31
src/test/regress/sql/misc_functions.sql
Normal file
31
src/test/regress/sql/misc_functions.sql
Normal file
@ -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();
|
Loading…
x
Reference in New Issue
Block a user