Commit 7c084d14 authored by Peter Eisentraut's avatar Peter Eisentraut

Bring SQL ref pages to consistent format, part 1.

parent 72aa9488
<!-- <!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/abort.sgml,v 1.11 2002/04/21 19:02:39 thomas Exp $ $Header: /cvsroot/pgsql/doc/src/sgml/ref/abort.sgml,v 1.12 2003/04/15 13:25:08 petere Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -8,130 +8,82 @@ PostgreSQL documentation ...@@ -8,130 +8,82 @@ PostgreSQL documentation
<refentrytitle id="sql-abort-title">ABORT</refentrytitle> <refentrytitle id="sql-abort-title">ABORT</refentrytitle>
<refmiscinfo>SQL - Language Statements</refmiscinfo> <refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta> </refmeta>
<refnamediv> <refnamediv>
<refname> <refname>ABORT</refname>
ABORT <refpurpose>abort the current transaction</refpurpose>
</refname>
<refpurpose>
abort the current transaction
</refpurpose>
</refnamediv> </refnamediv>
<refsynopsisdiv> <refsynopsisdiv>
<refsynopsisdivinfo> <synopsis>
<date>1999-07-20</date>
</refsynopsisdivinfo>
<synopsis>
ABORT [ WORK | TRANSACTION ] ABORT [ WORK | TRANSACTION ]
</synopsis> </synopsis>
<refsect2 id="R2-SQL-ABORT-1">
<refsect2info>
<date>1998-09-27</date>
</refsect2info>
<title>
Inputs
</title>
<para>
None.
</para>
</refsect2>
<refsect2 id="R2-SQL-ABORT-2">
<refsect2info>
<date>1998-09-27</date>
</refsect2info>
<title>
Outputs
</title>
<para>
<variablelist>
<varlistentry>
<term><computeroutput>
ROLLBACK
</computeroutput></term>
<listitem>
<para>
Message returned if successful.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><computeroutput>
WARNING: ROLLBACK: no transaction in progress
</computeroutput></term>
<listitem>
<para>
If there is not any transaction currently in progress.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
</refsynopsisdiv> </refsynopsisdiv>
<refsect1 id="R1-SQL-ABORT-1"> <refsect1>
<refsect1info> <title>Description</title>
<date>1998-09-27</date>
</refsect1info>
<title>
Description
</title>
<para> <para>
<command>ABORT</command> rolls back the current transaction and causes <command>ABORT</command> rolls back the current transaction and causes
all the updates made by the transaction to be discarded. all the updates made by the transaction to be discarded.
This command is identical This command is identical
in behavior to the <acronym>SQL92</acronym> command <command>ROLLBACK</command>, in behavior to the standard <acronym>SQL</acronym> command <command>ROLLBACK</command>,
and is present only for historical reasons. and is present only for historical reasons.
</para> </para>
<refsect2 id="R2-SQL-ABORT-3">
<refsect2info>
<date>1998-09-27</date>
</refsect2info>
<title>
Notes
</title>
<para>
Use <command>COMMIT</command> to successfully
terminate a transaction.
</para>
</refsect2>
</refsect1> </refsect1>
<refsect1 id="R1-SQL-ABORT-2"> <refsect1>
<title> <title>Diagnostics</title>
Usage
</title> <variablelist>
<varlistentry>
<term><computeroutput>ROLLBACK</computeroutput></term>
<listitem>
<para>
Message returned if successful.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><computeroutput>WARNING: ROLLBACK: no transaction in progress</computeroutput></term>
<listitem>
<para>
If there is not any transaction currently in progress.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Notes</title>
<para>
Use <command>COMMIT</command> to successfully
terminate a transaction.
</para>
</refsect1>
<refsect1>
<title>Examples</title>
<para> <para>
To abort all changes: To abort all changes:
<programlisting> <programlisting>
ABORT WORK; ABORT WORK;
</programlisting> </programlisting>
</para> </para>
</refsect1> </refsect1>
<refsect1 id="R1-SQL-ABORT-3"> <refsect1>
<title> <title>Compatibility</title>
Compatibility
</title> <para>
This command is a <productname>PostgreSQL</productname> extension
<refsect2 id="R2-SQL-ABORT-4"> present for historical reasons. <command>ROLLBACK</command> is the
<refsect2info> equivalent standard SQL command.
<date>1998-09-27</date> </para>
</refsect2info>
<title>
SQL92
</title>
<para>
This command is a <productname>PostgreSQL</productname> extension present
for historical reasons. <command>ROLLBACK</command> is the <acronym>SQL92</acronym>
equivalent command.
</para>
</refsect2>
</refsect1> </refsect1>
</refentry> </refentry>
......
<!-- <!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/alter_database.sgml,v 1.5 2003/03/25 16:15:38 petere Exp $ $Header: /cvsroot/pgsql/doc/src/sgml/ref/alter_database.sgml,v 1.6 2003/04/15 13:25:08 petere Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -32,18 +32,18 @@ ALTER DATABASE <replaceable class="PARAMETER">name</replaceable> RESET <replacea ...@@ -32,18 +32,18 @@ ALTER DATABASE <replaceable class="PARAMETER">name</replaceable> RESET <replacea
value becomes the session default value. value becomes the session default value.
The database-specific default The database-specific default
overrides whatever setting is present in <filename>postgresql.conf</> overrides whatever setting is present in <filename>postgresql.conf</>
or has been received from the postmaster. or has been received from the <command>postmaster</command> command line.
</para> </para>
<para> <para>
Only a superuser or the database owner can change the session defaults for a Only the database owner or a superuser can change the session defaults for a
database. database.
</para> </para>
</refsect1>
<refsect2> <refsect1>
<title>Parameters</title> <title>Parameters</title>
<para>
<variablelist> <variablelist>
<varlistentry> <varlistentry>
<term><replaceable class="PARAMETER">name</replaceable></term> <term><replaceable class="PARAMETER">name</replaceable></term>
...@@ -77,14 +77,11 @@ ALTER DATABASE <replaceable class="PARAMETER">name</replaceable> RESET <replacea ...@@ -77,14 +77,11 @@ ALTER DATABASE <replaceable class="PARAMETER">name</replaceable> RESET <replacea
</listitem> </listitem>
</varlistentry> </varlistentry>
</variablelist> </variablelist>
</para>
</refsect2>
</refsect1> </refsect1>
<refsect1> <refsect1>
<title>Diagnostics</title> <title>Diagnostics</title>
<para>
<variablelist> <variablelist>
<varlistentry> <varlistentry>
<term><computeroutput>ALTER DATABASE</computeroutput></term> <term><computeroutput>ALTER DATABASE</computeroutput></term>
...@@ -105,7 +102,6 @@ ALTER DATABASE <replaceable class="PARAMETER">name</replaceable> RESET <replacea ...@@ -105,7 +102,6 @@ ALTER DATABASE <replaceable class="PARAMETER">name</replaceable> RESET <replacea
</listitem> </listitem>
</varlistentry> </varlistentry>
</variablelist> </variablelist>
</para>
</refsect1> </refsect1>
<refsect1> <refsect1>
......
<!-- <!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/alter_group.sgml,v 1.8 2002/04/21 19:02:39 thomas Exp $ $Header: /cvsroot/pgsql/doc/src/sgml/ref/alter_group.sgml,v 1.9 2003/04/15 13:25:08 petere Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -8,92 +8,29 @@ PostgreSQL documentation ...@@ -8,92 +8,29 @@ PostgreSQL documentation
<refentrytitle id="SQL-ALTERGROUP-title">ALTER GROUP</refentrytitle> <refentrytitle id="SQL-ALTERGROUP-title">ALTER GROUP</refentrytitle>
<refmiscinfo>SQL - Language Statements</refmiscinfo> <refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta> </refmeta>
<refnamediv> <refnamediv>
<refname> <refname>ALTER GROUP</refname>
ALTER GROUP <refpurpose>add users to a group or remove users from a group</refpurpose>
</refname>
<refpurpose>
add users to a group or remove users from a group
</refpurpose>
</refnamediv> </refnamediv>
<refsynopsisdiv> <refsynopsisdiv>
<refsynopsisdivinfo> <synopsis>
<date>2000-01-14</date> ALTER GROUP <replaceable class="PARAMETER">groupname</replaceable> ADD USER <replaceable class="PARAMETER">username</replaceable> [, ... ]
</refsynopsisdivinfo> ALTER GROUP <replaceable class="PARAMETER">groupname</replaceable> DROP USER <replaceable class="PARAMETER">username</replaceable> [, ... ]
<synopsis> </synopsis>
ALTER GROUP <replaceable class="PARAMETER">name</replaceable> ADD USER <replaceable class="PARAMETER">username</replaceable> [, ... ]
ALTER GROUP <replaceable class="PARAMETER">name</replaceable> DROP USER <replaceable class="PARAMETER">username</replaceable> [, ... ]
</synopsis>
<refsect2 id="R2-SQL-ALTERGROUP-1">
<refsect2info>
<date>2000-01-14</date>
</refsect2info>
<title>
Inputs
</title>
<para>
<variablelist>
<varlistentry>
<term><replaceable class="PARAMETER">name</replaceable></term>
<listitem>
<para>
The name of the group to modify.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">username</replaceable></term>
<listitem>
<para>
Users which are to be added or removed from the group. The user
names must exist.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
<refsect2 id="R2-SQL-ALTERGROUP-2">
<refsect2info>
<date>2000-01-14</date>
</refsect2info>
<title>
Outputs
</title>
<para>
<variablelist>
<varlistentry>
<term><computeroutput>ALTER GROUP</computeroutput></term>
<listitem>
<para>
Message returned if the alteration was successful.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
</refsynopsisdiv> </refsynopsisdiv>
<refsect1 id="R1-SQL-ALTERGROUP-1"> <refsect1>
<refsect1info> <title>Description</title>
<date>2000-01-14</date>
</refsect1info>
<title>
Description
</title>
<para> <para>
<command>ALTER GROUP</command> is used to add or remove users from a <command>ALTER GROUP</command> is used to add or remove users from a
group. Only database superusers can use this command. group. Only database superusers can use this command.
Adding a user to a group does not create the user. Similarly, removing Adding a user to a group does not create the user. Similarly, removing
a user from a group does not drop the user itself. a user from a group does not drop the user itself.
</para> </para>
<para> <para>
Use <xref linkend="SQL-CREATEGROUP" endterm="SQL-CREATEGROUP-title"> Use <xref linkend="SQL-CREATEGROUP" endterm="SQL-CREATEGROUP-title">
to create a new group and <xref linkend="SQL-DROPGROUP" to create a new group and <xref linkend="SQL-DROPGROUP"
...@@ -101,10 +38,48 @@ ALTER GROUP <replaceable class="PARAMETER">name</replaceable> DROP USER <replace ...@@ -101,10 +38,48 @@ ALTER GROUP <replaceable class="PARAMETER">name</replaceable> DROP USER <replace
</para> </para>
</refsect1> </refsect1>
<refsect1 id="R1-SQL-ALTERGROUP-2"> <refsect1>
<title> <title>Parameter</title>
Usage
</title> <variablelist>
<varlistentry>
<term><replaceable class="PARAMETER">groupname</replaceable></term>
<listitem>
<para>
The name of the group to modify.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">username</replaceable></term>
<listitem>
<para>
Users which are to be added or removed from the group. The users
must exist.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Diagnostics</title>
<variablelist>
<varlistentry>
<term><computeroutput>ALTER GROUP</computeroutput></term>
<listitem>
<para>
Message returned if the alteration was successful.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Examples</title>
<para> <para>
Add users to a group: Add users to a group:
...@@ -121,24 +96,13 @@ ALTER GROUP workers DROP USER beth; ...@@ -121,24 +96,13 @@ ALTER GROUP workers DROP USER beth;
</para> </para>
</refsect1> </refsect1>
<refsect1 id="R1-SQL-ALTERGROUP-3"> <refsect1>
<title> <title>Compatibility</title>
Compatibility
</title>
<refsect2 id="R2-SQL-ALTERGROUP-4"> <para>
<refsect2info> There is no <command>ALTER GROUP</command> statement in the SQL
<date>2000-01-14</date> standard. The concept of roles is similar.
</refsect2info> </para>
<title>
SQL92
</title>
<para>
There is no <command>ALTER GROUP</command> statement in
<acronym>SQL92</acronym>. The concept of roles is
similar.
</para>
</refsect2>
</refsect1> </refsect1>
</refentry> </refentry>
......
This diff is collapsed.
<!-- <!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/alter_trigger.sgml,v 1.4 2003/04/15 13:25:08 petere Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
<refentry id="SQL-ALTERTRIGGER"> <refentry id="SQL-ALTERTRIGGER">
<refmeta> <refmeta>
<refentrytitle id="sql-altertrigger-title"> <refentrytitle id="sql-altertrigger-title">ALTER TRIGGER</refentrytitle>
ALTER TRIGGER
</refentrytitle>
<refmiscinfo>SQL - Language Statements</refmiscinfo> <refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta> </refmeta>
<refnamediv> <refnamediv>
<refname> <refname>ALTER TRIGGER</refname>
ALTER TRIGGER <refpurpose>change the definition of a trigger</refpurpose>
</refname>
<refpurpose>
change the definition of a trigger
</refpurpose>
</refnamediv> </refnamediv>
<refsynopsisdiv> <refsynopsisdiv>
<refsynopsisdivinfo> <synopsis>
<date>2002-04-19</date>
</refsynopsisdivinfo>
<synopsis>
ALTER TRIGGER <replaceable class="PARAMETER">trigger</replaceable> ON <replaceable class="PARAMETER">table</replaceable> ALTER TRIGGER <replaceable class="PARAMETER">trigger</replaceable> ON <replaceable class="PARAMETER">table</replaceable>
RENAME TO <replaceable class="PARAMETER">newname</replaceable> RENAME TO <replaceable class="PARAMETER">newname</replaceable>
</synopsis> </synopsis>
<refsect2 id="R2-SQL-ALTERTRIGGER-1">
<refsect2info>
<date>2002-04-19</date>
</refsect2info>
<title>
Inputs
</title>
<para>
<variablelist>
<varlistentry>
<term><replaceable class="PARAMETER"> trigger </replaceable></term>
<listitem>
<para>
The name of an existing trigger to alter.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER"> table </replaceable></term>
<listitem>
<para>
The name of the table on which this trigger acts.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER"> newname </replaceable></term>
<listitem>
<para>
New name for the existing trigger.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
<refsect2 id="R2-SQL-ALTERTRIGGER-2">
<refsect2info>
<date>2002-04-19</date>
</refsect2info>
<title>
Outputs
</title>
<para>
<variablelist>
<varlistentry>
<term><computeroutput>ALTER TRIGGER</computeroutput></term>
<listitem>
<para>
Message returned from trigger renaming.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><computeroutput>ERROR</computeroutput></term>
<listitem>
<para>
Message returned if trigger is not available, or new name is a duplicate of another existing trigger on the table.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
</refsynopsisdiv> </refsynopsisdiv>
<refsect1 id="R1-SQL-ALTERTRIGGER-1"> <refsect1>
<refsect1info> <title>Description</title>
<date>2002-04-19</date>
</refsect1info>
<title>
Description
</title>
<para> <para>
<command>ALTER TRIGGER</command> changes the definition of an existing trigger. <command>ALTER TRIGGER</command> changes properties of an existing
The <literal>RENAME</literal> clause causes the name of a trigger on the given table trigger. The <literal>RENAME</literal> clause changes the name of
to change without otherwise changing the trigger definition. the given trigger without otherwise changing the trigger
definition.
</para> </para>
<para> <para>
You must own the table on which the trigger acts in order to change its properties. You must own the table on which the trigger acts to be allowed to change its properties.
</para> </para>
</refsect1>
<refsect1>
<title>Parameter</title>
<variablelist>
<varlistentry>
<term><replaceable class="PARAMETER">trigger</replaceable></term>
<listitem>
<para>
The name of an existing trigger to alter.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">table</replaceable></term>
<listitem>
<para>
The name of the table on which this trigger acts.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">newname</replaceable></term>
<listitem>
<para>
The new name for the trigger.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect2 id="R2-SQL-ALTERTRIGGER-3"> <refsect1>
<refsect2info> <title>Diagnostics</title>
<date>2002-04-19</date>
</refsect2info> <variablelist>
<title> <varlistentry>
Notes <term><computeroutput>ALTER TRIGGER</computeroutput></term>
</title> <listitem>
<para> <para>
Refer to <command>CREATE TRIGGER</command> for a further description Message returned if successful.
of valid arguments. </para>
</para> </listitem>
</refsect2> </varlistentry>
<varlistentry>
<term><computeroutput>ERROR</computeroutput></term>
<listitem>
<para>
If the trigger does not exist, or the new name is a duplicate of
another existing trigger on the table.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1> </refsect1>
<refsect1 id="R1-SQL-ALTERTRIGGER-2"> <refsect1>
<title> <title>Examples</title>
Usage
</title>
<para> <para>
To rename an existing trigger: To rename an existing trigger:
<programlisting> <programlisting>
ALTER TRIGGER emp_stamp ON emp RENAME TO emp_track_chgs; ALTER TRIGGER emp_stamp ON emp RENAME TO emp_track_chgs;
</programlisting> </programlisting>
</para> </para>
</refsect1> </refsect1>
<refsect1 id="R1-SQL-ALTERTRIGGER-3"> <refsect1>
<title> <title>Compatibility</title>
Compatibility
</title> <para>
<command>ALTER TRIGGER</command> is a <productname>PostgreSQL</>
<refsect2 id="R2-SQL-ALTERTRIGGER-4"> extension of the SQL standard.
<refsect2info> </para>
<date>2002-04-19</date>
</refsect2info>
<title>SQL92</title>
<para>
<command>ALTER TRIGGER</command> is a <productname>PostgreSQL</>
extension of SQL92.
</para>
</refsect2>
</refsect1> </refsect1>
</refentry> </refentry>
......
<!-- <!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/alter_user.sgml,v 1.26 2003/03/25 16:15:39 petere Exp $ $Header: /cvsroot/pgsql/doc/src/sgml/ref/alter_user.sgml,v 1.27 2003/04/15 13:25:08 petere Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -20,7 +20,7 @@ ALTER USER <replaceable class="PARAMETER">username</replaceable> [ [ WITH ] <rep ...@@ -20,7 +20,7 @@ ALTER USER <replaceable class="PARAMETER">username</replaceable> [ [ WITH ] <rep
where <replaceable class="PARAMETER">option</replaceable> can be: where <replaceable class="PARAMETER">option</replaceable> can be:
[ ENCRYPTED | UNENCRYPTED ] PASSWORD '<replaceable class="PARAMETER">password</replaceable>' [ ENCRYPTED | UNENCRYPTED ] PASSWORD '<replaceable class="PARAMETER">password</replaceable>'
| CREATEDB | NOCREATEDB | CREATEDB | NOCREATEDB
| CREATEUSER | NOCREATEUSER | CREATEUSER | NOCREATEUSER
| VALID UNTIL '<replaceable class="PARAMETER">abstime</replaceable>' | VALID UNTIL '<replaceable class="PARAMETER">abstime</replaceable>'
...@@ -42,8 +42,8 @@ ALTER USER <replaceable class="PARAMETER">username</replaceable> RESET <replacea ...@@ -42,8 +42,8 @@ ALTER USER <replaceable class="PARAMETER">username</replaceable> RESET <replacea
<para> <para>
The first variant of this command in the synopsis changes certain The first variant of this command in the synopsis changes certain
global user privileges and authentication settings. (See below for global user privileges and authentication settings. (See below for
details.) Only a database superuser can change privileges and details.) Only a database superuser can change these privileges and
password expiration with this command. Ordinary users can only the password expiration with this command. Ordinary users can only
change their own password. change their own password.
</para> </para>
...@@ -52,15 +52,15 @@ ALTER USER <replaceable class="PARAMETER">username</replaceable> RESET <replacea ...@@ -52,15 +52,15 @@ ALTER USER <replaceable class="PARAMETER">username</replaceable> RESET <replacea
a specified configuration variable. Whenever the user subsequently a specified configuration variable. Whenever the user subsequently
starts a new session, the specified value becomes the session default, starts a new session, the specified value becomes the session default,
overriding whatever setting is present in <filename>postgresql.conf</> overriding whatever setting is present in <filename>postgresql.conf</>
or has been received from the postmaster. or has been received from the <command>postmaster</command> command line.
Ordinary users can change their own session defaults. Ordinary users can change their own session defaults.
Superusers can change anyone's session defaults. Superusers can change anyone's session defaults.
</para> </para>
</refsect1>
<refsect2> <refsect1>
<title>Parameters</title> <title>Parameters</title>
<para>
<variablelist> <variablelist>
<varlistentry> <varlistentry>
<term><replaceable class="PARAMETER">username</replaceable></term> <term><replaceable class="PARAMETER">username</replaceable></term>
...@@ -99,8 +99,8 @@ ALTER USER <replaceable class="PARAMETER">username</replaceable> RESET <replacea ...@@ -99,8 +99,8 @@ ALTER USER <replaceable class="PARAMETER">username</replaceable> RESET <replacea
<listitem> <listitem>
<para> <para>
These clauses define a user's ability to create databases. If These clauses define a user's ability to create databases. If
<literal>CREATEDB</literal> is specified, the user being <literal>CREATEDB</literal> is specified, the user
defined will be allowed to create his own databases. Using will be allowed to create his own databases. Using
<literal>NOCREATEDB</literal> will deny a user the ability to <literal>NOCREATEDB</literal> will deny a user the ability to
create databases. create databases.
</para> </para>
...@@ -125,7 +125,7 @@ ALTER USER <replaceable class="PARAMETER">username</replaceable> RESET <replacea ...@@ -125,7 +125,7 @@ ALTER USER <replaceable class="PARAMETER">username</replaceable> RESET <replacea
<para> <para>
The date (and, optionally, the time) The date (and, optionally, the time)
at which this user's password is to expire. To set the password at which this user's password is to expire. To set the password
never to expire, use 'infinity'. never to expire, use <literal>'infinity'</>.
</para> </para>
</listitem> </listitem>
</varlistentry> </varlistentry>
...@@ -152,14 +152,11 @@ ALTER USER <replaceable class="PARAMETER">username</replaceable> RESET <replacea ...@@ -152,14 +152,11 @@ ALTER USER <replaceable class="PARAMETER">username</replaceable> RESET <replacea
</listitem> </listitem>
</varlistentry> </varlistentry>
</variablelist> </variablelist>
</para>
</refsect2>
</refsect1> </refsect1>
<refsect1> <refsect1>
<title>Diagnostics</title> <title>Diagnostics</title>
<para>
<variablelist> <variablelist>
<varlistentry> <varlistentry>
<term><computeroutput>ALTER USER</computeroutput></term> <term><computeroutput>ALTER USER</computeroutput></term>
...@@ -175,12 +172,11 @@ ALTER USER <replaceable class="PARAMETER">username</replaceable> RESET <replacea ...@@ -175,12 +172,11 @@ ALTER USER <replaceable class="PARAMETER">username</replaceable> RESET <replacea
<listitem> <listitem>
<para> <para>
Error message returned if the specified user is not known to Error message returned if the specified user is not known to
the database. the database system.
</para> </para>
</listitem> </listitem>
</varlistentry> </varlistentry>
</variablelist> </variablelist>
</para>
</refsect1> </refsect1>
<refsect1> <refsect1>
...@@ -226,10 +222,10 @@ ALTER USER manuel VALID UNTIL 'Jan 31 2030'; ...@@ -226,10 +222,10 @@ ALTER USER manuel VALID UNTIL 'Jan 31 2030';
<para> <para>
Change a user's valid until date, specifying that his Change a user's valid until date, specifying that his
authorization should expire at midday on 4th May 1998 using authorization should expire at midday on 4th May 2005 using
the time zone which is one hour ahead of <acronym>UTC</>: the time zone which is one hour ahead of <acronym>UTC</>:
<programlisting> <programlisting>
ALTER USER chris VALID UNTIL 'May 4 12:00:00 1998 +1'; ALTER USER chris VALID UNTIL 'May 4 12:00:00 2005 +1';
</programlisting> </programlisting>
</para> </para>
......
<!-- <!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/analyze.sgml,v 1.11 2003/03/25 16:15:39 petere Exp $ $Header: /cvsroot/pgsql/doc/src/sgml/ref/analyze.sgml,v 1.12 2003/04/15 13:25:08 petere Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -8,97 +8,24 @@ PostgreSQL documentation ...@@ -8,97 +8,24 @@ PostgreSQL documentation
<refentrytitle id="sql-analyze-title">ANALYZE</refentrytitle> <refentrytitle id="sql-analyze-title">ANALYZE</refentrytitle>
<refmiscinfo>SQL - Language Statements</refmiscinfo> <refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta> </refmeta>
<refnamediv> <refnamediv>
<refname> <refname>ANALYZE</refname>
ANALYZE <refpurpose>collect statistics about a database</refpurpose>
</refname>
<refpurpose>
collect statistics about a database
</refpurpose>
</refnamediv> </refnamediv>
<refsynopsisdiv> <refsynopsisdiv>
<refsynopsisdivinfo> <synopsis>
<date>2001-05-04</date>
</refsynopsisdivinfo>
<synopsis>
ANALYZE [ VERBOSE ] [ <replaceable class="PARAMETER">table</replaceable> [ (<replaceable class="PARAMETER">column</replaceable> [, ...] ) ] ] ANALYZE [ VERBOSE ] [ <replaceable class="PARAMETER">table</replaceable> [ (<replaceable class="PARAMETER">column</replaceable> [, ...] ) ] ]
</synopsis> </synopsis>
<refsect2 id="R2-SQL-ANALYZE-1">
<refsect2info>
<date>2001-05-04</date>
</refsect2info>
<title>
Inputs
</title>
<para>
<variablelist>
<varlistentry>
<term>VERBOSE</term>
<listitem>
<para>
Enables display of progress messages.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">table</replaceable></term>
<listitem>
<para>
The name (possibly schema-qualified) of a specific table to
analyze. Defaults to all tables in the current database.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">column</replaceable></term>
<listitem>
<para>
The name of a specific column to analyze. Defaults to all columns.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
<refsect2 id="R2-SQL-ANALYZE-2">
<refsect2info>
<date>2001-05-04</date>
</refsect2info>
<title>
Outputs
</title>
<para>
<variablelist>
<varlistentry>
<term><computeroutput>
<returnvalue>ANALYZE</returnvalue>
</computeroutput></term>
<listitem>
<para>
The command is complete.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
</refsynopsisdiv> </refsynopsisdiv>
<refsect1 id="R1-SQL-ANALYZE-1"> <refsect1>
<refsect1info> <title>Description</title>
<date>2001-05-04</date>
</refsect1info>
<title>
Description
</title>
<para> <para>
<command>ANALYZE</command> collects statistics about the contents of <command>ANALYZE</command> collects statistics about the contents of
<productname>PostgreSQL</productname> tables, and stores the results in tables in the database, and stores the results in
the system table <literal>pg_statistic</literal>. Subsequently, the system table <literal>pg_statistic</literal>. Subsequently,
the query planner uses the statistics to help determine the most efficient the query planner uses the statistics to help determine the most efficient
execution plans for queries. execution plans for queries.
...@@ -108,16 +35,61 @@ ANALYZE [ VERBOSE ] [ <replaceable class="PARAMETER">table</replaceable> [ (<rep ...@@ -108,16 +35,61 @@ ANALYZE [ VERBOSE ] [ <replaceable class="PARAMETER">table</replaceable> [ (<rep
With no parameter, <command>ANALYZE</command> examines every table in the With no parameter, <command>ANALYZE</command> examines every table in the
current database. With a parameter, <command>ANALYZE</command> examines current database. With a parameter, <command>ANALYZE</command> examines
only that table. It is further possible to give a list of column names, only that table. It is further possible to give a list of column names,
in which case only the statistics for those columns are updated. in which case only the statistics for those columns are collected.
</para> </para>
</refsect1>
<refsect1>
<title>Parameters</title>
<variablelist>
<varlistentry>
<term><literal>VERBOSE</literal></term>
<listitem>
<para>
Enables display of progress messages.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">table</replaceable></term>
<listitem>
<para>
The name (possibly schema-qualified) of a specific table to
analyze. Defaults to all tables in the current database.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">column</replaceable></term>
<listitem>
<para>
The name of a specific column to analyze. Defaults to all columns.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect2 id="R2-SQL-ANALYZE-3"> <refsect1>
<refsect2info> <title>Diagnostics</title>
<date>2001-05-04</date>
</refsect2info> <variablelist>
<title> <varlistentry>
Notes <term><computeroutput>ANALYZE</computeroutput></term>
</title> <listitem>
<para>
The command is complete.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Notes</title>
<para> <para>
It is a good idea to run <command>ANALYZE</command> periodically, or It is a good idea to run <command>ANALYZE</command> periodically, or
...@@ -138,7 +110,7 @@ ANALYZE [ VERBOSE ] [ <replaceable class="PARAMETER">table</replaceable> [ (<rep ...@@ -138,7 +110,7 @@ ANALYZE [ VERBOSE ] [ <replaceable class="PARAMETER">table</replaceable> [ (<rep
<para> <para>
For large tables, <command>ANALYZE</command> takes a random sample of the For large tables, <command>ANALYZE</command> takes a random sample of the
table contents, rather than examining every row. This allows even very table contents, rather than examining every row. This allows even very
large tables to be analyzed in a small amount of time. Note however large tables to be analyzed in a small amount of time. Note, however,
that the statistics are only approximate, and will change slightly each that the statistics are only approximate, and will change slightly each
time <command>ANALYZE</command> is run, even if the actual table contents time <command>ANALYZE</command> is run, even if the actual table contents
did not change. This may result in small changes in the planner's did not change. This may result in small changes in the planner's
...@@ -159,7 +131,7 @@ ANALYZE [ VERBOSE ] [ <replaceable class="PARAMETER">table</replaceable> [ (<rep ...@@ -159,7 +131,7 @@ ANALYZE [ VERBOSE ] [ <replaceable class="PARAMETER">table</replaceable> [ (<rep
The extent of analysis can be controlled by adjusting the The extent of analysis can be controlled by adjusting the
<literal>default_statistics_target</> parameter variable, or on a <literal>default_statistics_target</> parameter variable, or on a
column-by-column basis by setting the per-column column-by-column basis by setting the per-column
statistics target with <command>ALTER TABLE ALTER COLUMN SET statistics target with <command>ALTER TABLE ... ALTER COLUMN ... SET
STATISTICS</command> (see STATISTICS</command> (see
<xref linkend="sql-altertable" endterm="sql-altertable-title">). The <xref linkend="sql-altertable" endterm="sql-altertable-title">). The
target value sets the maximum number of entries in the most-common-value target value sets the maximum number of entries in the most-common-value
...@@ -170,7 +142,7 @@ ANALYZE [ VERBOSE ] [ <replaceable class="PARAMETER">table</replaceable> [ (<rep ...@@ -170,7 +142,7 @@ ANALYZE [ VERBOSE ] [ <replaceable class="PARAMETER">table</replaceable> [ (<rep
in <literal>pg_statistic</literal>. in <literal>pg_statistic</literal>.
In particular, setting the statistics target to zero disables collection of In particular, setting the statistics target to zero disables collection of
statistics for that column. It may be useful to do that for columns that statistics for that column. It may be useful to do that for columns that
are never used as part of the WHERE, GROUP BY, or ORDER BY clauses of are never used as part of the <literal>WHERE</>, <literal>GROUP BY</>, or <literal>ORDER BY</> clauses of
queries, since the planner will have no use for statistics on such columns. queries, since the planner will have no use for statistics on such columns.
</para> </para>
...@@ -180,26 +152,14 @@ ANALYZE [ VERBOSE ] [ <replaceable class="PARAMETER">table</replaceable> [ (<rep ...@@ -180,26 +152,14 @@ ANALYZE [ VERBOSE ] [ <replaceable class="PARAMETER">table</replaceable> [ (<rep
the target causes a proportional increase in the time and space needed the target causes a proportional increase in the time and space needed
to do <command>ANALYZE</command>. to do <command>ANALYZE</command>.
</para> </para>
</refsect2>
</refsect1> </refsect1>
<refsect1 id="R1-SQL-ANALYZE-3"> <refsect1>
<title> <title>Compatibility</title>
Compatibility
</title> <para>
There is no <command>ANALYZE</command> statement in the SQL standard.
<refsect2 id="R2-SQL-ANALYZE-4"> </para>
<refsect2info>
<date>2001-05-04</date>
</refsect2info>
<title>
SQL92
</title>
<para>
There is no <command>ANALYZE</command> statement in <acronym>SQL92</acronym>.
</para>
</refsect2>
</refsect1> </refsect1>
</refentry> </refentry>
......
<!-- <!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/begin.sgml,v 1.22 2003/03/25 16:15:39 petere Exp $ $Header: /cvsroot/pgsql/doc/src/sgml/ref/begin.sgml,v 1.23 2003/04/15 13:25:08 petere Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -8,218 +8,137 @@ PostgreSQL documentation ...@@ -8,218 +8,137 @@ PostgreSQL documentation
<refentrytitle id="SQL-BEGIN-TITLE">BEGIN</refentrytitle> <refentrytitle id="SQL-BEGIN-TITLE">BEGIN</refentrytitle>
<refmiscinfo>SQL - Language Statements</refmiscinfo> <refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta> </refmeta>
<refnamediv> <refnamediv>
<refname> <refname>BEGIN</refname>
BEGIN <refpurpose>start a transaction block</refpurpose>
</refname> </refnamediv>
<refpurpose>
start a transaction block
</refpurpose>
</refnamediv>
<refsynopsisdiv> <refsynopsisdiv>
<refsynopsisdivinfo> <synopsis>
<date>1999-07-20</date>
</refsynopsisdivinfo>
<synopsis>
BEGIN [ WORK | TRANSACTION ] BEGIN [ WORK | TRANSACTION ]
</synopsis> </synopsis>
<refsect2 id="R2-SQL-BEGIN-1">
<refsect2info>
<date>1999-06-11</date>
</refsect2info>
<title>
Inputs
</title>
<para>
<variablelist>
<varlistentry>
<term>WORK</term>
<term>TRANSACTION</term>
<listitem>
<para>
Optional keywords. They have no effect.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
<refsect2 id="R2-SQL-BEGIN-2">
<refsect2info>
<date>1999-06-11</date>
</refsect2info>
<title>
Outputs
</title>
<para>
<variablelist>
<varlistentry>
<term><computeroutput>
BEGIN
</computeroutput></term>
<listitem>
<para>
This signifies that a new transaction has been started.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><computeroutput>
WARNING: BEGIN: already a transaction in progress
</computeroutput></term>
<listitem>
<para>
This indicates that a transaction was already in progress.
The current transaction is not affected.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
</refsynopsisdiv> </refsynopsisdiv>
<refsect1 id="R1-SQL-BEGIN-1"> <refsect1>
<refsect1info> <title>Description</title>
<date>1999-06-11</date>
</refsect1info>
<title>
Description
</title>
<para> <para>
By default, <productname>PostgreSQL</productname> executes transactions By default, <productname>PostgreSQL</productname> executes
in <firstterm>unchained mode</firstterm> transactions in <quote>autocommit</quote> mode, that is, each
(also known as <quote>autocommit</quote> in other database statement is executed in its own transaction and a commit is
systems). implicitly performed at the end of the statement (if execution was
In other words, each user statement is executed in its own transaction successful, otherwise a rollback is done).
and a commit is implicitly performed at the end of the statement <command>BEGIN</command> initiates a transaction block, that is,
(if execution was successful, otherwise a rollback is done). all statements after <command>BEGIN</command> command will be
<command>BEGIN</command> initiates a user transaction in chained mode, executed in a single transaction until an explicit <xref
i.e., all user statements after <command>BEGIN</command> command will linkend="sql-commit" endterm="sql-commit-title"> or <xref
be executed in a single transaction until an explicit linkend="sql-rollback" endterm="sql-rollback-title">. Statements
<xref linkend="sql-commit" endterm="sql-commit-title"> or are executed more quickly in a transaction block, because
<xref linkend="sql-rollback" endterm="sql-rollback-title">. transaction start/commit requires significant CPU and disk
Statements are executed more quickly in chained mode, activity. Execution of multiple statements inside a transaction is
because transaction start/commit requires significant CPU and disk also useful to ensure consistency when changing several related
activity. Execution of multiple statements inside a transaction tables: other sessions will be unable to see the intermediate states
is also useful to ensure consistency when changing several wherein not all the related updates have been done.
related tables: other clients will be unable to see the intermediate
states wherein not all the related updates have been done.
</para> </para>
</refsect1>
<refsect1>
<title>Parameters</title>
<para> <variablelist>
The default transaction isolation level in <varlistentry>
<productname>PostgreSQL</productname> <term><literal>WORK</literal></term>
is READ COMMITTED, wherein each query inside the transaction sees changes <term><literal>TRANSACTION</literal></term>
committed before that query begins execution. So, you have to use <listitem>
<command>SET TRANSACTION ISOLATION LEVEL SERIALIZABLE</command> <para>
just after <command>BEGIN</command> if you need more rigorous transaction Optional key words. They have no effect.
isolation. (Alternatively, you can change the default transaction </para>
isolation level; see <xref linkend="runtime-config"> for details.) </listitem>
In SERIALIZABLE mode queries will see only changes committed before </varlistentry>
the entire </variablelist>
transaction began (actually, before execution of the first <acronym>DML</> statement </refsect1>
in the transaction).
</para> <refsect1>
<title>Diagnostics</title>
<variablelist>
<varlistentry>
<term><computeroutput>BEGIN</computeroutput></term>
<listitem>
<para>
This signifies that a new transaction has been started.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><computeroutput>WARNING: BEGIN: already a transaction in progress</computeroutput></term>
<listitem>
<para>
This indicates that a transaction was already in progress. The
current transaction is not affected.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Notes</title>
<para> <para>
Transactions have the standard <acronym>ACID</acronym> <xref linkend="sql-start-transaction"
(atomic, consistent, isolatable, and durable) properties. endterm="sql-start-transaction-title"> has the same functionality
as <command>BEGIN</>.
</para> </para>
<refsect2 id="R2-SQL-BEGIN-3">
<refsect2info>
<date>1999-06-11</date>
</refsect2info>
<title>
Notes
</title>
<para>
<xref linkend="sql-start-transaction"
endterm="sql-start-transaction-title"> has the same functionality
as <command>BEGIN</>.
</para>
<para> <para>
Use <xref linkend="SQL-COMMIT" endterm="SQL-COMMIT-TITLE"> Use <xref linkend="SQL-COMMIT" endterm="SQL-COMMIT-TITLE"> or
or <xref linkend="SQL-ROLLBACK" endterm="SQL-ROLLBACK-TITLE">
<xref linkend="SQL-ROLLBACK" endterm="SQL-ROLLBACK-TITLE"> to terminate a transaction.
to terminate a transaction. </para>
</para>
<para>
Refer to <xref linkend="sql-lock" endterm="sql-lock-title">
for further information
about locking tables inside a transaction.
</para>
<para> <para>
If you turn <varname>autocommit</> mode off, then <command>BEGIN</> If you turn the configuration parameter <varname>autocommit</> off,
is not required: any SQL command automatically starts a transaction. then <command>BEGIN</> is not required: any SQL command
</para> automatically starts a transaction.
</refsect2> </para>
</refsect1> </refsect1>
<refsect1 id="R1-SQL-BEGIN-2"> <refsect1>
<title> <title>Examples</title>
Usage
</title>
<para> <para>
To begin a user transaction: To begin a transaction block:
<programlisting> <programlisting>
BEGIN WORK; BEGIN;
</programlisting> </programlisting>
</para> </para>
</refsect1> </refsect1>
<refsect1 id="R1-SQL-BEGIN-3"> <refsect1>
<title> <title>Compatibility</title>
Compatibility
</title>
<refsect2 id="R2-SQL-BEGIN-4">
<refsect2info>
<date>1999-06-11</date>
</refsect2info>
<title>
SQL92
</title>
<para> <para>
<command>BEGIN</command> <command>BEGIN</command> is a <productname>PostgreSQL</productname>
is a <productname>PostgreSQL</productname> language extension. language extension. There is no explicit <command>BEGIN</command>
There is no explicit <command>BEGIN</command> command in the SQL standard; transaction initiation is
command in <acronym>SQL92</acronym>; always implicit and it terminates either with a
transaction initiation is always implicit and it terminates either <command>COMMIT</command> or <command>ROLLBACK</command> statement.
with a <command>COMMIT</command> or <command>ROLLBACK</command> statement. </para>
<note>
<para>
Many relational database systems offer an autocommit feature as a
convenience.
</para>
</note>
</para>
<para> <para>
Incidentally, the <literal>BEGIN</literal> keyword is used for a different Other relational database systems may offer an autocommit feature
purpose in embedded SQL. You are advised to be careful about the transaction as a convenience.
semantics when porting database applications. </para>
</para>
<para> <para>
<acronym>SQL92</acronym> also requires SERIALIZABLE to be the default Incidentally, the <literal>BEGIN</literal> key word is used for a
transaction isolation level. different purpose in embedded SQL. You are advised to be careful
</para> about the transaction semantics when porting database applications.
</refsect2> </para>
</refsect1> </refsect1>
</refentry> </refentry>
......
<!-- $Header: /cvsroot/pgsql/doc/src/sgml/ref/checkpoint.sgml,v 1.8 2003/03/25 16:15:39 petere Exp $ --> <!-- $Header: /cvsroot/pgsql/doc/src/sgml/ref/checkpoint.sgml,v 1.9 2003/04/15 13:25:08 petere Exp $ -->
<refentry id="sql-checkpoint"> <refentry id="sql-checkpoint">
<refmeta> <refmeta>
...@@ -24,8 +24,8 @@ CHECKPOINT ...@@ -24,8 +24,8 @@ CHECKPOINT
Write-Ahead Logging (WAL) puts a checkpoint in the transaction log Write-Ahead Logging (WAL) puts a checkpoint in the transaction log
every so often. (To adjust the automatic checkpoint interval, see every so often. (To adjust the automatic checkpoint interval, see
the run-time the run-time
configuration options <parameter>CHECKPOINT_SEGMENTS</parameter> configuration options <varname>checkpoint_segments</varname>
and <parameter>CHECKPOINT_TIMEOUT</parameter>.) and <varname>checkpoint_timeout</varname>.)
The <command>CHECKPOINT</command> command forces an immediate checkpoint The <command>CHECKPOINT</command> command forces an immediate checkpoint
when the command is issued, without waiting for a scheduled checkpoint. when the command is issued, without waiting for a scheduled checkpoint.
</para> </para>
......
<!-- <!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/close.sgml,v 1.13 2002/05/18 15:44:47 petere Exp $ $Header: /cvsroot/pgsql/doc/src/sgml/ref/close.sgml,v 1.14 2003/04/15 13:25:08 petere Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -8,144 +8,104 @@ PostgreSQL documentation ...@@ -8,144 +8,104 @@ PostgreSQL documentation
<refentrytitle id="SQL-CLOSE-TITLE">CLOSE</refentrytitle> <refentrytitle id="SQL-CLOSE-TITLE">CLOSE</refentrytitle>
<refmiscinfo>SQL - Language Statements</refmiscinfo> <refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta> </refmeta>
<refnamediv> <refnamediv>
<refname> <refname>CLOSE</refname>
CLOSE <refpurpose>close a cursor</refpurpose>
</refname>
<refpurpose>
close a cursor
</refpurpose>
</refnamediv> </refnamediv>
<refsynopsisdiv> <refsynopsisdiv>
<refsynopsisdivinfo> <synopsis>
<date>1999-07-20</date>
</refsynopsisdivinfo>
<synopsis>
CLOSE <replaceable class="PARAMETER">cursor</replaceable> CLOSE <replaceable class="PARAMETER">cursor</replaceable>
</synopsis> </synopsis>
<refsect2 id="R2-SQL-CLOSE-1">
<refsect2info>
<date>1998-09-08</date>
</refsect2info>
<title>
Inputs
</title>
<para>
<variablelist>
<varlistentry>
<term><replaceable class="PARAMETER">cursor</replaceable></term>
<listitem>
<para>
The name of an open cursor to close.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
<refsect2 id="R2-SQL-CLOSE-2">
<refsect2info>
<date>1998-09-08</date>
</refsect2info>
<title>
Outputs
</title>
<para>
<variablelist>
<varlistentry>
<term><computeroutput>
CLOSE CURSOR
</computeroutput></term>
<listitem>
<para>
Message returned if the cursor is successfully closed.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><computeroutput>
WARNING: PerformPortalClose: portal "<replaceable class="PARAMETER">cursor</replaceable>" not found
</computeroutput></term>
<listitem>
<para>
This warning is given if
<replaceable class="PARAMETER">cursor</replaceable> is not
declared or has already been closed.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
</refsynopsisdiv> </refsynopsisdiv>
<refsect1 id="R1-SQL-CLOSE-1"> <refsect1>
<refsect1info> <title>Description</title>
<date>1998-09-08</date>
</refsect1info>
<title>
Description
</title>
<para> <para>
<command>CLOSE</command> frees the resources associated with an open cursor. <command>CLOSE</command> frees the resources associated with an open cursor.
After the cursor is closed, no subsequent operations After the cursor is closed, no subsequent operations
are allowed on it. A cursor should be closed when it is are allowed on it. A cursor should be closed when it is
no longer needed. no longer needed.
</para> </para>
<para> <para>
An implicit close is executed for every open cursor when a Every open cursor is implicitly closed when a transaction is
transaction is terminated by <command>COMMIT</command> terminated by <command>COMMIT</command> or
or <command>ROLLBACK</command>. <command>ROLLBACK</command>.
</para> </para>
</refsect1>
<refsect1>
<title>Parameters</title>
<variablelist>
<varlistentry>
<term><replaceable class="PARAMETER">cursor</replaceable></term>
<listitem>
<para>
The name of an open cursor to close.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect2 id="R2-SQL-CLOSE-3"> <refsect1>
<refsect2info> <title>Diagnostics</title>
<date>1998-09-08</date>
</refsect2info> <variablelist>
<title> <varlistentry>
Notes <term><computeroutput>CLOSE CURSOR</computeroutput></term>
</title> <listitem>
<para> <para>
<productname>PostgreSQL</productname> does not have Message returned if the cursor is successfully closed.
an explicit <command>OPEN</command> cursor statement; </para>
a cursor is considered open when it is declared. </listitem>
Use the <command>DECLARE</command> statement to declare a cursor. </varlistentry>
</para>
</refsect2> <varlistentry>
<term><computeroutput>WARNING: PerformPortalClose: portal "<replaceable class="PARAMETER">cursor</replaceable>" not found</computeroutput></term>
<listitem>
<para>
This warning is given if <replaceable
class="PARAMETER">cursor</replaceable> is not declared or has
already been closed.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1> </refsect1>
<refsect1 id="R1-SQL-CLOSE-2"> <refsect1>
<title> <title>Notes</title>
Usage
</title>
<para> <para>
Close the cursor <literal>liahona</literal>: <productname>PostgreSQL</productname> does not have an explicit
<command>OPEN</command> cursor statement; a cursor is considered
open when it is declared. Use the <command>DECLARE</command>
statement to declare a cursor.
</para> </para>
<programlisting> </refsect1>
<refsect1>
<title>Examples</title>
<para>
Close the cursor <literal>liahona</literal>:
<programlisting>
CLOSE liahona; CLOSE liahona;
</programlisting> </programlisting>
</para>
</refsect1> </refsect1>
<refsect1 id="R1-SQL-CLOSE-3"> <refsect1>
<title> <title>Compatibility</title>
Compatibility
</title>
<refsect2 id="R2-SQL-CLOSE-4"> <para>
<refsect2info> <command>CLOSE</command> is fully conforming with the SQL standard.
<date>1998-09-08</date> </para>
</refsect2info>
<title>
SQL92
</title>
<para>
<command>CLOSE</command> is fully compatible with SQL92.
</para>
</refsect2>
</refsect1> </refsect1>
</refentry> </refentry>
......
<!-- <!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/cluster.sgml,v 1.25 2003/03/25 16:15:39 petere Exp $ $Header: /cvsroot/pgsql/doc/src/sgml/ref/cluster.sgml,v 1.26 2003/04/15 13:25:08 petere Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -8,89 +8,27 @@ PostgreSQL documentation ...@@ -8,89 +8,27 @@ PostgreSQL documentation
<refentrytitle id="sql-cluster-title">CLUSTER</refentrytitle> <refentrytitle id="sql-cluster-title">CLUSTER</refentrytitle>
<refmiscinfo>SQL - Language Statements</refmiscinfo> <refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta> </refmeta>
<refnamediv> <refnamediv>
<refname> <refname>CLUSTER</refname>
CLUSTER <refpurpose>cluster a table according to an index</refpurpose>
</refname>
<refpurpose>
cluster a table according to an index
</refpurpose>
</refnamediv> </refnamediv>
<refsynopsisdiv> <refsynopsisdiv>
<refsynopsisdivinfo> <synopsis>
<date>1999-07-20</date>
</refsynopsisdivinfo>
<synopsis>
CLUSTER <replaceable class="PARAMETER">indexname</replaceable> ON <replaceable class="PARAMETER">tablename</replaceable> CLUSTER <replaceable class="PARAMETER">indexname</replaceable> ON <replaceable class="PARAMETER">tablename</replaceable>
CLUSTER <replaceable class="PARAMETER">tablename</replaceable> CLUSTER <replaceable class="PARAMETER">tablename</replaceable>
CLUSTER CLUSTER
</synopsis> </synopsis>
<refsect2 id="R2-SQL-CLUSTER-1">
<refsect2info>
<date>1998-09-08</date>
</refsect2info>
<title>
Inputs
</title>
<para>
</para>
<variablelist>
<varlistentry>
<term><replaceable class="PARAMETER">indexname</replaceable></term>
<listitem>
<para>
The name of an index.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">table</replaceable></term>
<listitem>
<para>
The name (possibly schema-qualified) of a table.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect2>
<refsect2 id="R2-SQL-CLUSTER-2">
<refsect2info>
<date>1998-09-08</date>
</refsect2info>
<title>
Outputs
</title>
<para>
<variablelist>
<varlistentry>
<term><computeroutput>
CLUSTER
</computeroutput></term>
<listitem>
<para>
The clustering was done successfully.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
</refsynopsisdiv> </refsynopsisdiv>
<refsect1 id="R1-SQL-CLUSTER-1"> <refsect1>
<refsect1info> <title>Description</title>
<date>1998-09-08</date>
</refsect1info>
<title>
Description
</title>
<para> <para>
<command>CLUSTER</command> instructs <productname>PostgreSQL</productname> <command>CLUSTER</command> instructs <productname>PostgreSQL</productname>
to cluster the table specified to cluster the table specified
by <replaceable class="parameter">table</replaceable> by <replaceable class="parameter">tablename</replaceable>
based on the index specified by based on the index specified by
<replaceable class="parameter">indexname</replaceable>. The index must <replaceable class="parameter">indexname</replaceable>. The index must
already have been defined on already have been defined on
...@@ -102,19 +40,19 @@ CLUSTER ...@@ -102,19 +40,19 @@ CLUSTER
based on the index information. Clustering is a one-time operation: based on the index information. Clustering is a one-time operation:
when the table is subsequently updated, the changes are when the table is subsequently updated, the changes are
not clustered. That is, no attempt is made to store new or not clustered. That is, no attempt is made to store new or
updated tuples according to their index order. If one wishes, one can updated rows according to their index order. If one wishes, one can
periodically re-cluster by issuing the command again. periodically recluster by issuing the command again.
</para> </para>
<para> <para>
When a table is clustered, <productname>PostgreSQL</productname> When a table is clustered, <productname>PostgreSQL</productname>
remembers on which index it was clustered. The form remembers on which index it was clustered. The form
<command>CLUSTER <replaceable class="parameter">tablename</replaceable></command>, <command>CLUSTER <replaceable class="parameter">tablename</replaceable></command>,
re-clusters the table on the same index that it was clustered before. reclusters the table on the same index that it was clustered before.
</para> </para>
<para> <para>
<command>CLUSTER</command> without any parameter re-clusters all the tables <command>CLUSTER</command> without any parameter reclusters all the tables
in the in the
current database that the calling user owns, or all tables if called current database that the calling user owns, or all tables if called
by a superuser. (Never-clustered tables are not included.) This by a superuser. (Never-clustered tables are not included.) This
...@@ -129,33 +67,62 @@ CLUSTER ...@@ -129,33 +67,62 @@ CLUSTER
table until the <command>CLUSTER</command> is finished. See table until the <command>CLUSTER</command> is finished. See
<xref linkend="explicit-locking"> for more information on database locking. <xref linkend="explicit-locking"> for more information on database locking.
</para> </para>
</refsect1>
<refsect1>
<title>Parameter</title>
<variablelist>
<varlistentry>
<term><replaceable class="PARAMETER">indexname</replaceable></term>
<listitem>
<para>
The name of an index.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">tablename</replaceable></term>
<listitem>
<para>
The name (possibly schema-qualified) of a table.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Diagnostics</title>
<variablelist>
<varlistentry>
<term><computeroutput>CLUSTER</computeroutput></term>
<listitem>
<para>
The clustering was done successfully.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect2 id="R2-SQL-CLUSTER-3"> <refsect1>
<refsect2info> <title>Notes</title>
<date>1998-09-08</date>
</refsect2info>
<title>
Notes
</title>
<para> <para>
In cases where you are accessing single rows randomly In cases where you are accessing single rows randomly
within a table, the actual order of the data in the heap within a table, the actual order of the data in the
table is unimportant. However, if you tend to access some table is unimportant. However, if you tend to access some
data more than others, and there is an index that groups data more than others, and there is an index that groups
them together, you will benefit from using <command>CLUSTER</command>. them together, you will benefit from using <command>CLUSTER</command>.
</para> If you are requesting a range of indexed values from a table, or a
<para>
Another place where <command>CLUSTER</command> is helpful is in
cases where you use an
index to pull out several rows from a table. If you are
requesting a range of indexed values from a table, or a
single indexed value that has multiple rows that match, single indexed value that has multiple rows that match,
<command>CLUSTER</command> will help because once the index identifies the <command>CLUSTER</command> will help because once the index identifies the
heap page for the first row that matches, all other rows heap page for the first row that matches, all other rows
that match are probably already on the same heap page, that match are probably already on the same heap page,
saving disk accesses and speeding up the query. and so you save disk accesses and speed up the query.
</para> </para>
<para> <para>
...@@ -166,23 +133,17 @@ CLUSTER ...@@ -166,23 +133,17 @@ CLUSTER
sizes. sizes.
</para> </para>
<para>
<command>CLUSTER</command> preserves <command>GRANT</command>,
inheritance, index, foreign key, and other ancillary information
about the table.
</para>
<para> <para>
Because <command>CLUSTER</command> remembers the clustering information, Because <command>CLUSTER</command> remembers the clustering information,
one can cluster the tables one wants clustered manually the first time, and one can cluster the tables one wants clustered manually the first time, and
setup a timed event similar to <command>VACUUM</command> so that the tables setup a timed event similar to <command>VACUUM</command> so that the tables
are periodically re-clustered. are periodically reclustered.
</para> </para>
<para> <para>
Because the optimizer records statistics about the ordering of tables, it Because the planner records statistics about the ordering of tables, it
is advisable to run <command>ANALYZE</command> on the newly clustered is advisable to run <command>ANALYZE</command> on the newly clustered
table. Otherwise, the optimizer may make poor choices of query plans. table. Otherwise, the planner may make poor choices of query plans.
</para> </para>
<para> <para>
...@@ -196,68 +157,57 @@ CLUSTER ...@@ -196,68 +157,57 @@ CLUSTER
but the majority of a big table will not fit in the cache.) but the majority of a big table will not fit in the cache.)
The other way to cluster a table is to use The other way to cluster a table is to use
<programlisting> <programlisting>
SELECT <replaceable class="parameter">columnlist</replaceable> INTO TABLE <replaceable class="parameter">newtable</replaceable> CREATE TABLE <replaceable class="parameter">newtable</replaceable> AS
FROM <replaceable class="parameter">table</replaceable> ORDER BY <replaceable class="parameter">columnlist</replaceable> SELECT <replaceable class="parameter">columnlist</replaceable> FROM <replaceable class="parameter">table</replaceable> ORDER BY <replaceable class="parameter">columnlist</replaceable>;
</programlisting> </programlisting>
which uses the <productname>PostgreSQL</productname> sorting code in which uses the <productname>PostgreSQL</productname> sorting code in
the ORDER BY clause to create the desired order; this is usually much the <literal>ORDER BY</literal> clause to create the desired order; this is usually much
faster than an index scan for faster than an index scan for
unordered data. You then drop the old table, use unordered data. You then drop the old table, use
<command>ALTER TABLE...RENAME</command> <command>ALTER TABLE ... RENAME</command>
to rename <replaceable class="parameter">newtable</replaceable> to the old name, and to rename <replaceable class="parameter">newtable</replaceable> to the old name, and
recreate the table's indexes. However, this approach does not preserve recreate the table's indexes. However, this approach does not preserve
OIDs, constraints, foreign key relationships, granted privileges, and OIDs, constraints, foreign key relationships, granted privileges, and
other ancillary properties of the table --- all such items must be other ancillary properties of the table --- all such items must be
manually recreated. manually recreated.
</para> </para>
</refsect2>
</refsect1> </refsect1>
<refsect1 id="R1-SQL-CLUSTER-2"> <refsect1>
<title> <title>Examples</title>
Usage
</title>
<para> <para>
Cluster the <literal>employees</literal> relation on the basis of Cluster the table <literal>employees</literal> on the basis of
its ID attribute: its index <literal>emp_ind</literal>:
</para> <programlisting>
<programlisting>
CLUSTER emp_ind ON emp; CLUSTER emp_ind ON emp;
</programlisting> </programlisting>
</para>
<para> <para>
Cluster the <literal>employees</literal> relation using the same Cluster the <literal>employees</literal> relation using the same
index that was used before: index that was used before:
</para> <programlisting>
<programlisting>
CLUSTER emp; CLUSTER emp;
</programlisting> </programlisting>
</para>
<para> <para>
Cluster all the tables on the database that have previously been clustered: Cluster all the tables on the database that have previously been clustered:
</para> <programlisting>
<programlisting>
CLUSTER; CLUSTER;
</programlisting> </programlisting>
</para>
</refsect1> </refsect1>
<refsect1 id="R1-SQL-CLUSTER-3"> <refsect1>
<title> <title>Compatibility</title>
Compatibility
</title> <para>
There is no <command>CLUSTER</command> statement in the SQL standard.
<refsect2 id="R2-SQL-CLUSTER-4"> </para>
<refsect2info>
<date>1998-09-08</date>
</refsect2info>
<title>
SQL92
</title>
<para>
There is no <command>CLUSTER</command> statement in SQL92.
</para>
</refsect2>
</refsect1> </refsect1>
<refsect1> <refsect1>
......
<!-- <!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/comment.sgml,v 1.20 2002/07/12 18:43:12 tgl Exp $ $Header: /cvsroot/pgsql/doc/src/sgml/ref/comment.sgml,v 1.21 2003/04/15 13:25:08 petere Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -8,21 +8,16 @@ PostgreSQL documentation ...@@ -8,21 +8,16 @@ PostgreSQL documentation
<refentrytitle id="SQL-COMMENT-TITLE">COMMENT</refentrytitle> <refentrytitle id="SQL-COMMENT-TITLE">COMMENT</refentrytitle>
<refmiscinfo>SQL - Language Statements</refmiscinfo> <refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta> </refmeta>
<refnamediv> <refnamediv>
<refname> <refname>COMMENT</refname>
COMMENT <refpurpose>define or change the comment of an object</refpurpose>
</refname>
<refpurpose>
define or change the comment of an object
</refpurpose>
</refnamediv> </refnamediv>
<refsynopsisdiv> <refsynopsisdiv>
<refsynopsisdivinfo> <synopsis>
<date>1999-07-20</date>
</refsynopsisdivinfo>
<synopsis>
COMMENT ON COMMENT ON
[ {
TABLE <replaceable class="PARAMETER">object_name</replaceable> | TABLE <replaceable class="PARAMETER">object_name</replaceable> |
COLUMN <replaceable class="PARAMETER">table_name</replaceable>.<replaceable class="PARAMETER">column_name</replaceable> | COLUMN <replaceable class="PARAMETER">table_name</replaceable>.<replaceable class="PARAMETER">column_name</replaceable> |
AGGREGATE <replaceable class="PARAMETER">agg_name</replaceable> (<replaceable class="PARAMETER">agg_type</replaceable>) | AGGREGATE <replaceable class="PARAMETER">agg_name</replaceable> (<replaceable class="PARAMETER">agg_type</replaceable>) |
...@@ -38,83 +33,21 @@ COMMENT ON ...@@ -38,83 +33,21 @@ COMMENT ON
TRIGGER <replaceable class="PARAMETER">trigger_name</replaceable> ON <replaceable class="PARAMETER">table_name</replaceable> | TRIGGER <replaceable class="PARAMETER">trigger_name</replaceable> ON <replaceable class="PARAMETER">table_name</replaceable> |
TYPE <replaceable class="PARAMETER">object_name</replaceable> | TYPE <replaceable class="PARAMETER">object_name</replaceable> |
VIEW <replaceable class="PARAMETER">object_name</replaceable> VIEW <replaceable class="PARAMETER">object_name</replaceable>
] IS <replaceable class="PARAMETER">'text'</replaceable> } IS <replaceable class="PARAMETER">'text'</replaceable>
</synopsis> </synopsis>
<refsect2 id="R2-SQL-COMMENT-1">
<refsect2info>
<date>1999-10-25</date>
</refsect2info>
<title>
Inputs
</title>
<para>
<variablelist>
<varlistentry>
<term><replaceable class="PARAMETER">object_name,
table_name.column_name, agg_name, constraint_name, func_name, op, rule_name, trigger_name</replaceable></term>
<listitem>
<para>
The name of the object to be be commented. Names of tables,
aggregates, domains, functions, indexes, operators, sequences, types,
and views
may be schema-qualified.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">text</replaceable></term>
<listitem>
<para>
The comment to add.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
<refsect2 id="R2-SQL-COMMENT-2">
<refsect2info>
<date>1998-09-08</date>
</refsect2info>
<title>
Outputs
</title>
<para>
<variablelist>
<varlistentry>
<term><computeroutput>
COMMENT
</computeroutput></term>
<listitem>
<para>
Message returned if the table is successfully commented.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
</refsynopsisdiv> </refsynopsisdiv>
<refsect1 id="R1-SQL-COMMENT-1"> <refsect1>
<refsect1info> <title>Description</title>
<date>1998-10-25</date>
</refsect1info>
<title>
Description
</title>
<para> <para>
<command>COMMENT</command> stores a comment about a database object. <command>COMMENT</command> stores a comment about a database object.
Comments can be Comments can be
easily retrieved with <command>psql</command>'s easily retrieved with the <application>psql</application> commands
<command>\dd</command>, <command>\d+</command>, or <command>\l+</command> <command>\dd</command>, <command>\d+</command>, and <command>\l+</command>.
commands. Other user interfaces to retrieve comments can be built atop Other user interfaces to retrieve comments can be built atop
the same built-in functions that <command>psql</command> uses, namely the same built-in functions that <application>psql</application> uses, namely
<function>obj_description()</> and <function>col_description()</>. <function>obj_description</> and <function>col_description</>.
</para> </para>
<para> <para>
...@@ -124,75 +57,114 @@ COMMENT ...@@ -124,75 +57,114 @@ COMMENT
string. string.
Comments are automatically dropped when the object is dropped. Comments are automatically dropped when the object is dropped.
</para> </para>
</refsect1>
<refsect1>
<title>Parameters</title>
<variablelist>
<varlistentry>
<term><replaceable class="parameter">object_name</replaceable></term>
<term><replaceable class="parameter">table_name.column_name</replaceable></term>
<term><replaceable class="parameter">aggname</replaceable></term>
<term><replaceable class="parameter">constraint_name</replaceable></term>
<term><replaceable class="parameter">func_name</replaceable></term>
<term><replaceable class="parameter">op</replaceable></term>
<term><replaceable class="parameter">rule_name</replaceable></term>
<term><replaceable class="parameter">trigger_name</replaceable></term>
<listitem>
<para>
The name of the object to be be commented. Names of tables,
aggregates, domains, functions, indexes, operators, sequences,
types, and views may be schema-qualified.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">text</replaceable></term>
<listitem>
<para>
The new comment.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Diagnostics</title>
<variablelist>
<varlistentry>
<term><computeroutput>COMMENT</computeroutput></term>
<listitem>
<para>
Message returned if the comment was successfully changed.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Notes</title>
<note>
<para> <para>
There is presently no security mechanism There is presently no security mechanism for comments: any user
for comments: any user connected to a database can see all the comments connected to a database can see all the comments for objects in
for objects in that database (although only superusers can change that database (although only superusers can change comments for
comments for objects that they don't own). Therefore, don't put objects that they don't own). Therefore, don't put
security-critical information in comments. security-critical information in comments.
</para> </para>
</note>
</refsect1> </refsect1>
<refsect1 id="R1-SQL-COMMENT-2"> <refsect1>
<title> <title>Examples</title>
Usage
</title>
<para> <para>
Attach a comment to the table <literal>mytable</literal>: Attach a comment to the table <literal>mytable</literal>:
<programlisting> <programlisting>
COMMENT ON TABLE mytable IS 'This is my table.'; COMMENT ON TABLE mytable IS 'This is my table.';
</programlisting> </programlisting>
Remove it again: Remove it again:
<programlisting> <programlisting>
COMMENT ON TABLE mytable IS NULL; COMMENT ON TABLE mytable IS NULL;
</programlisting> </programlisting>
</para> </para>
<para> <para>
Some more examples: Some more examples:
<programlisting> <programlisting>
COMMENT ON AGGREGATE my_aggregate (double precision) IS 'Computes sample variance'; COMMENT ON AGGREGATE my_aggregate (double precision) IS 'Computes sample variance';
COMMENT ON COLUMN my_table.my_field IS 'Employee ID number'; COMMENT ON COLUMN my_table.my_column IS 'Employee ID number';
COMMENT ON DATABASE my_database IS 'Development Database'; COMMENT ON DATABASE my_database IS 'Development Database';
COMMENT ON DOMAIN my_domain IS 'Email Address Domain'; COMMENT ON DOMAIN my_domain IS 'Email Address Domain';
COMMENT ON FUNCTION my_function (timestamp) IS 'Returns Roman Numeral'; COMMENT ON FUNCTION my_function (timestamp) IS 'Returns Roman Numeral';
COMMENT ON INDEX my_index IS 'Enforces uniqueness on employee id'; COMMENT ON INDEX my_index IS 'Enforces uniqueness on employee ID';
COMMENT ON OPERATOR ^ (text, text) IS 'Performs intersection of two texts'; COMMENT ON OPERATOR ^ (text, text) IS 'Performs intersection of two texts';
COMMENT ON OPERATOR ^ (NONE, text) IS 'This is a prefix operator on text'; COMMENT ON OPERATOR ^ (NONE, text) IS 'This is a prefix operator on text';
COMMENT ON RULE my_rule ON my_table IS 'Logs UPDATES of employee records'; COMMENT ON RULE my_rule ON my_table IS 'Logs updates of employee records';
COMMENT ON SCHEMA my_schema IS 'Departmental data'; COMMENT ON SCHEMA my_schema IS 'Departmental data';
COMMENT ON SEQUENCE my_sequence IS 'Used to generate primary keys'; COMMENT ON SEQUENCE my_sequence IS 'Used to generate primary keys';
COMMENT ON TABLE my_schema.my_table IS 'Employee Information'; COMMENT ON TABLE my_schema.my_table IS 'Employee Information';
COMMENT ON TRIGGER my_trigger ON my_table IS 'Used for R.I.'; COMMENT ON TRIGGER my_trigger ON my_table IS 'Used for RI';
COMMENT ON TYPE complex IS 'Complex Number datatype'; COMMENT ON TYPE complex IS 'Complex number data type';
COMMENT ON VIEW my_view IS 'View of departmental costs'; COMMENT ON VIEW my_view IS 'View of departmental costs';
</programlisting> </programlisting>
</para> </para>
</refsect1> </refsect1>
<refsect1 id="R1-SQL-COMMENT-3"> <refsect1>
<title> <title>Compatibility</title>
Compatibility
</title> <para>
There is no <command>COMMENT</command> command in the SQL standard.
<refsect2 id="R2-SQL-COMMENT-4"> </para>
<refsect2info>
<date>1998-09-08</date>
</refsect2info>
<title>
SQL92
</title>
<para>
There is no <command>COMMENT</command> in <acronym>SQL92</acronym>.
</para>
</refsect2>
</refsect1> </refsect1>
</refentry> </refentry>
......
<!-- <!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/commit.sgml,v 1.14 2002/04/21 19:02:39 thomas Exp $ $Header: /cvsroot/pgsql/doc/src/sgml/ref/commit.sgml,v 1.15 2003/04/15 13:25:08 petere Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -8,141 +8,96 @@ PostgreSQL documentation ...@@ -8,141 +8,96 @@ PostgreSQL documentation
<refentrytitle id="SQL-COMMIT-TITLE">COMMIT</refentrytitle> <refentrytitle id="SQL-COMMIT-TITLE">COMMIT</refentrytitle>
<refmiscinfo>SQL - Language Statements</refmiscinfo> <refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta> </refmeta>
<refnamediv> <refnamediv>
<refname> <refname>COMMIT</refname>
COMMIT <refpurpose>commit the current transaction</refpurpose>
</refname>
<refpurpose>
commit the current transaction
</refpurpose>
</refnamediv> </refnamediv>
<refsynopsisdiv> <refsynopsisdiv>
<refsynopsisdivinfo> <synopsis>
<date>1999-07-20</date>
</refsynopsisdivinfo>
<synopsis>
COMMIT [ WORK | TRANSACTION ] COMMIT [ WORK | TRANSACTION ]
</synopsis> </synopsis>
<refsect2 id="R2-SQL-COMMIT-1">
<refsect2info>
<date>1998-09-08</date>
</refsect2info>
<title>
Inputs
</title>
<para>
<variablelist>
<varlistentry>
<term>WORK</term>
<term>TRANSACTION</term>
<listitem>
<para>
Optional keywords. They have no effect.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
<refsect2 id="R2-SQL-COMMIT-2">
<refsect2info>
<date>1998-09-08</date>
</refsect2info>
<title>
Outputs
</title>
<para>
<variablelist>
<varlistentry>
<term><computeroutput>
COMMIT
</computeroutput></term>
<listitem>
<para>
Message returned if the transaction is successfully committed.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><computeroutput>
WARNING: COMMIT: no transaction in progress
</computeroutput></term>
<listitem>
<para>
If there is no transaction in progress.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
</refsynopsisdiv> </refsynopsisdiv>
<refsect1 id="R1-SQL-COMMIT-1"> <refsect1>
<refsect1info> <title>Description</title>
<date>1998-09-08</date>
</refsect1info>
<title>
Description
</title>
<para> <para>
<command>COMMIT</command> commits the current transaction. All <command>COMMIT</command> commits the current transaction. All
changes made by the transaction become visible to others changes made by the transaction become visible to others
and are guaranteed to be durable if a crash occurs. and are guaranteed to be durable if a crash occurs.
</para> </para>
</refsect1>
<refsect2 id="R2-SQL-COMMIT-3"> <refsect1>
<refsect2info> <title>Parameters</title>
<date>1998-09-08</date>
</refsect2info>
<title>
Notes
</title>
<para>
The keywords WORK and TRANSACTION are noise and can be omitted.
</para>
<para> <variablelist>
Use <xref linkend="SQL-ROLLBACK" endterm="SQL-ROLLBACK-TITLE"> <varlistentry>
to abort a transaction. <term><literal>WORK</literal></term>
</para> <term><literal>TRANSACTION</literal></term>
</refsect2> <listitem>
<para>
Optional key words. They have no effect.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1> </refsect1>
<refsect1>
<title>Diagnostics</title>
<variablelist>
<varlistentry>
<term><computeroutput>COMMIT</computeroutput></term>
<listitem>
<para>
Message returned if the transaction was successfully committed.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><computeroutput>WARNING: COMMIT: no transaction in progress</computeroutput></term>
<listitem>
<para>
Message if there is no transaction in progress.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Notes</title>
<refsect1 id="R1-SQL-COMMIT-2">
<title>
Usage
</title>
<para> <para>
To make all changes permanent: Use <xref linkend="SQL-ROLLBACK" endterm="SQL-ROLLBACK-TITLE"> to
<programlisting> abort a transaction.
COMMIT WORK; </para>
</programlisting> </refsect1>
<refsect1>
<title>Examples</title>
<para>
To commit the current transaction and make all changes permanent:
<programlisting>
COMMIT;
</programlisting>
</para> </para>
</refsect1> </refsect1>
<refsect1 id="R1-SQL-COMMIT-3"> <refsect1>
<title> <title>Compatibility</title>
Compatibility
</title>
<refsect2 id="R2-SQL-COMMIT-4"> <para>
<refsect2info> The SQL standard only specifies the two forms
<date>1998-09-08</date> <literal>COMMIT</literal> and <literal>COMMIT
</refsect2info> WORK</literal>. Otherwise, this command is fully conforming.
<title> </para>
SQL92
</title>
<para>
<acronym>SQL92</acronym> only specifies the two forms <literal>COMMIT</literal>
and <literal>COMMIT WORK</literal>. Otherwise full compatibility.
</para>
</refsect2>
</refsect1> </refsect1>
</refentry> </refentry>
......
This diff is collapsed.
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment