Table of Contents

NAME

copy -- copy data to or from a class from or to a Unix file.

SYNOPSIS

copy [binary ] classname [with oids ]
   to |from ' filename' |stdin |stdout
   [using delimiters ' delim' ]

DESCRIPTION

Copy moves data between Postgres classes and standard Unix files. The keyword binary changes the behavior of field formatting, as described below. Classname is the name of an existing class. The keyword with oids copies the internal unique object id (OID) for each row. Classname is the name of an existing class. Filename is the absolute Unix pathname of the file. In place of a filename, the keywords stdin and stdout can be used so that input to copy can be written by a Libpq application and output from the copy command can be read by a Libpq application.

The binary keyword will force all data to be stored/read as binary objects rather than as ASCII text. It is somewhat faster than the normal copy command, but is not generally portable, and the files generated are somewhat larger, although this factor is highly dependent on the data itself. By default, a ASCII copy uses a tab (\t) character as a delimiter. The delimiter may also be changed to any other single-character with the use of using delimiters. Characters in data fields which happen to match the delimiter character will be quoted.

You must have read access on any class whose values are read by the copy command, and either write or append access to a class to which values are being appended by the copy command.

FORMAT OF OUTPUT FILES

ASCII COPY FORMAT

When copy is used without the binary keyword, the file generated will have each instance on a line, with each attribute separated by the delimiter character. Embedded delimiter characters will be preceeded by a backslash character (\). The attribute values themselves are strings generated by the output function associated with each attribute type. The output function for a type should not try to generate the backslash character; this will be handled by copy itself.

The actual format for each instance is <attr1><tab><attr2><tab>...<tab><attrn><newline>
The oid is placed on the beginning of the line if specified.

If copy is sending its output to standard output instead of a file, it will send a backslash(\) and a period (.) followed immediately by a newline, on a line by themselves, when it is done. Similarly, if copy is reading from standard input, it will expect a backslash (\) and a period (.) followed by a newline, as the first three characters on a line, to denote end-of-file. However, copy will terminate (followed by the backend itself) if a true EOF is encountered.

The backslash character has special meaning. NULL attributes are output as \N. A literal backslash character is output as two consecutive backslashes. A literal tab character is represented as a backslash and a tab. A literal newline character is represented as a backslash and a newline. When loading ASCII data not generated by PostgreSQL, you will need to convert backslash characters (\) to double-backslashes (\\) so they are loaded properly.

BINARY COPY FORMAT

In the case of copy binary, the first four bytes in the file will be the number of instances in the file. If this number is zero, the copy binary command will read until end of file is encountered. Otherwise, it will stop reading when this number of instances has been read. Remaining data in the file will be ignored.

The format for each instance in the file is as follows. Note that this format must be followed EXACTLY. Unsigned four-byte integer quantities are called uint32 in the below description. The first value is:
   uint32 number of tuples
then for each tuple:
   uint32 total length of data segment
   uint32 oid (if specified)
   uint32 number of null attributes
   [uint32 attribute number of first null attribute
    ...
    uint32 attribute number of nth null attribute],
   <data segment>

ALIGNMENT OF BINARY DATA

On Sun-3s, 2-byte attributes are aligned on two-byte boundaries, and all larger attributes are aligned on four-byte boundaries. Character attributes are aligned on single-byte boundaries. On other machines, all attributes larger than 1 byte are aligned on four-byte boundaries. Note that variable length attributes are preceded by the attribute's length; arrays are simply contiguous streams of the array element type.

SEE ALSO

insert(l) , create table(l) , vacuum(l) , libpq.

BUGS

Files used as arguments to the copy command must reside on or be accessible to the the database server machine by being either on local disks or a networked file system.

Copy stops operation at the first error. This should not lead to problems in the event of a copy from, but the target relation will, of course, be partially modified in a copy to. The vacuum(l) query should be used to clean up after a failed copy.

Because Postgres operates out of a different directory than the user's working directory at the time Postgres is invoked, the result of copying to a file `foo' (without additional path information) may yield unexpected results for the naive user. In this case, `foo' will wind up in $PGDATA /foo. In general, the full pathname should be used when specifying files to be copied.


Table of Contents