├── LICENSE ├── Makefile ├── README.md ├── custom_aggregate.sql ├── grt.c ├── grt.sql ├── queries.sql └── structure.sql /LICENSE: -------------------------------------------------------------------------------- 1 | Copyright (c) 2016 Jack Christensen 2 | 3 | MIT License 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining 6 | a copy of this software and associated documentation files (the 7 | "Software"), to deal in the Software without restriction, including 8 | without limitation the rights to use, copy, modify, merge, publish, 9 | distribute, sublicense, and/or sell copies of the Software, and to 10 | permit persons to whom the Software is furnished to do so, subject to 11 | the following conditions: 12 | 13 | The above copyright notice and this permission notice shall be 14 | included in all copies or substantial portions of the Software. 15 | 16 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, 17 | EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF 18 | MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND 19 | NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE 20 | LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION 21 | OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION 22 | WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. 23 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | MODULES = grt 2 | PGXS := $(shell pg_config --pgxs) 3 | include $(PGXS) 4 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Custom Aggregate Greatest Running Total 2 | 3 | This is the source code for the [Custom Aggregates in PostgreSQL](https://hashrocket.com/blog/posts/custom-aggregates-in-postgresql) blog post. 4 | 5 | To load the test data: 6 | 7 | ``` 8 | psql -f structure.sql 9 | ``` 10 | 11 | To install the PL/pgSQL custom aggregate: 12 | 13 | ``` 14 | psql -f custom_aggregate.sql 15 | ``` 16 | 17 | To install the C custom aggregate: 18 | 19 | ``` 20 | make install 21 | psql -f grt.sql 22 | ``` 23 | 24 | ## License 25 | 26 | MIT 27 | -------------------------------------------------------------------------------- /custom_aggregate.sql: -------------------------------------------------------------------------------- 1 | drop aggregate if exists greatest_running_total(float8); 2 | drop function if exists grt_finalfunc(point); 3 | drop function if exists grt_sfunc(point, float8); 4 | 5 | create function grt_sfunc(agg_state point, el float8) 6 | returns point 7 | immutable 8 | language plpgsql 9 | as $$ 10 | declare 11 | greatest_sum float8; 12 | current_sum float8; 13 | begin 14 | if agg_state is null then 15 | return point(el, el); 16 | end if; 17 | 18 | current_sum := agg_state[0] + el; 19 | if agg_state[1] < current_sum then 20 | greatest_sum := current_sum; 21 | else 22 | greatest_sum := agg_state[1]; 23 | end if; 24 | 25 | return point(current_sum, greatest_sum); 26 | end; 27 | $$; 28 | 29 | create function grt_finalfunc(agg_state point) 30 | returns float8 31 | immutable 32 | strict 33 | language plpgsql 34 | as $$ 35 | begin 36 | return agg_state[1]; 37 | end; 38 | $$; 39 | 40 | create aggregate greatest_running_total (float8) 41 | ( 42 | sfunc = grt_sfunc, 43 | stype = point, 44 | finalfunc = grt_finalfunc 45 | ); 46 | -------------------------------------------------------------------------------- /grt.c: -------------------------------------------------------------------------------- 1 | #include "postgres.h" 2 | #include "fmgr.h" 3 | #include "utils/geo_decls.h" 4 | 5 | #ifdef PG_MODULE_MAGIC 6 | PG_MODULE_MAGIC; 7 | #endif 8 | 9 | PG_FUNCTION_INFO_V1(grt_sfunc); 10 | 11 | Datum 12 | grt_sfunc(PG_FUNCTION_ARGS) 13 | { 14 | Point *new_agg_state = (Point *) palloc(sizeof(Point)); 15 | double el = PG_GETARG_FLOAT8(1); 16 | 17 | bool isnull = PG_ARGISNULL(0); 18 | if(isnull) { 19 | new_agg_state->x = el; 20 | new_agg_state->y = el; 21 | PG_RETURN_POINT_P(new_agg_state); 22 | } 23 | 24 | Point *agg_state = PG_GETARG_POINT_P(0); 25 | 26 | new_agg_state->x = agg_state->x + el; 27 | if(new_agg_state->x > agg_state->y) { 28 | new_agg_state->y = new_agg_state->x; 29 | } else { 30 | new_agg_state->y = agg_state->y; 31 | } 32 | 33 | PG_RETURN_POINT_P(new_agg_state); 34 | } 35 | -------------------------------------------------------------------------------- /grt.sql: -------------------------------------------------------------------------------- 1 | drop aggregate if exists greatest_running_total(float8); 2 | drop function if exists grt_finalfunc(point); 3 | drop function if exists grt_sfunc(point, float8); 4 | 5 | create function 6 | grt_sfunc( point, float8 ) 7 | returns 8 | point 9 | as 10 | 'grt.so', 'grt_sfunc' 11 | language 12 | c 13 | immutable; 14 | 15 | create function grt_finalfunc(agg_state point) 16 | returns float8 17 | immutable 18 | language plpgsql 19 | as $$ 20 | begin 21 | return agg_state[1]; 22 | end; 23 | $$; 24 | 25 | create aggregate greatest_running_total (float8) 26 | ( 27 | sfunc = grt_sfunc, 28 | stype = point, 29 | finalfunc = grt_finalfunc 30 | ); 31 | 32 | 33 | 34 | 35 | -------------------------------------------------------------------------------- /queries.sql: -------------------------------------------------------------------------------- 1 | -- Initial running total 2 | select id, amount, sum(amount) over (order by id asc) as running_total 3 | from entries 4 | ; 5 | 6 | -- What is greatest running total 7 | select max(running_total) 8 | from ( 9 | select sum(amount) over (order by id asc) as running_total 10 | from entries 11 | ) t 12 | ; 13 | 14 | -- What is greatest running total with custom aggregate 15 | select greatest_running_total(amount order by id asc) from entries; 16 | 17 | -- What and when was the greatest running total 18 | select * 19 | from ( 20 | select id, amount, sum(amount) over (order by id asc) as running_total 21 | from entries 22 | ) t 23 | order by running_total desc 24 | limit 1 25 | ; 26 | 27 | -- What and when is greatest running total 28 | select id, amount, sum(amount) over w as running_total 29 | from entries 30 | window w as (order by id asc) 31 | order by sum(amount) over w desc 32 | limit 1 33 | ; 34 | -------------------------------------------------------------------------------- /structure.sql: -------------------------------------------------------------------------------- 1 | drop table if exists entries; 2 | create table entries( 3 | id serial primary key, 4 | amount float8 not null 5 | ); 6 | 7 | -- Ensure "random" rows are created the same for each test run. 8 | select setseed(0); 9 | 10 | insert into entries(amount) 11 | select (2000 * random()) - 1000 12 | from generate_series(1, 1000000); 13 | --------------------------------------------------------------------------------