COPY
Copies data between a file and a table.
Syntax
COPY <table_name> [(<column_name> [, ...])]
FROM {'<file_name>' | STDIN}
[ [ WITH ] ( <option> [, ...] ) ]
COPY { <table_name> [(<column_name> [, ...])] | (<query>)}
TO STDOUT
[ [ WITH ] ( <option> [, ...] ) ]
where <option> can be any of the following:
FORMAT <format_name>
OIDS [ <boolean> ]
FREEZE [ <boolean> ]
DELIMITER '<delimiter_character>'
NULL '<null string>'
HEADER [ <boolean> ]
QUOTE '<quote_character>'
ESCAPE '<escape_character>'
FORCE_QUOTE { ( <column_name> [, ...] ) | * }
FORCE_NOT_NULL ( <column_name> [, ...] )
FORCE_NULL ( <column_name> [, ...] )
ENCODING '<encoding_name>'
FILL MISSING FIELDS
LOG ERRORS [ SEGMENT REJECT LIMIT <count> [ ROWS | PERCENT ] ]
Description
COPY
moves data between Relyt tables and standard file-system files. COPY ... TO
copies the contents of a table to a file, while COPY ... FROM
copies data from a file to a table (appending the data to whatever is in the table already). COPY ... TO
can also copy the results of a SELECT
query.
If a list of columns is specified, COPY
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, COPY ... FROM
will insert the default values for those columns.
Output
On successful completion, a COPY
command returns a command tag of the form, where <count>
is the number of rows copied:
COPY <count>
If running a COPY ... FROM
command in single row error isolation mode, the following notice message will be returned if any rows were not loaded due to format errors, where <count>
is the number of rows rejected:
NOTICE: Rejected <count> badly formatted rows.
Parameters
-
<table_name>
The name of an existing table. You can specify the name with the schema qualification.
-
<column_name>
An optional list of columns to be copied. If no column list is specified, all columns of the table will be copied.
When copying in text format, the default, a row of data in a column of type
bytea
can be up to 256 MB. -
<query>
A
SELECT
orVALUES
command whose results are to be copied. Note that parentheses are required around the query. -
<file_name>
The path name of the input or output file. Currently, only S3 files are supported.
-
STDIN
Specifies that input comes from the client application.
-
STDOUT
Specifies that output goes to the client application.
-
<boolean>
Specifies whether the selected option should be turned on or off. You can write
TRUE
,ON
, or1
to enable the option, andFALSE
,OFF
, or0
to deactivate it. The boolean value can also be omitted, in which caseTRUE
is assumed. -
FORMAT
Selects the data format to be read or written:
text
,csv
(Comma Separated Values), orbinary
. The default istext
. -
OIDS
Specifies copying the OID for each row. (An error is raised if OIDS is specified for a table that does not have OIDs, or in the case of copying a query.)
-
FREEZE
Requests copying the data with rows already frozen, just as they would be after running the
VACUUM FREEZE
command. This is intended as a performance option for initial data loading. Rows will be frozen only if the table being loaded has been created or truncated in the current subtransaction, there are no cursors open, and there are no older snapshots held by this transaction.Note that all other sessions will immediately be able to see the data once it has been successfully loaded. This violates the normal rules of MVCC visibility and users specifying this option should be aware of the potential problems this might cause.
-
DELIMITER
Specifies the character that separates columns within each row (line) of the file. The default is a tab character in
text
format, a comma inCSV
format. This must be a single one-byte character. This option is not allowed when usingbinary
format. -
NULL
Specifies the string that represents a null value. The default is
\N
(backslash-N) intext
format, and an unquoted empty string inCSV
format. You might prefer an empty string even intext
format for cases where you don't want to distinguish nulls from empty strings. This option is not allowed when usingbinary
format.noteWhen using
COPY ... FROM
, 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 withCOPY ... TO
. -
HEADER
Specifies that a file contains a header line with the names of each column in the file. On output, the first line contains the column names from the table, and on input, the first line is ignored. This option is allowed only when using
CSV
format. -
QUOTE
Specifies the quoting character to be used when a data value is quoted. The default is double-quote. This must be a single one-byte character. This option is allowed only when using
CSV
format. -
ESCAPE
Specifies the character that should appear before a data character that matches the
QUOTE
value. The default is the same as theQUOTE
value (so that the quoting character is doubled if it appears in the data). This must be a single one-byte character. This option is allowed only when usingCSV
format. -
FORCE_QUOTE
Forces quoting to be used for all non-
NULL
values in each specified column.NULL
output is never quoted. If*
is specified, non-NULL
values will be quoted in all columns. This option is allowed only inCOPY TO
, and only when usingCSV
format. -
FORCE_NOT_NULL
Do not match the specified columns' values against the null string. In the default case where the null string is empty, this means that empty values will be read as zero-length strings rather than nulls, even when they are not quoted. This option is allowed only in
COPY FROM
, and only when usingCSV
format. -
FORCE_NULL
Match the specified columns' values against the null string, even if it has been quoted, and if a match is found set the value to
NULL
. In the default case where the null string is empty, this converts a quoted empty string intoNULL
. This option is allowed only inCOPY FROM
, and only when usingCSV
format. -
ENCODING
Specifies that the file is encoded in the encoding_name. If this option is omitted, the current client encoding is used. See the Usage notes below for more details.
-
NEWLINE
Specifies the newline used in your data files —
LF
(Line feed, 0x0A),CR
(Carriage return, 0x0D), orCRLF
(Carriage return plus line feed, 0x0D 0x0A). -
CSV
Selects Comma Separated Value (CSV) mode.
-
FILL MISSING FIELDS
In
COPY ... FROM
more for bothTEXT
andCSV
, specifyingFILL MISSING FIELDS
will set missing trailing field values toNULL
(instead of reporting an error) when a row of data has missing data fields at the end of a line or row. Blank rows, fields with aNOT NULL
constraint, and trailing delimiters on a line will still report an error.
File formats
File formats supported by COPY
include:
Text format
When the text
format is used, 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
(tab by default). 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 string is used in place of columns that are null. COPY ... FROM
will raise an error if any line of the input file contains more or fewer columns than are expected. If OIDS
is specified, the OID
is read or written as the first column, preceding the user data columns.
The data file has two reserved characters that have special meaning to COPY
:
-
The designated delimiter character (tab by default), which is used to separate fields in the data file.
-
A UNIX-style line feed (
\n
or0x0a
), which is used to designate a new row in the data file. It is strongly recommended that applications generatingCOPY
data convert data line feeds to UNIX-style line feeds rather than Microsoft Windows style carriage return line feeds (\r\n
or0x0a 0x0d
).
If your data contains either of these characters, you must escape the character so COPY
treats it as data and not as a field separator or new row.
By default, the escape character is a backslash () for text-formatted files and a double quote (") for csv
-formatted files. If you want to use a different escape character, you can do so using the ESCAPE AS
clause. Make sure to choose an escape character that is not used anywhere in your data file as an actual data value. You can also deactivate escaping in text-formatted files by using ESCAPE 'OFF'
.
For example, suppose you have a table with three columns and you want to load the following three fields using COPY
.
- percentage sign = %
- vertical bar = |
- backslash = \
Your designated <delimiter_character>
is |
(pipe character), and your designated escape character is *
(asterisk). The formatted row in your data file would look like this:
percentage sign = % | vertical bar = *| | backslash = \
Notice how the pipe character that is part of the data has been escaped using the asterisk character (*). Also notice that we do not need to escape the backslash since we are using an alternative escape character.
The following characters must be preceded by the escape character if they appear as part of a column value: the escape character itself, newline, carriage return, and the current delimiter character. You can specify a different escape character using the ESCAPE AS
clause.
CSV format
This format option is used for importing and exporting the Comma Separated Value (CSV) file format used by many other programs, such as spreadsheets. Instead of the escaping rules used by Relyt standard text format, it produces and recognizes the common CSV escaping mechanism.
The values in each record are separated by the DELIMITER
character. If the value contains the delimiter character, the QUOTE
character, the ESCAPE
character (which is double quote by default), the NULL
string, a carriage return, or line feed character, then the whole value is prefixed and suffixed by the QUOTE
character. You can also use FORCE_QUOTE
to force quotes when outputting non-NULL
values in specific columns.
The CSV format has no standard way to distinguish a NULL
value from an empty string. Relyt COPY
handles this by quoting. A NULL
is output as the NULL
parameter string and is not quoted, while a non-NULL
value matching the NULL
string is quoted. For example, with the default settings, a NULL
is written as an unquoted empty string, while an empty string data value is written with double quotes (""). Reading values follows similar rules. You can use FORCE_NOT_NULL
to prevent NULL
input comparisons for specific columns. You can also use FORCE_NULL
to convert quoted null string data values to NULL
.
Because backslash is not a special character in the CSV
format, \.
, the end-of-data marker, could also appear as a data value. To avoid any misinterpretation, a \.
data value appearing as a lone entry on a line is automatically quoted on output, and on input, if quoted, is not interpreted as the end-of-data marker. If you are loading a file created by another application that has a single unquoted column and might have a value of \.
, you might need to quote that value in the input file.
In CSV
format, all characters are significant. A quoted value surrounded by white space, or any characters other than DELIMITER
, will include those characters. This can cause errors if you import data from a system that pads CSV lines with white space out to some fixed width. If such a situation arises you might need to preprocess the CSV file to remove the trailing white space, before importing the data into Relyt.
CSV
format will both recognize and produce CSV files with quoted values containing embedded carriage returns and line feeds. Thus the files are not strictly one line per table row like text-format files.
Many programs produce strange and occasionally perverse CSV files, so the file format is more a convention than a standard. Thus you might encounter some files that cannot be imported using this mechanism, and COPY
might produce files that other programs cannot process.
Binary format
The binary
format option causes all data to be stored/read as binary format rather than as text. It is somewhat faster than the text and CSV
formats, but a binary-format file is less portable across machine architectures and Relyt versions. Also, the binary format is very data type specific; for example it will not work to output binary data from a smallint
column and read it into an integer
column, even though that would work fine in text format.
The binary file format consists of a file header, zero or more tuples containing the row data, and a file trailer. Headers and data are in network byte order.
-
File Header — The file header consists of 15 bytes of fixed fields, followed by a variable-length header extension area. The fixed fields are:
-
Signature — 11-byte sequence 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.)
-
Flags field — 32-bit integer 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 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 cancel 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 is defined, and the rest must be zero (Bit 16: 1 if data has OIDs, 0 if not).
-
Header extension area length — 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. 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.
-
-
Tuples — 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.
There is no alignment padding or any other extra data between fields.
Presently, all data values in a binary-format 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.
If OIDs are included in the file, the OID field immediately follows the field-count word. It is a normal field except that it is 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.
-
File Trailer — The file trailer consists of a 16-bit integer word containing
-1
. This is easily distinguished from a tuple's field-count word. 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.
Usage notes
COPY
can only be used with tables, not with external tables or views. However, you can write COPY (SELECT * FROM viewname) TO ...
.
COPY
only deals with the specific table named; it does not copy data to or from child tables. Thus for example COPY <table> TO
shows the same data as SELECT * FROM ONLY table
. But COPY (SELECT * FROM table) TO ...
can be used to dump all of the data in an inheritance hierarchy.
The BINARY
keyword 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 Relyt versions. Also, you cannot run COPY FROM
in single row error isolation mode if the data is in binary format.
You must have SELECT
privilege on the table whose values are read by COPY TO
, and INSERT
privilege on the table into which values are inserted by COPY FROM
. It is sufficient to have column privileges on the columns listed in the command.
COPY FROM
will invoke any triggers and check constraints on the destination table. However, it will not invoke rewrite rules. Note that in this release, violations of constraints are not evaluated for single row error isolation mode.
COPY
input and output is affected by DateStyle
. To ensure portability to other Relyt installations that might use non-default DateStyle
settings, DateStyle
should be set to ISO before using COPY TO
. It is also a good idea to avoid dumping data with IntervalStyle
set to sql_standard
, because negative interval values might be misinterpreted by a server that has a different setting for IntervalStyle
.
Input data is interpreted according to ENCODING
option or the current client encoding, and output data is encoded in ENCODING
or the current client encoding, even if the data does not pass through the client but is read from or written to a file directly by the server.
When copying XML data from a file in text mode, the server configuration parameter xmloption
affects the validation of the XML data that is copied. If the value is content
(the default), XML data is validated as an XML content fragment. If the parameter value is document
, XML data is validated as an XML document. If the XML data is not valid, COPY
returns an error.
By default, COPY
stops operation at the first error. This should not lead to problems in the event of a COPY TO
, but the target table will already have received earlier rows in a COPY FROM
. 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 FROM
operation. You may wish to invoke VACUUM
to recover the wasted space. Another option would be to use single row error isolation mode to filter out error rows while still loading good rows.
FORCE_NULL
and FORCE_NOT_NULL
can be used simultaneously on the same column. This results in converting quoted null strings to null values and unquoted null strings to empty strings.
When a DW user runs a COPY command, the command can be controlled by a resource queue. The resource queue must be configured with the ACTIVE_STATEMENTS
parameter that specifies a maximum limit on the number of queries that can be run by roles assigned to that queue. Relyt does not apply a cost value or memory value to a COPY
command, resource queues with only cost or memory limits do not affect the running of COPY
commands.
Examples
Copy a table to the client using the vertical bar (|) as the field delimiter:
COPY country TO STDOUT (DELIMITER '|');
Copy data from an S3 file into the country
table:
COPY nation FROM 's3://s3.ap-southeast-1.amazonaws.com/******/tpch/100m/nation.tbl'
ACCESS_KEY_ID '******'
SECRET_ACCESS_KEY '******'
CSV DELIMITER '|'
HEADER;
Standard SQL compatibility
There is no COPY
statement in the SQL standard.