mirror of
https://github.com/postgres/postgres.git
synced 2025-12-21 05:21:08 +03:00
binary format read/created by COPY BINARY. It also mentions the contrib/binarycopy module. Lee Kindness.
615 lines
21 KiB
Plaintext
615 lines
21 KiB
Plaintext
<!--
|
|
$Header: /cvsroot/pgsql/doc/src/sgml/ref/copy.sgml,v 1.47 2003/08/17 04:33:02 momjian 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>
|
|
<synopsis>
|
|
COPY <replaceable class="parameter">table</replaceable> [ ( <replaceable class="parameter">column</replaceable> [, ...] ) ]
|
|
FROM { '<replaceable class="parameter">filename</replaceable>' | STDIN }
|
|
[ [ 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>' | STDOUT }
|
|
[ [ WITH ]
|
|
[ BINARY ]
|
|
[ OIDS ]
|
|
[ DELIMITER [ AS ] '<replaceable class="parameter">delimiter</replaceable>' ]
|
|
[ NULL [ AS ] '<replaceable class="parameter">null string</replaceable>' ] ]
|
|
</synopsis>
|
|
</refsynopsisdiv>
|
|
|
|
<refsect1>
|
|
<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 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 column list,
|
|
<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> server to directly read from
|
|
or write to a file. The file must be accessible to the server and
|
|
the name must be specified from the viewpoint of the server. When
|
|
<literal>STDIN</literal> or <literal>STDOUT</literal> is
|
|
specified, data is transmitted via the connection between the
|
|
client and the server.
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Parameters</title>
|
|
|
|
<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</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 path name of the input or output file.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>STDIN</literal></term>
|
|
<listitem>
|
|
<para>
|
|
Specifies that input comes from the client application.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>STDOUT</literal></term>
|
|
<listitem>
|
|
<para>
|
|
Specifies that output goes to the client application.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>BINARY</literal></term>
|
|
<listitem>
|
|
<para>
|
|
Causes all data to be stored or read in binary format rather
|
|
than as text. You cannot specify the <option>DELIMITER</option>
|
|
or <option>NULL</option> options in binary mode.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>OIDS</literal></term>
|
|
<listitem>
|
|
<para>
|
|
Specifies copying the OID for each row. (An error is raised if
|
|
<literal>OIDS</literal> is specified for a table that does not
|
|
have OIDs.)
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">delimiter</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The single character that separates columns within each row
|
|
(line) of the file. The default is a tab character.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><replaceable class="parameter">null string</replaceable></term>
|
|
<listitem>
|
|
<para>
|
|
The string that represents a null value. The default is
|
|
<literal>\N</literal> (backslash-N). You might prefer an empty
|
|
string, for example.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
On a <command>COPY FROM</command>, 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 with
|
|
<command>COPY TO</command>.
|
|
</para>
|
|
</note>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Diagnostics</title>
|
|
|
|
<variablelist>
|
|
<varlistentry>
|
|
<term><computeroutput>COPY</computeroutput></term>
|
|
<listitem>
|
|
<para>
|
|
The copy operation completed successfully.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Notes</title>
|
|
|
|
<para>
|
|
<command>COPY</command> can only be used with plain tables, not
|
|
with views.
|
|
</para>
|
|
|
|
<para>
|
|
The <literal>BINARY</literal> key word causes all data to be
|
|
stored/read as binary format rather than as text. It is
|
|
somewhat faster than the normal text mode, but a binary-format
|
|
file is less portable across machine architectures and
|
|
<productname>PostgreSQL</productname> versions.
|
|
</para>
|
|
|
|
<para>
|
|
You must have select privilege on the table
|
|
whose values are read by <command>COPY TO</command>, and
|
|
insert privilege on the table into which values
|
|
are inserted by <command>COPY FROM</command>.
|
|
</para>
|
|
|
|
<para>
|
|
Files named in a <command>COPY</command> command are read or written
|
|
directly by the server, 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 server has privileges to access.
|
|
</para>
|
|
|
|
<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 server when <command>\copy</command> is used.
|
|
</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
|
|
server 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 working directory of the server process (somewhere below
|
|
the data directory), not the client's working directory.
|
|
</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 table 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>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>File Formats</title>
|
|
|
|
<refsect2>
|
|
<title>Text Format</title>
|
|
|
|
<para>
|
|
When <command>COPY</command> is used without the <literal>BINARY</literal> option,
|
|
the data read or written is a text file with one line per table row.
|
|
Columns in a row are separated by the delimiter character.
|
|
The column 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 columns 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.
|
|
If <literal>OIDS</literal> is specified, the OID is read or written as the first column,
|
|
preceding the user data columns.
|
|
</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 file, since the end of file
|
|
serves perfectly well; it is needed only when copying data to or from
|
|
client applications using pre-3.0 client protocol.
|
|
</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 a column value: backslash itself,
|
|
newline, carriage return, 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 it is
|
|
possible to represent a data carriage return by a backslash and carriage
|
|
return, and to represent a data newline by a backslash and newline.
|
|
However, these representations might not be accepted in future releases.
|
|
They are also highly vulnerable to corruption if the COPY file is
|
|
transferred across different machines (for example, from Unix to Windows
|
|
or vice versa).
|
|
</para>
|
|
|
|
<para>
|
|
<command>COPY TO</command> will terminate each row with a Unix-style
|
|
newline (<quote><literal>\n</></>), or carriage return/newline
|
|
("\r\n") for servers running MS Windows.
|
|
<command>COPY FROM</command> can handle lines ending with newlines,
|
|
carriage returns, or carriage return/newlines.
|
|
</para>
|
|
</refsect2>
|
|
|
|
<refsect2>
|
|
<title>Binary Format</title>
|
|
|
|
<para>
|
|
The file format used for <command>COPY BINARY</command> changed in
|
|
<application>PostgreSQL</application> 7.4. The new format consists
|
|
of a file header, zero or more tuples containing the row data, and
|
|
a file trailer. Headers and data are now in network byte order.
|
|
</para>
|
|
|
|
<refsect3>
|
|
<title>File Header</title>
|
|
|
|
<para>
|
|
The file header consists of 15 bytes of fixed fields, followed
|
|
by a variable-length header extension area. The fixed fields are:
|
|
|
|
<variablelist>
|
|
<varlistentry>
|
|
<term>Signature</term>
|
|
<listitem>
|
|
<para>
|
|
11-byte sequence <literal>PGCOPY\n\377\r\n\0</> --- note that the zero byte
|
|
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 end-of-line-translation
|
|
filters, dropped zero bytes, dropped high bits, or parity changes.)
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term>Flags field</term>
|
|
<listitem>
|
|
<para>
|
|
32-bit integer bit mask to denote important aspects of the file format. Bits
|
|
are numbered from 0 (<acronym>LSB</>) to 31 (<acronym>MSB</>). Note that
|
|
this field is stored in network byte order (most significant byte first),
|
|
as are all the integer fields used in the file format. 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 data; if 0, not
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term>Header extension area length</term>
|
|
<listitem>
|
|
<para>
|
|
32-bit integer, length in bytes of remainder of header, not including self.
|
|
Currently, this is 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>
|
|
<title>Tuples</title>
|
|
<para>
|
|
Each tuple begins with a 16-bit integer 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 a 32-bit length word followed by that many bytes of field data. (The
|
|
length word does not include itself, and can be zero.) As a special case,
|
|
-1 indicates a NULL field value. No value bytes follow in the NULL case.
|
|
</para>
|
|
|
|
<para>
|
|
There is no alignment padding or any other extra data between fields.
|
|
</para>
|
|
|
|
<para>
|
|
Presently, all data values in a <command>COPY BINARY</command> file are
|
|
assumed to be in binary format (format code one). It is anticipated that a
|
|
future extension may add a header field that allows per-column format codes
|
|
to be specified.
|
|
</para>
|
|
|
|
<para>
|
|
To determine the appropriate binary format for the actual tuple data you
|
|
should consult the <application>PostgreSQL</application> source, in
|
|
particular the <function>*send</> and <function>*recv</> functions for
|
|
the data type (typically found in the <filename>src/backend/utils/adt</filename>
|
|
directory). The <application>contrib/binarycopy</application> module
|
|
can also be used to create an appropriate format file.
|
|
</para>
|
|
|
|
<para>
|
|
If OIDs are included in the file, 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 length word --- 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>
|
|
<title>File Trailer</title>
|
|
|
|
<para>
|
|
The file trailer consists of a 16-bit integer 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>
|
|
<title>Examples</title>
|
|
|
|
<para>
|
|
The following example copies a table to the client
|
|
using the vertical bar (<literal>|</literal>) as the field delimiter:
|
|
<programlisting>
|
|
COPY country TO STDOUT WITH DELIMITER '|';
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
To copy data from a file into the <literal>country</> table:
|
|
<programlisting>
|
|
COPY country FROM '/usr1/proj/bray/sql/country_data';
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Here is a sample of data suitable for copying into a table from
|
|
<literal>STDIN</literal>:
|
|
<programlisting>
|
|
AF AFGHANISTAN
|
|
AL ALBANIA
|
|
DZ ALGERIA
|
|
ZM ZAMBIA
|
|
ZW ZIMBABWE
|
|
</programlisting>
|
|
Note that the white space on each line is actually a tab character.
|
|
</para>
|
|
|
|
<para>
|
|
The following is the same data, output in binary format.
|
|
The data is shown after filtering through the
|
|
Unix utility <command>od -c</command>. The table has three columns;
|
|
the first has type <type>char(2)</type>, the second has type <type>text</type>,
|
|
and the third has type <type>integer</type>. All the rows have a null value
|
|
in the third column.
|
|
<programlisting>
|
|
0000000 P G C O P Y \n 377 \r \n \0 \0 \0 \0 \0 \0
|
|
0000020 \0 \0 \0 \0 003 \0 \0 \0 002 A F \0 \0 \0 013 A
|
|
0000040 F G H A N I S T A N 377 377 377 377 \0 003
|
|
0000060 \0 \0 \0 002 A L \0 \0 \0 007 A L B A N I
|
|
0000100 A 377 377 377 377 \0 003 \0 \0 \0 002 D Z \0 \0 \0
|
|
0000120 007 A L G E R I A 377 377 377 377 \0 003 \0 \0
|
|
0000140 \0 002 Z M \0 \0 \0 006 Z A M B I A 377 377
|
|
0000160 377 377 \0 003 \0 \0 \0 002 Z W \0 \0 \0 \b Z I
|
|
0000200 M B A B W E 377 377 377 377 377 377
|
|
</programlisting>
|
|
</para>
|
|
</refsect1>
|
|
|
|
<refsect1>
|
|
<title>Compatibility</title>
|
|
|
|
<para>
|
|
There is no <command>COPY</command> statement in the SQL standard.
|
|
</para>
|
|
|
|
<para>
|
|
The following syntax was used before PostgreSQL version 7.3 and is
|
|
still supported:
|
|
|
|
<synopsis>
|
|
COPY [ BINARY ] <replaceable class="parameter">table</replaceable> [ WITH OIDS ]
|
|
FROM { '<replaceable class="parameter">filename</replaceable>' | STDIN }
|
|
[ [USING] DELIMITERS '<replaceable class="parameter">delimiter</replaceable>' ]
|
|
[ WITH NULL AS '<replaceable class="parameter">null string</replaceable>' ]
|
|
|
|
COPY [ BINARY ] <replaceable class="parameter">table</replaceable> [ WITH OIDS ]
|
|
TO { '<replaceable class="parameter">filename</replaceable>' | STDOUT }
|
|
[ [USING] DELIMITERS '<replaceable class="parameter">delimiter</replaceable>' ]
|
|
[ WITH NULL AS '<replaceable class="parameter">null string</replaceable>' ]
|
|
</synopsis>
|
|
</para>
|
|
</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:
|
|
-->
|