Permalink
Browse files

First version of the first_last_agg extension.

  • Loading branch information...
0 parents commit aa300dcf835b206027c2bd659da73b6cd3fb2725 @wulczer committed May 25, 2011
Showing with 303 additions and 0 deletions.
  1. +4 −0 .gitignore
  2. +42 −0 META.json
  3. +25 −0 Makefile
  4. +17 −0 README.md
  5. +39 −0 doc/first_last_agg.md
  6. +5 −0 first_last_agg.control
  7. +4 −0 sql/first_last_agg--unpackaged--0.1.0.sql
  8. +21 −0 sql/first_last_agg.sql
  9. +51 −0 src/first_last_agg.c
  10. +67 −0 test/expected/agg.out
  11. +28 −0 test/sql/agg.sql
@@ -0,0 +1,4 @@
+.deps/
+sql/first_last_agg--0.1.0.sql
+src/first_last_agg.o
+src/first_last_agg.so
@@ -0,0 +1,42 @@
+{
+ "name": "first_last_agg",
+ "abstract": "Provides first() and last() aggregate functions.",
+ "version": "0.1.0",
+ "maintainer": [
+ "Jan Urbański <wulczer@wulczer.org>"
+ ],
+ "release_status": "testing",
+ "license": "postgresql",
+ "prereqs": {
+ "build": {
+ "PostgreSQL": "9.0.0"
+ }
+ },
+ "provides": {
+ "first_last_agg": {
+ "file": "sql/first_last_agg.sql",
+ "docfile": "doc/first_last_agg.md",
+ "version": "0.1.0"
+ }
+ },
+ "resources": {
+ "bugtracker": {
+ "web": "http://github.com/wulczer/first_last_agg/issues/"
+ },
+ "repository": {
+ "url": "git://github.com/wulczer/first_last_agg.git",
+ "web": "http://github.com/wulczer/first_last_agg/",
+ "type": "git"
+ }
+ },
+ "generated_by": "Jan Urbański",
+ "meta-spec": {
+ "version": "1.0.0",
+ "url": "http://pgxn.org/meta/spec.txt"
+ },
+ "tags": [
+ "first aggregate",
+ "last aggregate",
+ "aggregate function"
+ ]
+}
@@ -0,0 +1,25 @@
+EXTENSION = first_last_agg
+EXTVERSION = $(shell grep default_version $(EXTENSION).control | \
+ sed -e "s/default_version[[:space:]]*=[[:space:]]*'\([^']*\)'/\1/")
+
+DATA = $(filter-out $(wildcard sql/*--*.sql),$(wildcard sql/*.sql))
+DOCS = $(wildcard doc/*.md)
+TESTS = $(wildcard test/sql/*.sql)
+REGRESS = $(patsubst test/sql/%.sql,%,$(TESTS))
+REGRESS_OPTS = --inputdir=test
+MODULES = $(patsubst %.c,%,$(wildcard src/*.c))
+PG_CONFIG = pg_config
+PG91 = $(shell $(PG_CONFIG) --version | grep -qE " 8\.| 9\.0" && echo no || echo yes)
+
+ifeq ($(PG91),yes)
+all: sql/$(EXTENSION)--$(EXTVERSION).sql
+
+sql/$(EXTENSION)--$(EXTVERSION).sql: sql/$(EXTENSION).sql
+ cp $< $@
+
+DATA = $(wildcard sql/*--*.sql) sql/$(EXTENSION)--$(EXTVERSION).sql
+EXTRA_CLEAN = sql/$(EXTENSION)--$(EXTVERSION).sql
+endif
+
+PGXS := $(shell $(PG_CONFIG) --pgxs)
+include $(PGXS)
@@ -0,0 +1,17 @@
+first_last_agg
+--------------
+
+A simple extension providing two aggregate functions, `last` and `first`
+aggregate functions, operating on any element type and returning the last or
+the first value of the group.
+
+Since by default the ordering inside groups created by a `GROUP BY` expression
+is not defined, it is advisable to use an `ORDER BY` clause inside the
+aggregate expression (see the [aggregate function syntax](http://www.postgresql.org/docs/current/static/sql-expressions.html#SYNTAX-AGGREGATES))
+"")).
+This feature has been added in PostgreSQL 9.0.
+
+This extension is intended to replace the corresponding
+[first](http://wiki.postgresql.org/wiki/Last_%28aggregate%29) and
+[last](http://wiki.postgresql.org/wiki/First_%28aggregate%29) aggregates from
+the PostgreSQL wiki.
@@ -0,0 +1,39 @@
+first-last-agg 0.1.0
+====================
+
+Synopsis
+--------
+
+ % CREATE EXTENSION first_last_agg;
+ CREATE EXTENSION
+
+ % SELECT last(x order by y) FROM (VALUES (1, 3), (2, 1), (3, 2)) AS v(x, y);
+ last
+ ------
+ 1
+
+ % SELECT first(x order by y) FROM (VALUES (1, 3), (2, 1), (3, 2)) AS v(x, y);
+ first
+ -------
+ 2
+
+Description
+-----------
+
+This library contains two simple aggregate functions, `first` and
+`last`, operating on any element type. They return the first or the
+last value of the aggregated group, respectively.
+
+It is useful with aggregates with `order by`, for easily taking one
+element from an aggregate group when you don't really care which do
+you get and for emulating a similar functionality from Oracle.
+
+Author
+------
+
+[Jan Urbański](http://wulczer.org/), based on code from the
+[PostgreSQL wiki](http://wiki.postgresql.org/), specifically on the
+SQL definitions of
+[first](http://wiki.postgresql.org/wiki/First_%28aggregate%29) and
+[last](http://wiki.postgresql.org/wiki/Last_%28aggregate%29) taken
+from there.
@@ -0,0 +1,5 @@
+# first_last_agg extension
+comment = 'first() and last() aggregate functions'
+default_version = '0.1.0'
+module_pathname = '$libdir/first_last_agg'
+relocatable = true
@@ -0,0 +1,4 @@
+ALTER EXTENSION "first-last-agg" ADD FUNCTION first_sfunc(anyelement, anyelement);
+ALTER EXTENSION "first-last-agg" ADD FUNCTION last_sfunc(anyelement, anyelement);
+ALTER EXTENSION "first-last-agg" ADD AGGREGATE last(anyelement);
+ALTER EXTENSION "first-last-agg" ADD AGGREGATE first(anyelement);
@@ -0,0 +1,21 @@
+CREATE OR REPLACE FUNCTION last_sfunc(anyelement, anyelement)
+RETURNS anyelement
+AS '$libdir/first-last-agg', 'last_sfunc'
+LANGUAGE C IMMUTABLE STRICT;
+
+CREATE OR REPLACE FUNCTION first_sfunc(anyelement, anyelement)
+RETURNS anyelement
+AS '$libdir/first-last-agg', 'first_sfunc'
+LANGUAGE C IMMUTABLE STRICT;
+
+DROP AGGREGATE IF EXISTS first(anyelement);
+CREATE AGGREGATE first(anyelement) (
+ SFUNC = first_sfunc,
+ STYPE = anyelement
+);
+
+DROP AGGREGATE IF EXISTS last(anyelement);
+CREATE AGGREGATE last(anyelement) (
+ SFUNC = last_sfunc,
+ STYPE = anyelement
+);
@@ -0,0 +1,51 @@
+/*------------------------------------------------------------------------
+ *
+ * first-last-agg.c
+ * first() and last() aggregate functions working on anyelement
+ *
+ * Copyright (c) 2011, PostgreSQL Global Development Group
+ *
+ *-------------------------------------------------------------------------
+ */
+#include "postgres.h"
+
+#include "fmgr.h"
+
+PG_MODULE_MAGIC;
+
+extern Datum first_sfunc(PG_FUNCTION_ARGS);
+extern Datum last_sfunc(PG_FUNCTION_ARGS);
+
+
+PG_FUNCTION_INFO_V1(first_sfunc);
+
+Datum
+first_sfunc(PG_FUNCTION_ARGS)
+{
+ Datum element;
+
+ /* if it's NULL, return NULL */
+ if (PG_ARGISNULL(0))
+ PG_RETURN_NULL();
+
+ /* otherwise simply return the first argument */
+ element = PG_GETARG_DATUM(0);
+ PG_RETURN_DATUM(element);
+}
+
+
+PG_FUNCTION_INFO_V1(last_sfunc);
+
+Datum
+last_sfunc(PG_FUNCTION_ARGS)
+{
+ Datum element;
+
+ /* if it's NULL, return NULL */
+ if (PG_ARGISNULL(1))
+ PG_RETURN_NULL();
+
+ /* otherwise simply return the second argument */
+ element = PG_GETARG_DATUM(1);
+ PG_RETURN_DATUM(element);
+}
@@ -0,0 +1,67 @@
+BEGIN;
+SET client_min_messages TO 'WARNING';
+\set ECHO 0
+RESET client_min_messages;
+CREATE TEMPORARY TABLE agg_test (
+ akey integer,
+ val1 integer,
+ val2 integer
+);
+INSERT INTO agg_test (akey, val1, val2)
+VALUES (1, 2, 1), (1, 4, 2), (1, 3, 3),
+ (2, 1, 4), (2, 5, 3), (2, NULL, 2), (2, 2, 1),
+ (3, NULL, NULL),
+ (4, 3, 1), (4, 5, NULL), (4, 7, 2),
+ (5, 5, 1), (5, 5, 2), (5, 5, 3);
+SELECT akey, first(val1 ORDER BY val2) AS first, last(val1 ORDER BY val2) AS last FROM agg_test GROUP BY akey ORDER BY akey;
+ akey | first | last
+------+-------+------
+ 1 | 2 | 3
+ 2 | 2 | 1
+ 3 | |
+ 4 | 3 | 5
+ 5 | 5 | 5
+(5 rows)
+
+SELECT akey, first(val1 ORDER BY val2 NULLS LAST) AS first, last(val1 ORDER BY val2 NULLS LAST) AS last FROM agg_test GROUP BY akey ORDER BY akey;
+ akey | first | last
+------+-------+------
+ 1 | 2 | 3
+ 2 | 2 | 1
+ 3 | |
+ 4 | 3 | 5
+ 5 | 5 | 5
+(5 rows)
+
+SELECT akey, first(val1 ORDER BY val2 ASC) AS first, last(val1 ORDER BY val2 DESC) AS last FROM agg_test GROUP BY akey ORDER BY akey;
+ akey | first | last
+------+-------+------
+ 1 | 2 | 2
+ 2 | 2 | 2
+ 3 | |
+ 4 | 3 | 3
+ 5 | 5 | 5
+(5 rows)
+
+SELECT akey, first(val1 ORDER BY val2 ASC NULLS FIRST) AS first, last(val1 ORDER BY val2 NULLS FIRST) AS last FROM agg_test GROUP BY akey ORDER BY akey;
+ akey | first | last
+------+-------+------
+ 1 | 2 | 3
+ 2 | 2 | 1
+ 3 | |
+ 4 | 5 | 7
+ 5 | 5 | 5
+(5 rows)
+
+SELECT akey, first(val1) AS first, last(val1) AS last FROM agg_test WHERE akey IN (3, 5) GROUP BY akey ORDER BY akey;
+ akey | first | last
+------+-------+------
+ 3 | |
+ 5 | 5 | 5
+(2 rows)
+
+SELECT akey, first(val1) AS first, last(val1) AS last FROM agg_test WHERE akey = 100;
+ akey | first | last
+------+-------+------
+ | |
+ROLLBACK;
@@ -0,0 +1,28 @@
+BEGIN;
+SET client_min_messages TO 'WARNING';
+\set ECHO 0
+\i sql/first_last_agg.sql
+\set ECHO all
+RESET client_min_messages;
+
+CREATE TEMPORARY TABLE agg_test (
+ akey integer,
+ val1 integer,
+ val2 integer
+);
+
+INSERT INTO agg_test (akey, val1, val2)
+VALUES (1, 2, 1), (1, 4, 2), (1, 3, 3),
+ (2, 1, 4), (2, 5, 3), (2, NULL, 2), (2, 2, 1),
+ (3, NULL, NULL),
+ (4, 3, 1), (4, 5, NULL), (4, 7, 2),
+ (5, 5, 1), (5, 5, 2), (5, 5, 3);
+
+SELECT akey, first(val1 ORDER BY val2) AS first, last(val1 ORDER BY val2) AS last FROM agg_test GROUP BY akey ORDER BY akey;
+SELECT akey, first(val1 ORDER BY val2 NULLS LAST) AS first, last(val1 ORDER BY val2 NULLS LAST) AS last FROM agg_test GROUP BY akey ORDER BY akey;
+SELECT akey, first(val1 ORDER BY val2 ASC) AS first, last(val1 ORDER BY val2 DESC) AS last FROM agg_test GROUP BY akey ORDER BY akey;
+SELECT akey, first(val1 ORDER BY val2 ASC NULLS FIRST) AS first, last(val1 ORDER BY val2 NULLS FIRST) AS last FROM agg_test GROUP BY akey ORDER BY akey;
+SELECT akey, first(val1) AS first, last(val1) AS last FROM agg_test WHERE akey IN (3, 5) GROUP BY akey ORDER BY akey;
+SELECT akey, first(val1) AS first, last(val1) AS last FROM agg_test WHERE akey = 100;
+
+ROLLBACK;

0 comments on commit aa300dc

Please sign in to comment.