Add trim_array() function.

This has been in the SQL spec since 2008.  It's a pretty thin
wrapper around the array slice functionality, but the spec
says we should have it, so here it is.

Vik Fearing, reviewed by Dian Fay

Discussion: https://postgr.es/m/fc92ce17-9655-8ff1-c62a-4dc4c8ccd815@postgresfriends.org
This commit is contained in:
Tom Lane 2021-03-03 16:39:57 -05:00
parent 3769e11a31
commit 0a687c8f10
7 changed files with 100 additions and 2 deletions

View File

@ -17930,6 +17930,24 @@ SELECT NULLIF(value, '(none)') ...
</para></entry> </para></entry>
</row> </row>
<row>
<entry role="func_table_entry"><para role="func_signature">
<indexterm>
<primary>trim_array</primary>
</indexterm>
<function>trim_array</function> ( <parameter>array</parameter> <type>anyarray</type>, <parameter>n</parameter> <type>integer</type> )
<returnvalue>anyarray</returnvalue>
</para>
<para>
Trims an array by removing the last <parameter>n</parameter> elements.
If the array is multidimensional, only the first dimension is trimmed.
</para>
<para>
<literal>trim_array(ARRAY[1,2,3,4,5,6], 2)</literal>
<returnvalue>{1,2,3,4}</returnvalue>
</para></entry>
</row>
<row> <row>
<entry role="func_table_entry"><para role="func_signature"> <entry role="func_table_entry"><para role="func_signature">
<indexterm> <indexterm>

View File

@ -398,7 +398,7 @@ S301 Enhanced UNNEST YES
S401 Distinct types based on array types NO S401 Distinct types based on array types NO
S402 Distinct types based on distinct types NO S402 Distinct types based on distinct types NO
S403 ARRAY_MAX_CARDINALITY NO S403 ARRAY_MAX_CARDINALITY NO
S404 TRIM_ARRAY NO S404 TRIM_ARRAY YES
T011 Timestamp in Information Schema NO T011 Timestamp in Information Schema NO
T021 BINARY and VARBINARY data types NO T021 BINARY and VARBINARY data types NO
T022 Advanced support for BINARY and VARBINARY data types NO T022 Advanced support for BINARY and VARBINARY data types NO

View File

@ -6631,3 +6631,46 @@ width_bucket_array_variable(Datum operand,
return left; return left;
} }
/*
* Trim the last N elements from an array by building an appropriate slice.
* Only the first dimension is trimmed.
*/
Datum
trim_array(PG_FUNCTION_ARGS)
{
ArrayType *v = PG_GETARG_ARRAYTYPE_P(0);
int n = PG_GETARG_INT32(1);
int array_length = ARR_DIMS(v)[0];
int16 elmlen;
bool elmbyval;
char elmalign;
int lower[MAXDIM];
int upper[MAXDIM];
bool lowerProvided[MAXDIM];
bool upperProvided[MAXDIM];
Datum result;
/* Per spec, throw an error if out of bounds */
if (n < 0 || n > array_length)
ereport(ERROR,
(errcode(ERRCODE_ARRAY_ELEMENT_ERROR),
errmsg("number of elements to trim must be between 0 and %d",
array_length)));
/* Set all the bounds as unprovided except the first upper bound */
memset(lowerProvided, false, sizeof(lowerProvided));
memset(upperProvided, false, sizeof(upperProvided));
upper[0] = ARR_LBOUND(v)[0] + array_length - n - 1;
upperProvided[0] = true;
/* Fetch the needed information about the element type */
get_typlenbyvalalign(ARR_ELEMTYPE(v), &elmlen, &elmbyval, &elmalign);
/* Get the slice */
result = array_get_slice(PointerGetDatum(v), 1,
upper, lower, upperProvided, lowerProvided,
-1, elmlen, elmbyval, elmalign);
PG_RETURN_DATUM(result);
}

View File

@ -53,6 +53,6 @@
*/ */
/* yyyymmddN */ /* yyyymmddN */
#define CATALOG_VERSION_NO 202103031 #define CATALOG_VERSION_NO 202103032
#endif #endif

View File

@ -1663,6 +1663,9 @@
proname => 'width_bucket', prorettype => 'int4', proname => 'width_bucket', prorettype => 'int4',
proargtypes => 'anycompatible anycompatiblearray', proargtypes => 'anycompatible anycompatiblearray',
prosrc => 'width_bucket_array' }, prosrc => 'width_bucket_array' },
{ oid => '8819', descr => 'remove last N elements of array',
proname => 'trim_array', prorettype => 'anyarray',
proargtypes => 'anyarray int4', prosrc => 'trim_array' },
{ oid => '3816', descr => 'array typanalyze', { oid => '3816', descr => 'array typanalyze',
proname => 'array_typanalyze', provolatile => 's', prorettype => 'bool', proname => 'array_typanalyze', provolatile => 's', prorettype => 'bool',
proargtypes => 'internal', prosrc => 'array_typanalyze' }, proargtypes => 'internal', prosrc => 'array_typanalyze' },

View File

@ -2399,3 +2399,24 @@ SELECT width_bucket(5, ARRAY[3, 4, NULL]);
ERROR: thresholds array must not contain NULLs ERROR: thresholds array must not contain NULLs
SELECT width_bucket(5, ARRAY[ARRAY[1, 2], ARRAY[3, 4]]); SELECT width_bucket(5, ARRAY[ARRAY[1, 2], ARRAY[3, 4]]);
ERROR: thresholds must be one-dimensional array ERROR: thresholds must be one-dimensional array
-- trim_array
SELECT arr, trim_array(arr, 2)
FROM
(VALUES ('{1,2,3,4,5,6}'::bigint[]),
('{1,2}'),
('[10:16]={1,2,3,4,5,6,7}'),
('[-15:-10]={1,2,3,4,5,6}'),
('{{1,10},{2,20},{3,30},{4,40}}')) v(arr);
arr | trim_array
-------------------------------+-----------------
{1,2,3,4,5,6} | {1,2,3,4}
{1,2} | {}
[10:16]={1,2,3,4,5,6,7} | {1,2,3,4,5}
[-15:-10]={1,2,3,4,5,6} | {1,2,3,4}
{{1,10},{2,20},{3,30},{4,40}} | {{1,10},{2,20}}
(5 rows)
SELECT trim_array(ARRAY[1, 2, 3], -1); -- fail
ERROR: number of elements to trim must be between 0 and 3
SELECT trim_array(ARRAY[1, 2, 3], 10); -- fail
ERROR: number of elements to trim must be between 0 and 3

View File

@ -722,3 +722,16 @@ SELECT width_bucket(5, '{}');
SELECT width_bucket('5'::text, ARRAY[3, 4]::integer[]); SELECT width_bucket('5'::text, ARRAY[3, 4]::integer[]);
SELECT width_bucket(5, ARRAY[3, 4, NULL]); SELECT width_bucket(5, ARRAY[3, 4, NULL]);
SELECT width_bucket(5, ARRAY[ARRAY[1, 2], ARRAY[3, 4]]); SELECT width_bucket(5, ARRAY[ARRAY[1, 2], ARRAY[3, 4]]);
-- trim_array
SELECT arr, trim_array(arr, 2)
FROM
(VALUES ('{1,2,3,4,5,6}'::bigint[]),
('{1,2}'),
('[10:16]={1,2,3,4,5,6,7}'),
('[-15:-10]={1,2,3,4,5,6}'),
('{{1,10},{2,20},{3,30},{4,40}}')) v(arr);
SELECT trim_array(ARRAY[1, 2, 3], -1); -- fail
SELECT trim_array(ARRAY[1, 2, 3], 10); -- fail