postgresql/contrib/intarray/sql/_int.sql
Bruce Momjian 181ca96e7a August 6, 2002
1. Reworked patch from Andrey Oktyabrski (ano@spider.ru) with
      functions: icount, sort, sort_asc, uniq, idx, subarray
      operations: #, +, -, |, &

FUNCTIONS:

  int   icount(int[]) - the number of elements in intarray
  int[] sort(int[], 'asc' | 'desc') - sort intarray
  int[] sort(int[]) - sort in ascending order
  int[] sort_asc(int[]),sort_desc(int[]) - shortcuts for sort
  int[] uniq(int[]) - returns unique elements
  int   idx(int[], int item) - returns index of first intarray matching element
                               to item, or '0' if matching failed.
  int[] subarray(int[],int START [, int LEN]) - returns part of intarray
                               starting from element number START (from 1)
                               and length LEN.
OPERATIONS:

  int[] && int[]  - overlap - returns TRUE if arrays has at least one common elements.
  int[] @  int[]  - contains - returns TRUE if left array contains right array
  int[] ~ int[]   - contained - returns TRUE if left array is contained in right array
  # int[]         - return the number of elements in array
  int[] + int     - push element to array ( add to end of array)
  int[] + int[]   - merge of arrays (right array added to the end of left one)
  int[] - int     - remove entries matched by right argument from array
  int[] - int[]   - remove left array from right
  int[] | int     - returns intarray - union of arguments
  int[] | int[]   - returns intarray as a union of two arrays
  int[] & int[]   - returns intersection of arrays

Oleg Bartunov
2002-08-10 20:38:29 +00:00

111 lines
3.7 KiB
PL/PgSQL

--
-- first, define the datatype. Turn off echoing so that expected file
-- does not depend on contents of seg.sql.
--
\set ECHO none
\i _int.sql
\set ECHO all
select intset(1234);
select icount('{1234234,234234}');
select sort('{1234234,-30,234234}');
select sort('{1234234,-30,234234}','asc');
select sort('{1234234,-30,234234}','desc');
select sort_asc('{1234234,-30,234234}');
select sort_desc('{1234234,-30,234234}');
select uniq('{1234234,-30,-30,234234,-30}');
select uniq(sort_asc('{1234234,-30,-30,234234,-30}'));
select idx('{1234234,-30,-30,234234,-30}',-30);
select subarray('{1234234,-30,-30,234234,-30}',2,3);
select subarray('{1234234,-30,-30,234234,-30}',-1,1);
select subarray('{1234234,-30,-30,234234,-30}',0,-1);
select #'{1234234,234234}'::int[];
select '{123,623,445}'::int[] + 1245;
select '{123,623,445}'::int[] + 445;
select '{123,623,445}'::int[] + '{1245,87,445}';
select '{123,623,445}'::int[] - 623;
select '{123,623,445}'::int[] - '{1623,623}';
select '{123,623,445}'::int[] | 623;
select '{123,623,445}'::int[] | 1623;
select '{123,623,445}'::int[] | '{1623,623}';
select '{123,623,445}'::int[] & '{1623,623}';
--test query_int
select '1'::query_int;
select ' 1'::query_int;
select '1 '::query_int;
select ' 1 '::query_int;
select ' ! 1 '::query_int;
select '!1'::query_int;
select '1|2'::query_int;
select '1|!2'::query_int;
select '!1|2'::query_int;
select '!1|!2'::query_int;
select '!(!1|!2)'::query_int;
select '!(!1|2)'::query_int;
select '!(1|!2)'::query_int;
select '!(1|2)'::query_int;
select '1&2'::query_int;
select '!1&2'::query_int;
select '1&!2'::query_int;
select '!1&!2'::query_int;
select '(1&2)'::query_int;
select '1&(2)'::query_int;
select '!(1)&2'::query_int;
select '!(1&2)'::query_int;
select '1|2&3'::query_int;
select '1|(2&3)'::query_int;
select '(1|2)&3'::query_int;
select '1|2&!3'::query_int;
select '1|!2&3'::query_int;
select '!1|2&3'::query_int;
select '!1|(2&3)'::query_int;
select '!(1|2)&3'::query_int;
select '(!1|2)&3'::query_int;
select '1|(2|(4|(5|6)))'::query_int;
select '1|2|4|5|6'::query_int;
select '1&(2&(4&(5&6)))'::query_int;
select '1&2&4&5&6'::query_int;
select '1&(2&(4&(5|6)))'::query_int;
select '1&(2&(4&(5|!6)))'::query_int;
CREATE TABLE test__int( a int[] );
\copy test__int from 'data/test__int.data'
SELECT count(*) from test__int WHERE a && '{23,50}';
SELECT count(*) from test__int WHERE a @@ '23|50';
SELECT count(*) from test__int WHERE a @ '{23,50}';
SELECT count(*) from test__int WHERE a @@ '23&50';
SELECT count(*) from test__int WHERE a @ '{20,23}';
SELECT count(*) from test__int WHERE a @@ '50&68';
SELECT count(*) from test__int WHERE a @ '{20,23}' or a @ '{50,68}';
SELECT count(*) from test__int WHERE a @@ '(20&23)|(50&68)';
CREATE INDEX text_idx on test__int using gist ( a gist__int_ops );
SELECT count(*) from test__int WHERE a && '{23,50}';
SELECT count(*) from test__int WHERE a @@ '23|50';
SELECT count(*) from test__int WHERE a @ '{23,50}';
SELECT count(*) from test__int WHERE a @@ '23&50';
SELECT count(*) from test__int WHERE a @ '{20,23}';
SELECT count(*) from test__int WHERE a @@ '50&68';
SELECT count(*) from test__int WHERE a @ '{20,23}' or a @ '{50,68}';
SELECT count(*) from test__int WHERE a @@ '(20&23)|(50&68)';
drop index text_idx;
CREATE INDEX text_idx on test__int using gist ( a gist__intbig_ops );
SELECT count(*) from test__int WHERE a && '{23,50}';
SELECT count(*) from test__int WHERE a @@ '23|50';
SELECT count(*) from test__int WHERE a @ '{23,50}';
SELECT count(*) from test__int WHERE a @@ '23&50';
SELECT count(*) from test__int WHERE a @ '{20,23}';
SELECT count(*) from test__int WHERE a @@ '50&68';
SELECT count(*) from test__int WHERE a @ '{20,23}' or a @ '{50,68}';
SELECT count(*) from test__int WHERE a @@ '(20&23)|(50&68)';