mirror of
https://github.com/zebrajr/postgres.git
synced 2025-12-06 12:20:15 +01:00
This allows these modules to be installed into a database without superuser privileges (assuming that the DBA or sysadmin has installed the module's files in the expected place). You only need CREATE privilege on the current database, which by default would be available to the database owner. The following modules are marked trusted: btree_gin btree_gist citext cube dict_int earthdistance fuzzystrmatch hstore hstore_plperl intarray isn jsonb_plperl lo ltree pg_trgm pgcrypto seg tablefunc tcn tsm_system_rows tsm_system_time unaccent uuid-ossp In the future we might mark some more modules trusted, but there seems to be no debate about these, and on the whole it seems wise to be conservative with use of this feature to start out with. Discussion: https://postgr.es/m/32315.1580326876@sss.pgh.pa.us
347 lines
12 KiB
Plaintext
347 lines
12 KiB
Plaintext
<!-- doc/src/sgml/intarray.sgml -->
|
|
|
|
<sect1 id="intarray" xreflabel="intarray">
|
|
<title>intarray</title>
|
|
|
|
<indexterm zone="intarray">
|
|
<primary>intarray</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
The <filename>intarray</filename> module provides a number of useful functions
|
|
and operators for manipulating null-free arrays of integers.
|
|
There is also support for indexed searches using some of the operators.
|
|
</para>
|
|
|
|
<para>
|
|
All of these operations will throw an error if a supplied array contains any
|
|
NULL elements.
|
|
</para>
|
|
|
|
<para>
|
|
Many of these operations are only sensible for one-dimensional arrays.
|
|
Although they will accept input arrays of more dimensions, the data is
|
|
treated as though it were a linear array in storage order.
|
|
</para>
|
|
|
|
<para>
|
|
This module is considered <quote>trusted</quote>, that is, it can be
|
|
installed by non-superusers who have <literal>CREATE</literal> privilege
|
|
on the current database.
|
|
</para>
|
|
|
|
<sect2>
|
|
<title><filename>intarray</filename> Functions and Operators</title>
|
|
|
|
<para>
|
|
The functions provided by the <filename>intarray</filename> module
|
|
are shown in <xref linkend="intarray-func-table"/>, the operators
|
|
in <xref linkend="intarray-op-table"/>.
|
|
</para>
|
|
|
|
<table id="intarray-func-table">
|
|
<title><filename>intarray</filename> Functions</title>
|
|
|
|
<tgroup cols="5">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry><function>icount(int[])</function><indexterm><primary>icount</primary></indexterm></entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>number of elements in array</entry>
|
|
<entry><literal>icount('{1,2,3}'::int[])</literal></entry>
|
|
<entry><literal>3</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>sort(int[], text dir)</function><indexterm><primary>sort</primary></indexterm></entry>
|
|
<entry><type>int[]</type></entry>
|
|
<entry>sort array — <parameter>dir</parameter> must be <literal>asc</literal> or <literal>desc</literal></entry>
|
|
<entry><literal>sort('{1,2,3}'::int[], 'desc')</literal></entry>
|
|
<entry><literal>{3,2,1}</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>sort(int[])</function></entry>
|
|
<entry><type>int[]</type></entry>
|
|
<entry>sort in ascending order</entry>
|
|
<entry><literal>sort(array[11,77,44])</literal></entry>
|
|
<entry><literal>{11,44,77}</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>sort_asc(int[])</function><indexterm><primary>sort_asc</primary></indexterm></entry>
|
|
<entry><type>int[]</type></entry>
|
|
<entry>sort in ascending order</entry>
|
|
<entry><literal></literal></entry>
|
|
<entry><literal></literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>sort_desc(int[])</function><indexterm><primary>sort_desc</primary></indexterm></entry>
|
|
<entry><type>int[]</type></entry>
|
|
<entry>sort in descending order</entry>
|
|
<entry><literal></literal></entry>
|
|
<entry><literal></literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>uniq(int[])</function><indexterm><primary>uniq</primary></indexterm></entry>
|
|
<entry><type>int[]</type></entry>
|
|
<entry>remove adjacent duplicates</entry>
|
|
<entry><literal>uniq(sort('{1,2,3,2,1}'::int[]))</literal></entry>
|
|
<entry><literal>{1,2,3}</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>idx(int[], int item)</function><indexterm><primary>idx</primary></indexterm></entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>index of first element matching <parameter>item</parameter> (0 if none)</entry>
|
|
<entry><literal>idx(array[11,22,33,22,11], 22)</literal></entry>
|
|
<entry><literal>2</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>subarray(int[], int start, int len)</function><indexterm><primary>subarray</primary></indexterm></entry>
|
|
<entry><type>int[]</type></entry>
|
|
<entry>portion of array starting at position <parameter>start</parameter>, <parameter>len</parameter> elements</entry>
|
|
<entry><literal>subarray('{1,2,3,2,1}'::int[], 2, 3)</literal></entry>
|
|
<entry><literal>{2,3,2}</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>subarray(int[], int start)</function></entry>
|
|
<entry><type>int[]</type></entry>
|
|
<entry>portion of array starting at position <parameter>start</parameter></entry>
|
|
<entry><literal>subarray('{1,2,3,2,1}'::int[], 2)</literal></entry>
|
|
<entry><literal>{2,3,2,1}</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>intset(int)</function><indexterm><primary>intset</primary></indexterm></entry>
|
|
<entry><type>int[]</type></entry>
|
|
<entry>make single-element array</entry>
|
|
<entry><literal>intset(42)</literal></entry>
|
|
<entry><literal>{42}</literal></entry>
|
|
</row>
|
|
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<table id="intarray-op-table">
|
|
<title><filename>intarray</filename> Operators</title>
|
|
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row>
|
|
<entry>Operator</entry>
|
|
<entry>Returns</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry><literal>int[] && int[]</literal></entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>overlap — <literal>true</literal> if arrays have at least one common element</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>int[] @> int[]</literal></entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>contains — <literal>true</literal> if left array contains right array</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>int[] <@ int[]</literal></entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>contained — <literal>true</literal> if left array is contained in right array</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal># int[]</literal></entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>number of elements in array</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>int[] # int</literal></entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>index (same as <function>idx</function> function)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>int[] + int</literal></entry>
|
|
<entry><type>int[]</type></entry>
|
|
<entry>push element onto array (add it to end of array)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>int[] + int[] </literal></entry>
|
|
<entry><type>int[]</type></entry>
|
|
<entry>array concatenation (right array added to the end of left one)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>int[] - int</literal></entry>
|
|
<entry><type>int[]</type></entry>
|
|
<entry>remove entries matching right argument from array</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>int[] - int[]</literal></entry>
|
|
<entry><type>int[]</type></entry>
|
|
<entry>remove elements of right array from left</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>int[] | int</literal></entry>
|
|
<entry><type>int[]</type></entry>
|
|
<entry>union of arguments</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>int[] | int[]</literal></entry>
|
|
<entry><type>int[]</type></entry>
|
|
<entry>union of arrays</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>int[] & int[]</literal></entry>
|
|
<entry><type>int[]</type></entry>
|
|
<entry>intersection of arrays</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>int[] @@ query_int</literal></entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry><literal>true</literal> if array satisfies query (see below)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>query_int ~~ int[]</literal></entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry><literal>true</literal> if array satisfies query (commutator of <literal>@@</literal>)</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
(Before PostgreSQL 8.2, the containment operators <literal>@></literal> and
|
|
<literal><@</literal> were respectively called <literal>@</literal> and <literal>~</literal>.
|
|
These names are still available, but are deprecated and will eventually be
|
|
retired. Notice that the old names are reversed from the convention
|
|
formerly followed by the core geometric data types!)
|
|
</para>
|
|
|
|
<para>
|
|
The operators <literal>&&</literal>, <literal>@></literal> and
|
|
<literal><@</literal> are equivalent to <productname>PostgreSQL</productname>'s built-in
|
|
operators of the same names, except that they work only on integer arrays
|
|
that do not contain nulls, while the built-in operators work for any array
|
|
type. This restriction makes them faster than the built-in operators
|
|
in many cases.
|
|
</para>
|
|
|
|
<para>
|
|
The <literal>@@</literal> and <literal>~~</literal> operators test whether an array
|
|
satisfies a <firstterm>query</firstterm>, which is expressed as a value of a
|
|
specialized data type <type>query_int</type>. A <firstterm>query</firstterm>
|
|
consists of integer values that are checked against the elements of
|
|
the array, possibly combined using the operators <literal>&</literal>
|
|
(AND), <literal>|</literal> (OR), and <literal>!</literal> (NOT). Parentheses
|
|
can be used as needed. For example,
|
|
the query <literal>1&(2|3)</literal> matches arrays that contain 1
|
|
and also contain either 2 or 3.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>Index Support</title>
|
|
|
|
<para>
|
|
<filename>intarray</filename> provides index support for the
|
|
<literal>&&</literal>, <literal>@></literal>, <literal><@</literal>,
|
|
and <literal>@@</literal> operators, as well as regular array equality.
|
|
</para>
|
|
|
|
<para>
|
|
Two GiST index operator classes are provided:
|
|
<literal>gist__int_ops</literal> (used by default) is suitable for
|
|
small- to medium-size data sets, while
|
|
<literal>gist__intbig_ops</literal> uses a larger signature and is more
|
|
suitable for indexing large data sets (i.e., columns containing
|
|
a large number of distinct array values).
|
|
The implementation uses an RD-tree data structure with
|
|
built-in lossy compression.
|
|
</para>
|
|
|
|
<para>
|
|
There is also a non-default GIN operator class
|
|
<literal>gin__int_ops</literal> supporting the same operators.
|
|
</para>
|
|
|
|
<para>
|
|
The choice between GiST and GIN indexing depends on the relative
|
|
performance characteristics of GiST and GIN, which are discussed elsewhere.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>Example</title>
|
|
|
|
<programlisting>
|
|
-- a message can be in one or more <quote>sections</quote>
|
|
CREATE TABLE message (mid INT PRIMARY KEY, sections INT[], ...);
|
|
|
|
-- create specialized index
|
|
CREATE INDEX message_rdtree_idx ON message USING GIST (sections gist__int_ops);
|
|
|
|
-- select messages in section 1 OR 2 - OVERLAP operator
|
|
SELECT message.mid FROM message WHERE message.sections && '{1,2}';
|
|
|
|
-- select messages in sections 1 AND 2 - CONTAINS operator
|
|
SELECT message.mid FROM message WHERE message.sections @> '{1,2}';
|
|
|
|
-- the same, using QUERY operator
|
|
SELECT message.mid FROM message WHERE message.sections @@ '1&2'::query_int;
|
|
</programlisting>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>Benchmark</title>
|
|
|
|
<para>
|
|
The source directory <filename>contrib/intarray/bench</filename> contains a
|
|
benchmark test suite, which can be run against an installed
|
|
<productname>PostgreSQL</productname> server. (It also requires <filename>DBD::Pg</filename>
|
|
to be installed.) To run:
|
|
</para>
|
|
|
|
<programlisting>
|
|
cd .../contrib/intarray/bench
|
|
createdb TEST
|
|
psql -c "CREATE EXTENSION intarray" TEST
|
|
./create_test.pl | psql TEST
|
|
./bench.pl
|
|
</programlisting>
|
|
|
|
<para>
|
|
The <filename>bench.pl</filename> script has numerous options, which
|
|
are displayed when it is run without any arguments.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>Authors</title>
|
|
|
|
<para>
|
|
All work was done by Teodor Sigaev (<email>teodor@sigaev.ru</email>) and
|
|
Oleg Bartunov (<email>oleg@sai.msu.su</email>). See
|
|
<ulink url="http://www.sai.msu.su/~megera/postgres/gist/"></ulink> for
|
|
additional information. Andrey Oktyabrski did a great work on adding new
|
|
functions and operations.
|
|
</para>
|
|
</sect2>
|
|
|
|
</sect1>
|