mirror of
https://github.com/postgres/postgres.git
synced 2026-02-13 07:43:11 -05:00
Until now, when executing an aggregate function as a window function within a window with moving frame start (that is, any frame start mode except UNBOUNDED PRECEDING), we had to recalculate the aggregate from scratch each time the frame head moved. This patch allows an aggregate definition to include an alternate "moving aggregate" implementation that includes an inverse transition function for removing rows from the aggregate's running state. As long as this can be done successfully, runtime is proportional to the total number of input rows, rather than to the number of input rows times the average frame length. This commit includes the core infrastructure, documentation, and regression tests using user-defined aggregates. Follow-on commits will update some of the built-in aggregates to use this feature. David Rowley and Florian Pflug, reviewed by Dean Rasheed; additional hacking by me
144 lines
3.6 KiB
PL/PgSQL
144 lines
3.6 KiB
PL/PgSQL
--
|
|
-- CREATE_AGGREGATE
|
|
--
|
|
|
|
-- all functions CREATEd
|
|
CREATE AGGREGATE newavg (
|
|
sfunc = int4_avg_accum, basetype = int4, stype = _int8,
|
|
finalfunc = int8_avg,
|
|
initcond1 = '{0,0}'
|
|
);
|
|
|
|
-- test comments
|
|
COMMENT ON AGGREGATE newavg_wrong (int4) IS 'an agg comment';
|
|
COMMENT ON AGGREGATE newavg (int4) IS 'an agg comment';
|
|
COMMENT ON AGGREGATE newavg (int4) IS NULL;
|
|
|
|
-- without finalfunc; test obsolete spellings 'sfunc1' etc
|
|
CREATE AGGREGATE newsum (
|
|
sfunc1 = int4pl, basetype = int4, stype1 = int4,
|
|
initcond1 = '0'
|
|
);
|
|
|
|
-- zero-argument aggregate
|
|
CREATE AGGREGATE newcnt (*) (
|
|
sfunc = int8inc, stype = int8,
|
|
initcond = '0'
|
|
);
|
|
|
|
-- old-style spelling of same
|
|
CREATE AGGREGATE oldcnt (
|
|
sfunc = int8inc, basetype = 'ANY', stype = int8,
|
|
initcond = '0'
|
|
);
|
|
|
|
-- aggregate that only cares about null/nonnull input
|
|
CREATE AGGREGATE newcnt ("any") (
|
|
sfunc = int8inc_any, stype = int8,
|
|
initcond = '0'
|
|
);
|
|
|
|
COMMENT ON AGGREGATE nosuchagg (*) IS 'should fail';
|
|
COMMENT ON AGGREGATE newcnt (*) IS 'an agg(*) comment';
|
|
COMMENT ON AGGREGATE newcnt ("any") IS 'an agg(any) comment';
|
|
|
|
-- multi-argument aggregate
|
|
create function sum3(int8,int8,int8) returns int8 as
|
|
'select $1 + $2 + $3' language sql strict immutable;
|
|
|
|
create aggregate sum2(int8,int8) (
|
|
sfunc = sum3, stype = int8,
|
|
initcond = '0'
|
|
);
|
|
|
|
-- multi-argument aggregates sensitive to distinct/order, strict/nonstrict
|
|
create type aggtype as (a integer, b integer, c text);
|
|
|
|
create function aggf_trans(aggtype[],integer,integer,text) returns aggtype[]
|
|
as 'select array_append($1,ROW($2,$3,$4)::aggtype)'
|
|
language sql strict immutable;
|
|
|
|
create function aggfns_trans(aggtype[],integer,integer,text) returns aggtype[]
|
|
as 'select array_append($1,ROW($2,$3,$4)::aggtype)'
|
|
language sql immutable;
|
|
|
|
create aggregate aggfstr(integer,integer,text) (
|
|
sfunc = aggf_trans, stype = aggtype[],
|
|
initcond = '{}'
|
|
);
|
|
|
|
create aggregate aggfns(integer,integer,text) (
|
|
sfunc = aggfns_trans, stype = aggtype[], sspace = 10000,
|
|
initcond = '{}'
|
|
);
|
|
|
|
-- variadic aggregate
|
|
create function least_accum(anyelement, variadic anyarray)
|
|
returns anyelement language sql as
|
|
'select least($1, min($2[i])) from generate_subscripts($2,1) g(i)';
|
|
|
|
create aggregate least_agg(variadic items anyarray) (
|
|
stype = anyelement, sfunc = least_accum
|
|
);
|
|
|
|
-- test ordered-set aggs using built-in support functions
|
|
create aggregate my_percentile_disc(float8 ORDER BY anyelement) (
|
|
stype = internal,
|
|
sfunc = ordered_set_transition,
|
|
finalfunc = percentile_disc_final
|
|
);
|
|
|
|
create aggregate my_rank(VARIADIC "any" ORDER BY VARIADIC "any") (
|
|
stype = internal,
|
|
sfunc = ordered_set_transition_multi,
|
|
finalfunc = rank_final,
|
|
hypothetical
|
|
);
|
|
|
|
alter aggregate my_percentile_disc(float8 ORDER BY anyelement)
|
|
rename to test_percentile_disc;
|
|
alter aggregate my_rank(VARIADIC "any" ORDER BY VARIADIC "any")
|
|
rename to test_rank;
|
|
|
|
\da test_*
|
|
|
|
-- moving-aggregate options
|
|
|
|
CREATE AGGREGATE sumdouble (float8)
|
|
(
|
|
stype = float8,
|
|
sfunc = float8pl,
|
|
mstype = float8,
|
|
msfunc = float8pl,
|
|
minvfunc = float8mi
|
|
);
|
|
|
|
-- invalid: nonstrict inverse with strict forward function
|
|
|
|
CREATE FUNCTION float8mi_n(float8, float8) RETURNS float8 AS
|
|
$$ SELECT $1 - $2; $$
|
|
LANGUAGE SQL;
|
|
|
|
CREATE AGGREGATE invalidsumdouble (float8)
|
|
(
|
|
stype = float8,
|
|
sfunc = float8pl,
|
|
mstype = float8,
|
|
msfunc = float8pl,
|
|
minvfunc = float8mi_n
|
|
);
|
|
|
|
-- invalid: non-matching result types
|
|
|
|
CREATE FUNCTION float8mi_int(float8, float8) RETURNS int AS
|
|
$$ SELECT CAST($1 - $2 AS INT); $$
|
|
LANGUAGE SQL;
|
|
|
|
CREATE AGGREGATE wrongreturntype (float8)
|
|
(
|
|
stype = float8,
|
|
sfunc = float8pl,
|
|
mstype = float8,
|
|
msfunc = float8pl,
|
|
minvfunc = float8mi_int
|
|
);
|