Commit 8096fe45 authored by Bruce Momjian's avatar Bruce Momjian

The added aggregates are:

(1) boolean-and and boolean-or aggregates named bool_and and bool_or.
    they (SHOULD;-) correspond to standard sql every and some/any aggregates.
    they do not have the right name as there is a problem with
    the standard and the parser for some/any. Tom also think that
    the standard name is misleading because NULL are ignored.
    Also add 'every' aggregate.

(2) bitwise integer aggregates named bit_and and bit_or for
    int2, int4, int8 and bit types. They are not standard, but I find
    them useful. I needed them once.


The patches adds:

- 2 new very short strict functions for boolean aggregates in
  src/backed/utils/adt/bool.c,
  src/include/utils/builtins.h and src/include/catalog/pg_proc.h

- the new aggregates declared in src/include/catalog/pg_proc.h and
  src/include/catalog/pg_aggregate.h

- some documentation and validation about these new aggregates.

Fabien COELHO
parent 3dc37cd8
<!--
$PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.203 2004/05/19 23:56:38 momjian Exp $
$PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.204 2004/05/26 15:25:57 momjian Exp $
PostgreSQL documentation
-->
......@@ -7553,6 +7553,76 @@ SELECT pg_type_is_visible('myschema.widget'::regtype);
<entry>the average (arithmetic mean) of all input values</entry>
</row>
<row>
<entry>
<indexterm>
<primary>bit_and</primary>
</indexterm>
<function>bit_and(<replaceable class="parameter">expression</replaceable>)</function>
</entry>
<entry>
<type>smallint</type>, <type>integer</type>, <type>bigint</type> or
<type>bit</type>,
</entry>
<entry>
same as argument data type.
</entry>
<entry>the bitwise-and of all non-null input values, or null if empty
</entry>
</row>
<row>
<entry>
<indexterm>
<primary>bit_or</primary>
</indexterm>
<function>bit_or(<replaceable class="parameter">expression</replaceable>)</function>
</entry>
<entry>
<type>smallint</type>, <type>integer</type>, <type>bigint</type> or
<type>bit</type>,
</entry>
<entry>
same as argument data type.
</entry>
<entry>the bitwise-or of all non-null input values, or null if empty.
</entry>
</row>
<row>
<entry>
<indexterm>
<primary>bool_and</primary>
</indexterm>
<function>bool_and(<replaceable class="parameter">expression</replaceable>)</function>
</entry>
<entry>
<type>bool</type>
</entry>
<entry>
<type>bool</type>
</entry>
<entry>true if all input values are true, otherwise false.
Also known as <function>bool_and</function>.
</entry>
</row>
<row>
<entry>
<indexterm>
<primary>bool_or</primary>
</indexterm>
<function>bool_or(<replaceable class="parameter">expression</replaceable>)</function>
</entry>
<entry>
<type>bool</type>
</entry>
<entry>
<type>bool</type>
</entry>
<entry>true if at least one input value is true, otherwise false</entry>
</row>
<row>
<entry><function>count(*)</function></entry>
<entry></entry>
......@@ -7570,6 +7640,24 @@ SELECT pg_type_is_visible('myschema.widget'::regtype);
</entry>
</row>
<row>
<entry>
<indexterm>
<primary>every</primary>
</indexterm>
<function>every(<replaceable class="parameter">expression</replaceable>)</function>
</entry>
<entry>
<type>bool</type>
</entry>
<entry>
<type>bool</type>
</entry>
<entry>true if all input values are true, otherwise false.
Also known as <function>bool_and</function>.
</entry>
</row>
<row>
<entry><function>max(<replaceable class="parameter">expression</replaceable>)</function></entry>
<entry>any numeric, string, or date/time type</entry>
......@@ -7660,6 +7748,29 @@ SELECT pg_type_is_visible('myschema.widget'::regtype);
used to substitute zero for null when necessary.
</para>
<note>
<indexterm>
<primary>ANY</primary>
</indexterm>
<indexterm>
<primary>SOME</primary>
</indexterm>
<para>
Boolean aggregates <function>bool_and</function> and
<function>bool_or</function> correspond to standard SQL aggregates
<function>every</function> and <function>any</function> or
<function>some</function>.
As for <function>any</function> and <function>some</function>,
it seems that there is an ambiguity built into the standard syntax:
<programlisting>
SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
</programlisting>
Here <function>ANY</function> can be considered both as leading
to a subquery or as an aggregate if the select expression returns 1 row.
Thus the standard name cannot be given to these aggregates.
</para>
</note>
<note>
<para>
Users accustomed to working with other SQL database management
......
......@@ -8,7 +8,7 @@
*
*
* IDENTIFICATION
* $PostgreSQL: pgsql/src/backend/utils/adt/bool.c,v 1.32 2004/05/07 00:24:58 tgl Exp $
* $PostgreSQL: pgsql/src/backend/utils/adt/bool.c,v 1.33 2004/05/26 15:25:59 momjian Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -248,3 +248,23 @@ isnotfalse(PG_FUNCTION_ARGS)
PG_RETURN_BOOL(b);
}
/*
* boolean-and and boolean-or aggregates.
*/
/* function for standard EVERY aggregate implementation conforming to SQL 2003.
* must be strict. It is also named bool_and for homogeneity.
*/
Datum booland_statefunc(PG_FUNCTION_ARGS)
{
PG_RETURN_BOOL(PG_GETARG_BOOL(0) && PG_GETARG_BOOL(1));
}
/* function for standard ANY/SOME aggregate conforming to SQL 2003.
* must be strict. The name of the aggregate is bool_or. See the doc.
*/
Datum boolor_statefunc(PG_FUNCTION_ARGS)
{
PG_RETURN_BOOL(PG_GETARG_BOOL(0) || PG_GETARG_BOOL(1));
}
......@@ -37,7 +37,7 @@
* Portions Copyright (c) 1996-2003, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/catalog/catversion.h,v 1.230 2004/05/14 21:42:28 neilc Exp $
* $PostgreSQL: pgsql/src/include/catalog/catversion.h,v 1.231 2004/05/26 15:26:00 momjian Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -53,6 +53,6 @@
*/
/* yyyymmddN */
#define CATALOG_VERSION_NO 200405141
#define CATALOG_VERSION_NO 200405261
#endif
......@@ -8,7 +8,7 @@
* Portions Copyright (c) 1996-2003, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/catalog/pg_aggregate.h,v 1.42 2003/11/29 22:40:58 pgsql Exp $
* $PostgreSQL: pgsql/src/include/catalog/pg_aggregate.h,v 1.43 2004/05/26 15:26:03 momjian Exp $
*
* NOTES
* the genbki.sh script reads this file and generates .bki
......@@ -149,6 +149,21 @@ DATA(insert ( 2157 float4_accum float8_stddev 1022 "{0,0,0}" ));
DATA(insert ( 2158 float8_accum float8_stddev 1022 "{0,0,0}" ));
DATA(insert ( 2159 numeric_accum numeric_stddev 1231 "{0,0,0}" ));
/* boolean-and and boolean-or */
DATA(insert ( 2517 booland_statefunc - 16 _null_ ));
DATA(insert ( 2518 boolor_statefunc - 16 _null_ ));
DATA(insert ( 2519 booland_statefunc - 16 _null_ ));
/* bitwise integer */
DATA(insert ( 2535 int2and - 21 _null_ ));
DATA(insert ( 2536 int2or - 21 _null_ ));
DATA(insert ( 2537 int4and - 23 _null_ ));
DATA(insert ( 2538 int4or - 23 _null_ ));
DATA(insert ( 2539 int8and - 20 _null_ ));
DATA(insert ( 2540 int8or - 20 _null_ ));
DATA(insert ( 2541 bitand - 1560 _null_ ));
DATA(insert ( 2542 bitor - 1560 _null_ ));
/*
* prototypes for functions in pg_aggregate.c
*/
......
......@@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2003, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/catalog/pg_proc.h,v 1.329 2004/05/14 21:42:28 neilc Exp $
* $PostgreSQL: pgsql/src/include/catalog/pg_proc.h,v 1.330 2004/05/26 15:26:04 momjian Exp $
*
* NOTES
* The script catalog/genbki.sh reads this file and generates .bki
......@@ -3537,6 +3537,41 @@ DATA(insert OID = 1069 ( generate_series PGNSP PGUID 12 f f t t v 2 20 "20 20"
DESCR("non-persistent series generator");
/* boolean aggregates */
DATA(insert OID = 2515 ( booland_statefunc PGNSP PGUID 12 f f t f i 2 16 "16 16" _null_ booland_statefunc - _null_ ));
DESCR("boolean-and aggregate transition function");
DATA(insert OID = 2516 ( boolor_statefunc PGNSP PGUID 12 f f t f i 2 16 "16 16" _null_ boolor_statefunc - _null_ ));
DESCR("boolean-or aggregate transition function");
DATA(insert OID = 2517 ( bool_and PGNSP PGUID 12 t f f f i 1 16 "16" _null_ aggregate_dummy - _null_ ));
DESCR("boolean-and aggregate");
/* ANY, SOME? These names conflict with subquery operators. See doc. */
DATA(insert OID = 2518 ( bool_or PGNSP PGUID 12 t f f f i 1 16 "16" _null_ aggregate_dummy - _null_ ));
DESCR("boolean-or aggregate");
DATA(insert OID = 2519 ( every PGNSP PGUID 12 t f f f i 1 16 "16" _null_ aggregate_dummy - _null_ ));
DESCR("boolean-and aggregate");
/* bitwise integer aggregates */
DATA(insert OID = 2535 ( bit_and PGNSP PGUID 12 t f f f i 1 21 "21" _null_ aggregate_dummy - _null_));
DESCR("bitwise-and smallint aggregate");
DATA(insert OID = 2536 ( bit_or PGNSP PGUID 12 t f f f i 1 21 "21" _null_ aggregate_dummy - _null_));
DESCR("bitwise-or smallint aggregate");
DATA(insert OID = 2537 ( bit_and PGNSP PGUID 12 t f f f i 1 23 "23" _null_ aggregate_dummy - _null_));
DESCR("bitwise-and integer aggregate");
DATA(insert OID = 2538 ( bit_or PGNSP PGUID 12 t f f f i 1 23 "23" _null_ aggregate_dummy - _null_));
DESCR("bitwise-or integer aggregate");
DATA(insert OID = 2539 ( bit_and PGNSP PGUID 12 t f f f i 1 20 "20" _null_ aggregate_dummy - _null_));
DESCR("bitwise-and bigint aggregate");
DATA(insert OID = 2540 ( bit_or PGNSP PGUID 12 t f f f i 1 20 "20" _null_ aggregate_dummy - _null_));
DESCR("bitwise-or bigint aggregate");
DATA(insert OID = 2541 ( bit_and PGNSP PGUID 12 t f f f i 1 1560 "1560" _null_ aggregate_dummy - _null_));
DESCR("bitwise-and bit aggregate");
DATA(insert OID = 2542 ( bit_or PGNSP PGUID 12 t f f f i 1 1560 "1560" _null_ aggregate_dummy - _null_));
DESCR("bitwise-or bit aggregate");
/*
* Symbolic values for provolatile column: these indicate whether the result
* of a function is dependent *only* on the values of its explicit arguments,
......
......@@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2003, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/utils/builtins.h,v 1.238 2004/05/14 21:42:30 neilc Exp $
* $PostgreSQL: pgsql/src/include/utils/builtins.h,v 1.239 2004/05/26 15:26:18 momjian Exp $
*
*-------------------------------------------------------------------------
*/
......@@ -68,6 +68,8 @@ extern Datum istrue(PG_FUNCTION_ARGS);
extern Datum isfalse(PG_FUNCTION_ARGS);
extern Datum isnottrue(PG_FUNCTION_ARGS);
extern Datum isnotfalse(PG_FUNCTION_ARGS);
extern Datum booland_statefunc(PG_FUNCTION_ARGS);
extern Datum boolor_statefunc(PG_FUNCTION_ARGS);
/* char.c */
extern Datum charin(PG_FUNCTION_ARGS);
......
......@@ -157,3 +157,139 @@ group by ten
having exists (select 1 from onek b
where sum(distinct a.four + b.four) = b.four);
ERROR: aggregates not allowed in WHERE clause
--
-- test for bitwise integer aggregates
--
CREATE TEMPORARY TABLE bitwise_test(
i2 INT2,
i4 INT4,
i8 INT8,
i INTEGER,
x INT2,
y BIT(4)
);
-- empty case
SELECT
BIT_AND(i2) AS "?",
BIT_OR(i4) AS "?"
FROM bitwise_test;
? | ?
---+---
|
(1 row)
COPY bitwise_test FROM STDIN NULL 'null';
SELECT
BIT_AND(i2) AS "1",
BIT_AND(i4) AS "1",
BIT_AND(i8) AS "1",
BIT_AND(i) AS "?",
BIT_AND(x) AS "0",
BIT_AND(y) AS "0100",
BIT_OR(i2) AS "7",
BIT_OR(i4) AS "7",
BIT_OR(i8) AS "7",
BIT_OR(i) AS "?",
BIT_OR(x) AS "7",
BIT_OR(y) AS "1101"
FROM bitwise_test;
1 | 1 | 1 | ? | 0 | 0100 | 7 | 7 | 7 | ? | 7 | 1101
---+---+---+---+---+------+---+---+---+---+---+------
1 | 1 | 1 | 1 | 0 | 0100 | 7 | 7 | 7 | 3 | 7 | 1101
(1 row)
--
-- test boolean aggregates
--
-- first test all possible transition and final states
SELECT
-- boolean and transitions
-- null because strict
booland_statefunc(NULL, NULL) IS NULL AS "t",
booland_statefunc(TRUE, NULL) IS NULL AS "t",
booland_statefunc(FALSE, NULL) IS NULL AS "t",
booland_statefunc(NULL, TRUE) IS NULL AS "t",
booland_statefunc(NULL, FALSE) IS NULL AS "t",
-- and actual computations
booland_statefunc(TRUE, TRUE) AS "t",
NOT booland_statefunc(TRUE, FALSE) AS "t",
NOT booland_statefunc(FALSE, TRUE) AS "t",
NOT booland_statefunc(FALSE, FALSE) AS "t";
t | t | t | t | t | t | t | t | t
---+---+---+---+---+---+---+---+---
t | t | t | t | t | t | t | t | t
(1 row)
SELECT
-- boolean or transitions
-- null because strict
boolor_statefunc(NULL, NULL) IS NULL AS "t",
boolor_statefunc(TRUE, NULL) IS NULL AS "t",
boolor_statefunc(FALSE, NULL) IS NULL AS "t",
boolor_statefunc(NULL, TRUE) IS NULL AS "t",
boolor_statefunc(NULL, FALSE) IS NULL AS "t",
-- actual computations
boolor_statefunc(TRUE, TRUE) AS "t",
boolor_statefunc(TRUE, FALSE) AS "t",
boolor_statefunc(FALSE, TRUE) AS "t",
NOT boolor_statefunc(FALSE, FALSE) AS "t";
t | t | t | t | t | t | t | t | t
---+---+---+---+---+---+---+---+---
t | t | t | t | t | t | t | t | t
(1 row)
CREATE TEMPORARY TABLE bool_test(
b1 BOOL,
b2 BOOL,
b3 BOOL,
b4 BOOL);
-- empty case
SELECT
BOOL_AND(b1) AS "n",
BOOL_OR(b3) AS "n"
FROM bool_test;
n | n
---+---
|
(1 row)
COPY bool_test FROM STDIN NULL 'null';
SELECT
BOOL_AND(b1) AS "f",
BOOL_AND(b2) AS "t",
BOOL_AND(b3) AS "f",
BOOL_AND(b4) AS "n",
BOOL_AND(NOT b2) AS "f",
BOOL_AND(NOT b3) AS "t"
FROM bool_test;
f | t | f | n | f | t
---+---+---+---+---+---
f | t | f | | f | t
(1 row)
SELECT
EVERY(b1) AS "f",
EVERY(b2) AS "t",
EVERY(b3) AS "f",
EVERY(b4) AS "n",
EVERY(NOT b2) AS "f",
EVERY(NOT b3) AS "t"
FROM bool_test;
f | t | f | n | f | t
---+---+---+---+---+---
f | t | f | | f | t
(1 row)
SELECT
BOOL_OR(b1) AS "t",
BOOL_OR(b2) AS "t",
BOOL_OR(b3) AS "f",
BOOL_OR(b4) AS "n",
BOOL_OR(NOT b2) AS "f",
BOOL_OR(NOT b3) AS "t"
FROM bool_test;
t | t | f | n | f | t
---+---+---+---+---+---
t | t | f | | f | t
(1 row)
......@@ -62,3 +62,121 @@ select ten, sum(distinct four) from onek a
group by ten
having exists (select 1 from onek b
where sum(distinct a.four + b.four) = b.four);
--
-- test for bitwise integer aggregates
--
CREATE TEMPORARY TABLE bitwise_test(
i2 INT2,
i4 INT4,
i8 INT8,
i INTEGER,
x INT2,
y BIT(4)
);
-- empty case
SELECT
BIT_AND(i2) AS "?",
BIT_OR(i4) AS "?"
FROM bitwise_test;
COPY bitwise_test FROM STDIN NULL 'null';
1 1 1 1 1 B0101
3 3 3 null 2 B0100
7 7 7 3 4 B1100
\.
SELECT
BIT_AND(i2) AS "1",
BIT_AND(i4) AS "1",
BIT_AND(i8) AS "1",
BIT_AND(i) AS "?",
BIT_AND(x) AS "0",
BIT_AND(y) AS "0100",
BIT_OR(i2) AS "7",
BIT_OR(i4) AS "7",
BIT_OR(i8) AS "7",
BIT_OR(i) AS "?",
BIT_OR(x) AS "7",
BIT_OR(y) AS "1101"
FROM bitwise_test;
--
-- test boolean aggregates
--
-- first test all possible transition and final states
SELECT
-- boolean and transitions
-- null because strict
booland_statefunc(NULL, NULL) IS NULL AS "t",
booland_statefunc(TRUE, NULL) IS NULL AS "t",
booland_statefunc(FALSE, NULL) IS NULL AS "t",
booland_statefunc(NULL, TRUE) IS NULL AS "t",
booland_statefunc(NULL, FALSE) IS NULL AS "t",
-- and actual computations
booland_statefunc(TRUE, TRUE) AS "t",
NOT booland_statefunc(TRUE, FALSE) AS "t",
NOT booland_statefunc(FALSE, TRUE) AS "t",
NOT booland_statefunc(FALSE, FALSE) AS "t";
SELECT
-- boolean or transitions
-- null because strict
boolor_statefunc(NULL, NULL) IS NULL AS "t",
boolor_statefunc(TRUE, NULL) IS NULL AS "t",
boolor_statefunc(FALSE, NULL) IS NULL AS "t",
boolor_statefunc(NULL, TRUE) IS NULL AS "t",
boolor_statefunc(NULL, FALSE) IS NULL AS "t",
-- actual computations
boolor_statefunc(TRUE, TRUE) AS "t",
boolor_statefunc(TRUE, FALSE) AS "t",
boolor_statefunc(FALSE, TRUE) AS "t",
NOT boolor_statefunc(FALSE, FALSE) AS "t";
CREATE TEMPORARY TABLE bool_test(
b1 BOOL,
b2 BOOL,
b3 BOOL,
b4 BOOL);
-- empty case
SELECT
BOOL_AND(b1) AS "n",
BOOL_OR(b3) AS "n"
FROM bool_test;
COPY bool_test FROM STDIN NULL 'null';
TRUE null FALSE null
FALSE TRUE null null
null TRUE FALSE null
\.
SELECT
BOOL_AND(b1) AS "f",
BOOL_AND(b2) AS "t",
BOOL_AND(b3) AS "f",
BOOL_AND(b4) AS "n",
BOOL_AND(NOT b2) AS "f",
BOOL_AND(NOT b3) AS "t"
FROM bool_test;
SELECT
EVERY(b1) AS "f",
EVERY(b2) AS "t",
EVERY(b3) AS "f",
EVERY(b4) AS "n",
EVERY(NOT b2) AS "f",
EVERY(NOT b3) AS "t"
FROM bool_test;
SELECT
BOOL_OR(b1) AS "t",
BOOL_OR(b2) AS "t",
BOOL_OR(b3) AS "f",
BOOL_OR(b4) AS "n",
BOOL_OR(NOT b2) AS "f",
BOOL_OR(NOT b3) AS "t"
FROM bool_test;
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment