Implement ANY_VALUE aggregate
SQL:2023 defines an ANY_VALUE aggregate whose purpose is to emit an implementation-dependent (i.e. non-deterministic) value from the aggregated rows. Author: Vik Fearing <vik@postgresfriends.org> Reviewed-by: Peter Eisentraut <peter.eisentraut@enterprisedb.com> Reviewed-by: David Rowley <dgrowleyml@gmail.com> Discussion: https://www.postgresql.org/message-id/flat/5cff866c-10a8-d2df-32cb-e9072e6b04a2@postgresfriends.org
This commit is contained in:
parent
7e5ddf7e4d
commit
2ddab010c2
@ -19735,6 +19735,20 @@ SELECT NULLIF(value, '(none)') ...
|
||||
</thead>
|
||||
|
||||
<tbody>
|
||||
<row>
|
||||
<entry role="func_table_entry"><para role="func_signature">
|
||||
<indexterm>
|
||||
<primary>any_value</primary>
|
||||
</indexterm>
|
||||
<function>any_value</function> ( <type>anyelement</type> )
|
||||
<returnvalue><replaceable>same as input type</replaceable></returnvalue>
|
||||
</para>
|
||||
<para>
|
||||
Returns an arbitrary value from the non-null input values.
|
||||
</para></entry>
|
||||
<entry>Yes</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry role="func_table_entry"><para role="func_signature">
|
||||
<indexterm>
|
||||
|
@ -520,6 +520,7 @@ T622 Trigonometric functions YES
|
||||
T623 General logarithm functions YES
|
||||
T624 Common logarithm functions YES
|
||||
T625 LISTAGG NO
|
||||
T626 ANY_VALUE YES SQL:202x draft
|
||||
T631 IN predicate with one list element YES
|
||||
T641 Multiple column assignment NO only some syntax variants supported
|
||||
T651 SQL-schema statements in SQL routines YES
|
||||
|
@ -1041,3 +1041,12 @@ pg_get_replica_identity_index(PG_FUNCTION_ARGS)
|
||||
else
|
||||
PG_RETURN_NULL();
|
||||
}
|
||||
|
||||
/*
|
||||
* Transition function for the ANY_VALUE aggregate
|
||||
*/
|
||||
Datum
|
||||
any_value_transfn(PG_FUNCTION_ARGS)
|
||||
{
|
||||
PG_RETURN_DATUM(PG_GETARG_DATUM(0));
|
||||
}
|
||||
|
@ -57,6 +57,6 @@
|
||||
*/
|
||||
|
||||
/* yyyymmddN */
|
||||
#define CATALOG_VERSION_NO 202302111
|
||||
#define CATALOG_VERSION_NO 202302221
|
||||
|
||||
#endif
|
||||
|
@ -634,4 +634,8 @@
|
||||
aggfinalfn => 'dense_rank_final', aggfinalextra => 't', aggfinalmodify => 'w',
|
||||
aggmfinalmodify => 'w', aggtranstype => 'internal' },
|
||||
|
||||
# any_value
|
||||
{ aggfnoid => 'any_value(anyelement)', aggtransfn => 'any_value_transfn',
|
||||
aggcombinefn => 'any_value_transfn', aggtranstype => 'anyelement' },
|
||||
|
||||
]
|
||||
|
@ -11927,4 +11927,12 @@
|
||||
prorettype => 'bytea', proargtypes => 'pg_brin_minmax_multi_summary',
|
||||
prosrc => 'brin_minmax_multi_summary_send' },
|
||||
|
||||
{ oid => '8981', descr => 'arbitrary value from among input values',
|
||||
proname => 'any_value', prokind => 'a', proisstrict => 'f',
|
||||
prorettype => 'anyelement', proargtypes => 'anyelement',
|
||||
prosrc => 'aggregate_dummy' },
|
||||
{ oid => '8982', descr => 'aggregate transition function',
|
||||
proname => 'any_value_transfn', prorettype => 'anyelement',
|
||||
proargtypes => 'anyelement anyelement', prosrc => 'any_value_transfn' },
|
||||
|
||||
]
|
||||
|
@ -25,6 +25,30 @@ SELECT avg(a) AS avg_32 FROM aggtest WHERE a < 100;
|
||||
32.6666666666666667
|
||||
(1 row)
|
||||
|
||||
SELECT any_value(v) FROM (VALUES (1), (2), (3)) AS v (v);
|
||||
any_value
|
||||
-----------
|
||||
1
|
||||
(1 row)
|
||||
|
||||
SELECT any_value(v) FROM (VALUES (NULL)) AS v (v);
|
||||
any_value
|
||||
-----------
|
||||
|
||||
(1 row)
|
||||
|
||||
SELECT any_value(v) FROM (VALUES (NULL), (1), (2)) AS v (v);
|
||||
any_value
|
||||
-----------
|
||||
1
|
||||
(1 row)
|
||||
|
||||
SELECT any_value(v) FROM (VALUES (array['hello', 'world'])) AS v (v);
|
||||
any_value
|
||||
---------------
|
||||
{hello,world}
|
||||
(1 row)
|
||||
|
||||
-- In 7.1, avg(float4) is computed using float8 arithmetic.
|
||||
-- Round the result to 3 digits to avoid platform-specific results.
|
||||
SELECT avg(b)::numeric(10,3) AS avg_107_943 FROM aggtest;
|
||||
@ -2033,6 +2057,12 @@ from (values ('a', 'b')) AS v(foo,bar);
|
||||
a
|
||||
(1 row)
|
||||
|
||||
select any_value(v) filter (where v > 2) from (values (1), (2), (3)) as v (v);
|
||||
any_value
|
||||
-----------
|
||||
3
|
||||
(1 row)
|
||||
|
||||
-- outer reference in FILTER (PostgreSQL extension)
|
||||
select (select count(*)
|
||||
from (values (1)) t0(inner_c))
|
||||
|
@ -24,6 +24,11 @@ SELECT avg(four) AS avg_1 FROM onek;
|
||||
|
||||
SELECT avg(a) AS avg_32 FROM aggtest WHERE a < 100;
|
||||
|
||||
SELECT any_value(v) FROM (VALUES (1), (2), (3)) AS v (v);
|
||||
SELECT any_value(v) FROM (VALUES (NULL)) AS v (v);
|
||||
SELECT any_value(v) FROM (VALUES (NULL), (1), (2)) AS v (v);
|
||||
SELECT any_value(v) FROM (VALUES (array['hello', 'world'])) AS v (v);
|
||||
|
||||
-- In 7.1, avg(float4) is computed using float8 arithmetic.
|
||||
-- Round the result to 3 digits to avoid platform-specific results.
|
||||
|
||||
@ -810,6 +815,8 @@ having exists (select 1 from onek b where sum(distinct a.four) = b.four);
|
||||
select max(foo COLLATE "C") filter (where (bar collate "POSIX") > '0')
|
||||
from (values ('a', 'b')) AS v(foo,bar);
|
||||
|
||||
select any_value(v) filter (where v > 2) from (values (1), (2), (3)) as v (v);
|
||||
|
||||
-- outer reference in FILTER (PostgreSQL extension)
|
||||
select (select count(*)
|
||||
from (values (1)) t0(inner_c))
|
||||
|
Loading…
x
Reference in New Issue
Block a user