-<!-- $PostgreSQL: pgsql/doc/src/sgml/auto-explain.sgml,v 1.8 2010/04/03 07:22:52 petere Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/auto-explain.sgml,v 1.9 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="auto-explain">
<title>auto_explain</title>
The module provides no SQL-accessible functions. To use it, simply
load it into the server. You can load it into an individual session:
- <programlisting>
+<programlisting>
LOAD 'auto_explain';
- </programlisting>
+</programlisting>
(You must be superuser to do that.) More typical usage is to preload
it into all sessions by including <literal>auto_explain</> in
<xref linkend="guc-custom-variable-classes">. Typical usage might be:
</para>
- <programlisting>
+<programlisting>
# postgresql.conf
shared_preload_libraries = 'auto_explain'
custom_variable_classes = 'auto_explain'
auto_explain.log_min_duration = '3s'
- </programlisting>
+</programlisting>
</sect2>
<sect2>
<title>Example</title>
- <programlisting>
- postgres=# LOAD 'auto_explain';
- postgres=# SET auto_explain.log_min_duration = 0;
- postgres=# SELECT count(*)
- FROM pg_class, pg_index
- WHERE oid = indrelid AND indisunique;
- </programlisting>
+<programlisting>
+postgres=# LOAD 'auto_explain';
+postgres=# SET auto_explain.log_min_duration = 0;
+postgres=# SELECT count(*)
+ FROM pg_class, pg_index
+ WHERE oid = indrelid AND indisunique;
+</programlisting>
<para>
This might produce log output such as:
</para>
- <programlisting><![CDATA[
- LOG: duration: 3.651 ms plan:
- Query Text: SELECT count(*)
- FROM pg_class, pg_index
- WHERE oid = indrelid AND indisunique;
- Aggregate (cost=16.79..16.80 rows=1 width=0) (actual time=3.626..3.627 rows=1 loops=1)
- -> Hash Join (cost=4.17..16.55 rows=92 width=0) (actual time=3.349..3.594 rows=92 loops=1)
- Hash Cond: (pg_class.oid = pg_index.indrelid)
- -> Seq Scan on pg_class (cost=0.00..9.55 rows=255 width=4) (actual time=0.016..0.140 rows=255 loops=1)
- -> Hash (cost=3.02..3.02 rows=92 width=4) (actual time=3.238..3.238 rows=92 loops=1)
- Buckets: 1024 Batches: 1 Memory Usage: 4kB
- -> Seq Scan on pg_index (cost=0.00..3.02 rows=92 width=4) (actual time=0.008..3.187 rows=92 loops=1)
- Filter: indisunique
-]]>
- </programlisting>
+<screen><![CDATA[
+LOG: duration: 3.651 ms plan:
+ Query Text: SELECT count(*)
+ FROM pg_class, pg_index
+ WHERE oid = indrelid AND indisunique;
+ Aggregate (cost=16.79..16.80 rows=1 width=0) (actual time=3.626..3.627 rows=1 loops=1)
+ -> Hash Join (cost=4.17..16.55 rows=92 width=0) (actual time=3.349..3.594 rows=92 loops=1)
+ Hash Cond: (pg_class.oid = pg_index.indrelid)
+ -> Seq Scan on pg_class (cost=0.00..9.55 rows=255 width=4) (actual time=0.016..0.140 rows=255 loops=1)
+ -> Hash (cost=3.02..3.02 rows=92 width=4) (actual time=3.238..3.238 rows=92 loops=1)
+ Buckets: 1024 Batches: 1 Memory Usage: 4kB
+ -> Seq Scan on pg_index (cost=0.00..3.02 rows=92 width=4) (actual time=0.008..3.187 rows=92 loops=1)
+ Filter: indisunique
+]]></screen>
</sect2>
<sect2>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/citext.sgml,v 1.4 2010/06/29 22:29:13 momjian Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/citext.sgml,v 1.5 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="citext">
<title>citext</title>
in <productname>PostgreSQL</> has been to use the <function>lower</>
function when comparing values, for example
- <programlisting>
- SELECT * FROM tab WHERE lower(col) = LOWER(?);
- </programlisting>
+<programlisting>
+SELECT * FROM tab WHERE lower(col) = LOWER(?);
+</programlisting>
</para>
<para>
<para>
Here's a simple example of usage:
- <programlisting>
- CREATE TABLE users (
- nick CITEXT PRIMARY KEY,
- pass TEXT NOT NULL
- );
+<programlisting>
+CREATE TABLE users (
+ nick CITEXT PRIMARY KEY,
+ pass TEXT NOT NULL
+);
- INSERT INTO users VALUES ( 'larry', md5(random()::text) );
- INSERT INTO users VALUES ( 'Tom', md5(random()::text) );
- INSERT INTO users VALUES ( 'Damian', md5(random()::text) );
- INSERT INTO users VALUES ( 'NEAL', md5(random()::text) );
- INSERT INTO users VALUES ( 'Bjørn', md5(random()::text) );
+INSERT INTO users VALUES ( 'larry', md5(random()::text) );
+INSERT INTO users VALUES ( 'Tom', md5(random()::text) );
+INSERT INTO users VALUES ( 'Damian', md5(random()::text) );
+INSERT INTO users VALUES ( 'NEAL', md5(random()::text) );
+INSERT INTO users VALUES ( 'Bjørn', md5(random()::text) );
- SELECT * FROM users WHERE nick = 'Larry';
- </programlisting>
+SELECT * FROM users WHERE nick = 'Larry';
+</programlisting>
The <command>SELECT</> statement will return one tuple, even though
the <structfield>nick</> column was set to <quote>larry</> and the query
-<!-- $PostgreSQL: pgsql/doc/src/sgml/client-auth.sgml,v 1.139 2010/06/29 22:29:13 momjian Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/client-auth.sgml,v 1.140 2010/07/29 19:34:40 petere Exp $ -->
<chapter id="client-authentication">
<title>Client Authentication</title>
Since LDAP often uses commas and spaces to separate the different
parts of a DN, it is often necessary to use double-quoted parameter
values when configuring LDAP options, for example:
+<programlisting>
+ldapserver=ldap.example.net ldapprefix="cn=" ldapsuffix=", dc=example, dc=net"
+</programlisting>
</para>
</note>
- <synopsis>
-ldapserver=ldap.example.net ldapprefix="cn=" ldapsuffix=", dc=example, dc=net"
- </synopsis>
</sect2>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/config.sgml,v 1.301 2010/07/27 19:01:16 petere Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/config.sgml,v 1.302 2010/07/29 19:34:40 petere Exp $ -->
<chapter Id="runtime-config">
<title>Server Configuration</title>
type a count of the number of granted locks and waiting locks is
also dumped as well as the totals. An example of the log file output
is shown here:
- </para>
- <para>
- LOG: LockAcquire: new: lock(0xb7acd844) id(24688,24696,0,0,0,1)
- grantMask(0) req(0,0,0,0,0,0,0)=0 grant(0,0,0,0,0,0,0)=0
- wait(0) type(AccessShareLock)
- </para>
- <para>
- LOG: GrantLock: lock(0xb7acd844) id(24688,24696,0,0,0,1)
- grantMask(2) req(1,0,0,0,0,0,0)=1 grant(1,0,0,0,0,0,0)=1
- wait(0) type(AccessShareLock)
-
- </para>
- <para>
- LOG: UnGrantLock: updated: lock(0xb7acd844) id(24688,24696,0,0,0,1)
- grantMask(0) req(0,0,0,0,0,0,0)=0 grant(0,0,0,0,0,0,0)=0
- wait(0) type(AccessShareLock)
- </para>
- <para>
- LOG: CleanUpLock: deleting: lock(0xb7acd844) id(24688,24696,0,0,0,1)
- grantMask(0) req(0,0,0,0,0,0,0)=0 grant(0,0,0,0,0,0,0)=0
- wait(0) type(INVALID)
- </para>
- <para>
+<screen>
+LOG: LockAcquire: new: lock(0xb7acd844) id(24688,24696,0,0,0,1)
+ grantMask(0) req(0,0,0,0,0,0,0)=0 grant(0,0,0,0,0,0,0)=0
+ wait(0) type(AccessShareLock)
+LOG: GrantLock: lock(0xb7acd844) id(24688,24696,0,0,0,1)
+ grantMask(2) req(1,0,0,0,0,0,0)=1 grant(1,0,0,0,0,0,0)=1
+ wait(0) type(AccessShareLock)
+LOG: UnGrantLock: updated: lock(0xb7acd844) id(24688,24696,0,0,0,1)
+ grantMask(0) req(0,0,0,0,0,0,0)=0 grant(0,0,0,0,0,0,0)=0
+ wait(0) type(AccessShareLock)
+LOG: CleanUpLock: deleting: lock(0xb7acd844) id(24688,24696,0,0,0,1)
+ grantMask(0) req(0,0,0,0,0,0,0)=0 grant(0,0,0,0,0,0,0)=0
+ wait(0) type(INVALID)
+</screen>
Details of the structure being dumped may be found in
src/include/storage/lock.h
</para>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/cube.sgml,v 1.7 2009/12/08 20:08:30 mha Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/cube.sgml,v 1.8 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="cube">
<title>cube</title>
<para>
The <filename>cube</> module includes a GiST index operator class for
<type>cube</> values.
- The operators supported by the GiST opclass include:
+ The operators supported by the GiST opclass are shown in <xref linkend="cube-gist-operators">.
</para>
- <itemizedlist>
- <listitem>
- <programlisting>
-a = b Same as
- </programlisting>
- <para>
- The cubes a and b are identical.
- </para>
- </listitem>
- <listitem>
- <programlisting>
-a && b Overlaps
- </programlisting>
- <para>
- The cubes a and b overlap.
- </para>
- </listitem>
- <listitem>
- <programlisting>
-a @> b Contains
- </programlisting>
- <para>
- The cube a contains the cube b.
- </para>
- </listitem>
- <listitem>
- <programlisting>
-a <@ b Contained in
- </programlisting>
- <para>
- The cube a is contained in the cube b.
- </para>
- </listitem>
- </itemizedlist>
+ <table id="cube-gist-operators">
+ <title>Cube GiST operators</title>
+ <tgroup cols="2">
+ <thead>
+ <row>
+ <entry>Operator</entry>
+ <entry>Description</entry>
+ </row>
+ </thead>
+
+ <tbody>
+ <row>
+ <entry><literal>a = b</></entry>
+ <entry>The cubes a and b are identical.</entry>
+ </row>
+
+ <row>
+ <entry><literal>a && b</></entry>
+ <entry>The cubes a and b overlap.</entry>
+ </row>
+
+ <row>
+ <entry><literal>a @> b</></entry>
+ <entry>The cube a contains the cube b.</entry>
+ </row>
+
+ <row>
+ <entry><literal>a <@ b</></entry>
+ <entry>The cube a is contained in the cube b.</entry>
+ </row>
+ </tbody>
+ </tgroup>
+ </table>
<para>
- (Before PostgreSQL 8.2, the containment operators @> and <@ were
- respectively called @ and ~. These names are still available, but are
+ (Before PostgreSQL 8.2, the containment operators <literal>@></> and <literal><@</> were
+ respectively called <literal>@</> and <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
datatypes!)
<para>
The standard B-tree operators are also provided, for example
- <programlisting>
-[a, b] < [c, d] Less than
-[a, b] > [c, d] Greater than
- </programlisting>
+ <informaltable>
+ <tgroup cols="2">
+ <thead>
+ <row>
+ <entry>Operator</entry>
+ <entry>Description</entry>
+ </row>
+ </thead>
+
+ <tbody>
+ <row>
+ <entry><literal>[a, b] < [c, d]</literal></entry>
+ <entry>Less than</entry>
+ </row>
+
+ <row>
+ <entry><literal>[a, b] > [c, d]</literal></entry>
+ <entry>Greater than</entry>
+ </row>
+ </tbody>
+ </tgroup>
+ </informaltable>
These operators do not make a lot of sense for any practical
purpose but sorting. These operators first compare (a) to (c),
-<!-- $PostgreSQL: pgsql/doc/src/sgml/datatype.sgml,v 1.254 2010/07/27 19:01:16 petere Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/datatype.sgml,v 1.255 2010/07/29 19:34:40 petere Exp $ -->
<chapter id="datatype">
<title>Data Types</title>
<para>
The <type>interval</type> type has an additional option, which is
to restrict the set of stored fields by writing one of these phrases:
-<programlisting>
- YEAR
- MONTH
- DAY
- HOUR
- MINUTE
- SECOND
- YEAR TO MONTH
- DAY TO HOUR
- DAY TO MINUTE
- DAY TO SECOND
- HOUR TO MINUTE
- HOUR TO SECOND
- MINUTE TO SECOND
-</programlisting>
+<literallayout class="monospaced">
+YEAR
+MONTH
+DAY
+HOUR
+MINUTE
+SECOND
+YEAR TO MONTH
+DAY TO HOUR
+DAY TO MINUTE
+DAY TO SECOND
+HOUR TO MINUTE
+HOUR TO SECOND
+MINUTE TO SECOND
+</literallayout>
Note that if both <replaceable>fields</replaceable> and
<replaceable>p</replaceable> are specified, the
<replaceable>fields</replaceable> must include <literal>SECOND</>,
of the operators:
<programlisting>
- SELECT 'fat & rat'::tsquery;
+SELECT 'fat & rat'::tsquery;
tsquery
---------------
'fat' & 'rat'
-<!-- $PostgreSQL: pgsql/doc/src/sgml/dblink.sgml,v 1.13 2010/06/15 20:29:01 tgl Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/dblink.sgml,v 1.14 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="dblink">
<title>dblink</title>
</refnamediv>
<refsynopsisdiv>
- <synopsis>
- dblink_connect(text connstr) returns text
- dblink_connect(text connname, text connstr) returns text
- </synopsis>
+<synopsis>
+dblink_connect(text connstr) returns text
+dblink_connect(text connname, text connstr) returns text
+</synopsis>
</refsynopsisdiv>
<refsect1>
<refsect1>
<title>Example</title>
- <programlisting>
- select dblink_connect('dbname=postgres');
- dblink_connect
- ----------------
- OK
- (1 row)
-
- select dblink_connect('myconn', 'dbname=postgres');
- dblink_connect
- ----------------
- OK
- (1 row)
-
- -- FOREIGN DATA WRAPPER functionality
- -- Note: local connection must require password authentication for this to work properly
- -- Otherwise, you will receive the following error from dblink_connect():
- -- ----------------------------------------------------------------------
- -- ERROR: password is required
- -- DETAIL: Non-superuser cannot connect if the server does not request a password.
- -- HINT: Target server's authentication method must be changed.
- CREATE USER dblink_regression_test WITH PASSWORD 'secret';
- CREATE FOREIGN DATA WRAPPER postgresql VALIDATOR postgresql_fdw_validator;
- CREATE SERVER fdtest FOREIGN DATA WRAPPER postgresql OPTIONS (hostaddr '127.0.0.1', dbname 'contrib_regression');
-
- CREATE USER MAPPING FOR dblink_regression_test SERVER fdtest OPTIONS (user 'dblink_regression_test', password 'secret');
- GRANT USAGE ON FOREIGN SERVER fdtest TO dblink_regression_test;
- GRANT SELECT ON TABLE foo TO dblink_regression_test;
-
- \set ORIGINAL_USER :USER
- \c - dblink_regression_test
- SELECT dblink_connect('myconn', 'fdtest');
- dblink_connect
- ----------------
- OK
- (1 row)
-
- SELECT * FROM dblink('myconn','SELECT * FROM foo') AS t(a int, b text, c text[]);
- a | b | c
- ----+---+---------------
- 0 | a | {a0,b0,c0}
- 1 | b | {a1,b1,c1}
- 2 | c | {a2,b2,c2}
- 3 | d | {a3,b3,c3}
- 4 | e | {a4,b4,c4}
- 5 | f | {a5,b5,c5}
- 6 | g | {a6,b6,c6}
- 7 | h | {a7,b7,c7}
- 8 | i | {a8,b8,c8}
- 9 | j | {a9,b9,c9}
- 10 | k | {a10,b10,c10}
- (11 rows)
-
- \c - :ORIGINAL_USER
- REVOKE USAGE ON FOREIGN SERVER fdtest FROM dblink_regression_test;
- REVOKE SELECT ON TABLE foo FROM dblink_regression_test;
- DROP USER MAPPING FOR dblink_regression_test SERVER fdtest;
- DROP USER dblink_regression_test;
- DROP SERVER fdtest;
- DROP FOREIGN DATA WRAPPER postgresql;
- </programlisting>
+<screen>
+SELECT dblink_connect('dbname=postgres');
+ dblink_connect
+----------------
+ OK
+(1 row)
+
+SELECT dblink_connect('myconn', 'dbname=postgres');
+ dblink_connect
+----------------
+ OK
+(1 row)
+
+-- FOREIGN DATA WRAPPER functionality
+-- Note: local connection must require password authentication for this to work properly
+-- Otherwise, you will receive the following error from dblink_connect():
+-- ----------------------------------------------------------------------
+-- ERROR: password is required
+-- DETAIL: Non-superuser cannot connect if the server does not request a password.
+-- HINT: Target server's authentication method must be changed.
+CREATE USER dblink_regression_test WITH PASSWORD 'secret';
+CREATE FOREIGN DATA WRAPPER postgresql VALIDATOR postgresql_fdw_validator;
+CREATE SERVER fdtest FOREIGN DATA WRAPPER postgresql OPTIONS (hostaddr '127.0.0.1', dbname 'contrib_regression');
+
+CREATE USER MAPPING FOR dblink_regression_test SERVER fdtest OPTIONS (user 'dblink_regression_test', password 'secret');
+GRANT USAGE ON FOREIGN SERVER fdtest TO dblink_regression_test;
+GRANT SELECT ON TABLE foo TO dblink_regression_test;
+
+\set ORIGINAL_USER :USER
+\c - dblink_regression_test
+SELECT dblink_connect('myconn', 'fdtest');
+ dblink_connect
+----------------
+ OK
+(1 row)
+
+SELECT * FROM dblink('myconn','SELECT * FROM foo') AS t(a int, b text, c text[]);
+ a | b | c
+----+---+---------------
+ 0 | a | {a0,b0,c0}
+ 1 | b | {a1,b1,c1}
+ 2 | c | {a2,b2,c2}
+ 3 | d | {a3,b3,c3}
+ 4 | e | {a4,b4,c4}
+ 5 | f | {a5,b5,c5}
+ 6 | g | {a6,b6,c6}
+ 7 | h | {a7,b7,c7}
+ 8 | i | {a8,b8,c8}
+ 9 | j | {a9,b9,c9}
+ 10 | k | {a10,b10,c10}
+(11 rows)
+
+\c - :ORIGINAL_USER
+REVOKE USAGE ON FOREIGN SERVER fdtest FROM dblink_regression_test;
+REVOKE SELECT ON TABLE foo FROM dblink_regression_test;
+DROP USER MAPPING FOR dblink_regression_test SERVER fdtest;
+DROP USER dblink_regression_test;
+DROP SERVER fdtest;
+DROP FOREIGN DATA WRAPPER postgresql;
+</screen>
</refsect1>
</refentry>
</refnamediv>
<refsynopsisdiv>
- <synopsis>
- dblink_connect_u(text connstr) returns text
- dblink_connect_u(text connname, text connstr) returns text
- </synopsis>
+<synopsis>
+dblink_connect_u(text connstr) returns text
+dblink_connect_u(text connname, text connstr) returns text
+</synopsis>
</refsynopsisdiv>
<refsect1>
</refnamediv>
<refsynopsisdiv>
- <synopsis>
- dblink_disconnect() returns text
- dblink_disconnect(text connname) returns text
- </synopsis>
+<synopsis>
+dblink_disconnect() returns text
+dblink_disconnect(text connname) returns text
+</synopsis>
</refsynopsisdiv>
<refsect1>
<refsect1>
<title>Example</title>
- <programlisting>
- test=# select dblink_disconnect();
- dblink_disconnect
- -------------------
- OK
- (1 row)
+<screen>
+SELECT dblink_disconnect();
+ dblink_disconnect
+-------------------
+ OK
+(1 row)
- select dblink_disconnect('myconn');
- dblink_disconnect
- -------------------
- OK
- (1 row)
- </programlisting>
+SELECT dblink_disconnect('myconn');
+ dblink_disconnect
+-------------------
+ OK
+(1 row)
+</screen>
</refsect1>
</refentry>
</refnamediv>
<refsynopsisdiv>
- <synopsis>
- dblink(text connname, text sql [, bool fail_on_error]) returns setof record
- dblink(text connstr, text sql [, bool fail_on_error]) returns setof record
- dblink(text sql [, bool fail_on_error]) returns setof record
- </synopsis>
+<synopsis>
+dblink(text connname, text sql [, bool fail_on_error]) returns setof record
+dblink(text connstr, text sql [, bool fail_on_error]) returns setof record
+dblink(text sql [, bool fail_on_error]) returns setof record
+</synopsis>
</refsynopsisdiv>
<refsect1>
This allows the column type information to be buried in the view,
instead of having to spell it out in every query. For example,
- <programlisting>
- create view myremote_pg_proc as
- select *
- from dblink('dbname=postgres', 'select proname, prosrc from pg_proc')
- as t1(proname name, prosrc text);
+<programlisting>
+CREATE VIEW myremote_pg_proc AS
+ SELECT *
+ FROM dblink('dbname=postgres', 'select proname, prosrc from pg_proc')
+ AS t1(proname name, prosrc text);
- select * from myremote_pg_proc where proname like 'bytea%';
- </programlisting>
+SELECT * FROM myremote_pg_proc WHERE proname LIKE 'bytea%';
+</programlisting>
</para>
</refsect1>
<refsect1>
<title>Example</title>
- <programlisting>
- select * from dblink('dbname=postgres', 'select proname, prosrc from pg_proc')
- as t1(proname name, prosrc text) where proname like 'bytea%';
- proname | prosrc
- ------------+------------
- byteacat | byteacat
- byteaeq | byteaeq
- bytealt | bytealt
- byteale | byteale
- byteagt | byteagt
- byteage | byteage
- byteane | byteane
- byteacmp | byteacmp
- bytealike | bytealike
- byteanlike | byteanlike
- byteain | byteain
- byteaout | byteaout
- (12 rows)
-
- select dblink_connect('dbname=postgres');
- dblink_connect
- ----------------
- OK
- (1 row)
-
- select * from dblink('select proname, prosrc from pg_proc')
- as t1(proname name, prosrc text) where proname like 'bytea%';
- proname | prosrc
- ------------+------------
- byteacat | byteacat
- byteaeq | byteaeq
- bytealt | bytealt
- byteale | byteale
- byteagt | byteagt
- byteage | byteage
- byteane | byteane
- byteacmp | byteacmp
- bytealike | bytealike
- byteanlike | byteanlike
- byteain | byteain
- byteaout | byteaout
- (12 rows)
-
- select dblink_connect('myconn', 'dbname=regression');
- dblink_connect
- ----------------
- OK
- (1 row)
-
- select * from dblink('myconn', 'select proname, prosrc from pg_proc')
- as t1(proname name, prosrc text) where proname like 'bytea%';
- proname | prosrc
- ------------+------------
- bytearecv | bytearecv
- byteasend | byteasend
- byteale | byteale
- byteagt | byteagt
- byteage | byteage
- byteane | byteane
- byteacmp | byteacmp
- bytealike | bytealike
- byteanlike | byteanlike
- byteacat | byteacat
- byteaeq | byteaeq
- bytealt | bytealt
- byteain | byteain
- byteaout | byteaout
- (14 rows)
- </programlisting>
+<screen>
+SELECT * FROM dblink('dbname=postgres', 'select proname, prosrc from pg_proc')
+ AS t1(proname name, prosrc text) WHERE proname LIKE 'bytea%';
+ proname | prosrc
+------------+------------
+ byteacat | byteacat
+ byteaeq | byteaeq
+ bytealt | bytealt
+ byteale | byteale
+ byteagt | byteagt
+ byteage | byteage
+ byteane | byteane
+ byteacmp | byteacmp
+ bytealike | bytealike
+ byteanlike | byteanlike
+ byteain | byteain
+ byteaout | byteaout
+(12 rows)
+
+SELECT dblink_connect('dbname=postgres');
+ dblink_connect
+----------------
+ OK
+(1 row)
+
+SELECT * FROM dblink('select proname, prosrc from pg_proc')
+ AS t1(proname name, prosrc text) WHERE proname LIKE 'bytea%';
+ proname | prosrc
+------------+------------
+ byteacat | byteacat
+ byteaeq | byteaeq
+ bytealt | bytealt
+ byteale | byteale
+ byteagt | byteagt
+ byteage | byteage
+ byteane | byteane
+ byteacmp | byteacmp
+ bytealike | bytealike
+ byteanlike | byteanlike
+ byteain | byteain
+ byteaout | byteaout
+(12 rows)
+
+SELECT dblink_connect('myconn', 'dbname=regression');
+ dblink_connect
+----------------
+ OK
+(1 row)
+
+SELECT * FROM dblink('myconn', 'select proname, prosrc from pg_proc')
+ AS t1(proname name, prosrc text) WHERE proname LIKE 'bytea%';
+ proname | prosrc
+------------+------------
+ bytearecv | bytearecv
+ byteasend | byteasend
+ byteale | byteale
+ byteagt | byteagt
+ byteage | byteage
+ byteane | byteane
+ byteacmp | byteacmp
+ bytealike | bytealike
+ byteanlike | byteanlike
+ byteacat | byteacat
+ byteaeq | byteaeq
+ bytealt | bytealt
+ byteain | byteain
+ byteaout | byteaout
+(14 rows)
+</screen>
</refsect1>
</refentry>
</refnamediv>
<refsynopsisdiv>
- <synopsis>
- dblink_exec(text connname, text sql [, bool fail_on_error]) returns text
- dblink_exec(text connstr, text sql [, bool fail_on_error]) returns text
- dblink_exec(text sql [, bool fail_on_error]) returns text
- </synopsis>
+<synopsis>
+dblink_exec(text connname, text sql [, bool fail_on_error]) returns text
+dblink_exec(text connstr, text sql [, bool fail_on_error]) returns text
+dblink_exec(text sql [, bool fail_on_error]) returns text
+</synopsis>
</refsynopsisdiv>
<refsect1>
<refsect1>
<title>Example</title>
- <programlisting>
- select dblink_connect('dbname=dblink_test_standby');
- dblink_connect
- ----------------
- OK
- (1 row)
-
- select dblink_exec('insert into foo values(21,''z'',''{"a0","b0","c0"}'');');
- dblink_exec
- -----------------
- INSERT 943366 1
- (1 row)
-
- select dblink_connect('myconn', 'dbname=regression');
- dblink_connect
- ----------------
- OK
- (1 row)
-
- select dblink_exec('myconn', 'insert into foo values(21,''z'',''{"a0","b0","c0"}'');');
- dblink_exec
- ------------------
- INSERT 6432584 1
- (1 row)
-
- select dblink_exec('myconn', 'insert into pg_class values (''foo'')',false);
- NOTICE: sql error
- DETAIL: ERROR: null value in column "relnamespace" violates not-null constraint
-
- dblink_exec
- -------------
- ERROR
- (1 row)
- </programlisting>
+<screen>
+SELECT dblink_connect('dbname=dblink_test_standby');
+ dblink_connect
+----------------
+ OK
+(1 row)
+
+SELECT dblink_exec('insert into foo values(21,''z'',''{"a0","b0","c0"}'');');
+ dblink_exec
+-----------------
+ INSERT 943366 1
+(1 row)
+
+SELECT dblink_connect('myconn', 'dbname=regression');
+ dblink_connect
+----------------
+ OK
+(1 row)
+
+SELECT dblink_exec('myconn', 'insert into foo values(21,''z'',''{"a0","b0","c0"}'');');
+ dblink_exec
+------------------
+ INSERT 6432584 1
+(1 row)
+
+SELECT dblink_exec('myconn', 'insert into pg_class values (''foo'')',false);
+NOTICE: sql error
+DETAIL: ERROR: null value in column "relnamespace" violates not-null constraint
+
+ dblink_exec
+-------------
+ ERROR
+(1 row)
+</screen>
</refsect1>
</refentry>
</refnamediv>
<refsynopsisdiv>
- <synopsis>
- dblink_open(text cursorname, text sql [, bool fail_on_error]) returns text
- dblink_open(text connname, text cursorname, text sql [, bool fail_on_error]) returns text
- </synopsis>
+<synopsis>
+dblink_open(text cursorname, text sql [, bool fail_on_error]) returns text
+dblink_open(text connname, text cursorname, text sql [, bool fail_on_error]) returns text
+</synopsis>
</refsynopsisdiv>
<refsect1>
<refsect1>
<title>Example</title>
- <programlisting>
- test=# select dblink_connect('dbname=postgres');
- dblink_connect
- ----------------
- OK
- (1 row)
+<screen>
+SELECT dblink_connect('dbname=postgres');
+ dblink_connect
+----------------
+ OK
+(1 row)
- test=# select dblink_open('foo', 'select proname, prosrc from pg_proc');
- dblink_open
- -------------
- OK
- (1 row)
- </programlisting>
+SELECT dblink_open('foo', 'select proname, prosrc from pg_proc');
+ dblink_open
+-------------
+ OK
+(1 row)
+</screen>
</refsect1>
</refentry>
</refnamediv>
<refsynopsisdiv>
- <synopsis>
- dblink_fetch(text cursorname, int howmany [, bool fail_on_error]) returns setof record
- dblink_fetch(text connname, text cursorname, int howmany [, bool fail_on_error]) returns setof record
- </synopsis>
+<synopsis>
+dblink_fetch(text cursorname, int howmany [, bool fail_on_error]) returns setof record
+dblink_fetch(text connname, text cursorname, int howmany [, bool fail_on_error]) returns setof record
+</synopsis>
</refsynopsisdiv>
<refsect1>
<refsect1>
<title>Example</title>
- <programlisting>
- test=# select dblink_connect('dbname=postgres');
- dblink_connect
- ----------------
- OK
- (1 row)
-
- test=# select dblink_open('foo', 'select proname, prosrc from pg_proc where proname like ''bytea%''');
- dblink_open
- -------------
- OK
- (1 row)
-
- test=# select * from dblink_fetch('foo', 5) as (funcname name, source text);
- funcname | source
- ----------+----------
- byteacat | byteacat
- byteacmp | byteacmp
- byteaeq | byteaeq
- byteage | byteage
- byteagt | byteagt
- (5 rows)
-
- test=# select * from dblink_fetch('foo', 5) as (funcname name, source text);
- funcname | source
- -----------+-----------
- byteain | byteain
- byteale | byteale
- bytealike | bytealike
- bytealt | bytealt
- byteane | byteane
- (5 rows)
-
- test=# select * from dblink_fetch('foo', 5) as (funcname name, source text);
- funcname | source
- ------------+------------
- byteanlike | byteanlike
- byteaout | byteaout
- (2 rows)
-
- test=# select * from dblink_fetch('foo', 5) as (funcname name, source text);
- funcname | source
- ----------+--------
- (0 rows)
- </programlisting>
+<screen>
+SELECT dblink_connect('dbname=postgres');
+ dblink_connect
+----------------
+ OK
+(1 row)
+
+SELECT dblink_open('foo', 'select proname, prosrc from pg_proc where proname like ''bytea%''');
+ dblink_open
+-------------
+ OK
+(1 row)
+
+SELECT * FROM dblink_fetch('foo', 5) AS (funcname name, source text);
+ funcname | source
+----------+----------
+ byteacat | byteacat
+ byteacmp | byteacmp
+ byteaeq | byteaeq
+ byteage | byteage
+ byteagt | byteagt
+(5 rows)
+
+SELECT * FROM dblink_fetch('foo', 5) AS (funcname name, source text);
+ funcname | source
+-----------+-----------
+ byteain | byteain
+ byteale | byteale
+ bytealike | bytealike
+ bytealt | bytealt
+ byteane | byteane
+(5 rows)
+
+SELECT * FROM dblink_fetch('foo', 5) AS (funcname name, source text);
+ funcname | source
+------------+------------
+ byteanlike | byteanlike
+ byteaout | byteaout
+(2 rows)
+
+SELECT * FROM dblink_fetch('foo', 5) AS (funcname name, source text);
+ funcname | source
+----------+--------
+(0 rows)
+</screen>
</refsect1>
</refentry>
</refnamediv>
<refsynopsisdiv>
- <synopsis>
- dblink_close(text cursorname [, bool fail_on_error]) returns text
- dblink_close(text connname, text cursorname [, bool fail_on_error]) returns text
- </synopsis>
+<synopsis>
+dblink_close(text cursorname [, bool fail_on_error]) returns text
+dblink_close(text connname, text cursorname [, bool fail_on_error]) returns text
+</synopsis>
</refsynopsisdiv>
<refsect1>
<refsect1>
<title>Example</title>
- <programlisting>
- test=# select dblink_connect('dbname=postgres');
- dblink_connect
- ----------------
- OK
- (1 row)
-
- test=# select dblink_open('foo', 'select proname, prosrc from pg_proc');
- dblink_open
- -------------
- OK
- (1 row)
-
- test=# select dblink_close('foo');
- dblink_close
- --------------
- OK
- (1 row)
- </programlisting>
+<screen>
+SELECT dblink_connect('dbname=postgres');
+ dblink_connect
+----------------
+ OK
+(1 row)
+
+SELECT dblink_open('foo', 'select proname, prosrc from pg_proc');
+ dblink_open
+-------------
+ OK
+(1 row)
+
+SELECT dblink_close('foo');
+ dblink_close
+--------------
+ OK
+(1 row)
+</screen>
</refsect1>
</refentry>
</refnamediv>
<refsynopsisdiv>
- <synopsis>
- dblink_get_connections() returns text[]
- </synopsis>
+<synopsis>
+dblink_get_connections() returns text[]
+</synopsis>
</refsynopsisdiv>
<refsect1>
<refsect1>
<title>Example</title>
- <programlisting>
- SELECT dblink_get_connections();
- </programlisting>
+<programlisting>
+SELECT dblink_get_connections();
+</programlisting>
</refsect1>
</refentry>
</refnamediv>
<refsynopsisdiv>
- <synopsis>
- dblink_error_message(text connname) returns text
- </synopsis>
+<synopsis>
+dblink_error_message(text connname) returns text
+</synopsis>
</refsynopsisdiv>
<refsect1>
<refsect1>
<title>Example</title>
- <programlisting>
- SELECT dblink_error_message('dtest1');
- </programlisting>
+<programlisting>
+SELECT dblink_error_message('dtest1');
+</programlisting>
</refsect1>
</refentry>
</refnamediv>
<refsynopsisdiv>
- <synopsis>
- dblink_send_query(text connname, text sql) returns int
- </synopsis>
+<synopsis>
+dblink_send_query(text connname, text sql) returns int
+</synopsis>
</refsynopsisdiv>
<refsect1>
<refsect1>
<title>Example</title>
- <programlisting>
- SELECT dblink_send_query('dtest1', 'SELECT * FROM foo WHERE f1 < 3');
- </programlisting>
+<programlisting>
+SELECT dblink_send_query('dtest1', 'SELECT * FROM foo WHERE f1 < 3');
+</programlisting>
</refsect1>
</refentry>
</refnamediv>
<refsynopsisdiv>
- <synopsis>
- dblink_is_busy(text connname) returns int
- </synopsis>
+<synopsis>
+dblink_is_busy(text connname) returns int
+</synopsis>
</refsynopsisdiv>
<refsect1>
<refsect1>
<title>Example</title>
- <programlisting>
- SELECT dblink_is_busy('dtest1');
- </programlisting>
+<programlisting>
+SELECT dblink_is_busy('dtest1');
+</programlisting>
</refsect1>
</refentry>
</refnamediv>
<refsynopsisdiv>
- <synopsis>
- dblink_get_notify() returns setof (notify_name text, be_pid int, extra text)
- dblink_get_notify(text connname) returns setof (notify_name text, be_pid int, extra text)
- </synopsis>
+<synopsis>
+dblink_get_notify() returns setof (notify_name text, be_pid int, extra text)
+dblink_get_notify(text connname) returns setof (notify_name text, be_pid int, extra text)
+</synopsis>
</refsynopsisdiv>
<refsect1>
<refsect1>
<title>Example</title>
- <programlisting>
-test=# SELECT dblink_exec('LISTEN virtual');
+<screen>
+SELECT dblink_exec('LISTEN virtual');
dblink_exec
-------------
LISTEN
(1 row)
-test=# SELECT * FROM dblink_get_notify();
+SELECT * FROM dblink_get_notify();
notify_name | be_pid | extra
-------------+--------+-------
(0 rows)
-test=# NOTIFY virtual;
+NOTIFY virtual;
NOTIFY
SELECT * FROM dblink_get_notify();
-------------+--------+-------
virtual | 1229 |
(1 row)
- </programlisting>
+</screen>
</refsect1>
</refentry>
</refnamediv>
<refsynopsisdiv>
- <synopsis>
- dblink_get_result(text connname [, bool fail_on_error]) returns setof record
- </synopsis>
+<synopsis>
+dblink_get_result(text connname [, bool fail_on_error]) returns setof record
+</synopsis>
</refsynopsisdiv>
<refsect1>
<refsect1>
<title>Example</title>
- <programlisting>
- contrib_regression=# SELECT dblink_connect('dtest1', 'dbname=contrib_regression');
- dblink_connect
- ----------------
- OK
- (1 row)
-
- contrib_regression=# SELECT * from
- contrib_regression-# dblink_send_query('dtest1', 'select * from foo where f1 < 3') as t1;
- t1
- ----
- 1
- (1 row)
-
- contrib_regression=# SELECT * from dblink_get_result('dtest1') as t1(f1 int, f2 text, f3 text[]);
- f1 | f2 | f3
- ----+----+------------
- 0 | a | {a0,b0,c0}
- 1 | b | {a1,b1,c1}
- 2 | c | {a2,b2,c2}
- (3 rows)
-
- contrib_regression=# SELECT * from dblink_get_result('dtest1') as t1(f1 int, f2 text, f3 text[]);
- f1 | f2 | f3
- ----+----+----
- (0 rows)
-
- contrib_regression=# SELECT * from
- dblink_send_query('dtest1', 'select * from foo where f1 < 3; select * from foo where f1 > 6') as t1;
- t1
- ----
- 1
- (1 row)
-
- contrib_regression=# SELECT * from dblink_get_result('dtest1') as t1(f1 int, f2 text, f3 text[]);
- f1 | f2 | f3
- ----+----+------------
- 0 | a | {a0,b0,c0}
- 1 | b | {a1,b1,c1}
- 2 | c | {a2,b2,c2}
- (3 rows)
-
- contrib_regression=# SELECT * from dblink_get_result('dtest1') as t1(f1 int, f2 text, f3 text[]);
- f1 | f2 | f3
- ----+----+---------------
- 7 | h | {a7,b7,c7}
- 8 | i | {a8,b8,c8}
- 9 | j | {a9,b9,c9}
- 10 | k | {a10,b10,c10}
- (4 rows)
-
- contrib_regression=# SELECT * from dblink_get_result('dtest1') as t1(f1 int, f2 text, f3 text[]);
- f1 | f2 | f3
- ----+----+----
- (0 rows)
- </programlisting>
+<screen>
+contrib_regression=# SELECT dblink_connect('dtest1', 'dbname=contrib_regression');
+ dblink_connect
+----------------
+ OK
+(1 row)
+
+contrib_regression=# SELECT * FROM
+contrib_regression-# dblink_send_query('dtest1', 'select * from foo where f1 < 3') AS t1;
+ t1
+----
+ 1
+(1 row)
+
+contrib_regression=# SELECT * FROM dblink_get_result('dtest1') AS t1(f1 int, f2 text, f3 text[]);
+ f1 | f2 | f3
+----+----+------------
+ 0 | a | {a0,b0,c0}
+ 1 | b | {a1,b1,c1}
+ 2 | c | {a2,b2,c2}
+(3 rows)
+
+contrib_regression=# SELECT * FROM dblink_get_result('dtest1') AS t1(f1 int, f2 text, f3 text[]);
+ f1 | f2 | f3
+----+----+----
+(0 rows)
+
+contrib_regression=# SELECT * FROM
+contrib_regression-# dblink_send_query('dtest1', 'select * from foo where f1 < 3; select * from foo where f1 > 6') AS t1;
+ t1
+----
+ 1
+(1 row)
+
+contrib_regression=# SELECT * FROM dblink_get_result('dtest1') AS t1(f1 int, f2 text, f3 text[]);
+ f1 | f2 | f3
+----+----+------------
+ 0 | a | {a0,b0,c0}
+ 1 | b | {a1,b1,c1}
+ 2 | c | {a2,b2,c2}
+(3 rows)
+
+contrib_regression=# SELECT * FROM dblink_get_result('dtest1') AS t1(f1 int, f2 text, f3 text[]);
+ f1 | f2 | f3
+----+----+---------------
+ 7 | h | {a7,b7,c7}
+ 8 | i | {a8,b8,c8}
+ 9 | j | {a9,b9,c9}
+ 10 | k | {a10,b10,c10}
+(4 rows)
+
+contrib_regression=# SELECT * FROM dblink_get_result('dtest1') AS t1(f1 int, f2 text, f3 text[]);
+ f1 | f2 | f3
+----+----+----
+(0 rows)
+</screen>
</refsect1>
</refentry>
</refnamediv>
<refsynopsisdiv>
- <synopsis>
- dblink_cancel_query(text connname) returns text
- </synopsis>
+<synopsis>
+dblink_cancel_query(text connname) returns text
+</synopsis>
</refsynopsisdiv>
<refsect1>
<refsect1>
<title>Example</title>
- <programlisting>
- SELECT dblink_cancel_query('dtest1');
- </programlisting>
+<programlisting>
+SELECT dblink_cancel_query('dtest1');
+</programlisting>
</refsect1>
</refentry>
</refnamediv>
<refsynopsisdiv>
- <synopsis>
- dblink_get_pkey(text relname) returns setof dblink_pkey_results
- </synopsis>
+<synopsis>
+dblink_get_pkey(text relname) returns setof dblink_pkey_results
+</synopsis>
</refsynopsisdiv>
<refsect1>
Returns one row for each primary key field, or no rows if the relation
has no primary key. The result rowtype is defined as
- <programlisting>
+<programlisting>
CREATE TYPE dblink_pkey_results AS (position int, colname text);
- </programlisting>
+</programlisting>
The <literal>position</> column simply runs from 1 to <replaceable>N</>;
it is the number of the field within the primary key, not the number
<refsect1>
<title>Example</title>
- <programlisting>
-test=# create table foobar(f1 int, f2 int, f3 int,
-test(# primary key(f1,f2,f3));
+<screen>
+CREATE TABLE foobar (
+ f1 int,
+ f2 int,
+ f3 int,
+ PRIMARY KEY (f1, f2, f3)
+);
CREATE TABLE
-test=# select * from dblink_get_pkey('foobar');
+
+SELECT * FROM dblink_get_pkey('foobar');
position | colname
----------+---------
1 | f1
2 | f2
3 | f3
(3 rows)
- </programlisting>
+</screen>
</refsect1>
</refentry>
</refnamediv>
<refsynopsisdiv>
- <synopsis>
- dblink_build_sql_insert(text relname,
- int2vector primary_key_attnums,
- integer num_primary_key_atts,
- text[] src_pk_att_vals_array,
- text[] tgt_pk_att_vals_array) returns text
- </synopsis>
+<synopsis>
+dblink_build_sql_insert(text relname,
+ int2vector primary_key_attnums,
+ integer num_primary_key_atts,
+ text[] src_pk_att_vals_array,
+ text[] tgt_pk_att_vals_array) returns text
+</synopsis>
</refsynopsisdiv>
<refsect1>
<refsect1>
<title>Example</title>
- <programlisting>
- test=# select dblink_build_sql_insert('foo', '1 2', 2, '{"1", "a"}', '{"1", "b''a"}');
- dblink_build_sql_insert
- --------------------------------------------------
- INSERT INTO foo(f1,f2,f3) VALUES('1','b''a','1')
- (1 row)
- </programlisting>
+<screen>
+SELECT dblink_build_sql_insert('foo', '1 2', 2, '{"1", "a"}', '{"1", "b''a"}');
+ dblink_build_sql_insert
+--------------------------------------------------
+ INSERT INTO foo(f1,f2,f3) VALUES('1','b''a','1')
+(1 row)
+</screen>
</refsect1>
</refentry>
</refnamediv>
<refsynopsisdiv>
- <synopsis>
- dblink_build_sql_delete(text relname,
- int2vector primary_key_attnums,
- integer num_primary_key_atts,
- text[] tgt_pk_att_vals_array) returns text
- </synopsis>
+<synopsis>
+dblink_build_sql_delete(text relname,
+ int2vector primary_key_attnums,
+ integer num_primary_key_atts,
+ text[] tgt_pk_att_vals_array) returns text
+</synopsis>
</refsynopsisdiv>
<refsect1>
<refsect1>
<title>Example</title>
- <programlisting>
- test=# select dblink_build_sql_delete('"MyFoo"', '1 2', 2, '{"1", "b"}');
- dblink_build_sql_delete
- ---------------------------------------------
- DELETE FROM "MyFoo" WHERE f1='1' AND f2='b'
- (1 row)
- </programlisting>
+<screen>
+SELECT dblink_build_sql_delete('"MyFoo"', '1 2', 2, '{"1", "b"}');
+ dblink_build_sql_delete
+---------------------------------------------
+ DELETE FROM "MyFoo" WHERE f1='1' AND f2='b'
+(1 row)
+</screen>
</refsect1>
</refentry>
</refnamediv>
<refsynopsisdiv>
- <synopsis>
- dblink_build_sql_update(text relname,
- int2vector primary_key_attnums,
- integer num_primary_key_atts,
- text[] src_pk_att_vals_array,
- text[] tgt_pk_att_vals_array) returns text
- </synopsis>
+<synopsis>
+dblink_build_sql_update(text relname,
+ int2vector primary_key_attnums,
+ integer num_primary_key_atts,
+ text[] src_pk_att_vals_array,
+ text[] tgt_pk_att_vals_array) returns text
+</synopsis>
</refsynopsisdiv>
<refsect1>
<refsect1>
<title>Example</title>
- <programlisting>
- test=# select dblink_build_sql_update('foo', '1 2', 2, '{"1", "a"}', '{"1", "b"}');
- dblink_build_sql_update
- -------------------------------------------------------------
- UPDATE foo SET f1='1',f2='b',f3='1' WHERE f1='1' AND f2='b'
- (1 row)
- </programlisting>
+<screen>
+SELECT dblink_build_sql_update('foo', '1 2', 2, '{"1", "a"}', '{"1", "b"}');
+ dblink_build_sql_update
+-------------------------------------------------------------
+ UPDATE foo SET f1='1',f2='b',f3='1' WHERE f1='1' AND f2='b'
+(1 row)
+</screen>
</refsect1>
</refentry>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/ddl.sgml,v 1.93 2010/04/06 02:18:04 momjian Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/ddl.sgml,v 1.94 2010/07/29 19:34:40 petere Exp $ -->
<chapter id="ddl">
<title>Data Definition</title>
just creating the partition tables as above, the table creation
script should really be:
- <programlisting>
+<programlisting>
CREATE TABLE measurement_y2006m02 (
CHECK ( logdate >= DATE '2006-02-01' AND logdate < DATE '2006-03-01' )
) INHERITS (measurement);
<para>
We probably need indexes on the key columns too:
- <programlisting>
+<programlisting>
CREATE INDEX measurement_y2006m02_logdate ON measurement_y2006m02 (logdate);
CREATE INDEX measurement_y2006m03_logdate ON measurement_y2006m03 (logdate);
...
-<!-- $PostgreSQL: pgsql/doc/src/sgml/dict-xsyn.sgml,v 1.3 2009/08/05 18:06:49 tgl Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/dict-xsyn.sgml,v 1.4 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="dict-xsyn">
<title>dict_xsyn</title>
<para>
Each line represents a group of synonyms for a single word, which is
given first on the line. Synonyms are separated by whitespace, thus:
- <programlisting>
+<programlisting>
word syn1 syn2 syn3
- </programlisting>
+</programlisting>
</para>
</listitem>
<listitem>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/ecpg.sgml,v 1.100 2010/05/13 14:16:41 mha Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/ecpg.sgml,v 1.101 2010/07/29 19:34:40 petere Exp $ -->
<chapter id="ecpg">
<title><application>ECPG</application> - Embedded <acronym>SQL</acronym> in C</title>
the dollar sign instead of the <literal>EXEC SQL</> primitive to introduce
embedded SQL commands.:
<programlisting>
- $int j = 3;
- $CONNECT TO :dbname;
- $CREATE TABLE test(i INT PRIMARY KEY, j INT);
- $INSERT INTO test(i, j) VALUES (7, :j);
- $COMMIT;
+$int j = 3;
+$CONNECT TO :dbname;
+$CREATE TABLE test(i INT PRIMARY KEY, j INT);
+$INSERT INTO test(i, j) VALUES (7, :j);
+$COMMIT;
</programlisting>
</para>
<para>
supported in Informix-mode without using <literal>typedef</literal>. In fact, in Informix-mode,
ECPG refuses to process source files that contain <literal>typedef sometype string;</literal>
<programlisting>
- EXEC SQL BEGIN DECLARE SECTION;
- string userid; /* this variable will contain trimmed data */
- EXEC SQL END DECLARE SECTION;
+EXEC SQL BEGIN DECLARE SECTION;
+string userid; /* this variable will contain trimmed data */
+EXEC SQL END DECLARE SECTION;
- EXEC SQL FETCH MYCUR INTO :userid;
+EXEC SQL FETCH MYCUR INTO :userid;
</programlisting>
</para>
</sect2>
This statement closes the current connection. In fact, this is a
synonym for ecpg's <literal>DISCONNECT CURRENT</>.:
<programlisting>
- $CLOSE DATABASE; /* close the current connection */
- EXEC SQL CLOSE DATABASE;
+$CLOSE DATABASE; /* close the current connection */
+EXEC SQL CLOSE DATABASE;
</programlisting>
</para>
</listitem>
Pointer to the field data. The pointer is of <literal>char *</literal> type,
the data pointed by it is in a binary format. Example:
<programlisting>
- int intval;
+int intval;
- switch (sqldata->sqlvar[i].sqltype)
- {
- case SQLINTEGER:
+switch (sqldata->sqlvar[i].sqltype)
+{
+ case SQLINTEGER:
intval = *(int *)sqldata->sqlvar[i].sqldata;
break;
- ...
- }
+ ...
+}
</programlisting>
</para>
</listitem>
that the value for this field is non-NULL. Otherwise a valid pointer and <literal>sqlitype</literal>
has to be properly set. Example:
<programlisting>
- if (*(int2 *)sqldata->sqlvar[i].sqlind != 0)
- printf("value is NULL\n");
+if (*(int2 *)sqldata->sqlvar[i].sqlind != 0)
+ printf("value is NULL\n");
</programlisting>
</para>
</listitem>
<para>
Example:
<programlisting>
- exec sql ifndef TZVAR;
- exec sql SET TIMEZONE TO 'GMT';
- exec sql elif TZNAME;
- exec sql SET TIMEZONE TO TZNAME;
- exec sql else;
- exec sql SET TIMEZONE TO TZVAR;
- exec sql endif;
+EXEC SQL ifndef TZVAR;
+EXEC SQL SET TIMEZONE TO 'GMT';
+EXEC SQL elif TZNAME;
+EXEC SQL SET TIMEZONE TO TZNAME;
+EXEC SQL else;
+EXEC SQL SET TIMEZONE TO TZVAR;
+EXEC SQL endif;
</programlisting>
</para>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.521 2010/07/03 17:21:48 momjian Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.522 2010/07/29 19:34:40 petere Exp $ -->
<chapter id="functions">
<title>Functions and Operators</title>
<primary>xmlconcat</primary>
</indexterm>
- <synopsis>
- <function>xmlconcat</function>(<replaceable>xml</replaceable><optional>, ...</optional>)
- </synopsis>
+<synopsis>
+<function>xmlconcat</function>(<replaceable>xml</replaceable><optional>, ...</optional>)
+</synopsis>
<para>
The function <function>xmlconcat</function> concatenates a list
</indexterm>
<synopsis>
- <function>xmlelement</function>(name <replaceable>name</replaceable> <optional>, xmlattributes(<replaceable>value</replaceable> <optional>AS <replaceable>attname</replaceable></optional> <optional>, ... </optional>)</optional> <optional><replaceable>, content, ...</replaceable></optional>)
- </synopsis>
+<function>xmlelement</function>(name <replaceable>name</replaceable> <optional>, xmlattributes(<replaceable>value</replaceable> <optional>AS <replaceable>attname</replaceable></optional> <optional>, ... </optional>)</optional> <optional><replaceable>, content, ...</replaceable></optional>)
+</synopsis>
<para>
The <function>xmlelement</function> expression produces an XML
<primary>xmlforest</primary>
</indexterm>
- <synopsis>
- <function>xmlforest</function>(<replaceable>content</replaceable> <optional>AS <replaceable>name</replaceable></optional> <optional>, ...</optional>)
- </synopsis>
+<synopsis>
+<function>xmlforest</function>(<replaceable>content</replaceable> <optional>AS <replaceable>name</replaceable></optional> <optional>, ...</optional>)
+</synopsis>
<para>
The <function>xmlforest</function> expression produces an XML
<primary>xmlpi</primary>
</indexterm>
- <synopsis>
- <function>xmlpi</function>(name <replaceable>target</replaceable> <optional>, <replaceable>content</replaceable></optional>)
- </synopsis>
+<synopsis>
+<function>xmlpi</function>(name <replaceable>target</replaceable> <optional>, <replaceable>content</replaceable></optional>)
+</synopsis>
<para>
The <function>xmlpi</function> expression creates an XML
<primary>xmlroot</primary>
</indexterm>
- <synopsis>
- <function>xmlroot</function>(<replaceable>xml</replaceable>, version <replaceable>text</replaceable> | no value <optional>, standalone yes|no|no value</optional>)
- </synopsis>
+<synopsis>
+<function>xmlroot</function>(<replaceable>xml</replaceable>, version <replaceable>text</replaceable> | no value <optional>, standalone yes|no|no value</optional>)
+</synopsis>
<para>
The <function>xmlroot</function> expression alters the properties
-<!-- $PostgreSQL: pgsql/doc/src/sgml/fuzzystrmatch.sgml,v 1.5 2009/04/06 15:43:00 tgl Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/fuzzystrmatch.sgml,v 1.6 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="fuzzystrmatch">
<title>fuzzystrmatch</title>
for working with Soundex codes:
</para>
- <programlisting>
- soundex(text) returns text
- difference(text, text) returns int
- </programlisting>
+<synopsis>
+soundex(text) returns text
+difference(text, text) returns int
+</synopsis>
<para>
The <function>soundex</> function converts a string to its Soundex code.
Here are some usage examples:
</para>
- <programlisting>
+<programlisting>
SELECT soundex('hello world!');
SELECT soundex('Anne'), soundex('Ann'), difference('Anne', 'Ann');
SELECT * FROM s WHERE soundex(nm) = soundex('john');
SELECT * FROM s WHERE difference(s.nm, 'john') > 2;
- </programlisting>
+</programlisting>
</sect2>
<sect2>
This function calculates the Levenshtein distance between two strings:
</para>
- <programlisting>
- levenshtein(text source, text target, int ins_cost, int del_cost, int sub_cost) returns int
- levenshtein(text source, text target) returns int
- </programlisting>
+<synopsis>
+levenshtein(text source, text target, int ins_cost, int del_cost, int sub_cost) returns int
+levenshtein(text source, text target) returns int
+</synopsis>
<para>
Both <literal>source</literal> and <literal>target</literal> can be any
Examples:
</para>
- <programlisting>
+<screen>
test=# SELECT levenshtein('GUMBO', 'GAMBOL');
levenshtein
-------------
-------------
3
(1 row)
- </programlisting>
+</screen>
</sect2>
<sect2>
This function calculates the metaphone code of an input string:
</para>
- <programlisting>
- metaphone(text source, int max_output_length) returns text
- </programlisting>
+<synopsis>
+metaphone(text source, int max_output_length) returns text
+</synopsis>
<para>
<literal>source</literal> has to be a non-null string with a maximum of
Example:
</para>
- <programlisting>
+<screen>
test=# SELECT metaphone('GUMBO', 4);
metaphone
-----------
KM
(1 row)
- </programlisting>
+</screen>
</sect2>
<sect2>
These functions compute the primary and alternate codes:
</para>
- <programlisting>
- dmetaphone(text source) returns text
- dmetaphone_alt(text source) returns text
- </programlisting>
+<synopsis>
+dmetaphone(text source) returns text
+dmetaphone_alt(text source) returns text
+</synopsis>
<para>
There is no length limit on the input strings.
Example:
</para>
- <programlisting>
+<screen>
test=# select dmetaphone('gumbo');
dmetaphone
------------
KMP
(1 row)
- </programlisting>
+</screen>
</sect2>
</sect1>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/hstore.sgml,v 1.12 2010/07/02 20:36:49 rhaas Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/hstore.sgml,v 1.13 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="hstore">
<title>hstore</title>
includes zero or more <replaceable>key</> <literal>=></>
<replaceable>value</> pairs separated by commas. Some examples:
- <programlisting>
- k => v
- foo => bar, baz => whatever
- "1-a" => "anything at all"
- </programlisting>
+<synopsis>
+k => v
+foo => bar, baz => whatever
+"1-a" => "anything at all"
+</synopsis>
The order of the pairs is not significant (and may not be reproduced on
output). Whitespace between pairs or around the <literal>=></> sign is
with duplicate keys, only one will be stored in the <type>hstore</> and
there is no guarantee as to which will be kept:
- <programlisting>
-% select 'a=>1,a=>2'::hstore;
+<programlisting>
+SELECT 'a=>1,a=>2'::hstore;
hstore
----------
"a"=>"1"
- </programlisting>
+</programlisting>
</para>
<para>
A value (but not a key) can be an SQL <literal>NULL</>. For example:
- <programlisting>
- key => NULL
- </programlisting>
+<programlisting>
+key => NULL
+</programlisting>
The <literal>NULL</> keyword is case-insensitive. Double-quote the
- <literal>NULL</> to treat it as the ordinary string "NULL".
+ <literal>NULL</> to treat it as the ordinary string <quote>NULL</quote>.
</para>
<note>
<type>hstore</> has GiST and GIN index support for the <literal>@></>,
<literal>?</>, <literal>?&</> and <literal>?|</> operators. For example:
</para>
- <programlisting>
+<programlisting>
CREATE INDEX hidx ON testhstore USING GIST (h);
CREATE INDEX hidx ON testhstore USING GIN (h);
- </programlisting>
+</programlisting>
<para>
<type>hstore</> also supports <type>btree</> or <type>hash</> indexes for
may be useful for equivalence lookups. Create indexes for <literal>=</>
comparisons as follows:
</para>
- <programlisting>
+<programlisting>
CREATE INDEX hidx ON testhstore USING BTREE (h);
CREATE INDEX hidx ON testhstore USING HASH (h);
- </programlisting>
+</programlisting>
</sect2>
<sect2>
<para>
Add a key, or update an existing key with a new value:
- </para>
- <programlisting>
+<programlisting>
UPDATE tab SET h = h || ('c' => '3');
- </programlisting>
+</programlisting>
+ </para>
<para>
Delete a key:
- </para>
- <programlisting>
+<programlisting>
UPDATE tab SET h = delete(h, 'k1');
- </programlisting>
+</programlisting>
+ </para>
<para>
Convert a <type>record</> to an <type>hstore</>:
- </para>
- <programlisting>
+<programlisting>
CREATE TABLE test (col1 integer, col2 text, col3 text);
INSERT INTO test VALUES (123, 'foo', 'bar');
---------------------------------------------
"col1"=>"123", "col2"=>"foo", "col3"=>"bar"
(1 row)
- </programlisting>
+</programlisting>
+ </para>
<para>
Convert an <type>hstore</> to a predefined <type>record</> type:
- </para>
- <programlisting>
+<programlisting>
CREATE TABLE test (col1 integer, col2 text, col3 text);
SELECT * FROM populate_record(null::test,
------+------+------
456 | zzz |
(1 row)
- </programlisting>
+</programlisting>
+ </para>
<para>
Modify an existing record using the values from an <type>hstore</>:
- </para>
- <programlisting>
+<programlisting>
CREATE TABLE test (col1 integer, col2 text, col3 text);
INSERT INTO test VALUES (123, 'foo', 'bar');
------+------+------
123 | foo | baz
(1 row)
- </programlisting>
+</programlisting>
+ </para>
</sect2>
<sect2>
<para>
Simple example:
- </para>
- <programlisting>
+<programlisting>
SELECT * FROM each('aaa=>bq, b=>NULL, ""=>1');
- </programlisting>
+</programlisting>
+ </para>
<para>
Using a table:
- </para>
- <programlisting>
+<programlisting>
SELECT (each(h)).key, (each(h)).value INTO stat FROM testhstore;
- </programlisting>
+</programlisting>
+ </para>
<para>
Online statistics:
- </para>
- <programlisting>
+<programlisting>
SELECT key, count(*) FROM
(SELECT (each(h)).key FROM testhstore) AS stat
GROUP BY key
title | 190
org | 189
...................
- </programlisting>
+</programlisting>
+ </para>
</sect2>
<sect2>
performance penalty when processing data that has not yet been modified by
the new code. It is possible to force an upgrade of all values in a table
column by doing an <literal>UPDATE</> statement as follows:
- </para>
- <programlisting>
+<programlisting>
UPDATE tablename SET hstorecol = hstorecol || '';
- </programlisting>
+</programlisting>
+ </para>
<para>
Another way to do it is:
- <programlisting>
+<programlisting>
ALTER TABLE tablename ALTER hstorecol TYPE hstore USING hstorecol || '';
- </programlisting>
+</programlisting>
The <command>ALTER TABLE</> method requires an exclusive lock on the table,
but does not result in bloating the table with old row versions.
</para>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/indexam.sgml,v 2.33 2010/02/08 04:33:51 tgl Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/indexam.sgml,v 2.34 2010/07/29 19:34:40 petere Exp $ -->
<chapter id="indexam">
<title>Index Access Method Interface Definition</title>
Compute the index access cost. A generic estimator might do this:
<programlisting>
- /*
- * Our generic assumption is that the index pages will be read
- * sequentially, so they cost seq_page_cost each, not random_page_cost.
- * Also, we charge for evaluation of the indexquals at each index row.
- * All the costs are assumed to be paid incrementally during the scan.
- */
- cost_qual_eval(&index_qual_cost, indexQuals, root);
- *indexStartupCost = index_qual_cost.startup;
- *indexTotalCost = seq_page_cost * numIndexPages +
- (cpu_index_tuple_cost + index_qual_cost.per_tuple) * numIndexTuples;
+/*
+ * Our generic assumption is that the index pages will be read
+ * sequentially, so they cost seq_page_cost each, not random_page_cost.
+ * Also, we charge for evaluation of the indexquals at each index row.
+ * All the costs are assumed to be paid incrementally during the scan.
+ */
+cost_qual_eval(&index_qual_cost, indexQuals, root);
+*indexStartupCost = index_qual_cost.startup;
+*indexTotalCost = seq_page_cost * numIndexPages +
+ (cpu_index_tuple_cost + index_qual_cost.per_tuple) * numIndexTuples;
</programlisting>
However, the above does not account for amortization of index reads
-<!-- $PostgreSQL: pgsql/doc/src/sgml/install-win32.sgml,v 1.58 2010/07/27 19:01:16 petere Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/install-win32.sgml,v 1.59 2010/07/29 19:34:40 petere Exp $ -->
<chapter id="install-win32">
<title>Installation from Source Code on <productname>Windows</productname></title>
and then apply any changes from <filename>config.pl</filename>. For example,
to specify the location of your <productname>Python</productname> installation,
put the following in <filename>config.pl</filename>:
- <screen>
- $config->{python} = 'c:\python26';
- </screen>
+<programlisting>
+$config->{python} = 'c:\python26';
+</programlisting>
You only need to specify those parameters that are different from what's in
<filename>config_default.pl</filename>.
</para>
<filename>buildenv.pl</filename> and put the required commands there. For
example, to add the path for bison when it's not in the PATH, create a file
containing:
- <screen>
- $ENV{PATH}=$ENV{PATH} . ';c:\some\where\bison\bin';
- </screen>
+<programlisting>
+$ENV{PATH}=$ENV{PATH} . ';c:\some\where\bison\bin';
+</programlisting>
</para>
<sect2>
<para>
To build all of PostgreSQL in release configuration (the default), run the
command:
- <screen>
- <userinput>
- build
- </userinput>
- </screen>
+<screen>
+<userinput>build</userinput>
+</screen>
To build all of PostgreSQL in debug configuration, run the command:
- <screen>
- <userinput>
- build DEBUG
- </userinput>
- </screen>
+<screen>
+<userinput>build DEBUG</userinput>
+</screen>
To build just a single project, for example psql, run the commands:
- <screen>
- <userinput>
- build psql
- </userinput>
- <userinput>
- build DEBUG psql
- </userinput>
- </screen>
+<screen>
+<userinput>build psql</userinput>
+<userinput>build DEBUG psql</userinput>
+</screen>
To change the default build configuration to debug, put the following
in the <filename>buildenv.pl</filename> file:
- <screen>
- <userinput>
- $ENV{CONFIG}="Debug";
- </userinput>
- </screen>
+<programlisting>
+$ENV{CONFIG}="Debug";
+</programlisting>
</para>
<para>
It is also possible to build from inside the Visual Studio GUI. In this
case, you need to run:
- <screen>
- <userinput>
- perl mkvcbuild.pl
- </userinput>
- </screen>
+<screen>
+<userinput>perl mkvcbuild.pl</userinput>
+</screen>
from the command prompt, and then open the generated
<filename>pgsql.sln</filename> (in the root directory of the source tree)
in Visual Studio.
<filename>debug</filename> or <filename>release</filename> directories. To
install these files using the standard layout, and also generate the files
required to initialize and use the database, run the command:
- <screen>
- <userinput>
- install c:\destination\directory
- </userinput>
- </screen>
+<screen>
+<userinput>install c:\destination\directory</userinput>
+</screen>
</para>
</sect2>
the <filename>buildenv.pl</filename> file. To run the tests, run one of
the following commands from the <filename>src\tools\msvc</filename>
directory:
- <screen>
- <userinput>
- vcregress check
- </userinput>
- <userinput>
- vcregress installcheck
- </userinput>
- <userinput>
- vcregress plcheck
- </userinput>
- <userinput>
- vcregress contribcheck
- </userinput>
- </screen>
+<screen>
+<userinput>vcregress check</userinput>
+<userinput>vcregress installcheck</userinput>
+<userinput>vcregress plcheck</userinput>
+<userinput>vcregress contribcheck</userinput>
+</screen>
To change the schedule used (default is parallel), append it to the
command line like:
- <screen>
- <userinput>
- vcregress check serial
- </userinput>
- </screen>
+<screen>
+<userinput>vcregress check serial</userinput>
+</screen>
For more information about the regression tests, see
<xref linkend="regress">.
</variablelist>
Edit the <filename>buildenv.pl</filename> file, and add a variable for the
location of the root directory, for example:
- <screen>
- $ENV{DOCROOT}='c:\docbook';
- </screen>
+<programlisting>
+$ENV{DOCROOT}='c:\docbook';
+</programlisting>
To build the documentation, run the command
<filename>builddoc.bat</filename>. Note that this will actually run the
build twice, in order to generate the indexes. The generated HTML files
-<!-- $PostgreSQL: pgsql/doc/src/sgml/intagg.sgml,v 1.4 2008/11/14 19:58:45 tgl Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/intagg.sgml,v 1.5 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="intagg">
<title>intagg</title>
<para>
Many database systems have the notion of a one to many table. Such a table
usually sits between two indexed tables, for example:
- </para>
- <programlisting>
+<programlisting>
CREATE TABLE left (id INT PRIMARY KEY, ...);
CREATE TABLE right (id INT PRIMARY KEY, ...);
CREATE TABLE one_to_many(left INT REFERENCES left, right INT REFERENCES right);
- </programlisting>
+</programlisting>
- <para>
It is typically used like this:
- </para>
- <programlisting>
- SELECT right.* from right JOIN one_to_many ON (right.id = one_to_many.right)
- WHERE one_to_many.left = <replaceable>item</>;
- </programlisting>
+<programlisting>
+SELECT right.* from right JOIN one_to_many ON (right.id = one_to_many.right)
+ WHERE one_to_many.left = <replaceable>item</>;
+</programlisting>
- <para>
This will return all the items in the right hand table for an entry
in the left hand table. This is a very common construct in SQL.
</para>
left hand entry. If you have a very dynamic system, there is not much you
can do. However, if you have some data which is fairly static, you can
create a summary table with the aggregator.
- </para>
- <programlisting>
-CREATE TABLE summary as
+<programlisting>
+CREATE TABLE summary AS
SELECT left, int_array_aggregate(right) AS right
FROM one_to_many
GROUP BY left;
- </programlisting>
+</programlisting>
- <para>
This will create a table with one row per left item, and an array
of right items. Now this is pretty useless without some way of using
the array; that's why there is an array enumerator. You can do
- </para>
- <programlisting>
+<programlisting>
SELECT left, int_array_enum(right) FROM summary WHERE left = <replaceable>item</>;
- </programlisting>
+</programlisting>
- <para>
The above query using <function>int_array_enum</> produces the same results
as
- </para>
- <programlisting>
+<programlisting>
SELECT left, right FROM one_to_many WHERE left = <replaceable>item</>;
- </programlisting>
+</programlisting>
- <para>
The difference is that the query against the summary table has to get
only one row from the table, whereas the direct query against
<structname>one_to_many</> must index scan and fetch a row for each entry.
On one system, an <command>EXPLAIN</> showed a query with a cost of 8488 was
reduced to a cost of 329. The original query was a join involving the
<structname>one_to_many</> table, which was replaced by:
- </para>
- <programlisting>
+<programlisting>
SELECT right, count(right) FROM
( SELECT left, int_array_enum(right) AS right
FROM summary JOIN (SELECT left FROM left_table WHERE left = <replaceable>item</>) AS lefts
) AS list
GROUP BY right
ORDER BY count DESC;
- </programlisting>
+</programlisting>
+ </para>
</sect2>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/intarray.sgml,v 1.10 2010/05/05 15:10:25 heikki Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/intarray.sgml,v 1.11 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="intarray">
<title>intarray</title>
<sect2>
<title>Example</title>
- <programlisting>
+<programlisting>
-- a message can be in one or more <quote>sections</>
CREATE TABLE message (mid INT PRIMARY KEY, sections INT[], ...);
-- the same, using QUERY operator
SELECT message.mid FROM message WHERE message.sections @@ '1&2'::query_int;
- </programlisting>
+</programlisting>
</sect2>
<sect2>
benchmark test suite. To run:
</para>
- <programlisting>
- cd .../bench
- createdb TEST
- psql TEST < ../_int.sql
- ./create_test.pl | psql TEST
- ./bench.pl
- </programlisting>
+<programlisting>
+cd .../bench
+createdb TEST
+psql TEST < ../_int.sql
+./create_test.pl | psql TEST
+./bench.pl
+</programlisting>
<para>
The <filename>bench.pl</> script has numerous options, which
-<!-- $PostgreSQL: pgsql/doc/src/sgml/isn.sgml,v 1.5 2009/05/18 11:08:24 petere Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/isn.sgml,v 1.6 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="isn">
<title>isn</title>
<sect2>
<title>Examples</title>
- <programlisting>
+<programlisting>
--Using the types directly:
SELECT isbn('978-0-393-04002-9');
SELECT isbn13('0901690546');
SELECT * FROM test;
SELECT isbn13(id) FROM test;
- </programlisting>
+</programlisting>
</sect2>
<sect2>
<para>
The information to implement this module was collected from
several sites, including:
- </para>
- <programlisting>
- http://www.isbn-international.org/
- http://www.issn.org/
- http://www.ismn-international.org/
- http://www.wikipedia.org/
- </programlisting>
+ <itemizedlist>
+ <listitem><para><ulink url="http://www.isbn-international.org/"></ulink></para></listitem>
+ <listitem><para><ulink url="http://www.issn.org/"></ulink></para></listitem>
+ <listitem><para><ulink url="http://www.ismn-international.org/"></ulink></para></listitem>
+ <listitem><para><ulink url="http://www.wikipedia.org/"></ulink></para></listitem>
+ </itemizedlist>
- <para>
The prefixes used for hyphenation were also compiled from:
- </para>
- <programlisting>
- http://www.gs1.org/productssolutions/idkeys/support/prefix_list.html
- http://www.isbn-international.org/en/identifiers.html
- http://www.ismn-international.org/ranges.html
- </programlisting>
+ <itemizedlist>
+ <listitem><para><ulink url="http://www.gs1.org/productssolutions/idkeys/support/prefix_list.html"></ulink></para></listitem>
+ <listitem><para><ulink url="http://www.isbn-international.org/en/identifiers.html"></ulink></para></listitem>
+ <listitem><para><ulink url="http://www.ismn-international.org/ranges.html"></ulink></para></listitem>
+ </itemizedlist>
- <para>
Care was taken during the creation of the algorithms and they
were meticulously verified against the suggested algorithms
in the official ISBN, ISMN, ISSN User Manuals.
-<!-- $PostgreSQL: pgsql/doc/src/sgml/libpq.sgml,v 1.316 2010/07/27 19:01:16 petere Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/libpq.sgml,v 1.317 2010/07/29 19:34:40 petere Exp $ -->
<chapter id="libpq">
<title><application>libpq</application> - C Library</title>
<para>
Makes a new connection to the database server.
- <synopsis>
- PGconn *PQconnectdbParams(const char **keywords, const char **values, int expand_dbname);
- </synopsis>
+<synopsis>
+PGconn *PQconnectdbParams(const char **keywords, const char **values, int expand_dbname);
+</synopsis>
</para>
<para>
<para>
Makes a new connection to the database server.
- <synopsis>
- PGconn *PQconnectdb(const char *conninfo);
- </synopsis>
+<synopsis>
+PGconn *PQconnectdb(const char *conninfo);
+</synopsis>
</para>
<para>
<indexterm><primary>nonblocking connection</primary></indexterm>
Make a connection to the database server in a nonblocking manner.
- <synopsis>
- PGconn *PQconnectStartParams(const char **keywords, const char **values, int expand_dbname);
- </synopsis>
+<synopsis>
+PGconn *PQconnectStartParams(const char **keywords, const char **values, int expand_dbname);
- <synopsis>
- PGconn *PQconnectStart(const char *conninfo);
- </synopsis>
+PGconn *PQconnectStart(const char *conninfo);
- <synopsis>
- PostgresPollingStatusType PQconnectPoll(PGconn *conn);
- </synopsis>
+PostgresPollingStatusType PQconnectPoll(PGconn *conn);
+</synopsis>
</para>
<para>
<para>
Closes the connection to the server. Also frees
memory used by the <structname>PGconn</structname> object.
- <synopsis>
- void PQfinish(PGconn *conn);
- </synopsis>
+<synopsis>
+void PQfinish(PGconn *conn);
+</synopsis>
</para>
<para>
<listitem>
<para>
Resets the communication channel to the server.
- <synopsis>
- void PQreset(PGconn *conn);
- </synopsis>
+<synopsis>
+void PQreset(PGconn *conn);
+</synopsis>
</para>
<para>
<para>
Reset the communication channel to the server, in a nonblocking manner.
- <synopsis>
- int PQresetStart(PGconn *conn);
- </synopsis>
- <synopsis>
- PostgresPollingStatusType PQresetPoll(PGconn *conn);
- </synopsis>
+<synopsis>
+int PQresetStart(PGconn *conn);
+
+PostgresPollingStatusType PQresetPoll(PGconn *conn);
+</synopsis>
</para>
<para>
<listitem>
<para>
Returns the database name of the connection.
- <synopsis>
- char *PQdb(const PGconn *conn);
- </synopsis>
+<synopsis>
+char *PQdb(const PGconn *conn);
+</synopsis>
</para>
</listitem>
</varlistentry>
<listitem>
<para>
Returns the user name of the connection.
- <synopsis>
- char *PQuser(const PGconn *conn);
- </synopsis>
+<synopsis>
+char *PQuser(const PGconn *conn);
+</synopsis>
</para>
</listitem>
</varlistentry>
<listitem>
<para>
Returns the password of the connection.
- <synopsis>
- char *PQpass(const PGconn *conn);
- </synopsis>
+<synopsis>
+char *PQpass(const PGconn *conn);
+</synopsis>
</para>
</listitem>
</varlistentry>
<listitem>
<para>
Returns the server host name of the connection.
- <synopsis>
- char *PQhost(const PGconn *conn);
- </synopsis>
+<synopsis>
+char *PQhost(const PGconn *conn);
+</synopsis>
</para>
</listitem>
</varlistentry>
<para>
Returns the port of the connection.
- <synopsis>
- char *PQport(const PGconn *conn);
- </synopsis>
+<synopsis>
+char *PQport(const PGconn *conn);
+</synopsis>
</para>
</listitem>
</varlistentry>
to the <acronym>TTY</acronym> setting, but the function remains
for backwards compatibility.)
- <synopsis>
- char *PQtty(const PGconn *conn);
- </synopsis>
+<synopsis>
+char *PQtty(const PGconn *conn);
+</synopsis>
</para>
</listitem>
</varlistentry>
<listitem>
<para>
Returns the command-line options passed in the connection request.
- <synopsis>
- char *PQoptions(const PGconn *conn);
- </synopsis>
+<synopsis>
+char *PQoptions(const PGconn *conn);
+</synopsis>
</para>
</listitem>
</varlistentry>
<listitem>
<para>
Returns the status of the connection.
- <synopsis>
- ConnStatusType PQstatus(const PGconn *conn);
- </synopsis>
+<synopsis>
+ConnStatusType PQstatus(const PGconn *conn);
+</synopsis>
</para>
<para>
<para>
Returns the current in-transaction status of the server.
- <synopsis>
- PGTransactionStatusType PQtransactionStatus(const PGconn *conn);
- </synopsis>
+<synopsis>
+PGTransactionStatusType PQtransactionStatus(const PGconn *conn);
+</synopsis>
The status can be <literal>PQTRANS_IDLE</literal> (currently idle),
<literal>PQTRANS_ACTIVE</literal> (a command is in progress),
<para>
Looks up a current parameter setting of the server.
- <synopsis>
- const char *PQparameterStatus(const PGconn *conn, const char *paramName);
- </synopsis>
+<synopsis>
+const char *PQparameterStatus(const PGconn *conn, const char *paramName);
+</synopsis>
Certain parameter values are reported by the server automatically at
connection startup or whenever their values change.
<listitem>
<para>
Interrogates the frontend/backend protocol being used.
- <synopsis>
- int PQprotocolVersion(const PGconn *conn);
- </synopsis>
+<synopsis>
+int PQprotocolVersion(const PGconn *conn);
+</synopsis>
Applications might wish to use this to determine whether certain
features are supported. Currently, the possible values are 2 (2.0
protocol), 3 (3.0 protocol), or zero (connection bad). This will
<listitem>
<para>
Returns an integer representing the backend version.
- <synopsis>
- int PQserverVersion(const PGconn *conn);
- </synopsis>
+<synopsis>
+int PQserverVersion(const PGconn *conn);
+</synopsis>
Applications might use this to determine the version of the database
server they are connected to. The number is formed by converting
the major, minor, and revision numbers into two-decimal-digit
<indexterm><primary>error message</></> Returns the error message
most recently generated by an operation on the connection.
- <synopsis>
- char *PQerrorMessage(const PGconn *conn);
- </synopsis>
+<synopsis>
+char *PQerrorMessage(const PGconn *conn);
+</synopsis>
</para>
currently open. (This will not change during normal operation,
but could change during connection setup or reset.)
- <synopsis>
- int PQsocket(const PGconn *conn);
- </synopsis>
+<synopsis>
+int PQsocket(const PGconn *conn);
+</synopsis>
</para>
</listitem>
server process</><tertiary>in libpq</></> of the backend server
process handling this connection.
- <synopsis>
- int PQbackendPID(const PGconn *conn);
- </synopsis>
+<synopsis>
+int PQbackendPID(const PGconn *conn);
+</synopsis>
</para>
<para>
required a password, but none was available.
Returns false (0) if not.
- <synopsis>
- int PQconnectionNeedsPassword(const PGconn *conn);
- </synopsis>
+<synopsis>
+int PQconnectionNeedsPassword(const PGconn *conn);
+</synopsis>
</para>
<para>
Returns true (1) if the connection authentication method
used a password. Returns false (0) if not.
- <synopsis>
- int PQconnectionUsedPassword(const PGconn *conn);
- </synopsis>
+<synopsis>
+int PQconnectionUsedPassword(const PGconn *conn);
+</synopsis>
</para>
<para>
Returns the SSL structure used in the connection, or null
if SSL is not in use.
- <synopsis>
- SSL *PQgetssl(const PGconn *conn);
- </synopsis>
+<synopsis>
+SSL *PQgetssl(const PGconn *conn);
+</synopsis>
</para>
<para>
<para>
Submits a command to the server and waits for the result.
- <synopsis>
- PGresult *PQexec(PGconn *conn, const char *command);
- </synopsis>
+<synopsis>
+PGresult *PQexec(PGconn *conn, const char *command);
+</synopsis>
</para>
<para>
<listitem>
<para>
Returns the result status of the command.
- <synopsis>
- ExecStatusType PQresultStatus(const PGresult *res);
- </synopsis>
+<synopsis>
+ExecStatusType PQresultStatus(const PGresult *res);
+</synopsis>
</para>
<para>
<function>PQresultStatus</> into a string constant describing the
status code. The caller should not free the result.
- <synopsis>
- char *PQresStatus(ExecStatusType status);
- </synopsis>
+<synopsis>
+char *PQresStatus(ExecStatusType status);
+</synopsis>
</para>
</listitem>
</varlistentry>
<para>
Returns the error message associated with the command, or an empty string
if there was no error.
- <synopsis>
- char *PQresultErrorMessage(const PGresult *res);
- </synopsis>
+<synopsis>
+char *PQresultErrorMessage(const PGresult *res);
+</synopsis>
If there was an error, the returned string will include a trailing
newline. The caller should not free the result directly. It will
be freed when the associated <structname>PGresult</> handle is
<listitem>
<para>
Returns an individual field of an error report.
- <synopsis>
- char *PQresultErrorField(const PGresult *res, int fieldcode);
- </synopsis>
+<synopsis>
+char *PQresultErrorField(const PGresult *res, int fieldcode);
+</synopsis>
<parameter>fieldcode</> is an error field identifier; see the symbols
listed below. <symbol>NULL</symbol> is returned if the
<structname>PGresult</structname> is not an error or warning result,
freed via <function>PQclear</function> when it is no longer
needed.
- <synopsis>
- void PQclear(PGresult *res);
- </synopsis>
+<synopsis>
+void PQclear(PGresult *res);
+</synopsis>
</para>
<para>
it returns an integer result, large result sets might overflow the
return value on 32-bit operating systems.
- <synopsis>
- int PQntuples(const PGresult *res);
- </synopsis>
+<synopsis>
+int PQntuples(const PGresult *res);
+</synopsis>
</para>
</listitem>
Returns the number of columns (fields) in each row of the query
result.
- <synopsis>
- int PQnfields(const PGresult *res);
- </synopsis>
+<synopsis>
+int PQnfields(const PGresult *res);
+</synopsis>
</para>
</listitem>
</varlistentry>
directly. It will be freed when the associated
<structname>PGresult</> handle is passed to
<function>PQclear</function>.
- <synopsis>
- char *PQfname(const PGresult *res,
- int column_number);
- </synopsis>
+<synopsis>
+char *PQfname(const PGresult *res,
+ int column_number);
+</synopsis>
</para>
<para>
<listitem>
<para>
Returns the column number associated with the given column name.
- <synopsis>
- int PQfnumber(const PGresult *res,
- const char *column_name);
- </synopsis>
+<synopsis>
+int PQfnumber(const PGresult *res,
+ const char *column_name);
+</synopsis>
</para>
<para>
<para>
Returns the OID of the table from which the given column was
fetched. Column numbers start at 0.
- <synopsis>
- Oid PQftable(const PGresult *res,
- int column_number);
- </synopsis>
+<synopsis>
+Oid PQftable(const PGresult *res,
+ int column_number);
+</synopsis>
</para>
<para>
Returns the column number (within its table) of the column making
up the specified query result column. Query-result column numbers
start at 0, but table columns have nonzero numbers.
- <synopsis>
- int PQftablecol(const PGresult *res,
- int column_number);
- </synopsis>
+<synopsis>
+int PQftablecol(const PGresult *res,
+ int column_number);
+</synopsis>
</para>
<para>
<para>
Returns the format code indicating the format of the given
column. Column numbers start at 0.
- <synopsis>
- int PQfformat(const PGresult *res,
- int column_number);
- </synopsis>
+<synopsis>
+int PQfformat(const PGresult *res,
+ int column_number);
+</synopsis>
</para>
<para>
Returns the data type associated with the given column number.
The integer returned is the internal OID number of the type.
Column numbers start at 0.
- <synopsis>
- Oid PQftype(const PGresult *res,
- int column_number);
- </synopsis>
+<synopsis>
+Oid PQftype(const PGresult *res,
+ int column_number);
+</synopsis>
</para>
<para>
<para>
Returns the type modifier of the column associated with the
given column number. Column numbers start at 0.
- <synopsis>
- int PQfmod(const PGresult *res,
- int column_number);
- </synopsis>
+<synopsis>
+int PQfmod(const PGresult *res,
+ int column_number);
+</synopsis>
</para>
<para>
<para>
Returns the size in bytes of the column associated with the
given column number. Column numbers start at 0.
- <synopsis>
- int PQfsize(const PGresult *res,
- int column_number);
- </synopsis>
+<synopsis>
+int PQfsize(const PGresult *res,
+ int column_number);
+</synopsis>
</para>
<para>
<para>
Returns 1 if the <structname>PGresult</> contains binary data
and 0 if it contains text data.
- <synopsis>
- int PQbinaryTuples(const PGresult *res);
- </synopsis>
+<synopsis>
+int PQbinaryTuples(const PGresult *res);
+</synopsis>
</para>
<para>
at 0. The caller should not free the result directly. It will
be freed when the associated <structname>PGresult</> handle is
passed to <function>PQclear</function>.
- <synopsis>
- char *PQgetvalue(const PGresult *res,
- int row_number,
- int column_number);
- </synopsis>
+<synopsis>
+char *PQgetvalue(const PGresult *res,
+ int row_number,
+ int column_number);
+</synopsis>
</para>
<para>
<para>
Tests a field for a null value. Row and column numbers start
at 0.
- <synopsis>
- int PQgetisnull(const PGresult *res,
- int row_number,
- int column_number);
- </synopsis>
+<synopsis>
+int PQgetisnull(const PGresult *res,
+ int row_number,
+ int column_number);
+</synopsis>
</para>
<para>
<para>
Returns the actual length of a field value in bytes. Row and
column numbers start at 0.
- <synopsis>
- int PQgetlength(const PGresult *res,
- int row_number,
- int column_number);
- </synopsis>
+<synopsis>
+int PQgetlength(const PGresult *res,
+ int row_number,
+ int column_number);
+</synopsis>
</para>
<para>
<listitem>
<para>
Returns the number of parameters of a prepared statement.
- <synopsis>
- int PQnparams(const PGresult *res);
- </synopsis>
+<synopsis>
+int PQnparams(const PGresult *res);
+</synopsis>
</para>
<para>
<para>
Returns the data type of the indicated statement parameter.
Parameter numbers start at 0.
- <synopsis>
- Oid PQparamtype(const PGresult *res, int param_number);
- </synopsis>
+<synopsis>
+Oid PQparamtype(const PGresult *res, int param_number);
+</synopsis>
</para>
<para>
<para>
Prints out all the rows and, optionally, the column names to
the specified output stream.
- <synopsis>
+<synopsis>
void PQprint(FILE *fout, /* output stream */
const PGresult *res,
const PQprintOpt *po);
-typedef struct {
- pqbool header; /* print output field headings and row count */
- pqbool align; /* fill align the fields */
- pqbool standard; /* old brain dead format */
- pqbool html3; /* output HTML tables */
- pqbool expanded; /* expand tables */
- pqbool pager; /* use pager for output if needed */
- char *fieldSep; /* field separator */
- char *tableOpt; /* attributes for HTML table element */
- char *caption; /* HTML table caption */
- char **fieldName; /* null-terminated array of replacement field names */
+typedef struct
+{
+ pqbool header; /* print output field headings and row count */
+ pqbool align; /* fill align the fields */
+ pqbool standard; /* old brain dead format */
+ pqbool html3; /* output HTML tables */
+ pqbool expanded; /* expand tables */
+ pqbool pager; /* use pager for output if needed */
+ char *fieldSep; /* field separator */
+ char *tableOpt; /* attributes for HTML table element */
+ char *caption; /* HTML table caption */
+ char **fieldName; /* null-terminated array of replacement field names */
} PQprintOpt;
- </synopsis>
+</synopsis>
</para>
<para>
<para>
Returns the command status tag from the SQL command that generated
the <structname>PGresult</structname>.
- <synopsis>
- char *PQcmdStatus(PGresult *res);
- </synopsis>
+<synopsis>
+char *PQcmdStatus(PGresult *res);
+</synopsis>
</para>
<para>
<listitem>
<para>
Returns the number of rows affected by the SQL command.
- <synopsis>
- char *PQcmdTuples(PGresult *res);
- </synopsis>
+<synopsis>
+char *PQcmdTuples(PGresult *res);
+</synopsis>
</para>
<para>
returns <literal>InvalidOid</literal>. This function will also
return <literal>InvalidOid</literal> if the table affected by the
<command>INSERT</> statement does not contain OIDs.
- <synopsis>
- Oid PQoidValue(const PGresult *res);
- </synopsis>
+<synopsis>
+Oid PQoidValue(const PGresult *res);
+</synopsis>
</para>
</listitem>
</varlistentry>
the <command>INSERT</command> did not insert exactly one row, or
if the target table does not have OIDs.) If the command was not
an <command>INSERT</command>, returns an empty string.
- <synopsis>
- char *PQoidStatus(const PGresult *res);
- </synopsis>
+<synopsis>
+char *PQoidStatus(const PGresult *res);
+</synopsis>
</para>
<para>
<listitem>
<para>
- <synopsis>
- size_t PQescapeLiteral(PGconn *conn, char *str, size_t len)
- </synopsis>
+<synopsis>
+size_t PQescapeLiteral(PGconn *conn, char *str, size_t len);
+</synopsis>
</para>
<para>
<listitem>
<para>
- <synopsis>
- size_t PQescapeIdentifier(PGconn *conn, char *str, size_t len)
- </synopsis>
+<synopsis>
+size_t PQescapeIdentifier(PGconn *conn, char *str, size_t len);
+</synopsis>
</para>
<para>
<listitem>
<para>
- <synopsis>
- size_t PQescapeStringConn (PGconn *conn,
- char *to, const char *from, size_t length,
- int *error);
- </synopsis>
+<synopsis>
+size_t PQescapeStringConn(PGconn *conn,
+ char *to, const char *from, size_t length,
+ int *error);
+</synopsis>
</para>
<para>
<listitem>
<para>
- <synopsis>
- size_t PQescapeString (char *to, const char *from, size_t length);
- </synopsis>
+<synopsis>
+size_t PQescapeString (char *to, const char *from, size_t length);
+</synopsis>
</para>
<para>
Escapes binary data for use within an SQL command with the type
<type>bytea</type>. As with <function>PQescapeStringConn</function>,
this is only used when inserting data directly into an SQL command string.
- <synopsis>
- unsigned char *PQescapeByteaConn(PGconn *conn,
- const unsigned char *from,
- size_t from_length,
- size_t *to_length);
- </synopsis>
+<synopsis>
+unsigned char *PQescapeByteaConn(PGconn *conn,
+ const unsigned char *from,
+ size_t from_length,
+ size_t *to_length);
+</synopsis>
</para>
<para>
<para>
<function>PQescapeBytea</> is an older, deprecated version of
<function>PQescapeByteaConn</>.
- <synopsis>
- unsigned char *PQescapeBytea(const unsigned char *from,
- size_t from_length,
- size_t *to_length);
- </synopsis>
+<synopsis>
+unsigned char *PQescapeBytea(const unsigned char *from,
+ size_t from_length,
+ size_t *to_length);
+</synopsis>
</para>
<para>
is needed when retrieving <type>bytea</type> data in text format,
but not when retrieving it in binary format.
- <synopsis>
- unsigned char *PQunescapeBytea(const unsigned char *from, size_t *to_length);
- </synopsis>
+<synopsis>
+unsigned char *PQunescapeBytea(const unsigned char *from, size_t *to_length);
+</synopsis>
</para>
<para>
1 is returned if the command was successfully dispatched and 0 if
not (in which case, use <function>PQerrorMessage</> to get more
information about the failure).
- <synopsis>
- int PQsendQuery(PGconn *conn, const char *command);
- </synopsis>
+<synopsis>
+int PQsendQuery(PGconn *conn, const char *command);
+</synopsis>
After successfully calling <function>PQsendQuery</function>, call
<function>PQgetResult</function> one or more times to obtain the
<para>
Submits a command and separate parameters to the server without
waiting for the result(s).
- <synopsis>
- int PQsendQueryParams(PGconn *conn,
- const char *command,
- int nParams,
- const Oid *paramTypes,
- const char * const *paramValues,
- const int *paramLengths,
- const int *paramFormats,
- int resultFormat);
- </synopsis>
+<synopsis>
+int PQsendQueryParams(PGconn *conn,
+ const char *command,
+ int nParams,
+ const Oid *paramTypes,
+ const char * const *paramValues,
+ const int *paramLengths,
+ const int *paramFormats,
+ int resultFormat);
+</synopsis>
This is equivalent to <function>PQsendQuery</function> except that
query parameters can be specified separately from the query string.
<para>
Sends a request to create a prepared statement with the given
parameters, without waiting for completion.
- <synopsis>
- int PQsendPrepare(PGconn *conn,
- const char *stmtName,
- const char *query,
- int nParams,
- const Oid *paramTypes);
- </synopsis>
+<synopsis>
+int PQsendPrepare(PGconn *conn,
+ const char *stmtName,
+ const char *query,
+ int nParams,
+ const Oid *paramTypes);
+</synopsis>
This is an asynchronous version of <function>PQprepare</>: it
returns 1 if it was able to dispatch the request, and 0 if not.
<para>
Sends a request to execute a prepared statement with given
parameters, without waiting for the result(s).
- <synopsis>
- int PQsendQueryPrepared(PGconn *conn,
- const char *stmtName,
- int nParams,
- const char * const *paramValues,
- const int *paramLengths,
- const int *paramFormats,
- int resultFormat);
- </synopsis>
+<synopsis>
+int PQsendQueryPrepared(PGconn *conn,
+ const char *stmtName,
+ int nParams,
+ const char * const *paramValues,
+ const int *paramLengths,
+ const int *paramFormats,
+ int resultFormat);
+</synopsis>
This is similar to <function>PQsendQueryParams</function>, but
the command to be executed is specified by naming a
<para>
Submits a request to obtain information about the specified
prepared statement, without waiting for completion.
- <synopsis>
- int PQsendDescribePrepared(PGconn *conn, const char *stmtName);
- </synopsis>
+<synopsis>
+int PQsendDescribePrepared(PGconn *conn, const char *stmtName);
+</synopsis>
This is an asynchronous version of <function>PQdescribePrepared</>:
it returns 1 if it was able to dispatch the request, and 0 if not.
<para>
Submits a request to obtain information about the specified
portal, without waiting for completion.
- <synopsis>
- int PQsendDescribePortal(PGconn *conn, const char *portalName);
- </synopsis>
+<synopsis>
+int PQsendDescribePortal(PGconn *conn, const char *portalName);
+</synopsis>
This is an asynchronous version of <function>PQdescribePortal</>:
it returns 1 if it was able to dispatch the request, and 0 if not.
<function>PQsendQueryPrepared</function> call, and returns it.
A null pointer is returned when the command is complete and there
will be no more results.
- <synopsis>
- PGresult *PQgetResult(PGconn *conn);
- </synopsis>
+<synopsis>
+PGresult *PQgetResult(PGconn *conn);
+</synopsis>
</para>
<para>
<listitem>
<para>
If input is available from the server, consume it.
- <synopsis>
- int PQconsumeInput(PGconn *conn);
- </synopsis>
+<synopsis>
+int PQconsumeInput(PGconn *conn);
+</synopsis>
</para>
<para>
<function>PQgetResult</function> would block waiting for input.
A 0 return indicates that <function>PQgetResult</function> can be
called with assurance of not blocking.
- <synopsis>
- int PQisBusy(PGconn *conn);
- </synopsis>
+<synopsis>
+int PQisBusy(PGconn *conn);
+</synopsis>
</para>
<para>
<listitem>
<para>
Sets the nonblocking status of the connection.
- <synopsis>
- int PQsetnonblocking(PGconn *conn, int arg);
- </synopsis>
+<synopsis>
+int PQsetnonblocking(PGconn *conn, int arg);
+</synopsis>
</para>
<para>
<listitem>
<para>
Returns the blocking status of the database connection.
- <synopsis>
- int PQisnonblocking(const PGconn *conn);
- </synopsis>
+<synopsis>
+int PQisnonblocking(const PGconn *conn);
+</synopsis>
</para>
<para>
for some reason, or 1 if it was unable to send all the data in
the send queue yet (this case can only occur if the connection
is nonblocking).
- <synopsis>
- int PQflush(PGconn *conn);
- </synopsis>
+<synopsis>
+int PQflush(PGconn *conn);
+</synopsis>
</para>
</listitem>
</varlistentry>
<para>
Creates a data structure containing the information needed to cancel
a command issued through a particular database connection.
- <synopsis>
- PGcancel *PQgetCancel(PGconn *conn);
- </synopsis>
+<synopsis>
+PGcancel *PQgetCancel(PGconn *conn);
+</synopsis>
</para>
<para>
<listitem>
<para>
Frees a data structure created by <function>PQgetCancel</function>.
- <synopsis>
- void PQfreeCancel(PGcancel *cancel);
- </synopsis>
+<synopsis>
+void PQfreeCancel(PGcancel *cancel);
+</synopsis>
</para>
<para>
<listitem>
<para>
Requests that the server abandon processing of the current command.
- <synopsis>
- int PQcancel(PGcancel *cancel, char *errbuf, int errbufsize);
- </synopsis>
+<synopsis>
+int PQcancel(PGcancel *cancel, char *errbuf, int errbufsize);
+</synopsis>
</para>
<para>
<para>
Requests that the server abandon processing of the current
command.
- <synopsis>
- int PQrequestCancel(PGconn *conn);
- </synopsis>
+<synopsis>
+int PQrequestCancel(PGconn *conn);
+</synopsis>
</para>
<para>
<para>
The function <function>PQfn</function><indexterm><primary>PQfn</></>
requests execution of a server function via the fast-path interface:
- <synopsis>
- PGresult *PQfn(PGconn *conn,
- int fnid,
- int *result_buf,
- int *result_len,
- int result_is_int,
- const PQArgBlock *args,
- int nargs);
-
- typedef struct {
- int len;
- int isint;
- union {
- int *ptr;
- int integer;
- } u;
- } PQArgBlock;
- </synopsis>
+<synopsis>
+PGresult *PQfn(PGconn *conn,
+ int fnid,
+ int *result_buf,
+ int *result_len,
+ int result_is_int,
+ const PQArgBlock *args,
+ int nargs);
+
+typedef struct
+{
+ int len;
+ int isint;
+ union
+ {
+ int *ptr;
+ int integer;
+ } u;
+} PQArgBlock;
+</synopsis>
</para>
<para>
notification is returned from <function>PQnotifies</>, it is considered
handled and will be removed from the list of notifications.
- <synopsis>
- PGnotify *PQnotifies(PGconn *conn);
+<synopsis>
+PGnotify *PQnotifies(PGconn *conn);
- typedef struct pgNotify {
- char *relname; /* notification channel name */
- int be_pid; /* process ID of notifying server process */
- char *extra; /* notification payload string */
- } PGnotify;
- </synopsis>
+typedef struct pgNotify
+{
+ char *relname; /* notification channel name */
+ int be_pid; /* process ID of notifying server process */
+ char *extra; /* notification payload string */
+} PGnotify;
+</synopsis>
After processing a <structname>PGnotify</structname> object returned
by <function>PQnotifies</function>, be sure to free it with
<listitem>
<para>
Sends data to the server during <literal>COPY_IN</> state.
- <synopsis>
- int PQputCopyData(PGconn *conn,
- const char *buffer,
- int nbytes);
- </synopsis>
+<synopsis>
+int PQputCopyData(PGconn *conn,
+ const char *buffer,
+ int nbytes);
+</synopsis>
</para>
<para>
<listitem>
<para>
Sends end-of-data indication to the server during <literal>COPY_IN</> state.
- <synopsis>
- int PQputCopyEnd(PGconn *conn,
- const char *errormsg);
- </synopsis>
+<synopsis>
+int PQputCopyEnd(PGconn *conn,
+ const char *errormsg);
+</synopsis>
</para>
<para>
<listitem>
<para>
Receives data from the server during <literal>COPY_OUT</> state.
- <synopsis>
- int PQgetCopyData(PGconn *conn,
- char **buffer,
- int async);
- </synopsis>
+<synopsis>
+int PQgetCopyData(PGconn *conn,
+ char **buffer,
+ int async);
+</synopsis>
</para>
<para>
<para>
Reads a newline-terminated line of characters (transmitted
by the server) into a buffer string of size <parameter>length</>.
- <synopsis>
- int PQgetline(PGconn *conn,
- char *buffer,
- int length);
- </synopsis>
+<synopsis>
+int PQgetline(PGconn *conn,
+ char *buffer,
+ int length);
+</synopsis>
</para>
<para>
<para>
Reads a row of <command>COPY</command> data (transmitted by the
server) into a buffer without blocking.
- <synopsis>
- int PQgetlineAsync(PGconn *conn,
- char *buffer,
- int bufsize);
- </synopsis>
+<synopsis>
+int PQgetlineAsync(PGconn *conn,
+ char *buffer,
+ int bufsize);
+</synopsis>
</para>
<para>
<para>
Sends a null-terminated string to the server. Returns 0 if
OK and <symbol>EOF</symbol> if unable to send the string.
- <synopsis>
- int PQputline(PGconn *conn,
- const char *string);
- </synopsis>
+<synopsis>
+int PQputline(PGconn *conn,
+ const char *string);
+</synopsis>
</para>
<para>
<para>
Sends a non-null-terminated string to the server. Returns
0 if OK and <symbol>EOF</symbol> if unable to send the string.
- <synopsis>
- int PQputnbytes(PGconn *conn,
- const char *buffer,
- int nbytes);
- </synopsis>
+<synopsis>
+int PQputnbytes(PGconn *conn,
+ const char *buffer,
+ int nbytes);
+</synopsis>
</para>
<para>
<listitem>
<para>
Synchronizes with the server.
- <synopsis>
- int PQendcopy(PGconn *conn);
- </synopsis>
+<synopsis>
+int PQendcopy(PGconn *conn);
+</synopsis>
This function waits until the server has finished the copying.
It should either be issued when the last string has been sent
to the server using <function>PQputline</function> or when the
<listitem>
<para>
Returns the client encoding.
- <synopsis>
- int PQclientEncoding(const PGconn *<replaceable>conn</replaceable>);
- </synopsis>
+<synopsis>
+int PQclientEncoding(const PGconn *<replaceable>conn</replaceable>);
+</synopsis>
Note that it returns the encoding ID, not a symbolic string
such as <literal>EUC_JP</literal>. To convert an encoding ID to an encoding name, you
<listitem>
<para>
Sets the client encoding.
- <synopsis>
- int PQsetClientEncoding(PGconn *<replaceable>conn</replaceable>, const char *<replaceable>encoding</replaceable>);
- </synopsis>
+<synopsis>
+int PQsetClientEncoding(PGconn *<replaceable>conn</replaceable>, const char *<replaceable>encoding</replaceable>);
+</synopsis>
<replaceable>conn</replaceable> is a connection to the server,
and <replaceable>encoding</replaceable> is the encoding you want to
<para>
Determines the verbosity of messages returned by
<function>PQerrorMessage</> and <function>PQresultErrorMessage</>.
- <synopsis>
- typedef enum {
- PQERRORS_TERSE,
- PQERRORS_DEFAULT,
- PQERRORS_VERBOSE
- } PGVerbosity;
+<synopsis>
+typedef enum
+{
+ PQERRORS_TERSE,
+ PQERRORS_DEFAULT,
+ PQERRORS_VERBOSE
+} PGVerbosity;
- PGVerbosity PQsetErrorVerbosity(PGconn *conn, PGVerbosity verbosity);
- </synopsis>
+PGVerbosity PQsetErrorVerbosity(PGconn *conn, PGVerbosity verbosity);
+</synopsis>
<function>PQsetErrorVerbosity</> sets the verbosity mode, returning
the connection's previous setting. In <firstterm>TERSE</> mode,
<listitem>
<para>
Enables tracing of the client/server communication to a debugging file stream.
- <synopsis>
- void PQtrace(PGconn *conn, FILE *stream);
- </synopsis>
+<synopsis>
+void PQtrace(PGconn *conn, FILE *stream);
+</synopsis>
</para>
<note>
<listitem>
<para>
Disables tracing started by <function>PQtrace</function>.
- <synopsis>
- void PQuntrace(PGconn *conn);
- </synopsis>
+<synopsis>
+void PQuntrace(PGconn *conn);
+</synopsis>
</para>
</listitem>
</varlistentry>
<listitem>
<para>
Frees memory allocated by <application>libpq</>.
- <synopsis>
- void PQfreemem(void *ptr);
- </synopsis>
+<synopsis>
+void PQfreemem(void *ptr);
+</synopsis>
</para>
<para>
<para>
Frees the data structures allocated by
<function>PQconndefaults</> or <function>PQconninfoParse</>.
- <synopsis>
- void PQconninfoFree(PQconninfoOption *connOptions);
- </synopsis>
+<synopsis>
+void PQconninfoFree(PQconninfoOption *connOptions);
+</synopsis>
</para>
<para>
<listitem>
<para>
Prepares the encrypted form of a <productname>PostgreSQL</> password.
- <synopsis>
- char * PQencryptPassword(const char *passwd, const char *user);
- </synopsis>
+<synopsis>
+char * PQencryptPassword(const char *passwd, const char *user);
+</synopsis>
This function is intended to be used by client applications that
wish to send commands like <literal>ALTER USER joe PASSWORD
'pwd'</>. It is good practice not to send the original cleartext
<listitem>
<para>
Constructs an empty <structname>PGresult</structname> object with the given status.
- <synopsis>
- PGresult *PQmakeEmptyPGresult(PGconn *conn, ExecStatusType status);
- </synopsis>
+<synopsis>
+PGresult *PQmakeEmptyPGresult(PGconn *conn, ExecStatusType status);
+</synopsis>
</para>
<para>
<structname>PGresult</structname> object. Returns non-zero for success,
zero if any event procedure fails.
- <synopsis>
- int PQfireResultCreateEvents(PGconn *conn, PGresult *res);
- </synopsis>
+<synopsis>
+int PQfireResultCreateEvents(PGconn *conn, PGresult *res);
+</synopsis>
</para>
<para>
<function>PQclear</function> must be called when the copy is no longer
needed. If the function fails, NULL is returned.
- <synopsis>
- PGresult *PQcopyResult(const PGresult *src, int flags);
- </synopsis>
+<synopsis>
+PGresult *PQcopyResult(const PGresult *src, int flags);
+</synopsis>
</para>
<para>
<listitem>
<para>
Sets the attributes of a <structname>PGresult</structname> object.
- <synopsis>
- int PQsetResultAttrs(PGresult *res, int numAttributes, PGresAttDesc *attDescs);
- </synopsis>
+<synopsis>
+int PQsetResultAttrs(PGresult *res, int numAttributes, PGresAttDesc *attDescs);
+</synopsis>
</para>
<para>
<listitem>
<para>
Sets a tuple field value of a <structname>PGresult</structname> object.
- <synopsis>
- int PQsetvalue(PGresult *res, int tup_num, int field_num, char *value, int len);
- </synopsis>
+<synopsis>
+int PQsetvalue(PGresult *res, int tup_num, int field_num, char *value, int len);
+</synopsis>
</para>
<para>
<listitem>
<para>
Allocate subsidiary storage for a <structname>PGresult</structname> object.
- <synopsis>
- void *PQresultAlloc(PGresult *res, size_t nBytes);
- </synopsis>
+<synopsis>
+void *PQresultAlloc(PGresult *res, size_t nBytes);
+</synopsis>
</para>
<para>
processor</></><indexterm><primary>PQsetNoticeProcessor</></> sets or
examines the current notice processor.
- <synopsis>
- typedef void (*PQnoticeReceiver) (void *arg, const PGresult *res);
+<synopsis>
+typedef void (*PQnoticeReceiver) (void *arg, const PGresult *res);
- PQnoticeReceiver
- PQsetNoticeReceiver(PGconn *conn,
- PQnoticeReceiver proc,
- void *arg);
+PQnoticeReceiver
+PQsetNoticeReceiver(PGconn *conn,
+ PQnoticeReceiver proc,
+ void *arg);
- typedef void (*PQnoticeProcessor) (void *arg, const char *message);
+typedef void (*PQnoticeProcessor) (void *arg, const char *message);
- PQnoticeProcessor
- PQsetNoticeProcessor(PGconn *conn,
- PQnoticeProcessor proc,
- void *arg);
- </synopsis>
+PQnoticeProcessor
+PQsetNoticeProcessor(PGconn *conn,
+ PQnoticeProcessor proc,
+ void *arg);
+</synopsis>
Each of these functions returns the previous notice receiver or
processor function pointer, and sets the new value. If you supply a
<para>
The default notice processor is simply:
- <programlisting>
+<programlisting>
static void
defaultNoticeProcessor(void *arg, const char *message)
{
register event will be fired per event handler per connection. If the
event procedure fails, the registration is aborted.
- <synopsis>
+<synopsis>
typedef struct
{
PGconn *conn;
} PGEventRegister;
- </synopsis>
+</synopsis>
When a <literal>PGEVT_REGISTER</literal> event is received, the
<parameter>evtInfo</parameter> pointer should be cast to a
<function>PQresetPoll</function> will return
<literal>PGRES_POLLING_FAILED</literal>.
- <synopsis>
+<synopsis>
typedef struct
{
PGconn *conn;
} PGEventConnReset;
- </synopsis>
+</synopsis>
When a <literal>PGEVT_CONNRESET</literal> event is received, the
<parameter>evtInfo</parameter> pointer should be cast to a
ability to manage this memory. Failure to clean up will lead
to memory leaks.
- <synopsis>
+<synopsis>
typedef struct
{
PGconn *conn;
} PGEventConnDestroy;
- </synopsis>
+</synopsis>
When a <literal>PGEVT_CONNDESTROY</literal> event is received, the
<parameter>evtInfo</parameter> pointer should be cast to a
<function>PQgetResult</function>. This event will only be fired after
the result has been created successfully.
- <synopsis>
+<synopsis>
typedef struct
{
PGconn *conn;
PGresult *result;
} PGEventResultCreate;
- </synopsis>
+</synopsis>
When a <literal>PGEVT_RESULTCREATE</literal> event is received, the
<parameter>evtInfo</parameter> pointer should be cast to a
or <literal>PGEVT_RESULTCOPY</literal> event for the source result
will receive <literal>PGEVT_RESULTCOPY</literal> events.
- <synopsis>
+<synopsis>
typedef struct
{
const PGresult *src;
PGresult *dest;
} PGEventResultCopy;
- </synopsis>
+</synopsis>
When a <literal>PGEVT_RESULTCOPY</literal> event is received, the
<parameter>evtInfo</parameter> pointer should be cast to a
ability to manage this memory. Failure to clean up will lead
to memory leaks.
- <synopsis>
+<synopsis>
typedef struct
{
PGresult *result;
} PGEventResultDestroy;
- </synopsis>
+</synopsis>
When a <literal>PGEVT_RESULTDESTROY</literal> event is received, the
<parameter>evtInfo</parameter> pointer should be cast to a
event procedure, that is, the user callback function that receives
events from libpq. The signature of an event procedure must be
- <synopsis>
+<synopsis>
int eventproc(PGEventId evtId, void *evtInfo, void *passThrough)
- </synopsis>
+</synopsis>
The <parameter>evtId</parameter> parameter indicates which
<literal>PGEVT</literal> event occurred. The
<para>
Registers an event callback procedure with libpq.
- <synopsis>
- int PQregisterEventProc(PGconn *conn, PGEventProc proc,
- const char *name, void *passThrough);
- </synopsis>
+<synopsis>
+int PQregisterEventProc(PGconn *conn, PGEventProc proc,
+ const char *name, void *passThrough);
+</synopsis>
</para>
<para>
for success and zero for failure. (Failure is only possible if
the proc has not been properly registered in the conn.)
- <synopsis>
- int PQsetInstanceData(PGconn *conn, PGEventProc proc, void *data);
- </synopsis>
+<synopsis>
+int PQsetInstanceData(PGconn *conn, PGEventProc proc, void *data);
+</synopsis>
</para>
</listitem>
</varlistentry>
Returns the conn's instanceData associated with proc, or NULL
if there is none.
- <synopsis>
- void *PQinstanceData(const PGconn *conn, PGEventProc proc);
- </synopsis>
+<synopsis>
+void *PQinstanceData(const PGconn *conn, PGEventProc proc);
+</synopsis>
</para>
</listitem>
</varlistentry>
for success and zero for failure. (Failure is only possible if the
proc has not been properly registered in the result.)
- <synopsis>
- int PQresultSetInstanceData(PGresult *res, PGEventProc proc, void *data);
- </synopsis>
+<synopsis>
+int PQresultSetInstanceData(PGresult *res, PGEventProc proc, void *data);
+</synopsis>
</para>
</listitem>
</varlistentry>
Returns the result's instanceData associated with proc, or NULL
if there is none.
- <synopsis>
- void *PQresultInstanceData(const PGresult *res, PGEventProc proc);
- </synopsis>
+<synopsis>
+void *PQresultInstanceData(const PGresult *res, PGEventProc proc);
+</synopsis>
</para>
</listitem>
</varlistentry>
libpq connections and results.
</para>
- <programlisting>
+<programlisting>
<![CDATA[
/* required header for libpq events (note: includes libpq-fe.h) */
#include <libpq-events.h>
<para>
This file should contain lines of the following format:
- <synopsis>
- <replaceable>hostname</replaceable>:<replaceable>port</replaceable>:<replaceable>database</replaceable>:<replaceable>username</replaceable>:<replaceable>password</replaceable>
- </synopsis>
+<synopsis>
+<replaceable>hostname</replaceable>:<replaceable>port</replaceable>:<replaceable>database</replaceable>:<replaceable>username</replaceable>:<replaceable>password</replaceable>
+</synopsis>
Each of the first four fields can be a literal value, or
<literal>*</literal>, which matches anything. The password field from
the first line that matches the current connection parameters will be
<literal>keyword = value</literal> pairs which will be used to set
connection options. The URL must conform to RFC 1959 and be of the
form
- <synopsis>
- ldap://[<replaceable>hostname</replaceable>[:<replaceable>port</replaceable>]]/<replaceable>search_base</replaceable>?<replaceable>attribute</replaceable>?<replaceable>search_scope</replaceable>?<replaceable>filter</replaceable>
- </synopsis>
+<synopsis>
+ldap://[<replaceable>hostname</replaceable>[:<replaceable>port</replaceable>]]/<replaceable>search_base</replaceable>?<replaceable>attribute</replaceable>?<replaceable>search_scope</replaceable>?<replaceable>filter</replaceable>
+</synopsis>
where <replaceable>hostname</replaceable> defaults to
<literal>localhost</literal> and <replaceable>port</replaceable>
defaults to 389.
<para>
A sample LDAP entry that has been created with the LDIF file
- <synopsis>
- version:1
- dn:cn=mydatabase,dc=mycompany,dc=com
- changetype:add
- objectclass:top
- objectclass:groupOfUniqueNames
- cn:mydatabase
- uniqueMember:host=dbserver.mycompany.com
- uniqueMember:port=5439
- uniqueMember:dbname=mydb
- uniqueMember:user=mydb_user
- uniqueMember:sslmode=require
- </synopsis>
+<programlisting>
+version:1
+dn:cn=mydatabase,dc=mycompany,dc=com
+changetype:add
+objectclass:top
+objectclass:groupOfUniqueNames
+cn:mydatabase
+uniqueMember:host=dbserver.mycompany.com
+uniqueMember:port=5439
+uniqueMember:dbname=mydb
+uniqueMember:user=mydb_user
+uniqueMember:sslmode=require
+</programlisting>
might be queried with the following LDAP URL:
- <synopsis>
- ldap://ldap.mycompany.com/dc=mycompany,dc=com?uniqueMember?one?(cn=mydatabase)
- </synopsis>
+<programlisting>
+ldap://ldap.mycompany.com/dc=mycompany,dc=com?uniqueMember?one?(cn=mydatabase)
+</programlisting>
</para>
<para>
You can also mix regular service file entries with LDAP lookups.
A complete example for a stanza in <filename>pg_service.conf</filename>
would be:
- <synopsis>
- # only host and port are stored in LDAP, specify dbname and user explicitly
- [customerdb]
- dbname=customer
- user=appuser
- ldap://ldap.acme.com/cn=dbserver,cn=hosts?pgconnectinfo?base?(objectclass=*)
- </synopsis>
+<programlisting>
+# only host and port are stored in LDAP, specify dbname and user explicitly
+[customerdb]
+dbname=customer
+user=appuser
+ldap://ldap.acme.com/cn=dbserver,cn=hosts?pgconnectinfo?base?(objectclass=*)
+</programlisting>
</para>
</sect1>
<listitem>
<para>
Allows applications to select which security libraries to initialize.
- <synopsis>
- void PQinitOpenSSL(int do_ssl, int do_crypto);
- </synopsis>
+<synopsis>
+void PQinitOpenSSL(int do_ssl, int do_crypto);
+</synopsis>
</para>
<para>
<listitem>
<para>
Allows applications to select which security libraries to initialize.
- <synopsis>
- void PQinitSSL(int do_ssl);
- </synopsis>
+<synopsis>
+void PQinitSSL(int do_ssl);
+</synopsis>
</para>
<para>
<para>
Returns the thread safety status of the
<application>libpq</application> library.
- <synopsis>
- int PQisthreadsafe();
- </synopsis>
+<synopsis>
+int PQisthreadsafe();
+</synopsis>
</para>
<para>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/lo.sgml,v 1.3 2007/12/06 04:12:10 tgl Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/lo.sgml,v 1.4 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="lo">
<title>lo</title>
Here's a simple example of usage:
</para>
- <programlisting>
- CREATE TABLE image (title TEXT, raster lo);
+<programlisting>
+CREATE TABLE image (title TEXT, raster lo);
- CREATE TRIGGER t_raster BEFORE UPDATE OR DELETE ON image
- FOR EACH ROW EXECUTE PROCEDURE lo_manage(raster);
- </programlisting>
+CREATE TRIGGER t_raster BEFORE UPDATE OR DELETE ON image
+ FOR EACH ROW EXECUTE PROCEDURE lo_manage(raster);
+</programlisting>
<para>
For each column that will contain unique references to large objects,
-<!-- $PostgreSQL: pgsql/doc/src/sgml/ltree.sgml,v 1.4 2010/03/17 17:12:31 petere Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/ltree.sgml,v 1.5 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="ltree">
<title>ltree</title>
for matching <type>ltree</> values. A simple word matches that
label within a path. A star symbol (<literal>*</>) matches zero
or more labels. For example:
- <programlisting>
+<synopsis>
foo <lineannotation>Match the exact label path <literal>foo</></lineannotation>
*.foo.* <lineannotation>Match any label path containing the label <literal>foo</></lineannotation>
*.foo <lineannotation>Match any label path whose last label is <literal>foo</></lineannotation>
- </programlisting>
+</synopsis>
</para>
<para>
Star symbols can also be quantified to restrict how many labels
they can match:
- <programlisting>
+<synopsis>
*{<replaceable>n</>} <lineannotation>Match exactly <replaceable>n</> labels</lineannotation>
*{<replaceable>n</>,} <lineannotation>Match at least <replaceable>n</> labels</lineannotation>
*{<replaceable>n</>,<replaceable>m</>} <lineannotation>Match at least <replaceable>n</> but not more than <replaceable>m</> labels</lineannotation>
*{,<replaceable>m</>} <lineannotation>Match at most <replaceable>m</> labels — same as </lineannotation> *{0,<replaceable>m</>}
- </programlisting>
+</synopsis>
</para>
<para>
There are several modifiers that can be put at the end of a non-star
label in <type>lquery</> to make it match more than just the exact match:
- <programlisting>
+<synopsis>
@ <lineannotation>Match case-insensitively, for example <literal>a@</> matches <literal>A</></lineannotation>
* <lineannotation>Match any label with this prefix, for example <literal>foo*</> matches <literal>foobar</></lineannotation>
% <lineannotation>Match initial underscore-separated words</lineannotation>
- </programlisting>
+</synopsis>
The behavior of <literal>%</> is a bit complicated. It tries to match
words rather than the entire label. For example
<literal>foo_bar%</> matches <literal>foo_bar_baz</> but not
<para>
Here's an annotated example of <type>lquery</type>:
- <programlisting>
- Top.*{0,2}.sport*@.!football|tennis.Russ*|Spain
- a. b. c. d. e.
- </programlisting>
+<programlisting>
+Top.*{0,2}.sport*@.!football|tennis.Russ*|Spain
+a. b. c. d. e.
+</programlisting>
This query will match any label path that:
</para>
<orderedlist numeration='loweralpha'>
<para>
Here's an example <type>ltxtquery</type>:
- <programlisting>
- Europe & Russia*@ & !Transportation
- </programlisting>
+<programlisting>
+Europe & Russia*@ & !Transportation
+</programlisting>
This will match paths that contain the label <literal>Europe</literal> and
any label beginning with <literal>Russia</literal> (case-insensitive),
but not paths containing the label <literal>Transportation</literal>.
<para>
Example of creating such an index:
</para>
- <programlisting>
- CREATE INDEX path_gist_idx ON test USING GIST (path);
- </programlisting>
+<programlisting>
+CREATE INDEX path_gist_idx ON test USING GIST (path);
+</programlisting>
</listitem>
<listitem>
<para>
<para>
Example of creating such an index:
</para>
- <programlisting>
- CREATE INDEX path_gist_idx ON test USING GIST (array_path);
- </programlisting>
+<programlisting>
+CREATE INDEX path_gist_idx ON test USING GIST (array_path);
+</programlisting>
<para>
Note: This index type is lossy.
</para>
<filename>contrib/ltree/ltreetest.sql</> in the source distribution):
</para>
- <programlisting>
+<programlisting>
CREATE TABLE test (path ltree);
INSERT INTO test VALUES ('Top');
INSERT INTO test VALUES ('Top.Science');
INSERT INTO test VALUES ('Top.Collections.Pictures.Astronomy.Astronauts');
CREATE INDEX path_gist_idx ON test USING gist(path);
CREATE INDEX path_idx ON test USING btree(path);
- </programlisting>
+</programlisting>
<para>
Now, we have a table <structname>test</> populated with data describing
the hierarchy shown below:
</para>
- <programlisting>
- Top
- / | \
- Science Hobbies Collections
- / | \
- Astronomy Amateurs_Astronomy Pictures
- / \ |
- Astrophysics Cosmology Astronomy
- / | \
- Galaxies Stars Astronauts
- </programlisting>
+<literallayout class="monospaced">
+ Top
+ / | \
+ Science Hobbies Collections
+ / | \
+ Astronomy Amateurs_Astronomy Pictures
+ / \ |
+Astrophysics Cosmology Astronomy
+ / | \
+ Galaxies Stars Astronauts
+</literallayout>
<para>
We can do inheritance:
- </para>
-
- <programlisting>
-ltreetest=# select path from test where path <@ 'Top.Science';
+<screen>
+ltreetest=> SELECT path FROM test WHERE path <@ 'Top.Science';
path
------------------------------------
Top.Science
Top.Science.Astronomy.Astrophysics
Top.Science.Astronomy.Cosmology
(4 rows)
- </programlisting>
+</screen>
+ </para>
<para>
Here are some examples of path matching:
- </para>
-
- <programlisting>
-ltreetest=# select path from test where path ~ '*.Astronomy.*';
+<screen>
+ltreetest=> SELECT path FROM test WHERE path ~ '*.Astronomy.*';
path
-----------------------------------------------
Top.Science.Astronomy
Top.Collections.Pictures.Astronomy.Astronauts
(7 rows)
-ltreetest=# select path from test where path ~ '*.!pictures@.*.Astronomy.*';
+ltreetest=> SELECT path FROM test WHERE path ~ '*.!pictures@.*.Astronomy.*';
path
------------------------------------
Top.Science.Astronomy
Top.Science.Astronomy.Astrophysics
Top.Science.Astronomy.Cosmology
(3 rows)
- </programlisting>
+</screen>
+ </para>
<para>
Here are some examples of full text search:
- </para>
- <programlisting>
-ltreetest=# select path from test where path @ 'Astro*% & !pictures@';
+<screen>
+ltreetest=> SELECT path FROM test WHERE path @ 'Astro*% & !pictures@';
path
------------------------------------
Top.Science.Astronomy
Top.Hobbies.Amateurs_Astronomy
(4 rows)
-ltreetest=# select path from test where path @ 'Astro* & !pictures@';
+ltreetest=> SELECT path FROM test WHERE path @ 'Astro* & !pictures@';
path
------------------------------------
Top.Science.Astronomy
Top.Science.Astronomy.Astrophysics
Top.Science.Astronomy.Cosmology
(3 rows)
- </programlisting>
+</screen>
+ </para>
<para>
Path construction using functions:
- </para>
- <programlisting>
-ltreetest=# select subpath(path,0,2)||'Space'||subpath(path,2) from test where path <@ 'Top.Science.Astronomy';
+<screen>
+ltreetest=> SELECT subpath(path,0,2)||'Space'||subpath(path,2) FROM test WHERE path <@ 'Top.Science.Astronomy';
?column?
------------------------------------------
Top.Science.Space.Astronomy
Top.Science.Space.Astronomy.Astrophysics
Top.Science.Space.Astronomy.Cosmology
(3 rows)
- </programlisting>
+</screen>
+ </para>
<para>
We could simplify this by creating a SQL function that inserts a label
at a specified position in a path:
- </para>
- <programlisting>
+<screen>
CREATE FUNCTION ins_label(ltree, int, text) RETURNS ltree
-AS 'select subpath($1,0,$2) || $3 || subpath($1,$2);'
-LANGUAGE SQL IMMUTABLE;
+ AS 'select subpath($1,0,$2) || $3 || subpath($1,$2);'
+ LANGUAGE SQL IMMUTABLE;
-ltreetest=# select ins_label(path,2,'Space') from test where path <@ 'Top.Science.Astronomy';
+ltreetest=> SELECT ins_label(path,2,'Space') FROM test WHERE path <@ 'Top.Science.Astronomy';
ins_label
------------------------------------------
Top.Science.Space.Astronomy
Top.Science.Space.Astronomy.Astrophysics
Top.Science.Space.Astronomy.Cosmology
(3 rows)
- </programlisting>
+</screen>
+ </para>
</sect2>
<sect2>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/monitoring.sgml,v 1.80 2010/04/26 19:56:55 tgl Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/monitoring.sgml,v 1.81 2010/07/29 19:34:40 petere Exp $ -->
<chapter id="monitoring">
<title>Monitoring Database Activity</title>
<para>
Add the probe definition to <filename>src/backend/utils/probes.d</>:
<programlisting>
- probe transaction__start(LocalTransactionId);
+probe transaction__start(LocalTransactionId);
</programlisting>
Note the use of the double underline in the probe name. In a DTrace
script using the probe, the double underline needs to be replaced with a
in the source code. In this case, it looks like the following:
<programlisting>
- TRACE_POSTGRESQL_TRANSACTION_START(vxid.localTransactionId);
+TRACE_POSTGRESQL_TRANSACTION_START(vxid.localTransactionId);
</programlisting>
</para>
</step>
is actually enabled:
<programlisting>
- if (TRACE_POSTGRESQL_TRANSACTION_START_ENABLED())
- TRACE_POSTGRESQL_TRANSACTION_START(some_function(...));
+if (TRACE_POSTGRESQL_TRANSACTION_START_ENABLED())
+ TRACE_POSTGRESQL_TRANSACTION_START(some_function(...));
</programlisting>
Each trace macro has a corresponding <literal>ENABLED</> macro.
-<!-- $PostgreSQL: pgsql/doc/src/sgml/oid2name.sgml,v 1.8 2010/05/25 15:55:28 momjian Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/oid2name.sgml,v 1.9 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="oid2name">
<title>oid2name</title>
<sect2>
<title>Examples</title>
- <programlisting>
+<screen>
$ # what's in this database server, anyway?
$ oid2name
All databases:
Filenode Table Name
----------------------
155156 foo
- </programlisting>
+</screen>
</sect2>
<sect2>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/pageinspect.sgml,v 1.6 2009/06/08 16:22:44 tgl Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/pageinspect.sgml,v 1.7 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="pageinspect">
<title>pageinspect</title>
<para>
A page image obtained with <function>get_raw_page</function> should be
passed as argument. For example:
- </para>
- <programlisting>
+<screen>
test=# SELECT * FROM page_header(get_raw_page('pg_class', 0));
lsn | tli | flags | lower | upper | special | pagesize | version | prune_xid
-----------+-----+-------+-------+-------+---------+----------+---------+-----------
0/24A1B50 | 1 | 1 | 232 | 368 | 8192 | 8192 | 4 | 0
- </programlisting>
-
- <para>
+</screen>
The returned columns correspond to the fields in the
<structname>PageHeaderData</> struct.
See <filename>src/include/storage/bufpage.h</> for details.
<para>
A heap page image obtained with <function>get_raw_page</function> should
be passed as argument. For example:
- </para>
- <programlisting>
+<screen>
test=# SELECT * FROM heap_page_items(get_raw_page('pg_class', 0));
- </programlisting>
- <para>
+</screen>
See <filename>src/include/storage/itemid.h</> and
<filename>src/include/access/htup.h</> for explanations of the fields
returned.
<para>
<function>bt_metap</function> returns information about a btree
index's metapage. For example:
- </para>
- <programlisting>
+<screen>
test=# SELECT * FROM bt_metap('pg_cast_oid_index');
-[ RECORD 1 ]-----
magic | 340322
level | 0
fastroot | 1
fastlevel | 0
- </programlisting>
+</screen>
+ </para>
</listitem>
</varlistentry>
<para>
<function>bt_page_stats</function> returns summary information about
single pages of btree indexes. For example:
- </para>
- <programlisting>
+<screen>
test=# SELECT * FROM bt_page_stats('pg_cast_oid_index', 1);
-[ RECORD 1 ]-+-----
blkno | 1
btpo_next | 0
btpo | 0
btpo_flags | 3
- </programlisting>
+</screen>
+ </para>
</listitem>
</varlistentry>
<para>
<function>bt_page_items</function> returns detailed information about
all of the items on a btree index page. For example:
- </para>
- <programlisting>
+<screen>
test=# SELECT * FROM bt_page_items('pg_cast_oid_index', 1);
itemoffset | ctid | itemlen | nulls | vars | data
------------+---------+---------+-------+------+-------------
6 | (0,6) | 12 | f | f | 28 27 00 00
7 | (0,7) | 12 | f | f | 29 27 00 00
8 | (0,8) | 12 | f | f | 2a 27 00 00
- </programlisting>
+</screen>
+ </para>
</listitem>
</varlistentry>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/pgarchivecleanup.sgml,v 1.1 2010/06/14 17:25:24 sriggs Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/pgarchivecleanup.sgml,v 1.2 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="pgarchivecleanup">
<title>pg_archivecleanup</title>
To configure a standby
server to use <application>pg_archivecleanup</>, put this into its
<filename>recovery.conf</filename> configuration file:
- </para>
- <programlisting>
+<programlisting>
archive_cleanup_command = 'pg_archivecleanup <replaceable>archiveDir</> %r'
- </programlisting>
- <para>
+</programlisting>
where <replaceable>archiveDir</> is the directory from which WAL segment
files should be restored.
</para>
</para>
<para>
The full syntax of <application>pg_archivecleanup</>'s command line is
- </para>
- <synopsis>
+<synopsis>
pg_archivecleanup <optional> <replaceable>option</> ... </optional> <replaceable>archivelocation</> <replaceable>restartwalfile</>
- </synopsis>
- <para>
+</synopsis>
When used as a standalone program all WAL files logically preceding the
<literal>restartwalfile</> will be removed <replaceable>archivelocation</>.
In this mode, if you specify a .backup filename, then only the file prefix
all WAL files archived prior to a specific base backup without error.
For example, the following example will remove all files older than
WAL filename 000000010000003700000010:
- </para>
- <programlisting>
+<programlisting>
pg_archivecleanup -d archive 000000010000003700000010.00000020.backup
pg_archivecleanup: keep WAL files 000000010000003700000010 and later
pg_archivecleanup: removing "archive/00000001000000370000000F"
pg_archivecleanup: removing "archive/00000001000000370000000E"
- </programlisting>
- <para>
+</programlisting>
<application>pg_archivecleanup</application> assumes that
<replaceable>archivelocation</> is a directory readable and writable by the
server-owning user.
<sect2>
<title>Examples</title>
- <para>On Linux or Unix systems, you might use:</para>
-
- <programlisting>
+ <para>On Linux or Unix systems, you might use:
+<programlisting>
archive_cleanup_command = 'pg_archivecleanup -d .../archive %r 2>>cleanup.log'
- </programlisting>
- <para>
+</programlisting>
where the archive directory is physically located on the standby server,
so that the <literal>archive_command</> is accessing it across NFS,
but the files are local to the standby.
-<!-- $PostgreSQL: pgsql/doc/src/sgml/pgbench.sgml,v 1.16 2010/05/25 15:55:28 momjian Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/pgbench.sgml,v 1.17 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="pgbench">
<title>pgbench</title>
<para>
Typical output from pgbench looks like:
- <programlisting>
+<screen>
transaction type: TPC-B (sort of)
scaling factor: 10
query mode: simple
number of transactions actually processed: 10000/10000
tps = 85.184871 (including connections establishing)
tps = 85.296346 (excluding connections establishing)
- </programlisting>
+</screen>
The first six lines report some of the most important parameter
settings. The next line reports the number of transactions completed
step, but will instead need to do whatever setup your test needs.)
Initialization looks like:
- <programlisting>
+<programlisting>
pgbench -i <optional> <replaceable>other-options</> </optional> <replaceable>dbname</>
- </programlisting>
+</programlisting>
where <replaceable>dbname</> is the name of the already-created
database to test in. (You may also need <literal>-h</>,
<para>
At the default <quote>scale factor</> of 1, the tables initially
contain this many rows:
- </para>
- <programlisting>
+<screen>
table # of rows
---------------------------------
pgbench_branches 1
pgbench_tellers 10
pgbench_accounts 100000
pgbench_history 0
- </programlisting>
- <para>
+</screen>
You can (and, for most purposes, probably should) increase the number
of rows by using the <literal>-s</> (scale factor) option. The
<literal>-F</> (fillfactor) option might also be used at this point.
Once you have done the necessary setup, you can run your benchmark
with a command that doesn't include <literal>-i</>, that is
- <programlisting>
+<programlisting>
pgbench <optional> <replaceable>options</> </optional> <replaceable>dbname</>
- </programlisting>
+</programlisting>
In nearly all cases, you'll need some options to make a useful test.
The most important options are <literal>-c</> (number of clients),
<para>
Example:
- <programlisting>
+<programlisting>
\set ntellers 10 * :scale
- </programlisting>
+</programlisting>
</para>
</listitem>
</varlistentry>
<para>
Example:
- <programlisting>
+<programlisting>
\setrandom aid 1 :naccounts
- </programlisting>
+</programlisting>
</para>
</listitem>
</varlistentry>
<para>
Example:
- <programlisting>
+<programlisting>
\sleep 10 ms
- </programlisting>
+</programlisting>
</para>
</listitem>
</varlistentry>
<para>
Example:
- <programlisting>
+<programlisting>
\setshell variable_to_be_assigned command literal_argument :variable ::literal_starting_with_colon
- </programlisting>
+</programlisting>
</para>
</listitem>
</varlistentry>
<para>
Example:
- <programlisting>
+<programlisting>
\shell command literal_argument :variable ::literal_starting_with_colon
- </programlisting>
+</programlisting>
</para>
</listitem>
</varlistentry>
As an example, the full definition of the built-in TPC-B-like
transaction is:
- <programlisting>
+<programlisting>
\set nbranches :scale
\set ntellers 10 * :scale
\set naccounts 100000 * :scale
UPDATE pgbench_branches SET bbalance = bbalance + :delta WHERE bid = :bid;
INSERT INTO pgbench_history (tid, bid, aid, delta, mtime) VALUES (:tid, :bid, :aid, :delta, CURRENT_TIMESTAMP);
END;
- </programlisting>
+</programlisting>
This script allows each iteration of the transaction to reference
different, randomly-chosen rows. (This example also shows why it's
<para>
The format of the log is:
- <programlisting>
- <replaceable>client_id</> <replaceable>transaction_no</> <replaceable>time</> <replaceable>file_no</> <replaceable>time_epoch</> <replaceable>time_us</>
- </programlisting>
+<synopsis>
+<replaceable>client_id</> <replaceable>transaction_no</> <replaceable>time</> <replaceable>file_no</> <replaceable>time_epoch</> <replaceable>time_us</>
+</synopsis>
where <replaceable>time</> is the elapsed transaction time in microseconds,
<replaceable>file_no</> identifies which script file was used
<para>
Here are example outputs:
- <programlisting>
+<screen>
0 199 2241 0 1175850568 995598
0 200 2465 0 1175850568 998079
0 201 2513 0 1175850569 608
0 202 2038 0 1175850569 2663
- </programlisting>
+</screen>
</para>
</sect2>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/pgbuffercache.sgml,v 2.6 2010/02/07 20:48:09 tgl Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/pgbuffercache.sgml,v 2.7 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="pgbuffercache">
<title>pg_buffercache</title>
<sect2>
<title>Sample output</title>
- <programlisting>
- regression=# SELECT c.relname, count(*) AS buffers
- FROM pg_buffercache b INNER JOIN pg_class c
- ON b.relfilenode = pg_relation_filenode(c.oid) AND
- b.reldatabase IN (0, (SELECT oid FROM pg_database
- WHERE datname = current_database()))
- GROUP BY c.relname
- ORDER BY 2 DESC
- LIMIT 10;
- relname | buffers
- ---------------------------------+---------
- tenk2 | 345
- tenk1 | 141
- pg_proc | 46
- pg_class | 45
- pg_attribute | 43
- pg_class_relname_nsp_index | 30
- pg_proc_proname_args_nsp_index | 28
- pg_attribute_relid_attnam_index | 26
- pg_depend | 22
- pg_depend_reference_index | 20
- (10 rows)
- </programlisting>
+<screen>
+regression=# SELECT c.relname, count(*) AS buffers
+ FROM pg_buffercache b INNER JOIN pg_class c
+ ON b.relfilenode = pg_relation_filenode(c.oid) AND
+ b.reldatabase IN (0, (SELECT oid FROM pg_database
+ WHERE datname = current_database()))
+ GROUP BY c.relname
+ ORDER BY 2 DESC
+ LIMIT 10;
+
+ relname | buffers
+---------------------------------+---------
+ tenk2 | 345
+ tenk1 | 141
+ pg_proc | 46
+ pg_class | 45
+ pg_attribute | 43
+ pg_class_relname_nsp_index | 30
+ pg_proc_proname_args_nsp_index | 28
+ pg_attribute_relid_attnam_index | 26
+ pg_depend | 22
+ pg_depend_reference_index | 20
+(10 rows)
+</screen>
</sect2>
<sect2>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/pgcrypto.sgml,v 1.9 2010/06/29 22:29:14 momjian Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/pgcrypto.sgml,v 1.10 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="pgcrypto">
<title>pgcrypto</title>
<sect3>
<title><function>digest()</function></title>
- <synopsis>
- digest(data text, type text) returns bytea
- digest(data bytea, type text) returns bytea
- </synopsis>
+<synopsis>
+digest(data text, type text) returns bytea
+digest(data bytea, type text) returns bytea
+</synopsis>
<para>
Computes a binary hash of the given <parameter>data</>.
<para>
If you want the digest as a hexadecimal string, use
<function>encode()</> on the result. For example:
+<programlisting>
+CREATE OR REPLACE FUNCTION sha1(bytea) returns text AS $$
+ SELECT encode(digest($1, 'sha1'), 'hex')
+$$ LANGUAGE SQL STRICT IMMUTABLE;
+</programlisting>
</para>
- <programlisting>
- CREATE OR REPLACE FUNCTION sha1(bytea) returns text AS $$
- SELECT encode(digest($1, 'sha1'), 'hex')
- $$ LANGUAGE SQL STRICT IMMUTABLE;
- </programlisting>
</sect3>
<sect3>
<title><function>hmac()</function></title>
- <synopsis>
- hmac(data text, key text, type text) returns bytea
- hmac(data bytea, key text, type text) returns bytea
- </synopsis>
+<synopsis>
+hmac(data text, key text, type text) returns bytea
+hmac(data bytea, key text, type text) returns bytea
+</synopsis>
<para>
Calculates hashed MAC for <parameter>data</> with key <parameter>key</>.
<sect3>
<title><function>crypt()</></title>
- <synopsis>
- crypt(password text, salt text) returns text
- </synopsis>
+<synopsis>
+crypt(password text, salt text) returns text
+</synopsis>
<para>
Calculates a crypt(3)-style hash of <parameter>password</>.
</para>
<para>
Example of setting a new password:
+<programlisting>
+UPDATE ... SET pswhash = crypt('new password', gen_salt('md5'));
+</programlisting>
</para>
- <programlisting>
- UPDATE ... SET pswhash = crypt('new password', gen_salt('md5'));
- </programlisting>
<para>
Example of authentication:
- </para>
- <programlisting>
- SELECT pswhash = crypt('entered password', pswhash) FROM ... ;
- </programlisting>
- <para>
+<programlisting>
+SELECT pswhash = crypt('entered password', pswhash) FROM ... ;
+</programlisting>
This returns <literal>true</> if the entered password is correct.
</para>
</sect3>
<sect3>
<title><function>gen_salt()</></title>
- <synopsis>
- gen_salt(type text [, iter_count integer ]) returns text
- </synopsis>
+<synopsis>
+gen_salt(type text [, iter_count integer ]) returns text
+</synopsis>
<para>
Generates a new random salt string for use in <function>crypt()</>.
<sect3>
<title><function>pgp_sym_encrypt()</function></title>
- <synopsis>
- pgp_sym_encrypt(data text, psw text [, options text ]) returns bytea
- pgp_sym_encrypt_bytea(data bytea, psw text [, options text ]) returns bytea
- </synopsis>
+<synopsis>
+pgp_sym_encrypt(data text, psw text [, options text ]) returns bytea
+pgp_sym_encrypt_bytea(data bytea, psw text [, options text ]) returns bytea
+</synopsis>
<para>
Encrypt <parameter>data</> with a symmetric PGP key <parameter>psw</>.
The <parameter>options</> parameter can contain option settings,
<sect3>
<title><function>pgp_sym_decrypt()</function></title>
- <synopsis>
- pgp_sym_decrypt(msg bytea, psw text [, options text ]) returns text
- pgp_sym_decrypt_bytea(msg bytea, psw text [, options text ]) returns bytea
- </synopsis>
+<synopsis>
+pgp_sym_decrypt(msg bytea, psw text [, options text ]) returns text
+pgp_sym_decrypt_bytea(msg bytea, psw text [, options text ]) returns bytea
+</synopsis>
<para>
Decrypt a symmetric-key-encrypted PGP message.
</para>
<sect3>
<title><function>pgp_pub_encrypt()</function></title>
- <synopsis>
- pgp_pub_encrypt(data text, key bytea [, options text ]) returns bytea
- pgp_pub_encrypt_bytea(data bytea, key bytea [, options text ]) returns bytea
- </synopsis>
+<synopsis>
+pgp_pub_encrypt(data text, key bytea [, options text ]) returns bytea
+pgp_pub_encrypt_bytea(data bytea, key bytea [, options text ]) returns bytea
+</synopsis>
<para>
Encrypt <parameter>data</> with a public PGP key <parameter>key</>.
Giving this function a secret key will produce a error.
<sect3>
<title><function>pgp_pub_decrypt()</function></title>
- <synopsis>
- pgp_pub_decrypt(msg bytea, key bytea [, psw text [, options text ]]) returns text
- pgp_pub_decrypt_bytea(msg bytea, key bytea [, psw text [, options text ]]) returns bytea
- </synopsis>
+<synopsis>
+pgp_pub_decrypt(msg bytea, key bytea [, psw text [, options text ]]) returns text
+pgp_pub_decrypt_bytea(msg bytea, key bytea [, psw text [, options text ]]) returns bytea
+</synopsis>
<para>
Decrypt a public-key-encrypted message. <parameter>key</> must be the
secret key corresponding to the public key that was used to encrypt.
<sect3>
<title><function>pgp_key_id()</function></title>
- <synopsis>
- pgp_key_id(bytea) returns text
- </synopsis>
+<synopsis>
+pgp_key_id(bytea) returns text
+</synopsis>
<para>
<function>pgp_key_id</> extracts the key ID of a PGP public or secret key.
Or it gives the key ID that was used for encrypting the data, if given
<sect3>
<title><function>armor()</function>, <function>dearmor()</function></title>
- <synopsis>
- armor(data bytea) returns text
- dearmor(data text) returns bytea
- </synopsis>
+<synopsis>
+armor(data bytea) returns text
+dearmor(data text) returns bytea
+</synopsis>
<para>
These functions wrap/unwrap binary data into PGP Ascii Armor format,
which is basically Base64 with CRC and additional formatting.
Options are named to be similar to GnuPG. An option's value should be
given after an equal sign; separate options from each other with commas.
For example:
+<programlisting>
+pgp_sym_encrypt(data, psw, 'compress-algo=1, cipher-algo=aes256')
+</programlisting>
</para>
- <programlisting>
- pgp_sym_encrypt(data, psw, 'compress-algo=1, cipher-algo=aes256')
- </programlisting>
<para>
All of the options except <literal>convert-crlf</literal> apply only to
<para>
Which cipher algorithm to use.
</para>
- <programlisting>
- Values: bf, aes128, aes192, aes256 (OpenSSL-only: <literal>3des</literal>, <literal>cast5</literal>)
- Default: aes128
- Applies to: pgp_sym_encrypt, pgp_pub_encrypt
- </programlisting>
+<literallayout>
+Values: bf, aes128, aes192, aes256 (OpenSSL-only: <literal>3des</literal>, <literal>cast5</literal>)
+Default: aes128
+Applies to: pgp_sym_encrypt, pgp_pub_encrypt
+</literallayout>
</sect4>
<sect4>
Which compression algorithm to use. Only available if
<productname>PostgreSQL</productname> was built with zlib.
</para>
- <programlisting>
- Values:
- 0 - no compression
- 1 - ZIP compression
- 2 - ZLIB compression (= ZIP plus meta-data and block CRCs)
- Default: 0
- Applies to: pgp_sym_encrypt, pgp_pub_encrypt
- </programlisting>
+<literallayout>
+Values:
+ 0 - no compression
+ 1 - ZIP compression
+ 2 - ZLIB compression (= ZIP plus meta-data and block CRCs)
+Default: 0
+Applies to: pgp_sym_encrypt, pgp_pub_encrypt
+</literallayout>
</sect4>
<sect4>
How much to compress. Higher levels compress smaller but are slower.
0 disables compression.
</para>
- <programlisting>
- Values: 0, 1-9
- Default: 6
- Applies to: pgp_sym_encrypt, pgp_pub_encrypt
- </programlisting>
+<literallayout>
+Values: 0, 1-9
+Default: 6
+Applies to: pgp_sym_encrypt, pgp_pub_encrypt
+</literallayout>
</sect4>
<sect4>
<literal>\r\n</literal> line-feeds. Use this to get fully RFC-compliant
behavior.
</para>
- <programlisting>
- Values: 0, 1
- Default: 0
- Applies to: pgp_sym_encrypt, pgp_pub_encrypt, pgp_sym_decrypt, pgp_pub_decrypt
- </programlisting>
+<literallayout>
+Values: 0, 1
+Default: 0
+Applies to: pgp_sym_encrypt, pgp_pub_encrypt, pgp_sym_decrypt, pgp_pub_decrypt
+</literallayout>
</sect4>
<sect4>
the addition of SHA-1 protected packets to RFC 4880.
Recent gnupg.org and pgp.com software supports it fine.
</para>
- <programlisting>
- Values: 0, 1
- Default: 0
- Applies to: pgp_sym_encrypt, pgp_pub_encrypt
- </programlisting>
+<literallayout>
+Values: 0, 1
+Default: 0
+Applies to: pgp_sym_encrypt, pgp_pub_encrypt
+</literallayout>
</sect4>
<sect4>
session key; this is for symmetric-key encryption, which by default
uses the S2K key directly.
</para>
- <programlisting>
- Values: 0, 1
- Default: 0
- Applies to: pgp_sym_encrypt
- </programlisting>
+<literallayout>
+Values: 0, 1
+Default: 0
+Applies to: pgp_sym_encrypt
+</literallayout>
</sect4>
<sect4>
<para>
Which S2K algorithm to use.
</para>
- <programlisting>
- Values:
- 0 - Without salt. Dangerous!
- 1 - With salt but with fixed iteration count.
- 3 - Variable iteration count.
- Default: 3
- Applies to: pgp_sym_encrypt
- </programlisting>
+<literallayout>
+Values:
+ 0 - Without salt. Dangerous!
+ 1 - With salt but with fixed iteration count.
+ 3 - Variable iteration count.
+Default: 3
+Applies to: pgp_sym_encrypt
+</literallayout>
</sect4>
<sect4>
<para>
Which digest algorithm to use in S2K calculation.
</para>
- <programlisting>
- Values: md5, sha1
- Default: sha1
- Applies to: pgp_sym_encrypt
- </programlisting>
+<literallayout>
+Values: md5, sha1
+Default: sha1
+Applies to: pgp_sym_encrypt
+</literallayout>
</sect4>
<sect4>
<para>
Which cipher to use for encrypting separate session key.
</para>
- <programlisting>
- Values: bf, aes, aes128, aes192, aes256
- Default: use cipher-algo
- Applies to: pgp_sym_encrypt
- </programlisting>
+<literallayout>
+Values: bf, aes, aes128, aes192, aes256
+Default: use cipher-algo
+Applies to: pgp_sym_encrypt
+</literallayout>
</sect4>
<sect4>
be done, but the message will be tagged as UTF-8. Without this option
it will not be.
</para>
- <programlisting>
- Values: 0, 1
- Default: 0
- Applies to: pgp_sym_encrypt, pgp_pub_encrypt
- </programlisting>
+<literallayout>
+Values: 0, 1
+Default: 0
+Applies to: pgp_sym_encrypt, pgp_pub_encrypt
+</literallayout>
</sect4>
</sect3>
<para>
To generate a new key:
+<programlisting>
+gpg --gen-key
+</programlisting>
</para>
- <programlisting>
- gpg --gen-key
- </programlisting>
<para>
The preferred key type is <quote>DSA and Elgamal</>.
</para>
</para>
<para>
To list keys:
+<programlisting>
+gpg --list-secret-keys
+</programlisting>
</para>
- <programlisting>
- gpg --list-secret-keys
- </programlisting>
<para>
To export a public key in ascii-armor format:
+<programlisting>
+gpg -a --export KEYID > public.key
+</programlisting>
</para>
- <programlisting>
- gpg -a --export KEYID > public.key
- </programlisting>
<para>
To export a secret key in ascii-armor format:
+<programlisting>
+gpg -a --export-secret-keys KEYID > secret.key
+</programlisting>
</para>
- <programlisting>
- gpg -a --export-secret-keys KEYID > secret.key
- </programlisting>
<para>
You need to use <function>dearmor()</> on these keys before giving them to
the PGP functions. Or if you can handle binary data, you can drop
encryption functions is discouraged.
</para>
- <synopsis>
- encrypt(data bytea, key bytea, type text) returns bytea
- decrypt(data bytea, key bytea, type text) returns bytea
+<synopsis>
+encrypt(data bytea, key bytea, type text) returns bytea
+decrypt(data bytea, key bytea, type text) returns bytea
- encrypt_iv(data bytea, key bytea, iv bytea, type text) returns bytea
- decrypt_iv(data bytea, key bytea, iv bytea, type text) returns bytea
- </synopsis>
+encrypt_iv(data bytea, key bytea, iv bytea, type text) returns bytea
+decrypt_iv(data bytea, key bytea, iv bytea, type text) returns bytea
+</synopsis>
<para>
Encrypt/decrypt data using the cipher method specified by
<parameter>type</parameter>. The syntax of the
<parameter>type</parameter> string is:
- </para>
- <synopsis>
- <replaceable>algorithm</> <optional> <literal>-</> <replaceable>mode</> </optional> <optional> <literal>/pad:</> <replaceable>padding</> </optional>
- </synopsis>
-
- <para>
+<synopsis>
+<replaceable>algorithm</> <optional> <literal>-</> <replaceable>mode</> </optional> <optional> <literal>/pad:</> <replaceable>padding</> </optional>
+</synopsis>
where <replaceable>algorithm</> is one of:
- </para>
+
<itemizedlist>
<listitem><para><literal>bf</literal> — Blowfish</para></listitem>
<listitem><para><literal>aes</literal> — AES (Rijndael-128)</para></listitem>
</itemizedlist>
- <para>
and <replaceable>mode</> is one of:
- </para>
<itemizedlist>
<listitem>
<para>
</para>
</listitem>
</itemizedlist>
- <para>
and <replaceable>padding</> is one of:
- </para>
<itemizedlist>
<listitem>
<para>
</para>
</listitem>
</itemizedlist>
+ </para>
<para>
So, for example, these are equivalent:
+<programlisting>
+encrypt(data, 'fooz', 'bf')
+encrypt(data, 'fooz', 'bf-cbc/pad:pkcs')
+</programlisting>
</para>
- <programlisting>
- encrypt(data, 'fooz', 'bf')
- encrypt(data, 'fooz', 'bf-cbc/pad:pkcs')
- </programlisting>
<para>
In <function>encrypt_iv</> and <function>decrypt_iv</>, the
<parameter>iv</> parameter is the initial value for the CBC mode;
<sect2>
<title>Random-data functions</title>
- <synopsis>
- gen_random_bytes(count integer) returns bytea
- </synopsis>
+<synopsis>
+gen_random_bytes(count integer) returns bytea
+</synopsis>
<para>
Returns <parameter>count</> cryptographically strong random bytes.
At most 1024 bytes can be extracted at a time. This is to avoid
-<!-- $PostgreSQL: pgsql/doc/src/sgml/pgfreespacemap.sgml,v 2.6 2010/04/23 23:21:43 rhaas Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/pgfreespacemap.sgml,v 2.7 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="pgfreespacemap">
<title>pg_freespacemap</title>
<sect2>
<title>Sample output</title>
- <programlisting>
+<screen>
postgres=# SELECT * FROM pg_freespace('foo');
blkno | avail
-------+-------
--------------
1216
(1 row)
-
- </programlisting>
+</screen>
</sect2>
<sect2>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/pgrowlocks.sgml,v 1.5 2009/05/18 11:08:24 petere Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/pgrowlocks.sgml,v 1.6 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="pgrowlocks">
<title>pgrowlocks</title>
rows. If you want to take a look at the row contents at the same time, you
could do something like this:
- <programlisting>
+<programlisting>
SELECT * FROM accounts AS a, pgrowlocks('accounts') AS p
WHERE p.locked_row = a.ctid;
- </programlisting>
+</programlisting>
Be aware however that (as of <productname>PostgreSQL</> 8.3) such a
query will be very inefficient.
<sect2>
<title>Sample output</title>
- <programlisting>
+<screen>
test=# SELECT * FROM pgrowlocks('t1');
locked_row | lock_type | locker | multi | xids | pids
------------+-----------+--------+-------+-----------+---------------
(0,3) | Exclusive | 804 | f | {804} | {29066}
(0,4) | Exclusive | 804 | f | {804} | {29066}
(4 rows)
- </programlisting>
+</screen>
</sect2>
<sect2>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/pgstandby.sgml,v 2.11 2010/05/25 15:55:28 momjian Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/pgstandby.sgml,v 2.12 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="pgstandby">
<title>pg_standby</title>
To configure a standby
server to use <application>pg_standby</>, put this into its
<filename>recovery.conf</filename> configuration file:
- </para>
- <programlisting>
+<programlisting>
restore_command = 'pg_standby <replaceable>archiveDir</> %f %p %r'
- </programlisting>
- <para>
+</programlisting>
where <replaceable>archiveDir</> is the directory from which WAL segment
files should be restored.
</para>
<para>
The full syntax of <application>pg_standby</>'s command line is
- </para>
- <synopsis>
+<synopsis>
pg_standby <optional> <replaceable>option</> ... </optional> <replaceable>archivelocation</> <replaceable>nextwalfile</> <replaceable>xlogfilepath</> <optional> <replaceable>restartwalfile</> </optional>
- </synopsis>
- <para>
+</synopsis>
When used within <literal>restore_command</literal>, the <literal>%f</> and
<literal>%p</> macros should be specified for <replaceable>nextwalfile</>
and <replaceable>xlogfilepath</> respectively, to provide the actual file
<sect2>
<title>Examples</title>
- <para>On Linux or Unix systems, you might use:</para>
+ <para>On Linux or Unix systems, you might use:
- <programlisting>
+<programlisting>
archive_command = 'cp %p .../archive/%f'
restore_command = 'pg_standby -d -s 2 -t /tmp/pgsql.trigger.5442 .../archive %f %p %r 2>>standby.log'
recovery_end_command = 'rm -f /tmp/pgsql.trigger.5442'
- </programlisting>
- <para>
+</programlisting>
where the archive directory is physically located on the standby server,
so that the <literal>archive_command</> is accessing it across NFS,
but the files are local to the standby (enabling use of <literal>ln</>).
This will:
- </para>
<itemizedlist>
<listitem>
<para>
</para>
</listitem>
</itemizedlist>
+ </para>
- <para>On Windows, you might use:</para>
+ <para>On Windows, you might use:
- <programlisting>
+<programlisting>
archive_command = 'copy %p ...\\archive\\%f'
restore_command = 'pg_standby -d -s 5 -t C:\pgsql.trigger.5442 ...\archive %f %p %r 2>>standby.log'
recovery_end_command = 'del C:\pgsql.trigger.5442'
- </programlisting>
- <para>
+</programlisting>
Note that backslashes need to be doubled in the
<literal>archive_command</>, but <emphasis>not</emphasis> in the
<literal>restore_command</> or <literal>recovery_end_command</>.
This will:
- </para>
<itemizedlist>
<listitem>
<para>
</para>
</listitem>
</itemizedlist>
+ </para>
<para>
The <literal>copy</> command on Windows sets the final file size
-<!-- $PostgreSQL: pgsql/doc/src/sgml/pgstatstatements.sgml,v 1.6 2010/01/08 00:38:20 itagaki Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/pgstatstatements.sgml,v 1.7 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="pgstatstatements">
<title>pg_stat_statements</title>
<filename>postgresql.conf</> file,
you will need to add <literal>pg_stat_statements</> to
<xref linkend="guc-custom-variable-classes">. Typical usage might be:
- </para>
- <programlisting>
+<programlisting>
# postgresql.conf
shared_preload_libraries = 'pg_stat_statements'
custom_variable_classes = 'pg_stat_statements'
pg_stat_statements.max = 10000
pg_stat_statements.track = all
- </programlisting>
+</programlisting>
+ </para>
</sect2>
<sect2>
<title>Sample output</title>
- <programlisting>
+<screen>
bench=# SELECT pg_stat_statements_reset();
$ pgbench -i bench
total_time | 0.08142
rows | 0
hit_percent | 34.4947735191637631
- </programlisting>
+</screen>
</sect2>
<sect2>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/pgstattuple.sgml,v 1.5 2009/05/18 11:08:24 petere Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/pgstattuple.sgml,v 1.6 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="pgstattuple">
<title>pgstattuple</title>
<para>
<function>pgstatindex</function> returns a record showing information
about a btree index. For example:
- </para>
- <programlisting>
+<programlisting>
test=> SELECT * FROM pgstatindex('pg_cast_oid_index');
-[ RECORD 1 ]------+------
version | 2
deleted_pages | 0
avg_leaf_density | 50.27
leaf_fragmentation | 0
- </programlisting>
+</programlisting>
+ </para>
<para>
The output columns are:
-<!-- $PostgreSQL: pgsql/doc/src/sgml/pgtrgm.sgml,v 2.2 2007/12/10 05:32:51 tgl Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/pgtrgm.sgml,v 2.3 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="pgtrgm">
<title>pg_trgm</title>
<para>
Example:
- <programlisting>
+<programlisting>
CREATE TABLE test_trgm (t text);
CREATE INDEX trgm_idx ON test_trgm USING gist (t gist_trgm_ops);
- </programlisting>
+</programlisting>
or
- <programlisting>
+<programlisting>
CREATE INDEX trgm_idx ON test_trgm USING gin (t gin_trgm_ops);
- </programlisting>
+</programlisting>
</para>
<para>
At this point, you will have an index on the <structfield>t</> column that
you can use for similarity searching. A typical query is
- </para>
- <programlisting>
+<programlisting>
SELECT t, similarity(t, '<replaceable>word</>') AS sml
FROM test_trgm
WHERE t % '<replaceable>word</>'
ORDER BY sml DESC, t;
- </programlisting>
- <para>
+</programlisting>
This will return all values in the text column that are sufficiently
similar to <replaceable>word</>, sorted from best match to worst. The
index will be used to make this a fast operation even over very large data
<para>
The first step is to generate an auxiliary table containing all
the unique words in the documents:
- </para>
- <programlisting>
+<programlisting>
CREATE TABLE words AS SELECT word FROM
ts_stat('SELECT to_tsvector(''simple'', bodytext) FROM documents');
- </programlisting>
+</programlisting>
- <para>
where <structname>documents</> is a table that has a text field
<structfield>bodytext</> that we wish to search. The reason for using
the <literal>simple</> configuration with the <function>to_tsvector</>
<para>
Next, create a trigram index on the word column:
- </para>
- <programlisting>
+<programlisting>
CREATE INDEX words_idx ON words USING gin(word gin_trgm_ops);
- </programlisting>
+</programlisting>
- <para>
Now, a <command>SELECT</command> query similar to the previous example can
be used to suggest spellings for misspelled words in user search terms.
A useful extra test is to require that the selected words are also of
-<!-- $PostgreSQL: pgsql/doc/src/sgml/plperl.sgml,v 2.86 2010/07/08 21:35:33 petere Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/plperl.sgml,v 2.87 2010/07/29 19:34:40 petere Exp $ -->
<chapter id="plperl">
<title>PL/Perl - Perl Procedural Language</title>
The advantage of prepared queries is that is it possible to use one prepared plan for more
than one query execution. After the plan is not needed anymore, it can be freed with
<literal>spi_freeplan</literal>:
- </para>
-
- <para>
- <programlisting>
+<programlisting>
CREATE OR REPLACE FUNCTION init() RETURNS VOID AS $$
$_SHARED{my_plan} = spi_prepare('SELECT (now() + $1)::date AS now',
'INTERVAL');
add_time | add_time | add_time
------------+------------+------------
2005-12-10 | 2005-12-11 | 2005-12-12
- </programlisting>
- </para>
-
- <para>
+</programlisting>
Note that the parameter subscript in <literal>spi_prepare</literal> is defined via
$1, $2, $3, etc, so avoid declaring query strings in double quotes that might easily
lead to hard-to-catch bugs.
<para>
Another example illustrates usage of an optional parameter in <literal>spi_exec_prepared</literal>:
- </para>
-
- <para>
- <programlisting>
+<programlisting>
CREATE TABLE hosts AS SELECT id, ('192.168.1.'||id)::inet AS address
FROM generate_series(1,3) AS id;
CREATE OR REPLACE FUNCTION init_hosts_query() RETURNS VOID AS $$
- $_SHARED{plan} = spi_prepare('SELECT * FROM hosts
+ $_SHARED{plan} = spi_prepare('SELECT * FROM hosts
WHERE address << $1', 'inet');
$$ LANGUAGE plperl;
(1,192.168.1.1)
(2,192.168.1.2)
(2 rows)
- </programlisting>
+</programlisting>
</para>
</listitem>
</varlistentry>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.155 2010/07/27 20:02:06 rhaas Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.156 2010/07/29 19:34:40 petere Exp $ -->
<chapter id="plpgsql">
<title><application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language</title>
As always, care must be taken to ensure that null values in a query do
not deliver unintended results. For example the <literal>WHERE</> clause
<programlisting>
- 'WHERE key = ' || quote_nullable(keyvalue)
+'WHERE key = ' || quote_nullable(keyvalue)
</programlisting>
will never succeed if <literal>keyvalue</> is null, because the
result of using the equality operator <literal>=</> with a null operand
is always null. If you wish null to work like an ordinary key value,
you would need to rewrite the above as
<programlisting>
- 'WHERE key IS NOT DISTINCT FROM ' || quote_nullable(keyvalue)
+'WHERE key IS NOT DISTINCT FROM ' || quote_nullable(keyvalue)
</programlisting>
(At present, <literal>IS NOT DISTINCT FROM</> is handled much less
efficiently than <literal>=</>, so don't do this unless you must.
<para>
For example, the following two fragments of code are equivalent:
<programlisting>
- BEGIN
- y := x / 0;
- EXCEPTION
- WHEN division_by_zero THEN
- NULL; -- ignore the error
- END;
+BEGIN
+ y := x / 0;
+EXCEPTION
+ WHEN division_by_zero THEN
+ NULL; -- ignore the error
+END;
</programlisting>
<programlisting>
- BEGIN
- y := x / 0;
- EXCEPTION
- WHEN division_by_zero THEN -- ignore the error
- END;
+BEGIN
+ y := x / 0;
+EXCEPTION
+ WHEN division_by_zero THEN -- ignore the error
+END;
</programlisting>
Which is preferable is a matter of taste.
</para>
not case-sensitive. Also, an error condition can be specified
by <literal>SQLSTATE</> code; for example these are equivalent:
<programlisting>
- WHEN division_by_zero THEN ...
- WHEN SQLSTATE '22012' THEN ...
+WHEN division_by_zero THEN ...
+WHEN SQLSTATE '22012' THEN ...
</programlisting>
</para>
As an example, consider this fragment:
<programlisting>
- INSERT INTO mytab(firstname, lastname) VALUES('Tom', 'Jones');
- BEGIN
- UPDATE mytab SET firstname = 'Joe' WHERE lastname = 'Jones';
- x := x + 1;
- y := x / 0;
- EXCEPTION
- WHEN division_by_zero THEN
- RAISE NOTICE 'caught division_by_zero';
- RETURN x;
- END;
+INSERT INTO mytab(firstname, lastname) VALUES('Tom', 'Jones');
+BEGIN
+ UPDATE mytab SET firstname = 'Joe' WHERE lastname = 'Jones';
+ x := x + 1;
+ y := x / 0;
+EXCEPTION
+ WHEN division_by_zero THEN
+ RAISE NOTICE 'caught division_by_zero';
+ RETURN x;
+END;
</programlisting>
When control reaches the assignment to <literal>y</>, it will
column reference is syntactically allowed. As an extreme case, consider
this example of poor programming style:
<programlisting>
- INSERT INTO foo (foo) VALUES (foo);
+INSERT INTO foo (foo) VALUES (foo);
</programlisting>
The first occurrence of <literal>foo</> must syntactically be a table
name, so it will not be substituted, even if the function has a variable
tables: is a given name meant to refer to a table column, or a variable?
Let's change the previous example to
<programlisting>
- INSERT INTO dest (col) SELECT foo + bar FROM src;
+INSERT INTO dest (col) SELECT foo + bar FROM src;
</programlisting>
Here, <literal>dest</> and <literal>src</> must be table names, and
<literal>col</> must be a column of <literal>dest</>, but <literal>foo</>
declare it in a labeled block and use the block's label
(see <xref linkend="plpgsql-structure">). For example,
<programlisting>
- <<block>>
- DECLARE
- foo int;
- BEGIN
- foo := ...;
- INSERT INTO dest (col) SELECT block.foo + bar FROM src;
+<<block>>
+DECLARE
+ foo int;
+BEGIN
+ foo := ...;
+ INSERT INTO dest (col) SELECT block.foo + bar FROM src;
</programlisting>
Here <literal>block.foo</> means the variable even if there is a column
<literal>foo</> in <literal>src</>. Function parameters, as well as
is equivalent to what you'd get in Oracle with:
<programlisting>
- BEGIN
- SAVEPOINT s1;
+BEGIN
+ SAVEPOINT s1;
+ ... code here ...
+EXCEPTION
+ WHEN ... THEN
+ ROLLBACK TO s1;
... code here ...
- EXCEPTION
- WHEN ... THEN
- ROLLBACK TO s1;
- ... code here ...
- WHEN ... THEN
- ROLLBACK TO s1;
- ... code here ...
- END;
+ WHEN ... THEN
+ ROLLBACK TO s1;
+ ... code here ...
+END;
</programlisting>
If you are translating an Oracle procedure that uses
<!--
-$PostgreSQL: pgsql/doc/src/sgml/ref/alter_domain.sgml,v 1.25 2010/04/03 07:22:56 petere Exp $
+$PostgreSQL: pgsql/doc/src/sgml/ref/alter_domain.sgml,v 1.26 2010/07/29 19:34:40 petere Exp $
PostgreSQL documentation
-->
</indexterm>
<refsynopsisdiv>
- <synopsis>
+<synopsis>
ALTER DOMAIN <replaceable class="PARAMETER">name</replaceable>
{ SET DEFAULT <replaceable class="PARAMETER">expression</replaceable> | DROP DEFAULT }
ALTER DOMAIN <replaceable class="PARAMETER">name</replaceable>
OWNER TO <replaceable class="PARAMETER">new_owner</replaceable>
ALTER DOMAIN <replaceable class="PARAMETER">name</replaceable>
SET SCHEMA <replaceable class="PARAMETER">new_schema</replaceable>
- </synopsis>
+</synopsis>
</refsynopsisdiv>
<refsect1>
<para>
To add a <literal>NOT NULL</literal> constraint to a domain:
- <programlisting>
+<programlisting>
ALTER DOMAIN zipcode SET NOT NULL;
- </programlisting>
+</programlisting>
To remove a <literal>NOT NULL</literal> constraint from a domain:
- <programlisting>
+<programlisting>
ALTER DOMAIN zipcode DROP NOT NULL;
- </programlisting>
+</programlisting>
</para>
- <para>
+ <para>
To add a check constraint to a domain:
- <programlisting>
+<programlisting>
ALTER DOMAIN zipcode ADD CONSTRAINT zipchk CHECK (char_length(VALUE) = 5);
- </programlisting>
+</programlisting>
</para>
- <para>
+ <para>
To remove a check constraint from a domain:
- <programlisting>
+<programlisting>
ALTER DOMAIN zipcode DROP CONSTRAINT zipchk;
- </programlisting>
+</programlisting>
</para>
<para>
To move the domain into a different schema:
- <programlisting>
+<programlisting>
ALTER DOMAIN zipcode SET SCHEMA customers;
- </programlisting>
+</programlisting>
</para>
</refsect1>
<!--
-$PostgreSQL: pgsql/doc/src/sgml/ref/alter_sequence.sgml,v 1.25 2010/04/03 07:22:57 petere Exp $
+$PostgreSQL: pgsql/doc/src/sgml/ref/alter_sequence.sgml,v 1.26 2010/07/29 19:34:40 petere Exp $
PostgreSQL documentation
-->
</indexterm>
<refsynopsisdiv>
- <synopsis>
+<synopsis>
ALTER SEQUENCE <replaceable class="parameter">name</replaceable> [ INCREMENT [ BY ] <replaceable class="parameter">increment</replaceable> ]
[ MINVALUE <replaceable class="parameter">minvalue</replaceable> | NO MINVALUE ] [ MAXVALUE <replaceable class="parameter">maxvalue</replaceable> | NO MAXVALUE ]
[ START [ WITH ] <replaceable class="parameter">start</replaceable> ]
ALTER SEQUENCE <replaceable class="parameter">name</replaceable> OWNER TO <replaceable class="PARAMETER">new_owner</replaceable>
ALTER SEQUENCE <replaceable class="parameter">name</replaceable> RENAME TO <replaceable class="parameter">new_name</replaceable>
ALTER SEQUENCE <replaceable class="parameter">name</replaceable> SET SCHEMA <replaceable class="parameter">new_schema</replaceable>
- </synopsis>
+</synopsis>
</refsynopsisdiv>
<refsect1>
<!--
-$PostgreSQL: pgsql/doc/src/sgml/ref/alter_type.sgml,v 1.8 2010/04/03 07:22:57 petere Exp $
+$PostgreSQL: pgsql/doc/src/sgml/ref/alter_type.sgml,v 1.9 2010/07/29 19:34:40 petere Exp $
PostgreSQL documentation
-->
</indexterm>
<refsynopsisdiv>
- <synopsis>
+<synopsis>
ALTER TYPE <replaceable class="PARAMETER">name</replaceable> RENAME TO <replaceable class="PARAMETER">new_name</replaceable>
ALTER TYPE <replaceable class="PARAMETER">name</replaceable> OWNER TO <replaceable class="PARAMETER">new_owner</replaceable>
ALTER TYPE <replaceable class="PARAMETER">name</replaceable> SET SCHEMA <replaceable class="PARAMETER">new_schema</replaceable>
- </synopsis>
+</synopsis>
</refsynopsisdiv>
<refsect1>
<refsect1>
<title>Examples</title>
- <para>
+ <para>
To rename a data type:
- <programlisting>
+<programlisting>
ALTER TYPE electronic_mail RENAME TO email;
- </programlisting>
+</programlisting>
</para>
- <para>
+ <para>
To change the owner of the type <literal>email</literal>
to <literal>joe</literal>:
- <programlisting>
+<programlisting>
ALTER TYPE email OWNER TO joe;
- </programlisting>
+</programlisting>
</para>
<para>
To change the schema of the type <literal>email</literal>
to <literal>customers</literal>:
- <programlisting>
+<programlisting>
ALTER TYPE email SET SCHEMA customers;
- </programlisting>
+</programlisting>
</para>
</refsect1>
<!--
-$PostgreSQL: pgsql/doc/src/sgml/ref/create_index.sgml,v 1.74 2010/04/03 07:22:58 petere Exp $
+$PostgreSQL: pgsql/doc/src/sgml/ref/create_index.sgml,v 1.75 2010/07/29 19:34:40 petere Exp $
PostgreSQL documentation
-->
To create a GiST index on a point attribute so that we
can efficiently use box operators on the result of the
conversion function:
- <programlisting>
+<programlisting>
CREATE INDEX pointloc
ON points USING gist (box(location,location));
SELECT * FROM points
WHERE box(location,location) && '(0,0),(1,1)'::box;
- </programlisting>
+</programlisting>
</para>
<para>
<!--
-$PostgreSQL: pgsql/doc/src/sgml/ref/grant.sgml,v 1.83 2010/04/03 07:23:01 petere Exp $
+$PostgreSQL: pgsql/doc/src/sgml/ref/grant.sgml,v 1.84 2010/07/29 19:34:41 petere Exp $
PostgreSQL documentation
-->
(1 row)
</programlisting>
The entries shown by <command>\dp</command> are interpreted thus:
-<programlisting>
- rolename=xxxx -- privileges granted to a role
- =xxxx -- privileges granted to PUBLIC
-
- r -- SELECT ("read")
- w -- UPDATE ("write")
- a -- INSERT ("append")
- d -- DELETE
- D -- TRUNCATE
- x -- REFERENCES
- t -- TRIGGER
- X -- EXECUTE
- U -- USAGE
- C -- CREATE
- c -- CONNECT
- T -- TEMPORARY
- arwdDxt -- ALL PRIVILEGES (for tables, varies for other objects)
- * -- grant option for preceding privilege
-
- /yyyy -- role that granted this privilege
-</programlisting>
+<literallayout class="monospaced">
+rolename=xxxx -- privileges granted to a role
+ =xxxx -- privileges granted to PUBLIC
+
+ r -- SELECT ("read")
+ w -- UPDATE ("write")
+ a -- INSERT ("append")
+ d -- DELETE
+ D -- TRUNCATE
+ x -- REFERENCES
+ t -- TRIGGER
+ X -- EXECUTE
+ U -- USAGE
+ C -- CREATE
+ c -- CONNECT
+ T -- TEMPORARY
+ arwdDxt -- ALL PRIVILEGES (for tables, varies for other objects)
+ * -- grant option for preceding privilege
+
+ /yyyy -- role that granted this privilege
+</literallayout>
The above example display would be seen by user <literal>miriam</> after
creating table <literal>mytable</> and doing:
-<!-- $PostgreSQL: pgsql/doc/src/sgml/release-8.1.sgml,v 1.7 2010/05/13 21:26:59 tgl Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/release-8.1.sgml,v 1.8 2010/07/29 19:34:40 petere Exp $ -->
<!-- See header comment in release.sgml about typical markup -->
<sect1 id="release-8-1-21">
Previously, only a predefined list of time zone names were
supported by <command>AT TIME ZONE</>. Now any supported time
zone name can be used, e.g.:
- <programlisting>
- SELECT CURRENT_TIMESTAMP AT TIME ZONE 'Europe/London';
- </programlisting>
+<programlisting>
+SELECT CURRENT_TIMESTAMP AT TIME ZONE 'Europe/London';
+</programlisting>
In the above query, the time zone used is adjusted based on the
daylight saving time rules that were in effect on the supplied
date.
the next day even if a daylight saving time adjustment occurs
between, whereas adding <literal>24 hours</> will give a different
local time when this happens. For example, under US DST rules:
- <programlisting>
- '2005-04-03 00:00:00-05' + '1 day' = '2005-04-04 00:00:00-04'
- '2005-04-03 00:00:00-05' + '24 hours' = '2005-04-04 01:00:00-04'
- </programlisting>
+<programlisting>
+'2005-04-03 00:00:00-05' + '1 day' = '2005-04-04 00:00:00-04'
+'2005-04-03 00:00:00-05' + '24 hours' = '2005-04-04 01:00:00-04'
+</programlisting>
</para>
</listitem>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/release-old.sgml,v 1.1 2009/05/02 20:17:19 tgl Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/release-old.sgml,v 1.2 2010/07/29 19:34:40 petere Exp $ -->
<!-- See header comment in release.sgml about typical markup -->
<sect1 id="release-7-3-21">
<title>Changes</title>
<para>
- <programlisting>
+<programlisting>
Remove unused WAL segments of large transactions (Tom)
Multiaction rule fix (Tom)
PL/pgSQL memory allocation fix (Jan)
BeOS fix
Disable COPY TO/FROM a view (Tom)
Cygwin build (Jason Tishler)
- </programlisting>
+</programlisting>
</para>
</sect2>
</sect1>
<title>Changes</title>
<para>
- <programlisting>
+<programlisting>
Fix PL/pgSQL SELECTs when returning no rows
Fix for psql backslash core dump
Referential integrity privilege fix
Optimizer fixes
pg_dump cleanups
- </programlisting>
+</programlisting>
</para>
</sect2>
</sect1>
<title>Changes</title>
<para>
- <programlisting>
+<programlisting>
Fix for numeric MODULO operator (Tom)
pg_dump fixes (Philip)
pg_dump can dump 7.0 databases (Philip)
ODBC fixes (Hiroshi)
EXTRACT can now take string argument (Thomas)
Python fixes (Darcy)
- </programlisting>
+</programlisting>
</para>
</sect2>
</sect1>
<title>Changes</title>
<para>
- <programlisting>
+<programlisting>
Bug Fixes
---------
Many multibyte/Unicode/locale fixes (Tatsuo and others)
New --template option to createdb
New contrib/pg_control utility (Oliver)
New FreeBSD tools ipc_check, start-scripts/freebsd
- </programlisting>
+</programlisting>
</para>
</sect2>
</sect1>
<title>Changes</title>
<para>
- <programlisting>
+<programlisting>
Jdbc fixes (Peter)
Large object fix (Tom)
Fix lean in COPY WITH OIDS leak (Tom)
Fix for inserting/copying longer multibyte strings into char() data
types (Tatsuo)
Fix for crash of backend, on abort (Tom)
- </programlisting>
+</programlisting>
</para>
</sect2>
</sect1>
<title>Changes</title>
<para>
- <programlisting>
+<programlisting>
Added documentation to tarball.
- </programlisting>
+</programlisting>
</para>
</sect2>
</sect1>
<title>Changes</title>
<para>
- <programlisting>
+<programlisting>
Fix many CLUSTER failures (Tom)
Allow ALTER TABLE RENAME works on indexes (Tom)
Fix plpgsql to handle datetime->timestamp and timespan->interval (Bruce)
Fix problem with quoted indexes that are too long (Tom)
JDBC ResultSet.getTimestamp() fix (Gregory Krasnow & Floyd Marinescu)
ecpg changes (Michael)
- </programlisting>
+</programlisting>
</para>
</sect2>
</sect1>
<title>Changes</title>
<para>
- <programlisting>
+<programlisting>
Bug Fixes
---------
Prevent function calls exceeding maximum number of arguments (Tom)
NetBSD fixes (Johnny C. Lam <email>lamj@stat.cmu.edu</email>)
Fixes for Alpha compiles
New multibyte encodings
- </programlisting>
+</programlisting>
</para>
</sect2>
</sect1>
<title>Changes</title>
<para>
- <programlisting>
+<programlisting>
Updated version of pgaccess 0.98
NT-specific patch
Fix dumping rules on inherited tables
- </programlisting>
+</programlisting>
</para>
</sect2>
</sect1>
<title>Changes</title>
<para>
- <programlisting>
+<programlisting>
subselect+CASE fixes(Tom)
Add SHLIB_LINK setting for solaris_i386 and solaris_sparc ports(Daren Sefcik)
Fixes for CASE in WHERE join clauses(Tom)
when reach end of pattern before end of text(Tom)
Repair incorrect cleanup of heap memory allocation during transaction abort(Tom)
Updated version of pgaccess 0.98
- </programlisting>
+</programlisting>
</para>
</sect2>
</sect1>
<title>Changes</title>
<para>
- <programlisting>
+<programlisting>
Add NT README file
Portability fixes for linux_ppc, IRIX, linux_alpha, OpenBSD, alpha
Remove QUERY_LIMIT, use SELECT...LIMIT
Fixed glitches affecting GROUP BY in subselects(Tom)
Fix some compiler warnings (Tomoaki Nishiyama)
Add Win1250 (Czech) support (Pavel Behal)
- </programlisting>
+</programlisting>
</para>
</sect2>
</sect1>
<title>Changes</title>
<para>
- <programlisting>
+<programlisting>
Bug Fixes
---------
Fix text<->float8 and text<->float4 conversion functions(Thomas)
Better support for HP-UX 11 and UnixWare
Improve file handling to be more uniform, prevent file descriptor leak(Tom)
New install commands for plpgsql(Jan)
- </programlisting>
+</programlisting>
</para>
</sect2>
</sect1>
<title>Changes</title>
<para>
- <programlisting>
+<programlisting>
Bug Fixes
---------
Fix for a tiny memory leak in PQsetdb/PQfinish(Bryan)
<title>Changes</title>
<para>
- <programlisting>
+<programlisting>
Configure detection improvements for tcl/tk(Brook Milligan, Alvin)
Manual page improvements(Bruce)
BETWEEN and LIKE fix(Thomas)
Remove DISTDIR(Bruce)
Makefile dependency cleanup(Jeroen van Vianen)
ASSERT fixes(Bruce)
- </programlisting>
+</programlisting>
</para>
</sect2>
</sect1>
<title>Changes</title>
<para>
- <programlisting>
+<programlisting>
ecpg cleanup/fixes, now version 1.1(Michael Meskes)
pg_user cleanup(Bruce)
large object fix for pg_dump and tclsh (alvin)
Fix for text arrays containing quotes(Doug Gibson)
Solaris compile fix(Albert Chin-A-Young)
Better identify tcl and tk libs and includes(Bruce)
- </programlisting>
+</programlisting>
</para>
</sect2>
</sect1>
<title>Changes</title>
<para>
- <programlisting>
+<programlisting>
Bug Fixes
---------
Fix binary cursors broken by MOVE implementation(Vadim)
from <command>psql</command> to update the existing system table:
<programlisting>
- update pg_aggregate set aggfinalfn = 'cash_div_flt8'
- where aggname = 'avg' and aggbasetype = 790;
+update pg_aggregate set aggfinalfn = 'cash_div_flt8'
+ where aggname = 'avg' and aggbasetype = 790;
</programlisting>
</para>
<para>
<title>Changes</title>
<para>
- <programlisting>
+<programlisting>
Allow TIME and TYPE column names(Thomas)
Allow larger range of true/false as boolean values(Thomas)
Support output of "now" and "current"(Thomas)
Fix for specifying a column twice in ORDER/GROUP BY(Vadim)
Documented new libpq function to return affected rows, PQcmdTuples(Bruce)
Trigger function for inserting user names for INSERT/UPDATE(Brook Milligan)
- </programlisting>
+</programlisting>
</para>
</sect2>
</sect1>
<title>Changes</title>
<para>
- <programlisting>
+<programlisting>
Bug Fixes
---------
Fix problems with pg_dump for inheritance, sequences, archive tables(Bruce)
<title>Changes</title>
<para>
- <programlisting>
+<programlisting>
fix for SET with options (Thomas)
allow pg_dump/pg_dumpall to preserve ownership of all tables/objects(Bruce)
new psql \connect option allows changing usernames without changing databases
Fix for Solaris assembler and include files(Yoshihiko Ichikawa)
allow underscores in usernames(Bruce)
pg_dumpall now returns proper status, portability fix(Bruce)
- </programlisting>
+</programlisting>
</para>
</sect2>
</sect1>
<title>Changes</title>
<para>
- <programlisting>
+<programlisting>
Bug Fixes
---------
packet length checking in library routines
<title>Changes</title>
<para>
- <programlisting>
+<programlisting>
Bug Fixes
---------
ALTER TABLE bug - running postgres process needs to re-read table definition
1.01 or 1.02 database is named <literal>testdb</literal> and you have cut the commands
from the end of this file and saved them in <filename>addfunc.sql</filename>:
<programlisting>
- % psql testdb -f addfunc.sql
+% psql testdb -f addfunc.sql
</programlisting>
Those upgrading 1.02 databases will get a warning when executing the
than NULL. See the copy manual page for full details.
<programlisting>
- sed 's/^\.$/\\./g' <in_file >out_file
+sed 's/^\.$/\\./g' <in_file >out_file
</programlisting>
</para>
<para>
If you do not want host-based authentication, you can comment out
the line:
<programlisting>
- HBA = 1
+HBA = 1
</programlisting>
in <filename>src/Makefile.global</filename>
</para>
If your 1.0 database is name <literal>testdb</literal>:
<programlisting>
- % psql testdb -f 1.0_to_1.01.sql
+% psql testdb -f 1.0_to_1.01.sql
</programlisting>
and then execute the following commands (cut and paste from here):
<para>
These timing results are from running the regression test with the commands
- <programlisting>
+<programlisting>
% cd src/test/regress
% make all
% time make runtest
- </programlisting>
+</programlisting>
</para>
<para>
Timing under Linux 2.0.27 seems to have a roughly 5% variation from run
<para>
Timing with <function>fsync()</function> disabled:
- <programlisting>
- Time System
- 02:00 Dual Pentium Pro 180, 224MB, UW-SCSI, Linux 2.0.36, gcc 2.7.2.3 -O2 -m486
- 04:38 Sparc Ultra 1 143MHz, 64MB, Solaris 2.6
- </programlisting>
+<literallayout class="monospaced">
+Time System
+02:00 Dual Pentium Pro 180, 224MB, UW-SCSI, Linux 2.0.36, gcc 2.7.2.3 -O2 -m486
+04:38 Sparc Ultra 1 143MHz, 64MB, Solaris 2.6
+</literallayout>
</para>
<para>
Timing with <function>fsync()</function> enabled:
- <programlisting>
- Time System
- 04:21 Dual Pentium Pro 180, 224MB, UW-SCSI, Linux 2.0.36, gcc 2.7.2.3 -O2 -m486
- </programlisting>
+<literallayout class="monospaced">
+Time System
+04:21 Dual Pentium Pro 180, 224MB, UW-SCSI, Linux 2.0.36, gcc 2.7.2.3 -O2 -m486
+</literallayout>
For the <systemitem class="osname">Linux</systemitem> system above, using <acronym>UW-SCSI</acronym> disks rather than (older) <acronym>IDE</acronym>
disks leads to a 50% improvement in speed on the regression test.
In general, however, 6.4 should be slightly faster than the previous release (thanks, Bruce!).
</para>
<para>
-<programlisting>
- Time System
- 02:26 Dual Pentium Pro 180, 96MB, UW-SCSI, Linux 2.0.30, gcc 2.7.2.1 -O2 -m486
-</programlisting>
+<literallayout class="monospaced">
+Time System
+02:26 Dual Pentium Pro 180, 96MB, UW-SCSI, Linux 2.0.30, gcc 2.7.2.1 -O2 -m486
+</literallayout>
</para>
</sect2>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/seg.sgml,v 1.6 2009/12/08 20:08:30 mha Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/seg.sgml,v 1.7 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="seg">
<title>seg</title>
6.50, and you input this reading into the database. What do you get
when you fetch it? Watch:
- <programlisting>
+<screen>
test=> select 6.50 :: float8 as "pH";
pH
---
6.5
(1 row)
- </programlisting>
+</screen>
In the world of measurements, 6.50 is not the same as 6.5. It may
sometimes be critically different. The experimenters usually write
<para>
Check this out:
- <programlisting>
+<screen>
test=> select '6.25 .. 6.50'::seg as "pH";
pH
------------
6.25 .. 6.50
(1 row)
- </programlisting>
+</screen>
</para>
</sect2>
<para>
The <filename>seg</> module includes a GiST index operator class for
<type>seg</> values.
- The operators supported by the GiST opclass include:
+ The operators supported by the GiST opclass are shown in <xref linkend="seg-gist-operators">.
</para>
- <itemizedlist>
- <listitem>
- <programlisting>
-[a, b] << [c, d] Is left of
- </programlisting>
- <para>
- [a, b] is entirely to the left of [c, d]. That is,
- [a, b] << [c, d] is true if b < c and false otherwise
- </para>
- </listitem>
- <listitem>
- <programlisting>
-[a, b] >> [c, d] Is right of
- </programlisting>
- <para>
- [a, b] is entirely to the right of [c, d]. That is,
- [a, b] >> [c, d] is true if a > d and false otherwise
- </para>
- </listitem>
- <listitem>
- <programlisting>
-[a, b] &< [c, d] Overlaps or is left of
- </programlisting>
- <para>
- This might be better read as <quote>does not extend to right of</quote>.
- It is true when b <= d.
- </para>
- </listitem>
- <listitem>
- <programlisting>
-[a, b] &> [c, d] Overlaps or is right of
- </programlisting>
- <para>
- This might be better read as <quote>does not extend to left of</quote>.
- It is true when a >= c.
- </para>
- </listitem>
- <listitem>
- <programlisting>
-[a, b] = [c, d] Same as
- </programlisting>
- <para>
- The segments [a, b] and [c, d] are identical, that is, a = c and b = d
- </para>
- </listitem>
- <listitem>
- <programlisting>
-[a, b] && [c, d] Overlaps
- </programlisting>
- <para>
- The segments [a, b] and [c, d] overlap.
- </para>
- </listitem>
- <listitem>
- <programlisting>
-[a, b] @> [c, d] Contains
- </programlisting>
- <para>
- The segment [a, b] contains the segment [c, d], that is,
- a <= c and b >= d
- </para>
- </listitem>
- <listitem>
- <programlisting>
-[a, b] <@ [c, d] Contained in
- </programlisting>
- <para>
- The segment [a, b] is contained in [c, d], that is,
- a >= c and b <= d
- </para>
- </listitem>
- </itemizedlist>
+ <table id="seg-gist-operators">
+ <title>Seg GiST operators</title>
+ <tgroup cols="2">
+ <thead>
+ <row>
+ <entry>Operator</entry>
+ <entry>Description</entry>
+ </row>
+ </thead>
+
+ <tbody>
+ <row>
+ <entry><literal>[a, b] << [c, d]</literal></entry>
+ <entry>[a, b] is entirely to the left of [c, d]. That is, [a,
+ b] << [c, d] is true if b < c and false otherwise.</entry>
+ </row>
+
+ <row>
+ <entry><literal>[a, b] >> [c, d]</literal></entry>
+ <entry>[a, b] is entirely to the right of [c, d]. That is, [a,
+ b] >> [c, d] is true if a > d and false otherwise.</entry>
+ </row>
+
+ <row>
+ <entry><literal>[a, b] &< [c, d]</literal></entry>
+ <entry>Overlaps or is left of — This might be better read
+ as <quote>does not extend to right of</quote>. It is true when
+ b <= d.</entry>
+ </row>
+
+ <row>
+ <entry><literal>[a, b] &> [c, d]</literal></entry>
+ <entry>Overlaps or is right of — This might be better read
+ as <quote>does not extend to left of</quote>. It is true when
+ a >= c.</entry>
+ </row>
+
+ <row>
+ <entry><literal>[a, b] = [c, d]</literal></entry>
+ <entry>Same as — The segments [a, b] and [c, d] are
+ identical, that is, a = c and b = d.</entry>
+ </row>
+
+ <row>
+ <entry><literal>[a, b] && [c, d]</literal></entry>
+ <entry>The segments [a, b] and [c, d] overlap.</entry>
+ </row>
+
+ <row>
+ <entry><literal>[a, b] @> [c, d]</literal></entry>
+ <entry>The segment [a, b] contains the segment [c, d], that is,
+ a <= c and b >= d.</entry>
+ </row>
+
+ <row>
+ <entry><literal>[a, b] <@ [c, d]</literal></entry>
+ <entry>The segment [a, b] is contained in [c, d], that is, a
+ >= c and b <= d.</entry>
+ </row>
+ </tbody>
+ </tgroup>
+ </table>
<para>
- (Before PostgreSQL 8.2, the containment operators @> and <@ were
- respectively called @ and ~. These names are still available, but are
+ (Before PostgreSQL 8.2, the containment operators <literal>@></> and <literal><@</> were
+ respectively called <literal>@</> and <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
datatypes!)
<para>
The standard B-tree operators are also provided, for example
- <programlisting>
-[a, b] < [c, d] Less than
-[a, b] > [c, d] Greater than
- </programlisting>
+ <informaltable>
+ <tgroup cols="2">
+ <thead>
+ <row>
+ <entry>Operator</entry>
+ <entry>Description</entry>
+ </row>
+ </thead>
+
+ <tbody>
+ <row>
+ <entry><literal>[a, b] < [c, d]</literal></entry>
+ <entry>Less than</entry>
+ </row>
+
+ <row>
+ <entry><literal>[a, b] > [c, d]</literal></entry>
+ <entry>Greater than</entry>
+ </row>
+ </tbody>
+ </tgroup>
+ </informaltable>
These operators do not make a lot of sense for any practical
purpose but sorting. These operators first compare (a) to (c),
for the boundaries. For example, it adds an extra digit to the lower
boundary if the resulting interval includes a power of ten:
- <programlisting>
+<screen>
postgres=> select '10(+-)1'::seg as seg;
seg
---------
9.0 .. 11 -- should be: 9 .. 11
- </programlisting>
+</screen>
</para>
<para>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/sql.sgml,v 1.48 2009/04/27 16:27:36 momjian Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/sql.sgml,v 1.49 2010/07/29 19:34:40 petere Exp $ -->
<chapter id="sql-intro">
<title>SQL</title>
<example>
<title id="supplier-fig">The Suppliers and Parts Database</title>
- <programlisting>
+<screen>
SUPPLIER: SELLS:
SNO | SNAME | CITY SNO | PNO
----+---------+-------- -----+-----
2 | Nut | 8
3 | Bolt | 15
4 | Cam | 25
- </programlisting>
+</screen>
</example>
</para>
necessary for a join.
Let the following two tables be given:
- <programlisting>
+<screen>
R: S:
A | B | C C | D | E
---+---+--- ---+---+---
1 | 2 | 3 3 | a | b
4 | 5 | 6 6 | c | d
7 | 8 | 9
- </programlisting>
+</screen>
</para>
</example>
<classname>R</classname> × <classname>S</classname> and
get:
- <programlisting>
+<screen>
R x S:
A | B | R.C | S.C | D | E
---+---+-----+-----+---+---
4 | 5 | 6 | 6 | c | d
7 | 8 | 9 | 3 | a | b
7 | 8 | 9 | 6 | c | d
- </programlisting>
+</screen>
</para>
<para>
σ<subscript>R.C=S.C</subscript>(R × S)
we get:
- <programlisting>
+<screen>
A | B | R.C | S.C | D | E
---+---+-----+-----+---+---
1 | 2 | 3 | 3 | a | b
4 | 5 | 6 | 6 | c | d
- </programlisting>
+</screen>
</para>
<para>
π<subscript>R.A,R.B,R.C,S.D,S.E</subscript>(σ<subscript>R.C=S.C</subscript>(R × S))
and get:
- <programlisting>
+<screen>
A | B | C | D | E
---+---+---+---+---
1 | 2 | 3 | a | b
4 | 5 | 6 | c | d
- </programlisting>
+</screen>
</para>
</listitem>
C and D.
Then we define the division as:
- <programlisting>
+<programlisting>
R ÷ S = {t ∣ ∀ t<subscript>s</subscript> ∈ S ∃ t<subscript>r</subscript> ∈ R
- </programlisting>
+</programlisting>
such that
t<subscript>r</subscript>(A,B)=t∧t<subscript>r</subscript>(C,D)=t<subscript>s</subscript>}
<para id="divide-example">
Given the following tables
- <programlisting>
+<screen>
R: S:
A | B | C | D C | D
---+---+---+--- ---+---
e | d | c | d
e | d | e | f
a | b | d | e
- </programlisting>
+</screen>
R ÷ S
is derived as
- <programlisting>
+<screen>
A | B
---+---
a | b
e | d
- </programlisting>
+</screen>
</para>
</listitem>
</itemizedlist>
This question can be answered
using relational algebra by the following operation:
- <programlisting>
+<programlisting>
π<subscript>SUPPLIER.SNAME</subscript>(σ<subscript>PART.PNAME='Screw'</subscript>(SUPPLIER ∏ SELLS ∏ PART))
- </programlisting>
+</programlisting>
</para>
<para>
(<xref linkend="supplier-fig" endterm="supplier-fig">)
we will obtain the following result:
- <programlisting>
+<screen>
SNAME
-------
Smith
Adams
- </programlisting>
+</screen>
</para>
</example>
</sect2>
The queries used in <acronym>TRC</acronym> are of the following
form:
- <programlisting>
+<programlisting>
x(A) ∣ F(x)
- </programlisting>
+</programlisting>
where <literal>x</literal> is a tuple variable
<classname>A</classname> is a set of attributes and <literal>F</literal> is a
<xref linkend="suppl-rel-alg" endterm="suppl-rel-alg">
using <acronym>TRC</acronym> we formulate the following query:
- <programlisting>
+<programlisting>
{x(SNAME) ∣ x ∈ SUPPLIER ∧
∃ y ∈ SELLS ∃ z ∈ PART (y(SNO)=x(SNO) ∧
z(PNO)=y(PNO) ∧
z(PNAME)='Screw')}
- </programlisting>
+</programlisting>
</para>
<para>
to involve
arithmetic operations as well as comparisons, e.g.:
- <programlisting>
+<programlisting>
A < B + 3.
- </programlisting>
+</programlisting>
Note
that + or other arithmetic operators appear neither in relational
<command>SELECT</command> statement,
used to retrieve data. The syntax is:
- <synopsis>
+<synopsis>
SELECT [ ALL | DISTINCT [ ON ( <replaceable class="PARAMETER">expression</replaceable> [, ...] ) ] ]
* | <replaceable class="PARAMETER">expression</replaceable> [ [ AS ] <replaceable class="PARAMETER">output_name</replaceable> ] [, ...]
[ INTO [ TEMPORARY | TEMP ] [ TABLE ] <replaceable class="PARAMETER">new_table</replaceable> ]
[ LIMIT { <replaceable class="PARAMETER">count</replaceable> | ALL } ]
[ OFFSET <replaceable class="PARAMETER">start</replaceable> ]
[ FOR { UPDATE | SHARE } [ OF <replaceable class="parameter">table_name</replaceable> [, ...] ] [ NOWAIT ] [...] ]
- </synopsis>
+</synopsis>
</para>
<para>
To retrieve all tuples from table PART where the attribute PRICE is
greater than 10 we formulate the following query:
- <programlisting>
+<programlisting>
SELECT * FROM PART
WHERE PRICE > 10;
- </programlisting>
+</programlisting>
and get the table:
- <programlisting>
+<screen>
PNO | PNAME | PRICE
-----+---------+--------
3 | Bolt | 15
4 | Cam | 25
- </programlisting>
+</screen>
</para>
<para>
only the attributes PNAME and PRICE from table PART we use the
statement:
- <programlisting>
+<programlisting>
SELECT PNAME, PRICE
FROM PART
WHERE PRICE > 10;
- </programlisting>
+</programlisting>
In this case the result is:
- <programlisting>
+<screen>
PNAME | PRICE
--------+--------
Bolt | 15
Cam | 25
- </programlisting>
+</screen>
Note that the <acronym>SQL</acronym> <command>SELECT</command>
corresponds to the <quote>projection</quote> in relational algebra
The qualifications in the WHERE clause can also be logically connected
using the keywords OR, AND, and NOT:
- <programlisting>
+<programlisting>
SELECT PNAME, PRICE
FROM PART
WHERE PNAME = 'Bolt' AND
(PRICE = 0 OR PRICE <= 15);
- </programlisting>
+</programlisting>
will lead to the result:
- <programlisting>
+<screen>
PNAME | PRICE
--------+--------
Bolt | 15
- </programlisting>
+</screen>
</para>
<para>
clause. For example if we want to know how much it would cost if we
take two pieces of a part we could use the following query:
- <programlisting>
+<programlisting>
SELECT PNAME, PRICE * 2 AS DOUBLE
FROM PART
WHERE PRICE * 2 < 50;
- </programlisting>
+</programlisting>
and we get:
- <programlisting>
+<screen>
PNAME | DOUBLE
--------+---------
Screw | 20
Nut | 16
Bolt | 30
- </programlisting>
+</screen>
Note that the word DOUBLE after the keyword AS is the new title of the
second column. This technique can be used for every element of the
To join the three tables SUPPLIER, PART and SELLS over their common
attributes we formulate the following statement:
- <programlisting>
+<programlisting>
SELECT S.SNAME, P.PNAME
FROM SUPPLIER S, PART P, SELLS SE
WHERE S.SNO = SE.SNO AND
P.PNO = SE.PNO;
- </programlisting>
+</programlisting>
and get the following table as a result:
- <programlisting>
+<screen>
SNAME | PNAME
-------+-------
Smith | Screw
Blake | Nut
Blake | Bolt
Blake | Cam
- </programlisting>
+</screen>
</para>
<para>
<para>
Another way to perform joins is to use the SQL JOIN syntax as follows:
- <programlisting>
-select sname, pname from supplier
+<programlisting>
+SELECT sname, pname from supplier
JOIN sells USING (sno)
JOIN part USING (pno);
- </programlisting>
+</programlisting>
giving again:
- <programlisting>
+<screen>
sname | pname
-------+-------
Smith | Screw
Jones | Cam
Blake | Cam
(8 rows)
- </programlisting>
+</screen>
</para>
<para>
If we want to know the average cost of all parts in table PART we use
the following query:
- <programlisting>
+<programlisting>
SELECT AVG(PRICE) AS AVG_PRICE
FROM PART;
- </programlisting>
+</programlisting>
</para>
<para>
The result is:
- <programlisting>
+<screen>
AVG_PRICE
-----------
14.5
- </programlisting>
+</screen>
</para>
<para>
If we want to know how many parts are defined in table PART we use
the statement:
- <programlisting>
+<programlisting>
SELECT COUNT(PNO)
FROM PART;
- </programlisting>
+</programlisting>
and get:
- <programlisting>
+<screen>
COUNT
-------
4
- </programlisting>
+</screen>
</para>
</example>
If we want to know how many parts are sold by every supplier we
formulate the query:
- <programlisting>
+<programlisting>
SELECT S.SNO, S.SNAME, COUNT(SE.PNO)
FROM SUPPLIER S, SELLS SE
WHERE S.SNO = SE.SNO
GROUP BY S.SNO, S.SNAME;
- </programlisting>
+</programlisting>
and get:
- <programlisting>
+<screen>
SNO | SNAME | COUNT
-----+-------+-------
1 | Smith | 2
2 | Jones | 1
3 | Adams | 2
4 | Blake | 3
- </programlisting>
+</screen>
</para>
<para>
First the join of the
tables SUPPLIER and SELLS is derived:
- <programlisting>
+<screen>
S.SNO | S.SNAME | SE.PNO
-------+---------+--------
1 | Smith | 1
4 | Blake | 2
4 | Blake | 3
4 | Blake | 4
- </programlisting>
+</screen>
</para>
<para>
Next we partition the tuples into groups by putting all tuples
together that agree on both attributes S.SNO and S.SNAME:
- <programlisting>
+<screen>
S.SNO | S.SNAME | SE.PNO
-------+---------+--------
1 | Smith | 1
4 | Blake | 2
| 3
| 4
- </programlisting>
+</screen>
</para>
<para>
If we want only those suppliers selling more than one part we use the
query:
- <programlisting>
+<programlisting>
SELECT S.SNO, S.SNAME, COUNT(SE.PNO)
FROM SUPPLIER S, SELLS SE
WHERE S.SNO = SE.SNO
GROUP BY S.SNO, S.SNAME
HAVING COUNT(SE.PNO) > 1;
- </programlisting>
+</programlisting>
and get:
- <programlisting>
+<screen>
SNO | SNAME | COUNT
-----+-------+-------
1 | Smith | 2
3 | Adams | 2
4 | Blake | 3
- </programlisting>
+</screen>
</para>
</example>
</para>
If we want to know all parts having a greater price than the part
named 'Screw' we use the query:
- <programlisting>
+<programlisting>
SELECT *
FROM PART
WHERE PRICE > (SELECT PRICE FROM PART
WHERE PNAME='Screw');
- </programlisting>
+</programlisting>
</para>
<para>
The result is:
- <programlisting>
+<screen>
PNO | PNAME | PRICE
-----+---------+--------
3 | Bolt | 15
4 | Cam | 25
- </programlisting>
+</screen>
</para>
<para>
If we want to know all suppliers that do not sell any part
(e.g., to be able to remove these suppliers from the database) we use:
- <programlisting>
+<programlisting>
SELECT *
FROM SUPPLIER S
WHERE NOT EXISTS
(SELECT * FROM SELLS SE
WHERE SE.SNO = S.SNO);
- </programlisting>
+</programlisting>
</para>
<para>
If we want to know the highest average part price among all our
suppliers, we cannot write MAX(AVG(PRICE)), but we can write:
- <programlisting>
+<programlisting>
SELECT MAX(subtable.avgprice)
FROM (SELECT AVG(P.PRICE) AS avgprice
FROM SUPPLIER S, PART P, SELLS SE
WHERE S.SNO = SE.SNO AND
P.PNO = SE.PNO
GROUP BY S.SNO) subtable;
- </programlisting>
+</programlisting>
The subquery returns one row per supplier (because of its GROUP BY)
and then we aggregate over those rows in the outer query.
<para>
The following query is an example for UNION:
- <programlisting>
+<programlisting>
SELECT S.SNO, S.SNAME, S.CITY
FROM SUPPLIER S
WHERE S.SNAME = 'Jones'
SELECT S.SNO, S.SNAME, S.CITY
FROM SUPPLIER S
WHERE S.SNAME = 'Adams';
- </programlisting>
+</programlisting>
gives the result:
- <programlisting>
+<screen>
SNO | SNAME | CITY
-----+-------+--------
2 | Jones | Paris
3 | Adams | Vienna
- </programlisting>
+</screen>
</para>
<para>
Here is an example for INTERSECT:
- <programlisting>
+<programlisting>
SELECT S.SNO, S.SNAME, S.CITY
FROM SUPPLIER S
WHERE S.SNO > 1
SELECT S.SNO, S.SNAME, S.CITY
FROM SUPPLIER S
WHERE S.SNO < 3;
- </programlisting>
+</programlisting>
gives the result:
- <programlisting>
+<screen>
SNO | SNAME | CITY
-----+-------+--------
2 | Jones | Paris
- </programlisting>
+</screen>
The only tuple returned by both parts of the query is the one having SNO=2.
</para>
<para>
Finally an example for EXCEPT:
- <programlisting>
+<programlisting>
SELECT S.SNO, S.SNAME, S.CITY
FROM SUPPLIER S
WHERE S.SNO > 1
SELECT S.SNO, S.SNAME, S.CITY
FROM SUPPLIER S
WHERE S.SNO > 3;
- </programlisting>
+</programlisting>
gives the result:
- <programlisting>
+<screen>
SNO | SNAME | CITY
-----+-------+--------
2 | Jones | Paris
3 | Adams | Vienna
- </programlisting>
+</screen>
</para>
</example>
</para>
one that creates a new relation (a new table). The syntax of the
<command>CREATE TABLE</command> command is:
- <synopsis>
+<synopsis>
CREATE TABLE <replaceable class="parameter">table_name</replaceable>
(<replaceable class="parameter">name_of_attr_1</replaceable> <replaceable class="parameter">type_of_attr_1</replaceable>
[, <replaceable class="parameter">name_of_attr_2</replaceable> <replaceable class="parameter">type_of_attr_2</replaceable>
[, ...]]);
- </synopsis>
+</synopsis>
<example>
<title id="table-create">Table Creation</title>
<xref linkend="supplier-fig" endterm="supplier-fig"> the
following <acronym>SQL</acronym> statements are used:
- <programlisting>
+<programlisting>
CREATE TABLE SUPPLIER
(SNO INTEGER,
SNAME VARCHAR(20),
CITY VARCHAR(20));
- </programlisting>
+</programlisting>
- <programlisting>
+<programlisting>
CREATE TABLE PART
(PNO INTEGER,
PNAME VARCHAR(20),
PRICE DECIMAL(4 , 2));
- </programlisting>
+</programlisting>
- <programlisting>
+<programlisting>
CREATE TABLE SELLS
(SNO INTEGER,
PNO INTEGER);
- </programlisting>
+</programlisting>
</para>
</example>
</para>
To create an index in <acronym>SQL</acronym>
the <command>CREATE INDEX</command> command is used. The syntax is:
- <programlisting>
+<programlisting>
CREATE INDEX <replaceable class="parameter">index_name</replaceable>
ON <replaceable class="parameter">table_name</replaceable> ( <replaceable class="parameter">name_of_attribute</replaceable> );
- </programlisting>
+</programlisting>
</para>
<para>
To create an index named I on attribute SNAME of relation SUPPLIER
we use the following statement:
- <programlisting>
+<programlisting>
CREATE INDEX I ON SUPPLIER (SNAME);
- </programlisting>
+</programlisting>
</para>
<para>
command is used to define a view. The syntax
is:
- <programlisting>
+<programlisting>
CREATE VIEW <replaceable class="parameter">view_name</replaceable>
AS <replaceable class="parameter">select_stmt</replaceable>
- </programlisting>
+</programlisting>
where <replaceable class="parameter">select_stmt</replaceable>
is a valid select statement as defined
the tables from
<xref linkend="supplier-fig" endterm="supplier-fig"> again):
- <programlisting>
+<programlisting>
CREATE VIEW London_Suppliers
AS SELECT S.SNAME, P.PNAME
FROM SUPPLIER S, PART P, SELLS SE
WHERE S.SNO = SE.SNO AND
P.PNO = SE.PNO AND
S.CITY = 'London';
- </programlisting>
+</programlisting>
</para>
<para>
<classname>London_Suppliers</classname> as
if it were another base table:
- <programlisting>
+<programlisting>
SELECT * FROM London_Suppliers
WHERE PNAME = 'Screw';
- </programlisting>
+</programlisting>
which will return the following table:
- <programlisting>
+<screen>
SNAME | PNAME
-------+-------
Smith | Screw
- </programlisting>
+</screen>
</para>
<para>
To destroy a table (including all tuples stored in that table) the
<command>DROP TABLE</command> command is used:
- <programlisting>
+<programlisting>
DROP TABLE <replaceable class="parameter">table_name</replaceable>;
- </programlisting>
+</programlisting>
</para>
<para>
To destroy the SUPPLIER table use the following statement:
- <programlisting>
+<programlisting>
DROP TABLE SUPPLIER;
- </programlisting>
+</programlisting>
</para>
<para>
The <command>DROP INDEX</command> command is used to destroy an index:
- <programlisting>
+<programlisting>
DROP INDEX <replaceable class="parameter">index_name</replaceable>;
- </programlisting>
+</programlisting>
</para>
<para>
Finally to destroy a given view use the command <command>DROP
VIEW</command>:
- <programlisting>
+<programlisting>
DROP VIEW <replaceable class="parameter">view_name</replaceable>;
- </programlisting>
+</programlisting>
</para>
</sect3>
</sect2>
with tuples using the command <command>INSERT INTO</command>.
The syntax is:
- <programlisting>
+<programlisting>
INSERT INTO <replaceable class="parameter">table_name</replaceable> (<replaceable class="parameter">name_of_attr_1</replaceable>
[, <replaceable class="parameter">name_of_attr_2</replaceable> [,...]])
VALUES (<replaceable class="parameter">val_attr_1</replaceable> [, <replaceable class="parameter">val_attr_2</replaceable> [, ...]]);
- </programlisting>
+</programlisting>
</para>
<para>
<xref linkend="supplier-fig" endterm="supplier-fig">) we use the
following statement:
- <programlisting>
+<programlisting>
INSERT INTO SUPPLIER (SNO, SNAME, CITY)
VALUES (1, 'Smith', 'London');
- </programlisting>
+</programlisting>
</para>
<para>
To insert the first tuple into the relation SELLS we use:
- <programlisting>
+<programlisting>
INSERT INTO SELLS (SNO, PNO)
VALUES (1, 1);
- </programlisting>
+</programlisting>
</para>
</sect3>
To change one or more attribute values of tuples in a relation the
<command>UPDATE</command> command is used. The syntax is:
- <programlisting>
+<programlisting>
UPDATE <replaceable class="parameter">table_name</replaceable>
SET <replaceable class="parameter">name_of_attr_1</replaceable> = <replaceable class="parameter">value_1</replaceable>
[, ... [, <replaceable class="parameter">name_of_attr_k</replaceable> = <replaceable class="parameter">value_k</replaceable>]]
WHERE <replaceable class="parameter">condition</replaceable>;
- </programlisting>
+</programlisting>
</para>
<para>
To change the value of attribute PRICE of the part 'Screw' in the
relation PART we use:
- <programlisting>
+<programlisting>
UPDATE PART
SET PRICE = 15
WHERE PNAME = 'Screw';
- </programlisting>
+</programlisting>
</para>
<para>
To delete a tuple from a particular table use the command DELETE
FROM. The syntax is:
- <programlisting>
+<programlisting>
DELETE FROM <replaceable class="parameter">table_name</replaceable>
WHERE <replaceable class="parameter">condition</replaceable>;
- </programlisting>
+</programlisting>
</para>
<para>
To delete the supplier called 'Smith' of the table SUPPLIER the
following statement is used:
- <programlisting>
+<programlisting>
DELETE FROM SUPPLIER
WHERE SNAME = 'Smith';
- </programlisting>
+</programlisting>
</para>
</sect3>
</sect2>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/sslinfo.sgml,v 1.4 2010/07/27 23:43:42 rhaas Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/sslinfo.sgml,v 1.5 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="sslinfo">
<title>sslinfo</title>
converted into ASN1 object identifiers using the OpenSSL object
database. The following values are acceptable:
</para>
- <programlisting>
+<literallayout class="monospaced">
commonName (alias CN)
surname (alias SN)
name
pseudonym
role
emailAddress
- </programlisting>
+</literallayout>
<para>
All of these fields are optional, except <structfield>commonName</>.
It depends
-/* $PostgreSQL: pgsql/doc/src/sgml/stylesheet.css,v 1.9 2009/08/26 21:18:29 petere Exp $ */
+/* $PostgreSQL: pgsql/doc/src/sgml/stylesheet.css,v 1.10 2010/07/29 19:34:40 petere Exp $ */
/* color scheme similar to www.postgresql.org */
/* miscellaneous */
-.SCREEN, .SYNOPSIS, .PROGRAMLISTING {
+PRE.LITERALLAYOUT, .SCREEN, .SYNOPSIS, .PROGRAMLISTING {
margin-left: 4ex;
}
-<!-- $PostgreSQL: pgsql/doc/src/sgml/tablefunc.sgml,v 1.4 2007/12/06 04:12:10 tgl Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/tablefunc.sgml,v 1.5 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="tablefunc">
<title>tablefunc</title>
<sect3>
<title><function>normal_rand</function></title>
- <programlisting>
+<synopsis>
normal_rand(int numvals, float8 mean, float8 stddev) returns setof float8
- </programlisting>
+</synopsis>
<para>
<function>normal_rand</> produces a set of normally distributed random
standard deviation of 3:
</para>
- <programlisting>
+<screen>
test=# SELECT * FROM normal_rand(1000, 5, 3);
normal_rand
----------------------
9.71308014517282
2.49639286969028
(1000 rows)
- </programlisting>
+</screen>
</sect3>
<sect3>
<title><function>crosstab(text)</function></title>
- <programlisting>
+<synopsis>
crosstab(text sql)
crosstab(text sql, int N)
- </programlisting>
+</synopsis>
<para>
The <function>crosstab</> function is used to produce <quote>pivot</>
displays, wherein data is listed across the page rather than down.
For example, we might have data like
- <programlisting>
+<programlisting>
row1 val11
row1 val12
row1 val13
row2 val22
row2 val23
...
- </programlisting>
+</programlisting>
which we wish to display like
- <programlisting>
+<programlisting>
row1 val11 val12 val13 ...
row2 val21 val22 val23 ...
...
- </programlisting>
+</programlisting>
The <function>crosstab</> function takes a text parameter that is a SQL
query producing raw data formatted in the first way, and produces a table
formatted in the second way.
<para>
For example, the provided query might produce a set something like:
- </para>
-
<programlisting>
row_name cat value
----------+-------+-------
row2 cat3 val7
row2 cat4 val8
</programlisting>
+ </para>
<para>
The <function>crosstab</> function is declared to return <type>setof
record</type>, so the actual names and types of the output columns must be
defined in the <literal>FROM</> clause of the calling <command>SELECT</>
statement, for example:
- </para>
-
- <programlisting>
- SELECT * FROM crosstab('...') AS ct(row_name text, category_1 text, category_2 text);
- </programlisting>
-
- <para>
+<programlisting>
+SELECT * FROM crosstab('...') AS ct(row_name text, category_1 text, category_2 text);
+</programlisting>
This example produces a set something like:
- </para>
-
- <programlisting>
+<programlisting>
<== value columns ==>
-row_name category_1 category_2
- ---------+------------+------------
- row1 val1 val2
- row2 val5 val6
- </programlisting>
+ row_name category_1 category_2
+----------+------------+------------
+ row1 val1 val2
+ row2 val5 val6
+</programlisting>
+ </para>
<para>
The <literal>FROM</> clause must define the output as one
<para>
Here is a complete example:
- </para>
-
- <programlisting>
+<programlisting>
CREATE TABLE ct(id SERIAL, rowid TEXT, attribute TEXT, value TEXT);
INSERT INTO ct(rowid, attribute, value) VALUES('test1','att1','val1');
INSERT INTO ct(rowid, attribute, value) VALUES('test1','att2','val2');
test1 | val2 | val3 |
test2 | val6 | val7 |
(2 rows)
- </programlisting>
+</programlisting>
+ </para>
<para>
You can avoid always having to write out a <literal>FROM</> clause to
<sect3>
<title><function>crosstab<replaceable>N</>(text)</function></title>
- <programlisting>
+<synopsis>
crosstab<replaceable>N</>(text sql)
- </programlisting>
+</synopsis>
<para>
The <function>crosstab<replaceable>N</></> functions are examples of how
<function>crosstab4</>, whose output rowtypes are defined as
</para>
- <programlisting>
+<programlisting>
CREATE TYPE tablefunc_crosstab_N AS (
row_name TEXT,
category_1 TEXT,
.
category_N TEXT
);
- </programlisting>
+</programlisting>
<para>
Thus, these functions can be used directly when the input query produces
<para>
For instance, the example given in the previous section would also
work as
- </para>
-
- <programlisting>
+<programlisting>
SELECT *
FROM crosstab3(
'select rowid, attribute, value
from ct
where attribute = ''att2'' or attribute = ''att3''
order by 1,2');
- </programlisting>
+</programlisting>
+ </para>
<para>
These functions are provided mostly for illustration purposes. You
can create your own return types and functions based on the
underlying <function>crosstab()</> function. There are two ways
to do it:
- </para>
<itemizedlist>
<listitem>
<function>crosstab</> C function. For example, if your source data
produces row names that are <type>text</>, and values that are
<type>float8</>, and you want 5 value columns:
- </para>
+<programlisting>
+CREATE TYPE my_crosstab_float8_5_cols AS (
+ my_row_name text,
+ my_category_1 float8,
+ my_category_2 float8,
+ my_category_3 float8,
+ my_category_4 float8,
+ my_category_5 float8
+);
- <programlisting>
- CREATE TYPE my_crosstab_float8_5_cols AS (
- my_row_name text,
- my_category_1 float8,
- my_category_2 float8,
- my_category_3 float8,
- my_category_4 float8,
- my_category_5 float8
- );
-
- CREATE OR REPLACE FUNCTION crosstab_float8_5_cols(text)
- RETURNS setof my_crosstab_float8_5_cols
- AS '$libdir/tablefunc','crosstab' LANGUAGE C STABLE STRICT;
- </programlisting>
+CREATE OR REPLACE FUNCTION crosstab_float8_5_cols(text)
+ RETURNS setof my_crosstab_float8_5_cols
+ AS '$libdir/tablefunc','crosstab' LANGUAGE C STABLE STRICT;
+</programlisting>
+ </para>
</listitem>
<listitem>
<para>
Use <literal>OUT</> parameters to define the return type implicitly.
The same example could also be done this way:
+<programlisting>
+CREATE OR REPLACE FUNCTION crosstab_float8_5_cols(
+ IN text,
+ OUT my_row_name text,
+ OUT my_category_1 float8,
+ OUT my_category_2 float8,
+ OUT my_category_3 float8,
+ OUT my_category_4 float8,
+ OUT my_category_5 float8)
+ RETURNS setof record
+ AS '$libdir/tablefunc','crosstab' LANGUAGE C STABLE STRICT;
+</programlisting>
</para>
-
- <programlisting>
- CREATE OR REPLACE FUNCTION crosstab_float8_5_cols(IN text,
- OUT my_row_name text,
- OUT my_category_1 float8,
- OUT my_category_2 float8,
- OUT my_category_3 float8,
- OUT my_category_4 float8,
- OUT my_category_5 float8)
- RETURNS setof record
- AS '$libdir/tablefunc','crosstab' LANGUAGE C STABLE STRICT;
- </programlisting>
</listitem>
</itemizedlist>
+ </para>
</sect3>
<sect3>
<title><function>crosstab(text, text)</function></title>
- <programlisting>
+<synopsis>
crosstab(text source_sql, text category_sql)
- </programlisting>
+</synopsis>
<para>
The main limitation of the single-parameter form of <function>crosstab</>
<para>
For example, <parameter>source_sql</parameter> might produce a set
something like:
- </para>
- <programlisting>
+<programlisting>
SELECT row_name, extra_col, cat, value FROM foo ORDER BY 1;
row_name extra_col cat value
row2 extra2 cat2 val6
row2 extra2 cat3 val7
row2 extra2 cat4 val8
- </programlisting>
+</programlisting>
+ </para>
<para>
<parameter>category_sql</parameter> is a SQL statement that produces
It must produce at least one row, or an error will be generated.
Also, it must not produce duplicate values, or an error will be
generated. <parameter>category_sql</parameter> might be something like:
- </para>
- <programlisting>
+<programlisting>
SELECT DISTINCT cat FROM foo ORDER BY 1;
cat
-------
cat2
cat3
cat4
- </programlisting>
+</programlisting>
+ </para>
<para>
The <function>crosstab</> function is declared to return <type>setof
record</type>, so the actual names and types of the output columns must be
defined in the <literal>FROM</> clause of the calling <command>SELECT</>
statement, for example:
- </para>
- <programlisting>
- SELECT * FROM crosstab('...', '...')
- AS ct(row_name text, extra text, cat1 text, cat2 text, cat3 text, cat4 text);
- </programlisting>
+<programlisting>
+SELECT * FROM crosstab('...', '...')
+ AS ct(row_name text, extra text, cat1 text, cat2 text, cat3 text, cat4 text);
+</programlisting>
+ </para>
<para>
This will produce a result something like:
+<programlisting>
+ <== value columns ==>
+row_name extra cat1 cat2 cat3 cat4
+---------+-------+------+------+------+------
+ row1 extra1 val1 val2 val4
+ row2 extra2 val5 val6 val7 val8
+</programlisting>
</para>
- <programlisting>
- <== value columns ==>
- row_name extra cat1 cat2 cat3 cat4
- ---------+-------+------+------+------+------
- row1 extra1 val1 val2 val4
- row2 extra2 val5 val6 val7 val8
- </programlisting>
-
<para>
The <literal>FROM</> clause must define the proper number of output
columns of the proper data types. If there are <replaceable>N</>
<para>
Here are two complete examples:
- </para>
-
- <programlisting>
+<programlisting>
create table sales(year int, month int, qty int);
insert into sales values(2007, 1, 1000);
insert into sales values(2007, 2, 1500);
2007 | 1000 | 1500 | | | | | 500 | | | | 1500 | 2000
2008 | 1000 | | | | | | | | | | |
(2 rows)
- </programlisting>
+</programlisting>
- <programlisting>
+<programlisting>
CREATE TABLE cth(rowid text, rowdt timestamp, attribute text, val text);
INSERT INTO cth VALUES('test1','01 March 2003','temperature','42');
INSERT INTO cth VALUES('test1','01 March 2003','test_result','PASS');
test1 | Sat Mar 01 00:00:00 2003 | 42 | PASS | | 2.6987
test2 | Sun Mar 02 00:00:00 2003 | 53 | FAIL | Sat Mar 01 00:00:00 2003 | 3.1234
(2 rows)
- </programlisting>
+</programlisting>
+ </para>
<para>
You can create predefined functions to avoid having to write out
<sect3>
<title><function>connectby</function></title>
- <programlisting>
+<synopsis>
connectby(text relname, text keyid_fld, text parent_keyid_fld
[, text orderby_fld ], text start_with, int max_depth
[, text branch_delim ])
- </programlisting>
+</synopsis>
<para>
The <function>connectby</> function produces a display of hierarchical
statement, for example:
</para>
- <programlisting>
- SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'pos', 'row2', 0, '~')
- AS t(keyid text, parent_keyid text, level int, branch text, pos int);
- </programlisting>
+<programlisting>
+SELECT * FROM connectby('connectby_tree', 'keyid', 'parent_keyid', 'pos', 'row2', 0, '~')
+ AS t(keyid text, parent_keyid text, level int, branch text, pos int);
+</programlisting>
<para>
The first two output columns are used for the current row's key and
<para>
Here is an example:
- </para>
-
- <programlisting>
+<programlisting>
CREATE TABLE connectby_tree(keyid text, parent_keyid text, pos int);
INSERT INTO connectby_tree VALUES('row1',NULL, 0);
row6 | row4 | 2 | 5
row8 | row6 | 3 | 6
(6 rows)
- </programlisting>
+</programlisting>
+ </para>
</sect3>
</sect2>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/textsearch.sgml,v 1.56 2010/04/03 07:22:56 petere Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/textsearch.sgml,v 1.57 2010/07/29 19:34:40 petere Exp $ -->
<chapter id="textsearch">
<title>Full Text Search</title>
<primary>to_tsvector</primary>
</indexterm>
- <synopsis>
- to_tsvector(<optional> <replaceable class="PARAMETER">config</replaceable> <type>regconfig</>, </optional> <replaceable class="PARAMETER">document</replaceable> <type>text</>) returns <type>tsvector</>
- </synopsis>
+<synopsis>
+to_tsvector(<optional> <replaceable class="PARAMETER">config</replaceable> <type>regconfig</>, </optional> <replaceable class="PARAMETER">document</replaceable> <type>text</>) returns <type>tsvector</>
+</synopsis>
<para>
<function>to_tsvector</function> parses a textual document into tokens,
text search configuration.
Here is a simple example:
-<programlisting>
+<screen>
SELECT to_tsvector('english', 'a fat cat sat on a mat - it ate a fat rats');
to_tsvector
-----------------------------------------------------
'ate':9 'cat':3 'fat':2,11 'mat':7 'rat':12 'sat':4
-</programlisting>
+</screen>
</para>
<para>
<primary>to_tsquery</primary>
</indexterm>
- <synopsis>
- to_tsquery(<optional> <replaceable class="PARAMETER">config</replaceable> <type>regconfig</>, </optional> <replaceable class="PARAMETER">querytext</replaceable> <type>text</>) returns <type>tsquery</>
- </synopsis>
+<synopsis>
+to_tsquery(<optional> <replaceable class="PARAMETER">config</replaceable> <type>regconfig</>, </optional> <replaceable class="PARAMETER">querytext</replaceable> <type>text</>) returns <type>tsquery</>
+</synopsis>
<para>
<function>to_tsquery</function> creates a <type>tsquery</> value from
the specified or default configuration, and discards any tokens that are
stop words according to the configuration. For example:
-<programlisting>
+<screen>
SELECT to_tsquery('english', 'The & Fat & Rats');
to_tsquery
---------------
'fat' & 'rat'
-</programlisting>
+</screen>
As in basic <type>tsquery</> input, weight(s) can be attached to each
lexeme to restrict it to match only <type>tsvector</> lexemes of those
weight(s). For example:
-<programlisting>
+<screen>
SELECT to_tsquery('english', 'Fat | Rats:AB');
to_tsquery
------------------
'fat' | 'rat':AB
-</programlisting>
+</screen>
Also, <literal>*</> can be attached to a lexeme to specify prefix matching:
-<programlisting>
+<screen>
SELECT to_tsquery('supern:*A & star:A*B');
to_tsquery
--------------------------
'supern':*A & 'star':*AB
-</programlisting>
+</screen>
Such a lexeme will match any word in a <type>tsvector</> that begins
with the given string.
In the example below, a thesaurus contains the rule <literal>supernovae
stars : sn</literal>:
-<programlisting>
+<screen>
SELECT to_tsquery('''supernovae stars'' & !crab');
to_tsquery
---------------
'sn' & !'crab'
-</programlisting>
+</screen>
Without quotes, <function>to_tsquery</function> will generate a syntax
error for tokens that are not separated by an AND or OR operator.
<primary>plainto_tsquery</primary>
</indexterm>
- <synopsis>
- plainto_tsquery(<optional> <replaceable class="PARAMETER">config</replaceable> <type>regconfig</>, </optional> <replaceable class="PARAMETER">querytext</replaceable> <type>text</>) returns <type>tsquery</>
- </synopsis>
+<synopsis>
+plainto_tsquery(<optional> <replaceable class="PARAMETER">config</replaceable> <type>regconfig</>, </optional> <replaceable class="PARAMETER">querytext</replaceable> <type>text</>) returns <type>tsquery</>
+</synopsis>
<para>
<function>plainto_tsquery</> transforms unformatted text
<para>
Example:
-<programlisting>
- SELECT plainto_tsquery('english', 'The Fat Rats');
+<screen>
+SELECT plainto_tsquery('english', 'The Fat Rats');
plainto_tsquery
-----------------
'fat' & 'rat'
-</programlisting>
+</screen>
Note that <function>plainto_tsquery</> cannot
recognize Boolean operators, weight labels, or prefix-match labels
in its input:
-<programlisting>
+<screen>
SELECT plainto_tsquery('english', 'The Fat & Rats:C');
plainto_tsquery
---------------------
'fat' & 'rat' & 'c'
-</programlisting>
+</screen>
Here, all the input punctuation was discarded as being space symbols.
</para>
</indexterm>
<term>
- <synopsis>
- ts_rank(<optional> <replaceable class="PARAMETER">weights</replaceable> <type>float4[]</>, </optional> <replaceable class="PARAMETER">vector</replaceable> <type>tsvector</>,
- <replaceable class="PARAMETER">query</replaceable> <type>tsquery</> <optional>, <replaceable class="PARAMETER">normalization</replaceable> <type>integer</> </optional>) returns <type>float4</>
- </synopsis>
+<synopsis>
+ts_rank(<optional> <replaceable class="PARAMETER">weights</replaceable> <type>float4[]</>, </optional> <replaceable class="PARAMETER">vector</replaceable> <type>tsvector</>,
+ <replaceable class="PARAMETER">query</replaceable> <type>tsquery</> <optional>, <replaceable class="PARAMETER">normalization</replaceable> <type>integer</> </optional>) returns <type>float4</>
+</synopsis>
</term>
<listitem>
</indexterm>
<term>
- <synopsis>
- ts_rank_cd(<optional> <replaceable class="PARAMETER">weights</replaceable> <type>float4[]</>, </optional> <replaceable class="PARAMETER">vector</replaceable> <type>tsvector</>,
- <replaceable class="PARAMETER">query</replaceable> <type>tsquery</> <optional>, <replaceable class="PARAMETER">normalization</replaceable> <type>integer</> </optional>) returns <type>float4</>
- </synopsis>
+<synopsis>
+ts_rank_cd(<optional> <replaceable class="PARAMETER">weights</replaceable> <type>float4[]</>, </optional> <replaceable class="PARAMETER">vector</replaceable> <type>tsvector</>,
+ <replaceable class="PARAMETER">query</replaceable> <type>tsquery</> <optional>, <replaceable class="PARAMETER">normalization</replaceable> <type>integer</> </optional>) returns <type>float4</>
+</synopsis>
</term>
<listitem>
heavily depending on how they are labeled. The weight arrays specify
how heavily to weigh each category of word, in the order:
-<programlisting>
+<synopsis>
{D-weight, C-weight, B-weight, A-weight}
-</programlisting>
+</synopsis>
If no <replaceable class="PARAMETER">weights</replaceable> are provided,
then these defaults are used:
<para>
Here is an example that selects only the ten highest-ranked matches:
-<programlisting>
+<screen>
SELECT title, ts_rank_cd(textsearch, query) AS rank
FROM apod, to_tsquery('neutrino|(dark & matter)') query
WHERE query @@ textsearch
Hot Gas and Dark Matter | 1.6123
Ice Fishing for Cosmic Neutrinos | 1.6
Weak Lensing Distorts the Universe | 0.818218
-</programlisting>
+</screen>
This is the same example using normalized ranking:
-<programlisting>
+<screen>
SELECT title, ts_rank_cd(textsearch, query, 32 /* rank/(rank+1) */ ) AS rank
FROM apod, to_tsquery('neutrino|(dark & matter)') query
WHERE query @@ textsearch
Hot Gas and Dark Matter | 0.617195790024749
Ice Fishing for Cosmic Neutrinos | 0.615384618911517
Weak Lensing Distorts the Universe | 0.450010798361481
-</programlisting>
+</screen>
</para>
<para>
<primary>ts_headline</primary>
</indexterm>
- <synopsis>
- ts_headline(<optional> <replaceable class="PARAMETER">config</replaceable> <type>regconfig</>, </optional> <replaceable class="PARAMETER">document</replaceable> <type>text</>, <replaceable class="PARAMETER">query</replaceable> <type>tsquery</> <optional>, <replaceable class="PARAMETER">options</replaceable> <type>text</> </optional>) returns <type>text</>
- </synopsis>
+<synopsis>
+ts_headline(<optional> <replaceable class="PARAMETER">config</replaceable> <type>regconfig</>, </optional> <replaceable class="PARAMETER">document</replaceable> <type>text</>, <replaceable class="PARAMETER">query</replaceable> <type>tsquery</> <optional>, <replaceable class="PARAMETER">options</replaceable> <type>text</> </optional>) returns <type>text</>
+</synopsis>
<para>
<function>ts_headline</function> accepts a document along
<para>
For example:
-<programlisting>
+<screen>
SELECT ts_headline('english',
'The most common type of search
is to find all documents containing given query terms
containing given <query> terms
and return them in order of their <similarity> to the
<query>.
-</programlisting>
+</screen>
</para>
<para>
</indexterm>
<term>
- <synopsis>
- <type>tsvector</> || <type>tsvector</>
- </synopsis>
+<synopsis>
+<type>tsvector</> || <type>tsvector</>
+</synopsis>
</term>
<listitem>
</indexterm>
<term>
- <synopsis>
- setweight(<replaceable class="PARAMETER">vector</replaceable> <type>tsvector</>, <replaceable class="PARAMETER">weight</replaceable> <type>"char"</>) returns <type>tsvector</>
- </synopsis>
+<synopsis>
+setweight(<replaceable class="PARAMETER">vector</replaceable> <type>tsvector</>, <replaceable class="PARAMETER">weight</replaceable> <type>"char"</>) returns <type>tsvector</>
+</synopsis>
</term>
<listitem>
</indexterm>
<term>
- <synopsis>
- length(<replaceable class="PARAMETER">vector</replaceable> <type>tsvector</>) returns <type>integer</>
- </synopsis>
+<synopsis>
+length(<replaceable class="PARAMETER">vector</replaceable> <type>tsvector</>) returns <type>integer</>
+</synopsis>
</term>
<listitem>
</indexterm>
<term>
- <synopsis>
- strip(<replaceable class="PARAMETER">vector</replaceable> <type>tsvector</>) returns <type>tsvector</>
- </synopsis>
+<synopsis>
+strip(<replaceable class="PARAMETER">vector</replaceable> <type>tsvector</>) returns <type>tsvector</>
+</synopsis>
</term>
<listitem>
<varlistentry>
<term>
- <synopsis>
- <type>tsquery</> && <type>tsquery</>
- </synopsis>
+<synopsis>
+<type>tsquery</> && <type>tsquery</>
+</synopsis>
</term>
<listitem>
<varlistentry>
<term>
- <synopsis>
- <type>tsquery</> || <type>tsquery</>
- </synopsis>
+<synopsis>
+<type>tsquery</> || <type>tsquery</>
+</synopsis>
</term>
<listitem>
<varlistentry>
<term>
- <synopsis>
- !! <type>tsquery</>
- </synopsis>
+<synopsis>
+!! <type>tsquery</>
+</synopsis>
</term>
<listitem>
</indexterm>
<term>
- <synopsis>
- numnode(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>) returns <type>integer</>
- </synopsis>
+<synopsis>
+numnode(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>) returns <type>integer</>
+</synopsis>
</term>
<listitem>
(returns > 0), or contains only stop words (returns 0).
Examples:
-<programlisting>
+<screen>
SELECT numnode(plainto_tsquery('the any'));
NOTICE: query contains only stopword(s) or doesn't contain lexeme(s), ignored
numnode
numnode
---------
3
-</programlisting>
+</screen>
</para>
</listitem>
</varlistentry>
</indexterm>
<term>
- <synopsis>
- querytree(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>) returns <type>text</>
- </synopsis>
+<synopsis>
+querytree(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>) returns <type>text</>
+</synopsis>
</term>
<listitem>
unindexable queries, for example those containing only stop words
or only negated terms. For example:
-<programlisting>
+<screen>
SELECT querytree(to_tsquery('!defined'));
querytree
-----------
-</programlisting>
+</screen>
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
- <synopsis>
- ts_rewrite (<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">target</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">substitute</replaceable> <type>tsquery</>) returns <type>tsquery</>
- </synopsis>
+<synopsis>
+ts_rewrite (<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">target</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">substitute</replaceable> <type>tsquery</>) returns <type>tsquery</>
+</synopsis>
</term>
<listitem>
wherever it appears in <replaceable
class="PARAMETER">query</replaceable>. For example:
-<programlisting>
+<screen>
SELECT ts_rewrite('a & b'::tsquery, 'a'::tsquery, 'c'::tsquery);
ts_rewrite
------------
'b' & 'c'
-</programlisting>
+</screen>
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>
- <synopsis>
- ts_rewrite (<replaceable class="PARAMETER">query</> <type>tsquery</>, <replaceable class="PARAMETER">select</> <type>text</>) returns <type>tsquery</>
- </synopsis>
+<synopsis>
+ts_rewrite (<replaceable class="PARAMETER">query</> <type>tsquery</>, <replaceable class="PARAMETER">select</> <type>text</>) returns <type>tsquery</>
+</synopsis>
</term>
<listitem>
(the target) are replaced by the second column value (the substitute)
within the current <replaceable>query</> value. For example:
-<programlisting>
+<screen>
CREATE TABLE aliases (t tsquery PRIMARY KEY, s tsquery);
INSERT INTO aliases VALUES('a', 'c');
ts_rewrite
------------
'b' & 'c'
-</programlisting>
+</screen>
</para>
<para>
Let's consider a real-life astronomical example. We'll expand query
<literal>supernovae</literal> using table-driven rewriting rules:
-<programlisting>
+<screen>
CREATE TABLE aliases (t tsquery primary key, s tsquery);
INSERT INTO aliases VALUES(to_tsquery('supernovae'), to_tsquery('supernovae|sn'));
ts_rewrite
---------------------------------
'crab' & ( 'supernova' | 'sn' )
-</programlisting>
+</screen>
We can change the rewriting rules just by updating the table:
-<programlisting>
+<screen>
UPDATE aliases
SET s = to_tsquery('supernovae|sn & !nebulae')
WHERE t = to_tsquery('supernovae');
ts_rewrite
---------------------------------------------
'crab' & ( 'supernova' | 'sn' & !'nebula' )
-</programlisting>
+</screen>
</para>
<para>
type. In the example below, we select only those rules which might match
the original query:
-<programlisting>
+<screen>
SELECT ts_rewrite('a & b'::tsquery,
'SELECT t,s FROM aliases WHERE ''a & b''::tsquery @> t');
ts_rewrite
------------
'b' & 'c'
-</programlisting>
+</screen>
</para>
</sect3>
your own.
</para>
- <synopsis>
- tsvector_update_trigger(<replaceable class="PARAMETER">tsvector_column_name</replaceable>, <replaceable class="PARAMETER">config_name</replaceable>, <replaceable class="PARAMETER">text_column_name</replaceable> <optional>, ... </optional>)
- tsvector_update_trigger_column(<replaceable class="PARAMETER">tsvector_column_name</replaceable>, <replaceable class="PARAMETER">config_column_name</replaceable>, <replaceable class="PARAMETER">text_column_name</replaceable> <optional>, ... </optional>)
- </synopsis>
+<synopsis>
+tsvector_update_trigger(<replaceable class="PARAMETER">tsvector_column_name</replaceable>, <replaceable class="PARAMETER">config_name</replaceable>, <replaceable class="PARAMETER">text_column_name</replaceable> <optional>, ... </optional>)
+tsvector_update_trigger_column(<replaceable class="PARAMETER">tsvector_column_name</replaceable>, <replaceable class="PARAMETER">config_column_name</replaceable>, <replaceable class="PARAMETER">text_column_name</replaceable> <optional>, ... </optional>)
+</synopsis>
<para>
These trigger functions automatically compute a <type>tsvector</>
parameters specified in the <command>CREATE TRIGGER</> command.
An example of their use is:
-<programlisting>
+<screen>
CREATE TABLE messages (
title text,
body text,
title | body
------------+-----------------------
title here | the body text is here
-</programlisting>
+</screen>
Having created this trigger, any change in <structfield>title</> or
<structfield>body</> will automatically be reflected into
$$ LANGUAGE plpgsql;
CREATE TRIGGER tsvectorupdate BEFORE INSERT OR UPDATE
-ON messages FOR EACH ROW EXECUTE PROCEDURE messages_trigger();
+ ON messages FOR EACH ROW EXECUTE PROCEDURE messages_trigger();
</programlisting>
</para>
configuration and for finding stop-word candidates.
</para>
- <synopsis>
- ts_stat(<replaceable class="PARAMETER">sqlquery</replaceable> <type>text</>, <optional> <replaceable class="PARAMETER">weights</replaceable> <type>text</>, </optional>
- OUT <replaceable class="PARAMETER">word</replaceable> <type>text</>, OUT <replaceable class="PARAMETER">ndoc</replaceable> <type>integer</>,
- OUT <replaceable class="PARAMETER">nentry</replaceable> <type>integer</>) returns <type>setof record</>
- </synopsis>
+<synopsis>
+ts_stat(<replaceable class="PARAMETER">sqlquery</replaceable> <type>text</>, <optional> <replaceable class="PARAMETER">weights</replaceable> <type>text</>, </optional>
+ OUT <replaceable class="PARAMETER">word</replaceable> <type>text</>, OUT <replaceable class="PARAMETER">ndoc</replaceable> <type>integer</>,
+ OUT <replaceable class="PARAMETER">nentry</replaceable> <type>integer</>) returns <type>setof record</>
+</synopsis>
<para>
<replaceable>sqlquery</replaceable> is a text value containing an SQL
piece of text. As an example, a hyphenated word will be reported both
as the entire word and as each component:
-<programlisting>
+<screen>
SELECT alias, description, token FROM ts_debug('foo-bar-beta1');
alias | description | token
-----------------+------------------------------------------+---------------
hword_asciipart | Hyphenated word part, all ASCII | bar
blank | Space symbols | -
hword_numpart | Hyphenated word part, letters and digits | beta1
-</programlisting>
+</screen>
This behavior is desirable since it allows searches to work for both
the whole compound word and for components. Here is another
instructive example:
-<programlisting>
+<screen>
SELECT alias, description, token FROM ts_debug('http://example.com/stuff/index.html');
alias | description | token
----------+---------------+------------------------------
url | URL | example.com/stuff/index.html
host | Host | example.com
url_path | URL path | /stuff/index.html
-</programlisting>
+</screen>
</para>
</sect1>
useless to store them in an index. However, stop words do affect the
positions in <type>tsvector</type>, which in turn affect ranking:
-<programlisting>
+<screen>
SELECT to_tsvector('english','in the list of stop words');
to_tsvector
----------------------------
'list':3 'stop':5 'word':6
-</programlisting>
+</screen>
The missing positions 1,2,4 are because of stop words. Ranks
calculated for documents with and without stop words are quite different:
-<programlisting>
+<screen>
SELECT ts_rank_cd (to_tsvector('english','in the list of stop words'), to_tsquery('list & stop'));
ts_rank_cd
------------
ts_rank_cd
------------
0.1
-</programlisting>
+</screen>
</para>
<para>
Now we can test our dictionary:
-<programlisting>
+<screen>
SELECT ts_lexize('public.simple_dict','YeS');
ts_lexize
-----------
ts_lexize
-----------
{}
-</programlisting>
+</screen>
</para>
<para>
selected by setting the dictionary's <literal>Accept</> parameter to
<literal>false</>. Continuing the example:
-<programlisting>
+<screen>
ALTER TEXT SEARCH DICTIONARY public.simple_dict ( Accept = false );
SELECT ts_lexize('public.simple_dict','YeS');
ts_lexize
-----------
{}
-</programlisting>
+</screen>
</para>
<para>
synonym dictionary and put it before the <literal>english_stem</>
dictionary. For example:
-<programlisting>
+<screen>
SELECT * FROM ts_debug('english', 'Paris');
alias | description | token | dictionaries | dictionary | lexemes
-----------+-----------------+-------+----------------+--------------+---------
alias | description | token | dictionaries | dictionary | lexemes
-----------+-----------------+-------+---------------------------+------------+---------
asciiword | Word, all ASCII | Paris | {my_synonym,english_stem} | my_synonym | {paris}
-</programlisting>
+</screen>
</para>
<para>
<para>
Contents of <filename>$SHAREDIR/tsearch_data/synonym_sample.syn</>:
- </para>
<programlisting>
postgres pgsql
postgresql pgsql
gogle googl
indices index*
</programlisting>
+ </para>
<para>
Results:
- </para>
-<programlisting>
-=# create text search dictionary syn( template=synonym,synonyms='synonym_sample');
-=# select ts_lexize('syn','indices');
+<screen>
+=# CREATE TEXT SEARCH DICTIONARY syn (template=synonym, synonyms='synonym_sample');
+=# SELECT ts_lexize('syn','indices');
ts_lexize
-----------
{index}
(1 row)
-=# create text search configuration tst ( copy=simple);
-=# alter text search configuration tst alter mapping for asciiword with syn;
-=# select to_tsquery('tst','indices');
+=# CREATE TEXT SEARCH CONFIGURATION tst (copy=simple);
+=# ALTER TEXT SEARCH CONFIGURATION tst ALTER MAPPING FOR asciiword WITH syn;
+=# SELECT to_tsquery('tst','indices');
to_tsquery
------------
'index':*
(1 row)
-=# select 'indexes are very useful'::tsvector;
+=# SELECT 'indexes are very useful'::tsvector;
tsvector
---------------------------------
'are' 'indexes' 'useful' 'very'
(1 row)
-=# select 'indexes are very useful'::tsvector @@ to_tsquery('tst','indices');
+=# SELECT 'indexes are very useful'::tsvector @@ to_tsquery('tst','indices');
?column?
----------
t
(1 row)
-=# select to_tsvector('tst','indices');
+=# SELECT to_tsvector('tst','indices');
to_tsvector
-------------
'index':1
(1 row)
-</programlisting>
+</screen>
+ </para>
<para>
The only parameter required by the <literal>synonym</> template is
<function>plainto_tsquery</function> and <function>to_tsvector</function>
which will break their input strings into multiple tokens:
-<programlisting>
+<screen>
SELECT plainto_tsquery('supernova star');
plainto_tsquery
-----------------
to_tsvector
-------------
'sn':1
-</programlisting>
+</screen>
In principle, one can use <function>to_tsquery</function> if you quote
the argument:
-<programlisting>
+<screen>
SELECT to_tsquery('''supernova star''');
to_tsquery
------------
'sn'
-</programlisting>
+</screen>
Notice that <literal>supernova star</literal> matches <literal>supernovae
stars</literal> in <literal>thesaurus_astro</literal> because we specified
To index the original phrase as well as the substitute, just include it
in the right-hand part of the definition:
-<programlisting>
+<screen>
supernovae stars : sn supernovae stars
SELECT plainto_tsquery('supernova star');
plainto_tsquery
-----------------------------
'sn' & 'supernova' & 'star'
-</programlisting>
+</screen>
</para>
</sect3>
The next step is to set the session to use the new configuration, which was
created in the <literal>public</> schema:
-<programlisting>
+<screen>
=> \dF
List of text search configurations
Schema | Name | Description
default_text_search_config
----------------------------
public.pg
-</programlisting>
+</screen>
</para>
</sect1>
<primary>ts_debug</primary>
</indexterm>
- <synopsis>
- ts_debug(<optional> <replaceable class="PARAMETER">config</replaceable> <type>regconfig</>, </optional> <replaceable class="PARAMETER">document</replaceable> <type>text</>,
- OUT <replaceable class="PARAMETER">alias</> <type>text</>,
- OUT <replaceable class="PARAMETER">description</> <type>text</>,
- OUT <replaceable class="PARAMETER">token</> <type>text</>,
- OUT <replaceable class="PARAMETER">dictionaries</> <type>regdictionary[]</>,
- OUT <replaceable class="PARAMETER">dictionary</> <type>regdictionary</>,
- OUT <replaceable class="PARAMETER">lexemes</> <type>text[]</>)
- returns setof record
- </synopsis>
+<synopsis>
+ts_debug(<optional> <replaceable class="PARAMETER">config</replaceable> <type>regconfig</>, </optional> <replaceable class="PARAMETER">document</replaceable> <type>text</>,
+ OUT <replaceable class="PARAMETER">alias</> <type>text</>,
+ OUT <replaceable class="PARAMETER">description</> <type>text</>,
+ OUT <replaceable class="PARAMETER">token</> <type>text</>,
+ OUT <replaceable class="PARAMETER">dictionaries</> <type>regdictionary[]</>,
+ OUT <replaceable class="PARAMETER">dictionary</> <type>regdictionary</>,
+ OUT <replaceable class="PARAMETER">lexemes</> <type>text[]</>)
+ returns setof record
+</synopsis>
<para>
<function>ts_debug</> displays information about every token of
<para>
Here is a simple example:
-<programlisting>
+<screen>
SELECT * FROM ts_debug('english','a fat cat sat on a mat - it ate a fat rats');
alias | description | token | dictionaries | dictionary | lexemes
-----------+-----------------+-------+----------------+--------------+---------
asciiword | Word, all ASCII | fat | {english_stem} | english_stem | {fat}
blank | Space symbols | | {} | |
asciiword | Word, all ASCII | rats | {english_stem} | english_stem | {rat}
-</programlisting>
+</screen>
</para>
<para>
ALTER MAPPING FOR asciiword WITH english_ispell, english_stem;
</programlisting>
-<programlisting>
+<screen>
SELECT * FROM ts_debug('public.english','The Brightest supernovaes');
alias | description | token | dictionaries | dictionary | lexemes
-----------+-----------------+-------------+-------------------------------+----------------+-------------
asciiword | Word, all ASCII | Brightest | {english_ispell,english_stem} | english_ispell | {bright}
blank | Space symbols | | {} | |
asciiword | Word, all ASCII | supernovaes | {english_ispell,english_stem} | english_stem | {supernova}
-</programlisting>
+</screen>
<para>
In this example, the word <literal>Brightest</> was recognized by the
You can reduce the width of the output by explicitly specifying which columns
you want to see:
-<programlisting>
+<screen>
SELECT alias, token, dictionary, lexemes
FROM ts_debug('public.english','The Brightest supernovaes');
alias | token | dictionary | lexemes
asciiword | Brightest | english_ispell | {bright}
blank | | |
asciiword | supernovaes | english_stem | {supernova}
-</programlisting>
+</screen>
</para>
</sect2>
<primary>ts_parse</primary>
</indexterm>
- <synopsis>
- ts_parse(<replaceable class="PARAMETER">parser_name</replaceable> <type>text</>, <replaceable class="PARAMETER">document</replaceable> <type>text</>,
- OUT <replaceable class="PARAMETER">tokid</> <type>integer</>, OUT <replaceable class="PARAMETER">token</> <type>text</>) returns <type>setof record</>
- ts_parse(<replaceable class="PARAMETER">parser_oid</replaceable> <type>oid</>, <replaceable class="PARAMETER">document</replaceable> <type>text</>,
- OUT <replaceable class="PARAMETER">tokid</> <type>integer</>, OUT <replaceable class="PARAMETER">token</> <type>text</>) returns <type>setof record</>
- </synopsis>
+<synopsis>
+ts_parse(<replaceable class="PARAMETER">parser_name</replaceable> <type>text</>, <replaceable class="PARAMETER">document</replaceable> <type>text</>,
+ OUT <replaceable class="PARAMETER">tokid</> <type>integer</>, OUT <replaceable class="PARAMETER">token</> <type>text</>) returns <type>setof record</>
+ts_parse(<replaceable class="PARAMETER">parser_oid</replaceable> <type>oid</>, <replaceable class="PARAMETER">document</replaceable> <type>text</>,
+ OUT <replaceable class="PARAMETER">tokid</> <type>integer</>, OUT <replaceable class="PARAMETER">token</> <type>text</>) returns <type>setof record</>
+</synopsis>
<para>
<function>ts_parse</> parses the given <replaceable>document</replaceable>
assigned token type and a <varname>token</varname> which is the text of the
token. For example:
-<programlisting>
+<screen>
SELECT * FROM ts_parse('default', '123 - a number');
tokid | token
-------+--------
1 | a
12 |
1 | number
-</programlisting>
+</screen>
</para>
<indexterm>
<primary>ts_token_type</primary>
</indexterm>
- <synopsis>
- ts_token_type(<replaceable class="PARAMETER">parser_name</> <type>text</>, OUT <replaceable class="PARAMETER">tokid</> <type>integer</>,
- OUT <replaceable class="PARAMETER">alias</> <type>text</>, OUT <replaceable class="PARAMETER">description</> <type>text</>) returns <type>setof record</>
- ts_token_type(<replaceable class="PARAMETER">parser_oid</> <type>oid</>, OUT <replaceable class="PARAMETER">tokid</> <type>integer</>,
- OUT <replaceable class="PARAMETER">alias</> <type>text</>, OUT <replaceable class="PARAMETER">description</> <type>text</>) returns <type>setof record</>
- </synopsis>
+<synopsis>
+ts_token_type(<replaceable class="PARAMETER">parser_name</> <type>text</>, OUT <replaceable class="PARAMETER">tokid</> <type>integer</>,
+ OUT <replaceable class="PARAMETER">alias</> <type>text</>, OUT <replaceable class="PARAMETER">description</> <type>text</>) returns <type>setof record</>
+ts_token_type(<replaceable class="PARAMETER">parser_oid</> <type>oid</>, OUT <replaceable class="PARAMETER">tokid</> <type>integer</>,
+ OUT <replaceable class="PARAMETER">alias</> <type>text</>, OUT <replaceable class="PARAMETER">description</> <type>text</>) returns <type>setof record</>
+</synopsis>
<para>
<function>ts_token_type</> returns a table which describes each type of
in configuration commands, and a short <varname>description</varname>. For
example:
-<programlisting>
+<screen>
SELECT * FROM ts_token_type('default');
tokid | alias | description
-------+-----------------+------------------------------------------
21 | int | Signed integer
22 | uint | Unsigned integer
23 | entity | XML entity
-</programlisting>
+</screen>
</para>
</sect2>
<primary>ts_lexize</primary>
</indexterm>
- <synopsis>
- ts_lexize(<replaceable class="PARAMETER">dict</replaceable> <type>regdictionary</>, <replaceable class="PARAMETER">token</replaceable> <type>text</>) returns <type>text[]</>
- </synopsis>
+<synopsis>
+ts_lexize(<replaceable class="PARAMETER">dict</replaceable> <type>regdictionary</>, <replaceable class="PARAMETER">token</replaceable> <type>text</>) returns <type>text[]</>
+</synopsis>
<para>
<function>ts_lexize</> returns an array of lexemes if the input
<para>
Examples:
-<programlisting>
+<screen>
SELECT ts_lexize('english_stem', 'stars');
ts_lexize
-----------
ts_lexize
-----------
{}
-</programlisting>
+</screen>
</para>
<note>
<emphasis>token</emphasis>, not text. Here is a case
where this can be confusing:
-<programlisting>
+<screen>
SELECT ts_lexize('thesaurus_astro','supernovae stars') is null;
?column?
----------
t
-</programlisting>
+</screen>
The thesaurus dictionary <literal>thesaurus_astro</literal> does know the
phrase <literal>supernovae stars</literal>, but <function>ts_lexize</>
token. Use <function>plainto_tsquery</> or <function>to_tsvector</> to
test thesaurus dictionaries, for example:
-<programlisting>
+<screen>
SELECT plainto_tsquery('supernovae stars');
plainto_tsquery
-----------------
'sn'
-</programlisting>
+</screen>
</para>
</note>
</indexterm>
<term>
- <synopsis>
- CREATE INDEX <replaceable>name</replaceable> ON <replaceable>table</replaceable> USING gist(<replaceable>column</replaceable>);
- </synopsis>
+<synopsis>
+CREATE INDEX <replaceable>name</replaceable> ON <replaceable>table</replaceable> USING gist(<replaceable>column</replaceable>);
+</synopsis>
</term>
<listitem>
</indexterm>
<term>
- <synopsis>
- CREATE INDEX <replaceable>name</replaceable> ON <replaceable>table</replaceable> USING gin(<replaceable>column</replaceable>);
- </synopsis>
+<synopsis>
+CREATE INDEX <replaceable>name</replaceable> ON <replaceable>table</replaceable> USING gin(<replaceable>column</replaceable>);
+</synopsis>
</term>
<listitem>
<para>
Information about text search configuration objects can be obtained
in <application>psql</application> using a set of commands:
- <synopsis>
- \dF{d,p,t}<optional>+</optional> <optional>PATTERN</optional>
- </synopsis>
+<synopsis>
+\dF{d,p,t}<optional>+</optional> <optional>PATTERN</optional>
+</synopsis>
An optional <literal>+</literal> produces more details.
</para>
regular expression and can provide <emphasis>separate</emphasis> patterns
for the schema and object names. The following examples illustrate this:
-<programlisting>
+<screen>
=> \dF *fulltext*
List of text search configurations
Schema | Name | Description
--------+--------------+-------------
public | fulltext_cfg |
-</programlisting>
+</screen>
-<programlisting>
+<screen>
=> \dF *.fulltext*
List of text search configurations
Schema | Name | Description
----------+----------------------------
fulltext | fulltext_cfg |
public | fulltext_cfg |
-</programlisting>
+</screen>
The available commands are:
</para>
<variablelist>
-
<varlistentry>
<term><synopsis>\dF<optional>+</optional> <optional>PATTERN</optional></synopsis></term>
-
<listitem>
<para>
List text search configurations (add <literal>+</> for more detail).
- </para>
-
- <para>
-
-<programlisting>
+<screen>
=> \dF russian
List of text search configurations
Schema | Name | Description
url_path | simple
version | simple
word | russian_stem
-</programlisting>
+</screen>
</para>
</listitem>
</varlistentry>
<listitem>
<para>
List text search dictionaries (add <literal>+</> for more detail).
- </para>
-
- <para>
-<programlisting>
+<screen>
=> \dFd
List of text search dictionaries
Schema | Name | Description
pg_catalog | spanish_stem | snowball stemmer for spanish language
pg_catalog | swedish_stem | snowball stemmer for swedish language
pg_catalog | turkish_stem | snowball stemmer for turkish language
-</programlisting>
+</screen>
</para>
</listitem>
</varlistentry>
<varlistentry>
-
<term><synopsis>\dFp<optional>+</optional> <optional>PATTERN</optional></synopsis></term>
<listitem>
<para>
List text search parsers (add <literal>+</> for more detail).
- </para>
-
- <para>
-<programlisting>
+<screen>
=> \dFp
List of text search parsers
Schema | Name | Description
version | Version number
word | Word, all letters
(23 rows)
-</programlisting>
+</screen>
</para>
</listitem>
</varlistentry>
<varlistentry>
-
<term><synopsis>\dFt<optional>+</optional> <optional>PATTERN</optional></synopsis></term>
<listitem>
<para>
List text search templates (add <literal>+</> for more detail).
- </para>
-
- <para>
-<programlisting>
+<screen>
=> \dFt
List of text search templates
Schema | Name | Description
pg_catalog | snowball | snowball stemmer
pg_catalog | synonym | synonym dictionary: replace word by its synonym
pg_catalog | thesaurus | thesaurus dictionary: phrase by phrase substitution
-</programlisting>
+</screen>
</para>
</listitem>
</varlistentry>
-
</variablelist>
</sect1>
<listitem>
<para>
Each line represents pair: character_with_accent character_without_accent
- <programlisting>
+<programlisting>
À A
Á A
 A
Ä A
Å A
Æ A
- </programlisting>
+</programlisting>
</para>
</listitem>
</itemizedlist>
<primary>unaccent</primary>
</indexterm>
- <synopsis>
- unaccent(<optional><replaceable class="PARAMETER">dictionary</replaceable>,
- </optional> <replaceable class="PARAMETER">string</replaceable>)
- returns <type>text</type>
- </synopsis>
+<synopsis>
+unaccent(<optional><replaceable class="PARAMETER">dictionary</replaceable>, </optional> <replaceable class="PARAMETER">string</replaceable>)
+returns <type>text</type>
+</synopsis>
<para>
<programlisting>
-SELECT unaccent('unaccent','Hôtel');
+SELECT unaccent('unaccent', 'Hôtel');
SELECT unaccent('Hôtel');
</programlisting>
</para>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/uuid-ossp.sgml,v 1.2 2007/12/06 04:12:10 tgl Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/uuid-ossp.sgml,v 1.3 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="uuid-ossp">
<title>uuid-ossp</title>
<para>
For example:
- <programlisting>
- SELECT uuid_generate_v3(uuid_ns_url(), 'http://www.postgresql.org');
- </programlisting>
+<programlisting>
+SELECT uuid_generate_v3(uuid_ns_url(), 'http://www.postgresql.org');
+</programlisting>
The name parameter will be MD5-hashed, so the cleartext cannot be
derived from the generated UUID.
-<!-- $PostgreSQL: pgsql/doc/src/sgml/vacuumlo.sgml,v 1.4 2009/02/26 16:02:37 petere Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/vacuumlo.sgml,v 1.5 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="vacuumlo">
<title>vacuumlo</title>
<sect2>
<title>Usage</title>
- <synopsis>
+<synopsis>
vacuumlo [options] database [database2 ... databaseN]
- </synopsis>
+</synopsis>
<para>
All databases named on the command line are processed. Available options
-<!-- $PostgreSQL: pgsql/doc/src/sgml/xaggr.sgml,v 1.40 2010/04/03 07:22:56 petere Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/xaggr.sgml,v 1.41 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="xaggr">
<title>User-Defined Aggregates</title>
aggregate transition or final function by calling
<function>AggCheckCallContext</>, for example:
<programlisting>
- if (AggCheckCallContext(fcinfo, NULL))
+if (AggCheckCallContext(fcinfo, NULL))
</programlisting>
One reason for checking this is that when it is true for a transition
function, the first input
-<!-- $PostgreSQL: pgsql/doc/src/sgml/xfunc.sgml,v 1.151 2010/07/26 20:14:05 petere Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/xfunc.sgml,v 1.152 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="xfunc">
<title>User-Defined Functions</title>
<function>AddinShmemInitLock</> when connecting to and initializing
its allocation of shared memory, as shown here:
<programlisting>
- static mystruct *ptr = NULL;
+static mystruct *ptr = NULL;
- if (!ptr)
+if (!ptr)
+{
+ bool found;
+
+ LWLockAcquire(AddinShmemInitLock, LW_EXCLUSIVE);
+ ptr = ShmemInitStruct("my struct name", size, &found);
+ if (!found)
{
- bool found;
-
- LWLockAcquire(AddinShmemInitLock, LW_EXCLUSIVE);
- ptr = ShmemInitStruct("my struct name", size, &found);
- if (!found)
- {
- initialize contents of shmem area;
- acquire any requested LWLocks using:
- ptr->mylockid = LWLockAssign();
- }
- LWLockRelease(AddinShmemInitLock);
+ initialize contents of shmem area;
+ acquire any requested LWLocks using:
+ ptr->mylockid = LWLockAssign();
}
+ LWLockRelease(AddinShmemInitLock);
+}
</programlisting>
</para>
</sect2>
-<!-- $PostgreSQL: pgsql/doc/src/sgml/xml2.sgml,v 1.8 2010/07/27 19:01:16 petere Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/xml2.sgml,v 1.9 2010/07/29 19:34:40 petere Exp $ -->
<sect1 id="xml2">
<title>xml2</title>
<tbody>
<row>
<entry>
- <synopsis>
- xml_is_well_formed(document) returns bool
- </synopsis>
+<synopsis>
+xml_is_well_formed(document) returns bool
+</synopsis>
</entry>
<entry>
<para>
</row>
<row>
<entry>
- <synopsis>
- xpath_string(document,query) returns text
- xpath_number(document,query) returns float4
- xpath_bool(document,query) returns bool
- </synopsis>
+<synopsis>
+xpath_string(document, query) returns text
+xpath_number(document, query) returns float4
+xpath_bool(document, query) returns bool
+</synopsis>
</entry>
<entry>
<para>
</row>
<row>
<entry>
- <synopsis>
- xpath_nodeset(document,query,toptag,itemtag) returns text
- </synopsis>
+<synopsis>
+xpath_nodeset(document, query, toptag, itemtag) returns text
+</synopsis>
</entry>
<entry>
<para>
This evaluates query on document and wraps the result in XML tags. If
the result is multivalued, the output will look like:
- </para>
- <literal>
- <toptag>
- <itemtag>Value 1 which could be an XML fragment</itemtag>
- <itemtag>Value 2....</itemtag>
- </toptag>
- </literal>
- <para>
+<synopsis>
+<toptag>
+<itemtag>Value 1 which could be an XML fragment</itemtag>
+<itemtag>Value 2....</itemtag>
+</toptag>
+</synopsis>
If either toptag or itemtag is an empty string, the relevant tag is omitted.
</para>
</entry>
</row>
<row>
<entry>
- <synopsis>
- xpath_nodeset(document,query) returns text
- </synopsis>
+<synopsis>
+xpath_nodeset(document, query) returns text
+</synopsis>
</entry>
<entry>
<para>
</row>
<row>
<entry>
- <synopsis>
- xpath_nodeset(document,query,itemtag) returns text
- </synopsis>
+<synopsis>
+xpath_nodeset(document, query, itemtag) returns text
+</synopsis>
</entry>
<entry>
<para>
</row>
<row>
<entry>
- <synopsis>
- xpath_list(document,query,separator) returns text
- </synopsis>
+<synopsis>
+xpath_list(document, query, separator) returns text
+</synopsis>
</entry>
<entry>
<para>
</row>
<row>
<entry>
- <synopsis>
- xpath_list(document,query) returns text
- </synopsis>
+<synopsis>
+xpath_list(document, query) returns text
+</synopsis>
</entry>
<entry>
This is a wrapper for the above function that uses <literal>,</>
<sect2>
<title><literal>xpath_table</literal></title>
- <synopsis>
- xpath_table(text key, text document, text relation, text xpaths, text criteria) returns setof record
- </synopsis>
+<synopsis>
+xpath_table(text key, text document, text relation, text xpaths, text criteria) returns setof record
+</synopsis>
<para>
<function>xpath_table</> is a table function that evaluates a set of XPath
<para>
The function has to be used in a <literal>FROM</> expression, with an
<literal>AS</> clause to specify the output columns; for example
- </para>
-
- <programlisting>
+<programlisting>
SELECT * FROM
xpath_table('article_id',
'article_xml',
'/article/author|/article/pages|/article/title',
'date_entered > ''2003-01-01'' ')
AS t(article_id integer, author text, page_count integer, title text);
- </programlisting>
-
- <para>
+</programlisting>
The <literal>AS</> clause defines the names and types of the columns in the
output table. The first is the <quote>key</> field and the rest correspond
to the XPath queries.
columns by name or join them to other tables. The function produces a
virtual table with which you can perform any operation you wish (e.g.
aggregation, joining, sorting etc). So we could also have:
- </para>
-
- <programlisting>
+<programlisting>
SELECT t.title, p.fullname, p.email
FROM xpath_table('article_id', 'article_xml', 'articles',
'/article/title|/article/author/@id',
AS t(article_id integer, title text, author_id integer),
tblPeopleInfo AS p
WHERE t.author_id = p.person_id;
- </programlisting>
-
- <para>
+</programlisting>
as a more complicated example. Of course, you could wrap all
of this in a view for convenience.
</para>
result will appear only on the first row of the result. The solution
to this is to use the key field as part of a join against a simpler
XPath query. As an example:
- </para>
- <programlisting>
- CREATE TABLE test (
- id int4 NOT NULL,
- xml text,
- CONSTRAINT pk PRIMARY KEY (id)
- );
-
- INSERT INTO test VALUES (1, '<doc num="C1">
- <line num="L1"><a>1</a><b>2</b><c>3</c></line>
- <line num="L2"><a>11</a><b>22</b><c>33</c></line>
- </doc>');
-
- INSERT INTO test VALUES (2, '<doc num="C2">
- <line num="L1"><a>111</a><b>222</b><c>333</c></line>
- <line num="L2"><a>111</a><b>222</b><c>333</c></line>
- </doc>');
-
- SELECT * FROM
- xpath_table('id','xml','test',
- '/doc/@num|/doc/line/@num|/doc/line/a|/doc/line/b|/doc/line/c',
- 'true')
- AS t(id int4, doc_num varchar(10), line_num varchar(10), val1 int4, val2 int4, val3 int4)
- WHERE id = 1 ORDER BY doc_num, line_num
-
- id | doc_num | line_num | val1 | val2 | val3
- ----+---------+----------+------+------+------
- 1 | C1 | L1 | 1 | 2 | 3
- 1 | | L2 | 11 | 22 | 33
- </programlisting>
+<programlisting>
+CREATE TABLE test (
+ id int PRIMARY KEY,
+ xml text
+);
+
+INSERT INTO test VALUES (1, '<doc num="C1">
+<line num="L1"><a>1</a><b>2</b><c>3</c></line>
+<line num="L2"><a>11</a><b>22</b><c>33</c></line>
+</doc>');
+
+INSERT INTO test VALUES (2, '<doc num="C2">
+<line num="L1"><a>111</a><b>222</b><c>333</c></line>
+<line num="L2"><a>111</a><b>222</b><c>333</c></line>
+</doc>');
+
+SELECT * FROM
+ xpath_table('id','xml','test',
+ '/doc/@num|/doc/line/@num|/doc/line/a|/doc/line/b|/doc/line/c',
+ 'true')
+ AS t(id int, doc_num varchar(10), line_num varchar(10), val1 int, val2 int, val3 int)
+WHERE id = 1 ORDER BY doc_num, line_num
+
+ id | doc_num | line_num | val1 | val2 | val3
+----+---------+----------+------+------+------
+ 1 | C1 | L1 | 1 | 2 | 3
+ 1 | | L2 | 11 | 22 | 33
+</programlisting>
+ </para>
<para>
To get doc_num on every line, the solution is to use two invocations
of xpath_table and join the results:
- </para>
- <programlisting>
- SELECT t.*,i.doc_num FROM
- xpath_table('id', 'xml', 'test',
- '/doc/line/@num|/doc/line/a|/doc/line/b|/doc/line/c',
- 'true')
- AS t(id int4, line_num varchar(10), val1 int4, val2 int4, val3 int4),
- xpath_table('id', 'xml', 'test', '/doc/@num', 'true')
- AS i(id int4, doc_num varchar(10))
- WHERE i.id=t.id AND i.id=1
- ORDER BY doc_num, line_num;
-
- id | line_num | val1 | val2 | val3 | doc_num
- ----+----------+------+------+------+---------
- 1 | L1 | 1 | 2 | 3 | C1
- 1 | L2 | 11 | 22 | 33 | C1
- (2 rows)
- </programlisting>
+<programlisting>
+SELECT t.*,i.doc_num FROM
+ xpath_table('id', 'xml', 'test',
+ '/doc/line/@num|/doc/line/a|/doc/line/b|/doc/line/c',
+ 'true')
+ AS t(id int, line_num varchar(10), val1 int, val2 int, val3 int),
+ xpath_table('id', 'xml', 'test', '/doc/@num', 'true')
+ AS i(id int, doc_num varchar(10))
+WHERE i.id=t.id AND i.id=1
+ORDER BY doc_num, line_num;
+
+ id | line_num | val1 | val2 | val3 | doc_num
+----+----------+------+------+------+---------
+ 1 | L1 | 1 | 2 | 3 | C1
+ 1 | L2 | 11 | 22 | 33 | C1
+(2 rows)
+</programlisting>
+ </para>
</sect3>
</sect2>
<sect3>
<title><literal>xslt_process</literal></title>
- <synopsis>
- xslt_process(text document, text stylesheet, text paramlist) returns text
- </synopsis>
+<synopsis>
+xslt_process(text document, text stylesheet, text paramlist) returns text
+</synopsis>
<para>
This function applies the XSL stylesheet to the document and returns