1
0
mirror of https://github.com/postgres/postgres.git synced 2025-10-24 01:29:19 +03:00

Add error_on_null(), checking if the input is the null value

This polymorphic function produces an error if the input value is
detected as being the null value; otherwise it returns the input value
unchanged.

This function can for example become handy in SQL function bodies, to
enforce that exactly one row was returned.

Author: Joel Jacobson <joel@compiler.org>
Reviewed-by: Vik Fearing <vik@postgresfriends.org>
Reviewed-by: Michael Paquier <michael@paquier.xyz>
Discussion: https://postgr.es/m/ece8c6d1-2ab1-45d5-ba12-8dec96fc8886@app.fastmail.com
Discussion: https://postgr.es/m/de94808d-ed58-4536-9e28-e79b09a534c7@app.fastmail.com
This commit is contained in:
Michael Paquier
2025-10-22 09:55:17 +09:00
parent 2470ca435c
commit 2b75c38b70
5 changed files with 81 additions and 0 deletions

View File

@@ -599,6 +599,28 @@ SELECT NOT(ROW(table.*) IS NOT NULL) FROM TABLE; -- detect at least one null in
</thead>
<tbody>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>error_on_null</primary>
</indexterm>
<function>error_on_null</function> ( <type>anyelement</type> )
<returnvalue>anyelement</returnvalue>
</para>
<para>
Checks if the input is the null value, generating an error if so;
otherwise, returns the input.
</para>
<para>
<literal>error_on_null(42)</literal>
<returnvalue>42</returnvalue>
</para>
<para>
<literal>error_on_null(row(null,null))</literal>
<returnvalue>(,)</returnvalue>
</para></entry>
</row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>

View File

@@ -186,6 +186,20 @@ pg_num_nonnulls(PG_FUNCTION_ARGS)
PG_RETURN_INT32(nargs - nulls);
}
/*
* error_on_null()
* Check if the input is the NULL value
*/
Datum
pg_error_on_null(PG_FUNCTION_ARGS)
{
if (PG_ARGISNULL(0))
ereport(ERROR,
(errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED),
errmsg("null value not allowed")));
PG_RETURN_DATUM(PG_GETARG_DATUM(0));
}
/*
* current_database()

View File

@@ -12543,6 +12543,9 @@
{ oid => '6292', descr => 'aggregate transition function',
proname => 'any_value_transfn', prorettype => 'anyelement',
proargtypes => 'anyelement anyelement', prosrc => 'any_value_transfn' },
{ oid => '8488', descr => 'check if input is the null value',
proname => 'error_on_null', proisstrict => 'f', prorettype => 'anyelement',
proargtypes => 'anyelement', prosrc => 'pg_error_on_null' },
{ oid => '6321', descr => 'list of available WAL summary files',
proname => 'pg_available_wal_summaries', prorows => '100', proretset => 't',

View File

@@ -177,6 +177,37 @@ ERROR: function num_nulls() does not exist
LINE 1: SELECT num_nulls();
^
DETAIL: No function of that name accepts the given number of arguments.
--
-- error_on_null()
--
SELECT error_on_null(1);
error_on_null
---------------
1
(1 row)
SELECT error_on_null(NULL::int);
ERROR: null value not allowed
SELECT error_on_null(NULL::int[]);
ERROR: null value not allowed
SELECT error_on_null('{1,2,NULL,3}'::int[]);
error_on_null
---------------
{1,2,NULL,3}
(1 row)
SELECT error_on_null(ROW(1,NULL::int));
error_on_null
---------------
(1,)
(1 row)
SELECT error_on_null(ROW(NULL,NULL));
error_on_null
---------------
(,)
(1 row)
--
-- canonicalize_path()
--

View File

@@ -77,6 +77,17 @@ SELECT num_nulls(VARIADIC '{}'::int[]);
SELECT num_nonnulls();
SELECT num_nulls();
--
-- error_on_null()
--
SELECT error_on_null(1);
SELECT error_on_null(NULL::int);
SELECT error_on_null(NULL::int[]);
SELECT error_on_null('{1,2,NULL,3}'::int[]);
SELECT error_on_null(ROW(1,NULL::int));
SELECT error_on_null(ROW(NULL,NULL));
--
-- canonicalize_path()
--