From 2b75c38b707a070922231de667a0bd08ee71b268 Mon Sep 17 00:00:00 2001 From: Michael Paquier Date: Wed, 22 Oct 2025 09:55:17 +0900 Subject: [PATCH] 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 Reviewed-by: Vik Fearing Reviewed-by: Michael Paquier 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 --- doc/src/sgml/func/func-comparison.sgml | 22 ++++++++++++++ src/backend/utils/adt/misc.c | 14 +++++++++ src/include/catalog/pg_proc.dat | 3 ++ src/test/regress/expected/misc_functions.out | 31 ++++++++++++++++++++ src/test/regress/sql/misc_functions.sql | 11 +++++++ 5 files changed, 81 insertions(+) diff --git a/doc/src/sgml/func/func-comparison.sgml b/doc/src/sgml/func/func-comparison.sgml index c1205983f8b..ecb1d89463a 100644 --- a/doc/src/sgml/func/func-comparison.sgml +++ b/doc/src/sgml/func/func-comparison.sgml @@ -599,6 +599,28 @@ SELECT NOT(ROW(table.*) IS NOT NULL) FROM TABLE; -- detect at least one null in + + + + error_on_null + + error_on_null ( anyelement ) + anyelement + + + Checks if the input is the null value, generating an error if so; + otherwise, returns the input. + + + error_on_null(42) + 42 + + + error_on_null(row(null,null)) + (,) + + + diff --git a/src/backend/utils/adt/misc.c b/src/backend/utils/adt/misc.c index 7cb7716e58b..fa1cb675027 100644 --- a/src/backend/utils/adt/misc.c +++ b/src/backend/utils/adt/misc.c @@ -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() diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat index b51d2b17379..eecb43ec6f0 100644 --- a/src/include/catalog/pg_proc.dat +++ b/src/include/catalog/pg_proc.dat @@ -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', diff --git a/src/test/regress/expected/misc_functions.out b/src/test/regress/expected/misc_functions.out index 36164a99c83..e76e28b95ce 100644 --- a/src/test/regress/expected/misc_functions.out +++ b/src/test/regress/expected/misc_functions.out @@ -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() -- diff --git a/src/test/regress/sql/misc_functions.sql b/src/test/regress/sql/misc_functions.sql index 23792c4132a..220472d5ad1 100644 --- a/src/test/regress/sql/misc_functions.sql +++ b/src/test/regress/sql/misc_functions.sql @@ -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() --