postgres/doc/src/sgml/ref/copy.sgml
Tom Lane 38bb77a5d1 ALTER TABLE DROP COLUMN works. Patch by Christopher Kings-Lynne,
code review by Tom Lane.  Remaining issues: functions that take or
return tuple types are likely to break if one drops (or adds!)
a column in the table defining the type.  Need to think about what
to do here.

Along the way: some code review for recent COPY changes; mark system
columns attnotnull = true where appropriate, per discussion a month ago.
2002-08-02 18:15:10 +00:00

724 lines
23 KiB
Plaintext

<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/copy.sgml,v 1.35 2002/08/02 18:15:04 tgl Exp $
PostgreSQL documentation
-->
<refentry id="SQL-COPY">
<refmeta>
<refentrytitle id="sql-copy-title">COPY</refentrytitle>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>
COPY
</refname>
<refpurpose>
copy data between files and tables
</refpurpose>
</refnamediv>
<refsynopsisdiv>
<refsynopsisdivinfo>
<date>1999-12-11</date>
</refsynopsisdivinfo>
<synopsis>
COPY <replaceable class="parameter">table</replaceable> [ ( <replaceable class="parameter">column</replaceable> [, ...] ) ]
FROM { '<replaceable class="parameter">filename</replaceable>' | <filename>stdin</filename> }
[ [ WITH ]
[ BINARY ]
[ OIDS ]
[ DELIMITER [ AS ] '<replaceable class="parameter">delimiter</replaceable>' ]
[ NULL [ AS ] '<replaceable class="parameter">null string</replaceable>' ] ]
COPY <replaceable class="parameter">table</replaceable> [ ( <replaceable class="parameter">column</replaceable> [, ...] ) ]
TO { '<replaceable class="parameter">filename</replaceable>' | <filename>stdout</filename> }
[ [ WITH ]
[ BINARY ]
[ OIDS ]
[ DELIMITER [ AS ] '<replaceable class="parameter">delimiter</replaceable>' ]
[ NULL [ AS ] '<replaceable class="parameter">null string</replaceable>' ] ]
</synopsis>
<refsect2 id="R2-SQL-COPY-1">
<refsect2info>
<date>1998-09-08</date>
</refsect2info>
<title>
Inputs
</title>
<para>
<variablelist>
<varlistentry>
<term><replaceable class="parameter">table</replaceable></term>
<listitem>
<para>
The name (possibly schema-qualified) of an existing table.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">column list</replaceable></term>
<listitem>
<para>
An optional list of columns to be copied. If no column list is
specified, all columns will be used.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">filename</replaceable></term>
<listitem>
<para>
The absolute Unix path name of the input or output file.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><filename>stdin</filename></term>
<listitem>
<para>
Specifies that input comes from the client application.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><filename>stdout</filename></term>
<listitem>
<para>
Specifies that output goes to the client application.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>BINARY</term>
<listitem>
<para>
Changes the behavior of field formatting, forcing all data to be
stored or read in binary format rather than as text. You can not
specify DELIMITER or NULL in binary mode.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>OIDS</term>
<listitem>
<para>
Specifies copying the internal object id (OID) for each row.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">delimiter</replaceable></term>
<listitem>
<para>
The character that separates fields within each row (line) of the file.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">null string</replaceable></term>
<listitem>
<para>
The string that represents a NULL value. The default is
<quote><literal>\N</literal></quote> (backslash-N). You might
prefer an empty string, for example.
</para>
<note>
<para>
On a copy in, any data item that matches this string will be stored as
a NULL value, so you should make sure that you use the same string
as you used on copy out.
</para>
</note>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
<refsect2 id="R2-SQL-COPY-2">
<refsect2info>
<date>1998-09-08</date>
</refsect2info>
<title>
Outputs
</title>
<para>
<variablelist>
<varlistentry>
<term><computeroutput>
COPY
</computeroutput></term>
<listitem>
<para>
The copy completed successfully.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><computeroutput>
ERROR: <replaceable>reason</replaceable>
</computeroutput></term>
<listitem>
<para>
The copy failed for the reason stated in the error message.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
</refsynopsisdiv>
<refsect1 id="R1-SQL-COPY-1">
<refsect1info>
<date>2001-01-02</date>
</refsect1info>
<title>
Description
</title>
<para>
<command>COPY</command> moves data between
<productname>PostgreSQL</productname> tables and standard file-system
files.
<command>COPY TO</command> copies the entire contents of a table
<emphasis>to</> a file, while <command>COPY FROM</command> copies
data <emphasis>from</> a file to a table (appending the data to
whatever is in the table already).
</para>
<para>
If a list of columns is specified, <command>COPY</command> will
only copy the data in the specified columns to or from the file.
If there are any columns in the table that are not in the file,
<command>COPY FROM</command> will insert the default values for
those columns.
</para>
<para>
<command>COPY</command> with a file name instructs the
<productname>PostgreSQL</productname> backend to directly read from
or write to a file. The file must be accessible to the backend and
the name must be specified from the viewpoint of the backend. When
<filename>stdin</filename> or <filename>stdout</filename> is
specified, data flows through the client frontend to the backend.
<tip>
<para>
Do not confuse <command>COPY</command> with the
<application>psql</application> instruction
<command>\copy</command>. <command>\copy</command> invokes
<command>COPY FROM stdin</command> or <command>COPY TO
stdout</command>, and then fetches/stores the data in a file
accessible to the <application>psql</application> client. Thus,
file accessibility and access rights depend on the client rather
than the backend when <command>\copy</command> is used.
</para>
</tip>
</para>
<refsect2 id="R2-SQL-COPY-3">
<refsect2info>
<date>2001-01-02</date>
</refsect2info>
<title>
Notes
</title>
<para>
<command>COPY</command> can only be used with plain tables, not with
views.
</para>
<para>
The BINARY keyword will force all data to be
stored/read as binary format rather than as text. It is
somewhat faster than the normal copy command, but a binary copy
file is not portable across machine architectures.
</para>
<para>
By default, a text copy uses a tab ("\t") character as a delimiter
between fields. The field delimiter may be changed to any other
single character with the keyword DELIMITER. Characters in data
fields that happen to match the delimiter character will be
backslash quoted.
</para>
<para>
You must have <firstterm>select privilege</firstterm> on any table
whose values are read by <command>COPY TO</command>, and
<firstterm>insert privilege</firstterm> on a table into which values
are being inserted by <command>COPY FROM</command>. The backend also
needs appropriate Unix permissions for any file read or written by
<command>COPY</command>.
</para>
<para>
<command>COPY FROM</command> will invoke any triggers and check
constraints on the destination table. However, it will not invoke rules.
</para>
<para>
<command>COPY</command> stops operation at the first error. This
should not lead to problems in the event of a <command>COPY
TO</command>, but the target relation will already have received
earlier rows in a <command>COPY FROM</command>. These rows will not
be visible or accessible, but they still occupy disk space. This may
amount to a considerable amount of wasted disk space if the failure
happened well into a large copy operation. You may wish to invoke
<command>VACUUM</command> to recover the wasted space.
</para>
<para>
Files named in a <command>COPY</command> command are read or written
directly by the backend, not by the client application. Therefore,
they must reside on or be accessible to the database server machine,
not the client. They must be accessible to and readable or writable
by the <application>PostgreSQL</application> user (the user ID the
server runs as), not the client. <command>COPY</command> naming a
file is only allowed to database superusers, since it allows reading
or writing any file that the backend has privileges to access.
<tip>
<para>
The
<application>psql</application> instruction <command>\copy</command>
reads or writes files on the client machine with the client's
permissions, so it is not restricted to superusers.
</para>
</tip>
</para>
<para>
It is recommended that the file name used in <command>COPY</command>
always be specified as an absolute path. This is enforced by the
backend in the case of <command>COPY TO</command>, but for
<command>COPY FROM</command> you do have the option of reading from
a file specified by a relative path. The path will be interpreted
relative to the backend's working directory (somewhere below
<filename>$PGDATA</filename>), not the client's working directory.
</para>
</refsect2>
</refsect1>
<refsect1 id="R1-SQL-COPY-2">
<refsect1info>
<date>2001-01-02</date>
</refsect1info>
<title>File Formats</title>
<refsect2>
<refsect2info>
<date>2002-02-12</date>
</refsect2info>
<title>Text Format</title>
<para>
When <command>COPY</command> is used without the BINARY option,
the file read or written is a text file with one line per table row.
Columns (attributes) in a row are separated by the delimiter character.
The attribute values themselves are strings generated by the
output function, or acceptable to the input function, of each
attribute's data type. The specified null-value string is used in
place of attributes that are NULL.
<command>COPY FROM</command> will raise an error if any line of the
input file contains more or fewer columns than are expected.
</para>
<para>
If OIDS is specified, the OID is read or written as the first column,
preceding the user data columns. (An error is raised if OIDS is
specified for a table that does not have OIDs.)
</para>
<para>
End of data can be represented by a single line containing just
backslash-period (<literal>\.</>). An end-of-data marker is
not necessary when reading from a Unix file, since the end of file
serves perfectly well; but an end marker must be provided when copying
data to or from a client application.
</para>
<para>
Backslash characters (<literal>\</>) may be used in the
<command>COPY</command> data to quote data characters that might
otherwise be taken as row or column delimiters. In particular, the
following characters <emphasis>must</> be preceded by a backslash if
they appear as part of an attribute value: backslash itself,
newline, and the current delimiter character.
</para>
<para>
The following special backslash sequences are recognized by
<command>COPY FROM</command>:
<informaltable>
<tgroup cols="2">
<thead>
<row>
<entry>Sequence</entry>
<entry>Represents</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>\b</></entry>
<entry>Backspace (ASCII 8)</entry>
</row>
<row>
<entry><literal>\f</></entry>
<entry>Form feed (ASCII 12)</entry>
</row>
<row>
<entry><literal>\n</></entry>
<entry>Newline (ASCII 10)</entry>
</row>
<row>
<entry><literal>\r</></entry>
<entry>Carriage return (ASCII 13)</entry>
</row>
<row>
<entry><literal>\t</></entry>
<entry>Tab (ASCII 9)</entry>
</row>
<row>
<entry><literal>\v</></entry>
<entry>Vertical tab (ASCII 11)</entry>
</row>
<row>
<entry><literal>\</><replaceable>digits</></entry>
<entry>Backslash followed by one to three octal digits specifies
the character with that numeric code</entry>
</row>
</tbody>
</tgroup>
</informaltable>
Presently, <command>COPY TO</command> will never emit an octal-digits
backslash sequence, but it does use the other sequences listed above
for those control characters.
</para>
<para>
Never put a backslash before a data character <literal>N</> or period
(<literal>.</>). Such pairs will be mistaken for the default null string
or the end-of-data marker, respectively. Any other backslashed character
that is not mentioned in the above table will be taken to represent itself.
</para>
<para>
It is strongly recommended that applications generating COPY data convert
data newlines and carriage returns to the <literal>\n</> and
<literal>\r</> sequences respectively. At present
(<productname>PostgreSQL</productname> 7.2 and older versions) it is
possible to represent a data carriage return without any special quoting,
and to represent a data newline by a backslash and newline. However,
these representations will not be accepted by default in future releases.
</para>
<para>
Note that the end of each row is marked by a Unix-style newline
("\n"). Presently, <command>COPY FROM</command> will not behave as
desired if given a file containing DOS- or Mac-style newlines.
This is expected to change in future releases.
</para>
</refsect2>
<refsect2>
<refsect2info>
<date>2001-01-02</date>
</refsect2info>
<title>Binary Format</title>
<para>
The file format used for <command>COPY BINARY</command> changed in
<application>PostgreSQL</application> v7.1. The new format consists
of a file header, zero or more tuples, and a file trailer.
</para>
<refsect3>
<refsect3info>
<date>2001-01-02</date>
</refsect3info>
<title>
File Header
</title>
<para>
The file header consists of 24 bytes of fixed fields, followed
by a variable-length header extension area. The fixed fields are:
<variablelist>
<varlistentry>
<term>Signature</term>
<listitem>
<para>
12-byte sequence <literal>PGBCOPY\n\377\r\n\0</> --- note that the null
is a required part of the signature. (The signature is designed to allow
easy identification of files that have been munged by a non-8-bit-clean
transfer. This signature will be changed by newline-translation
filters, dropped nulls, dropped high bits, or parity changes.)
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>Integer layout field</term>
<listitem>
<para>
int32 constant 0x01020304 in source's byte order. Potentially, a reader
could engage in byte-flipping of subsequent fields if the wrong byte
order is detected here.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>Flags field</term>
<listitem>
<para>
int32 bit mask to denote important aspects of the file format. Bits are
numbered from 0 (LSB) to 31 (MSB) --- note that this field is stored
with source's endianness, as are all subsequent integer fields. Bits
16-31 are reserved to denote critical file format issues; a reader
should abort if it finds an unexpected bit set in this range. Bits 0-15
are reserved to signal backwards-compatible format issues; a reader
should simply ignore any unexpected bits set in this range. Currently
only one flag bit is defined, and the rest must be zero:
<variablelist>
<varlistentry>
<term>Bit 16</term>
<listitem>
<para>
if 1, OIDs are included in the dump; if 0, not
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>Header extension area length</term>
<listitem>
<para>
int32 length in bytes of remainder of header, not including self. In
the initial version this will be zero, and the first tuple follows
immediately. Future changes to the format might allow additional data
to be present in the header. A reader should silently skip over any header
extension data it does not know what to do with.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
<para>
The header extension area is envisioned to contain a sequence of
self-identifying chunks. The flags field is not intended to tell readers
what is in the extension area. Specific design of header extension contents
is left for a later release.
</para>
<para>
This design allows for both backwards-compatible header additions (add
header extension chunks, or set low-order flag bits) and
non-backwards-compatible changes (set high-order flag bits to signal such
changes, and add supporting data to the extension area if needed).
</para>
</refsect3>
<refsect3>
<refsect3info>
<date>2001-01-02</date>
</refsect3info>
<title>
Tuples
</title>
<para>
Each tuple begins with an int16 count of the number of fields in the
tuple. (Presently, all tuples in a table will have the same count, but
that might not always be true.) Then, repeated for each field in the
tuple, there is an int16 typlen word possibly followed by field data.
The typlen field is interpreted thus:
<variablelist>
<varlistentry>
<term>Zero</term>
<listitem>
<para>
Field is NULL. No data follows.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>&gt; 0</term>
<listitem>
<para>
Field is a fixed-length data type. Exactly N
bytes of data follow the typlen word.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>-1</term>
<listitem>
<para>
Field is a varlena data type. The next four
bytes are the varlena header, which contains
the total value length including itself.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>&lt; -1</term>
<listitem>
<para>
Reserved for future use.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
<para>
For non-NULL fields, the reader can check that the typlen matches the
expected typlen for the destination column. This provides a simple
but very useful check that the data is as expected.
</para>
<para>
There is no alignment padding or any other extra data between fields.
Note also that the format does not distinguish whether a data type is
pass-by-reference or pass-by-value. Both of these provisions are
deliberate: they might help improve portability of the files (although
of course endianness and floating-point-format issues can still keep
you from moving a binary file across machines).
</para>
<para>
If OIDs are included in the dump, the OID field immediately follows the
field-count word. It is a normal field except that it's not included
in the field-count. In particular it has a typlen --- this will allow
handling of 4-byte vs 8-byte OIDs without too much pain, and will allow
OIDs to be shown as NULL if that ever proves desirable.
</para>
</refsect3>
<refsect3>
<refsect3info>
<date>2001-01-02</date>
</refsect3info>
<title>
File Trailer
</title>
<para>
The file trailer consists of an int16 word containing -1. This is
easily distinguished from a tuple's field-count word.
</para>
<para>
A reader should report an error if a field-count word is neither -1
nor the expected number of columns. This provides an extra
check against somehow getting out of sync with the data.
</para>
</refsect3>
</refsect2>
</refsect1>
<refsect1 id="R1-SQL-COPY-3">
<title>
Usage
</title>
<para>
The following example copies a table to standard output,
using a vertical bar (|) as the field
delimiter:
</para>
<programlisting>
COPY country TO <filename>stdout</filename> WITH DELIMITER '|';
</programlisting>
<para>
To copy data from a Unix file into a table country:
</para>
<programlisting>
COPY country FROM '/usr1/proj/bray/sql/country_data';
</programlisting>
<para>
Here is a sample of data suitable for copying into a table from
<filename>stdin</filename> (so it has the termination sequence on the
last line):
</para>
<programlisting>
AF AFGHANISTAN
AL ALBANIA
DZ ALGERIA
ZM ZAMBIA
ZW ZIMBABWE
\.
</programlisting>
<para>
Note that the white space on each line is actually a TAB.
</para>
<para>
The following is the same data, output in binary format on a
Linux/i586 machine. The data is shown after filtering through the
Unix utility <command>od -c</command>. The table has three fields;
the first is <type>char(2)</type>, the second is <type>text</type>,
and the third is <type>integer</type>. All the rows have a null value
in the third field.
</para>
<programlisting>
0000000 P G B C O P Y \n 377 \r \n \0 004 003 002 001
0000020 \0 \0 \0 \0 \0 \0 \0 \0 003 \0 377 377 006 \0 \0 \0
0000040 A F 377 377 017 \0 \0 \0 A F G H A N I S
0000060 T A N \0 \0 003 \0 377 377 006 \0 \0 \0 A L 377
0000100 377 \v \0 \0 \0 A L B A N I A \0 \0 003 \0
0000120 377 377 006 \0 \0 \0 D Z 377 377 \v \0 \0 \0 A L
0000140 G E R I A \0 \0 003 \0 377 377 006 \0 \0 \0 Z
0000160 M 377 377 \n \0 \0 \0 Z A M B I A \0 \0 003
0000200 \0 377 377 006 \0 \0 \0 Z W 377 377 \f \0 \0 \0 Z
0000220 I M B A B W E \0 \0 377 377
</programlisting>
</refsect1>
<refsect1 id="R1-SQL-COPY-6">
<title>
Compatibility
</title>
<refsect2 id="R2-SQL-COPY-4">
<refsect2info>
<date>1998-09-08</date>
</refsect2info>
<title>
SQL92
</title>
<para>
There is no <command>COPY</command> statement in SQL92.
</para>
</refsect2>
</refsect1>
</refentry>
<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"../reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
-->