slow sqlfunction (#42)

* rework array_dedup_append function

* array_dedup_append: implemented faster version

uses nested array remove for merge+deduplication
This commit is contained in:
Groovie | Mango 2024-01-11 17:39:44 +01:00 committed by GitHub
parent fd99ea1f0a
commit fbfef4db06
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
2 changed files with 16 additions and 18 deletions

View File

@ -132,23 +132,21 @@ CREATE TABLE banking_stage_results_2.accounts_map_transaction_latest(
tx_ids BIGINT[]
);
CREATE OR REPLACE FUNCTION __array_reverse(anyarray) RETURNS anyarray AS $$
SELECT ARRAY(
SELECT $1[i]
FROM generate_subscripts($1,1) AS s(i)
ORDER BY i DESC
);
$$ LANGUAGE SQL STRICT IMMUTABLE;
CREATE OR REPLACE FUNCTION array_dedup_append(base bigint[], append bigint[], n_limit int)
RETURNS bigint[]
AS $$
SELECT __array_reverse(array_agg(val)) FROM (
SELECT val FROM (
SELECT DISTINCT ON (val) pos, val FROM unnest(__array_reverse(array_cat(base, append))) WITH ORDINALITY as t(val, pos)
) AS deduped
ORDER BY pos
LIMIT n_limit
) AS result
$$ LANGUAGE SQL STRICT IMMUTABLE;
DECLARE
tmplist bigint[];
el bigint;
len int;
BEGIN
tmplist := base;
FOREACH el IN ARRAY append LOOP
tmplist := array_remove(tmplist, el);
tmplist := tmplist || el;
END LOOP;
len := CARDINALITY(tmplist);
RETURN tmplist[(len + 1 - n_limit):];
END
$$ LANGUAGE plpgsql IMMUTABLE CALLED ON NULL INPUT;

View File

@ -454,7 +454,7 @@ impl PostgresSession {
SELECT
acc_id,
array_dedup_append(
COALESCE((SELECT tx_ids FROM banking_stage_results_2.accounts_map_transaction_latest WHERE acc_id=amt_new.acc_id ), array[]::bigint[]),
(SELECT tx_ids FROM banking_stage_results_2.accounts_map_transaction_latest WHERE acc_id=amt_new.acc_id),
amt_new.tx_agged,
{limit}) AS tx_ids_agg
FROM amt_new