Copies data between a file and a table.
COPY <table_name> [(<column_name> [, ...])]
FROM {'<filename>' | PROGRAM '<command>' | STDIN}
[ [ WITH ] ( <option> [, ...] ) ]
[ WHERE <condition> ]
[ ON SEGMENT ]
COPY { <table_name> [(<column_name> [, ...])] | (<query>)}
TO {'<filename>' | PROGRAM '<command>' | STDOUT}
[ [ WITH ] ( <option> [, ...] ) ]
[ ON SEGMENT ]
where <option> can be one of:
FORMAT <format_name>
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 ] ]
IGNORE EXTERNAL PARTITIONS
COPY
moves data between Greenplum Database tables and standard file-system files. COPY TO
copies the contents of a table to a file (or multiple files based on the segment ID if copying ON SEGMENT
), 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 TO
copies only the data in the specified columns to the file. For COPY FROM, each field in the file is inserted, in order, into the specified column. Table columns not specified in the COPY FROM
column list will receive their default values.
COPY
with a file name instructs the Greenplum Database coordinator host to directly read from or write to a file. The file must be accessible by the operating system user running Greenplum Database (typically gpadmin
) on the coordinator host and the name must be specified from the viewpoint of the server. When PROGRAM
is specified, the server runs the given command and reads from the standard output of the program, or writes to the standard input of the program. The command must be specified from the viewpoint of the server, and be executable by the gpadmin
user. When STDIN
or STDOUT
is specified, data is transmitted via the connection between the client and the coordinator. STDIN
and STDOUT
cannot be used with the ON SEGMENT
clause.
When COPY
is used with the ON SEGMENT
clause, the COPY TO
causes segments to create individual segment-oriented files, which remain on the segment hosts. The filename argument for ON SEGMENT
takes the string literal <SEGID>
(required) and uses either the absolute path or the <SEG_DATA_DIR>
string literal. When the COPY
operation is run, the segment IDs and the paths of the segment data directories are substituted for the string literal values.
Using COPY TO
with a replicated table (DISTRIBUTED REPLICATED
) as source creates a file with rows from a single segment so that the target file contains no duplicate rows. Using COPY TO
with the ON SEGMENT
clause with a replicated table as source creates target files on segment hosts containing all table rows.
The ON SEGMENT
clause allows you to copy table data to files on segment hosts for use in operations such as migrating data between clusters or performing a backup. Segment data created by the ON SEGMENT
clause can be restored by tools such as gpfdist
, which is useful for high speed data loading.
CautionUse of the
ON SEGMENT
clause is recommended for expert users only.
If SEGMENT REJECT LIMIT
is provided, then a COPY FROM
operation will operate in single row error isolation mode. In this release, single row error isolation mode only applies to rows in the input file with format errors — for example, extra or missing attributes, attributes of a wrong data type, or invalid client encoding sequences. Constraint errors such as violation of a NOT NULL
, CHECK
, or UNIQUE
constraint will still be handled in 'all-or-nothing' input mode. The user can specify the number of error rows acceptable (on a per-segment basis), after which the entire COPY FROM
operation will be cancelled and no rows will be loaded. The count of error rows is per-segment, not per entire load operation. If the per-segment reject limit is not reached, then all rows not containing an error will be loaded and any error rows discarded. To keep error rows for further examination, specify the LOG ERRORS
clause to capture error log information. The error information and the row is stored internally in Greenplum Database.
An optional list of columns to be copied. If no column list is specified, all columns of the table except generated columns will be copied.
bytea
can be up to 256MB.
INSERT
,
UPDATE
, and
DELETE
queries a
RETURNING
clause must be provided, and the target relation must not have a conditional rule, nor an
ALSO
rule, nor an
INSTEAD
rule that expands to multiple statements.
E''
string and double any backslashes used in the path name.
Specify a command to run. In COPY FROM
, the input is read from standard output of the command, and in COPY TO
, the output is written to the standard input of the command. The command must be specified from the viewpoint of the Greenplum Database coordinator host system, and must be executable by the Greenplum Database administrator operating system user (gpadmin
).
The command is invoked by a shell. When passing arguments to the shell command that come from an untrusted source, strip or escape any special characters that have a special meaning for the shell. For security reasons, it is best to use a fixed command string, or at least avoid passing any user input in the string.
When ON SEGMENT
is specified, the command must be executable on all Greenplum Database primary segment hosts by the Greenplum Database administrator user (gpadmin
). The command is run by each Greenplum segment instance. The <SEGID>
is required in the command.
ON SEGMENT
clause for information about command syntax requirements and the data that is copied when the clause is specified.
ON SEGMENT
clause is not supported with
STDIN
.
ON SEGMENT
clause is not supported with
STDOUT
.
TRUE
,
ON
, or
1
to enable the option, and
FALSE
,
OFF
, or
0
to deactivate it. The boolean value can also be omitted, in which case
TRUE
is assumed.
text
,
csv
(Comma Separated Values), or
binary
. The default is
text
. See
File Formats for more information.
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. It is not currently possible to perform a COPY FREEZE
on a partitioned table.
text
format, a comma in
CSV
format. This must be a single one-byte character. This option is not allowed when using
binary
format.
Specifies the string that represents a null value. The default is \N
(backslash-N) in text
format, and an unquoted empty string in CSV
format. You might prefer an empty string even in text
format for cases where you don't want to distinguish nulls from empty strings. This option is not allowed when using binary
format.
NoteWhen using
COPY FROM
, Greenplum Database stores any data item that matches this string as a null value, so be sure that you use the same string that you specified inCOPY TO
.
CSV
format.
CSV
format.
QUOTE
value. The default is the same as the
QUOTE
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 using
CSV
format.
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 in
COPY TO
, and only when using
CSV
format.
COPY FROM
, and only when using
CSV
format.
NULL
. In the default case where the null string is empty, this converts a quoted empty string into
NULL
. This option is allowed only in
COPY FROM
, and only when using
CSV
format.
The optional WHERE
clause has the general form:
WHERE condition
boolean
. Any row that does not satisfy this condition will not be inserted to the table. A row satisfies the condition if it returns
true
when the actual row values are substituted for any variable references.
WHERE
expressions, and the evaluation does not see any changes made by the
COPY
itself (this matters when the expression contains calls to
VOLATILE
functions).
Specify individual, segment data files on the segment hosts. Each file contains the table data that is managed by the primary segment instance. For example, when copying data to files from a table with a COPY TO...ON SEGMENT
command, the command creates a file on the segment host for each segment instance on the host. Each file contains the table data that is managed by the segment instance.
The COPY
command does not copy data from or to mirror segment instances and segment data files.
The keywords STDIN
and STDOUT
are not supported with ON SEGMENT
.
The <SEG_DATA_DIR>
and <SEGID>
string literals are used to specify an absolute path and file name with the following syntax:
COPY <table> [TO|FROM] '<SEG_DATA_DIR>/<gpdumpname><SEGID>_<suffix>' ON SEGMENT;
ON SEGMENT
copying. The angle brackets (
<
and
>
) are part of the string literal used to specify the path.
COPY
replaces the string literal with the segment path(s) when
COPY
is run. An absolute path can be used in place of the
<SEG_DATA_DIR>
string literal.
ON SEGMENT
.
<SEGID>
is a required part of the file name when
ON SEGMENT
is specified. The angle brackets are part of the string literal used to specify the file name.
COPY TO
, the string literal is replaced by the content ID of the segment instance when the
COPY
command is run.
COPY FROM
, specify the segment instance content ID in the name of the file and place that file on the segment instance host. There must be a file for each primary segment instance on each host. When the
COPY FROM
command is run, the data is copied from the file to the segment instance.
When the PROGRAM command
clause is specified, the <SEGID>
string literal is required in the command, the <SEG_DATA_DIR>
string literal is optional. See Examples.
COPY FROM...ON SEGMENT
command, the table distribution policy is checked when data is copied into the table. By default, an error is returned if a data row violates the table distribution policy. You can deactivate the distribution policy check with the server configuration parameter
gp_enable_segment_copy_checking
. See
Notes.
LF
(Line feed, 0x0A),
CR
(Carriage return, 0x0D), or
CRLF
(Carriage return plus line feed, 0x0D 0x0A). If not specified, a Greenplum Database segment will detect the newline type by looking at the first row of data it receives and using the first newline type encountered.
COPY FROM
more for both
TEXT
and
CSV
, specifying
FILL MISSING FIELDS
will set missing trailing field values to
NULL
(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 a
NOT NULL
constraint, and trailing delimiters on a line will still report an error.
This is an optional clause that can precede a SEGMENT REJECT LIMIT
clause to capture error log information about rows with formatting errors.
Error log information is stored internally and is accessed with the Greenplum Database built-in SQL function gp_read_error_log()
.
Runs a COPY FROM
operation in single row error isolation mode. If the input rows have format errors they will be discarded provided that the reject limit count is not reached on any Greenplum Database segment instance during the load operation. The reject limit count can be specified as number of rows (the default) or percentage of total rows (1-100). If PERCENT
is used, each segment starts calculating the bad row percentage only after the number of rows specified by the parameter gp_reject_percent_threshold has been processed. The default for gp_reject_percent_threshold
is 300 rows. Constraint errors such as violation of a NOT NULL
, CHECK
, or UNIQUE
constraint will still be handled in 'all-or-nothing' input mode. If the limit is not reached, all good rows will be loaded and any error rows discarded.
NoteGreenplum Database limits the initial number of rows that can contain formatting errors if the
SEGMENT REJECT LIMIT
is not triggered first or is not specified. If the first 1000 rows are rejected, theCOPY
operation is stopped and rolled back.
The limit for the number of initial rejected rows can be changed with the Greenplum Database server configuration parameter gp_initial_bad_row_limit server configuration parameter documentation for information about the parameter.
When copying data from partitioned tables, data are not copied from leaf partitions that are external tables. A message is added to the log file when data are not copied.
If this clause is not specified and Greenplum Database attempts to copy data from a leaf partition that is an external table, an error is returned.
On successful completion, a COPY
command returns a command tag of the form, where <count>
identifies the number of rows copied:
COPY <count>
psql
prints this command tag only if the command was not COPY ... TO STDOUT
, or the equivalent psql
meta-command \copy ... to stdout
. This is to prevent confusing the command tag with the data that was just printed.
If running a COPY FROM
command in single row error isolation mode, Greenplum Database returns the following notice message if any rows were not loaded due to format errors. <count>
identifies the number of formatting errors and
NOTICE: found <count> data formatting errors (<n> or more input rows), rejected related input data
COPY TO
can only be used with plain tables, not with external tables or views, and does not copy rows from child tables or child partitions. For example, COPY <table> TO
copies the same rows as SELECT * FROM ONLY <table>
. However, you can write COPY (SELECT * FROM <viewname>) TO ...
to dump all of the rows in an inheritance hierarchy, partitioned table, or view.
Similarly, to copy data from a partitioned table with a leaf partition that is an external table, use an SQL query to select the data to copy. For example, if the table my_sales
contains a leaf partition that is an external table, this command COPY my_sales TO stdout
returns an error. This command sends the data to stdout
:
COPY (SELECT * from my_sales ) TO stdout;
COPY FROM
can be used with plain, foreign, or partitioned tables or with views that have INSTEAD OF INSERT triggers.
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.
If row-level security is enabled for the table, the relevant SELECT
policies will apply to COPY <table> TO
statements. Currently, COPY FROM
is not supported for tables with row-level security. Use equivalent INSERT
statements instead.
Files named in a COPY
command are read or written directly by the database server, not by the client application. Therefore, they must reside on or be accessible to the Greenplum Database coordinator host machine, not the client. They must be accessible to and readable or writable by the Greenplum Database system user (the user ID the server runs as), not the client. Only database superusers are permitted to name files with COPY
, because this allows reading or writing any file that the server has privileges to access.
Do not confuse COPY
with the psql
instruction \copy
. \copy
invokes COPY FROM STDIN
or COPY TO STDOUT
, and then fetches/stores the data in a file accessible to the psql
client. Thus, file accessibility and access rights depend on the client rather than the server when \copy
is used.
Always specify the file name used in COPY
as an absolute path. This is enforced by the server in the case of COPY TO
, but for COPY FROM
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 (normally the cluster's data directory), not the client's working directory
Executing a command with PROGRAM
might be restricted by the operating system's access control mechanisms.
COPY FROM
will invoke any triggers and check constraints on the destination table. However, it will not invoke rules. Note that in this release, violations of constraints are not evaluated for single row error isolation mode.
For identity columns, the COPY FROM
command will always write the column values provided in the input data, like the INSERT
option OVERRIDING SYSTEM VALUE
.
COPY
input and output is affected by DateStyle
. To ensure portability to other Greenplum Database installations that might use non-default DateStyle
settings, set DateStyle
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.
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 choose 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.
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 Greenplum Database versions. Also, you cannot run COPY FROM
in single row error isolation mode if the data is in binary format.
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.
When a COPY FROM...ON SEGMENT
command is run, the server configuration parameter gp_enable_segment_copy_checking controls whether Greenplum Database checks the table distribution policy (from the table DISTRIBUTED
clause) when data is copied into the table. The default is to check the distribution policy. An error is returned if the row of data violates the distribution policy for the segment instance.
Data from a table that is generated by a COPY TO...ON SEGMENT
command can be used to restore table data with COPY FROM...ON SEGMENT
. However, data restored to the segments is distributed according to the table distribution policy at the time the files were generated with the COPY TO
command. The COPY
command might return table distribution policy errors, if you attempt to restore table data and the table distribution policy was changed after the COPY FROM...ON SEGMENT
was run.
NoteIf you run
COPY FROM...ON SEGMENT
and the server configuration parametergp_enable_segment_copy_checking
isfalse
, manual redistribution of table data might be required. See theALTER TABLE
clauseWITH REORGANIZE
.
When you specify the LOG ERRORS
clause, Greenplum Database captures errors that occur while reading the external table data. You can view and manage the captured error log data.
Use the built-in SQL function gp_read_error_log('table\_name')
. It requires SELECT
privilege on table_name. This example displays the error log information for data loaded into table ext_expenses
with a COPY
command:
SELECT * from gp_read_error_log('ext_expenses');
For information about the error log format, see Viewing Bad Rows in the Error Log in the Greenplum Database Administrator Guide.
The function returns FALSE
if table_name does not exist.
If error log data exists for the specified table, the new error log data is appended to existing error log data. The error log information is not replicated to mirror segments.
Use the built-in SQL function gp_truncate_error_log('table\_name')
to delete the error log data for table_name. It requires the table owner privilege This example deletes the error log information captured when moving data into the table ext_expenses
:
SELECT gp_truncate_error_log('ext_expenses');
The function returns FALSE
if table_name does not exist.
Specify the *
wildcard character to delete error log information for existing tables in the current database. Specify the string *.*
to delete all database error log information, including error log information that was not deleted due to previous database issues. If *
is specified, database owner privilege is required. If *.*
is specified, operating system super-user privilege is required.
When a Greenplum Database user who is not a superuser 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. Greenplum Database 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.
A non-superuser can run only these types of COPY
commands:
COPY FROM
command where the source is stdin
COPY TO
command where the destination is stdout
For information about resource queues, refer to Using Resource Queues in the Greenplum Database Administrator Guide.
The file formats supported by COPY
include text, CSV, and binary.
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.
Backslash characters (\
) can be used in the COPY
data to quote data characters that might otherwise be taken as row or column delimiters. In particular, the following characters 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.
The specified null string is sent by COPY TO
without adding any backslashes; conversely, COPY FROM
matches the input against the null string before removing backslashes. Therefore, a null string such as \N
cannot be confused with the actual data value \N
(which would be represented as \\N
).
The following special backslash sequences are recognized by COPY FROM
:
Sequence | Represents |
---|---|
\b | Backspace (ASCII 8) |
\f | Form feed (ASCII 12) |
\n | Newline (ASCII 10) |
\r | Carriage return (ASCII 13) |
\t | Tab (ASCII 9) |
\v | Vertical tab (ASCII 11) |
\digits | Backslash followed by one to three octal digits specifies the byte with that numeric code |
\xdigits | Backslash x followed by one or two hex digits specifies the byte with that numeric code |
COPY TO
will never emit an octal or hex-digits backslash sequence, but it does use the other sequences listed above for those control characters.
Any other backslashed character that is not mentioned in the above table will be taken to represent itself. However, beware of adding backslashes unnecessarily, since that might accidentally produce a string matching the end-of-data marker (\.
) or the null string (\N
by default). These strings will be recognized before any other backslash processing is done.
Ensure that applications generating COPY
data convert data newlines and carriage returns to the \n
and \r
sequences respectively. It is currently 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, and 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).
All backslash sequences are interpreted after encoding conversion. The bytes specified with the octal and hex-digit backslash sequences must form valid characters in the database encoding.
COPY TO
will terminate each row with a Unix-style newline (\n
). Servers running on Microsoft Windows instead output carriage return/newline (\r\n
), but only for COPY
to a server file; for consistency across platforms, COPY TO STDOUT
always sends \n
regardless of server platform. COPY FROM
can handle lines ending with newlines, carriage returns, or carriage return/newlines. To reduce the risk of error due to un-backslashed newlines or carriage returns that were meant as data, COPY FROM
issues a warning if the line endings in the input are not all alike.
To summarize, two reserved characters have special meaning to COPY
:
\n
or 0x0a
), which is used to designate a new row in the data file.By default, the escape character for a text-format file is a \\
(backslash). If you want to use a different escape character, you can do so using the ESCAPE
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'
.
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. The following characters must also 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.
For example, suppose you have a table with three columns and you want to load the following three fields using COPY
.
Your designated delimiter_character is |
(pipe character), and your designated escape character is *
(asterisk). The formatted row in your data file would appear as follows:
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.
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 Greenplum Database 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. Greenplum Database 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.
NoteIn
CSV
format, all characters are significant. A quoted value surrounded by white space, or any characters other thanDELIMITER
, 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 Greenplum Database.
CSV
format will both recognize and produce CSV files with quoted values containing embedded carriage returns and line feeds. The files are not strictly one line per table row like text-format files.
NoteMany programs produce strange CSV files, so the file format is more a convention than a standard. You might encounter some files that cannot be imported using this mechanism, and
COPY
might produce files that other programs cannot process.
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 Greenplum Database 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.
The file header consists of 15 bytes of fixed fields, followed by a variable-length header extension area. The fixed fields are:
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.)
Each tuple begins with a 16-bit integer count of the number of fields in the tuple. (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.
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. Note that Greenplum Database no longer supports OID system columns.
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.
Copy a table to the client using the vertical bar (|
) as the field delimiter:
COPY country TO STDOUT (DELIMITER '|');
Copy data from a file into the country
table:
COPY country FROM '/home/usr1/sql/country_data';
Copy into a file just the countries whose names start with 'A':
COPY (SELECT * FROM country WHERE country_name LIKE 'A%') TO '/home/usr1/sql/a_list_countries.copy';
To copy into a compressed file, you can pipe the output through an external compression program:
COPY country TO PROGRAM 'gzip > /usr1/proj/bray/sql/country_data.gz';
Greenplum-specific examples START
Copy data from a file into the sales
table using single row error isolation mode and log errors:
COPY sales FROM '/home/usr1/sql/sales_data' LOG ERRORS
SEGMENT REJECT LIMIT 10 ROWS;
To copy segment data for later use, use the ON SEGMENT
clause. Use of the COPY ... TO ... ON SEGMENT
command takes the form:
COPY <table> TO '<SEG_DATA_DIR>/<gpdumpname><SEGID>_<suffix>' ON SEGMENT;
The <SEGID>
is required. However, you can substitute an absolute path for the <SEG_DATA_DIR>
string literal in the path.
When you pass in the string literal <SEG_DATA_DIR>
and <SEGID>
to COPY
, COPY
will fill in the appropriate values when the operation is run.
For example, if you have mytable
with the segments and mirror segments like this:
contentid | dbid | file segment location
0 | 1 | /home/usr1/data1/gpsegdir0
0 | 3 | /home/usr1/data_mirror1/gpsegdir0
1 | 4 | /home/usr1/data2/gpsegdir1
1 | 2 | /home/usr1/data_mirror2/gpsegdir1
running the command:
COPY mytable TO '<SEG_DATA_DIR>/mytable_backup<SEGID>.txt' ON SEGMENT;
would result in the following files:
/home/usr1/data1/gpsegdir0/mytable_backup0.txt
/home/usr1/data2/gpsegdir1/mytable_backup1.txt
The content ID in the first column is the identifier inserted into the file path (for example, gpsegdir0/mytable_backup0.txt
above) Files are created on the segment hosts, rather than on the coordinator, as they would be in a standard COPY
operation. No data files are created for the mirror segments when using ON SEGMENT
copying.
If an absolute path is specified, instead of <SEG_DATA_DIR>
, such as in the statement
COPY mytable TO '/tmp/gpdir/mytable_backup_<SEGID>.txt' ON SEGMENT;
files would be placed in /tmp/gpdir
on every segment. The gpfdist
tool can also be used to restore data files generated with COPY TO
with the ON SEGMENT
option if redistribution is necessary.
NoteTools such as
gpfdist
can be used to restore data. The backup/restore tools will not work with files that were manually generated withCOPY TO ON SEGMENT
.
This example uses a SELECT
statement to copy data to files on each segment:
COPY (SELECT * FROM testtbl) TO '/tmp/mytst<SEGID>' ON SEGMENT;
This example copies the data from the lineitem
table and uses the PROGRAM
clause to add the data to the /tmp/lineitem_program.csv
file with cat
utility. The file is placed on the Greenplum Database coordinator.
COPY lineitem TO PROGRAM 'cat > /tmp/lineitem.csv' CSV;
This example uses the PROGRAM
and ON SEGMENT
clauses to copy data to files on the segment hosts. On the segment hosts, the COPY
command replaces <SEGID>
with the segment content ID to create a file for each segment instance on the segment host.
COPY lineitem TO PROGRAM 'cat > /tmp/lineitem_program<SEGID>.csv' ON SEGMENT CSV;
This example uses the PROGRAM
and ON SEGMENT
clauses to copy data from files on the segment hosts. The COPY
command replaces <SEGID>
with the segment content ID when copying data from the files. On the segment hosts, there must be a file for each segment instance where the file name contains the segment content ID on the segment host.
COPY lineitem_4 FROM PROGRAM 'cat /tmp/lineitem_program<SEGID>.csv' ON SEGMENT CSV;
Greenplum-specific examples END
There is no COPY
statement in the SQL standard.
The following syntax was used in earlier versions of Greenplum Database and is still supported:
COPY <table_name> [(<column_name> [, ...])] FROM {'<filename>' | PROGRAM '<command>' | STDIN}
[ [WITH]
[ON SEGMENT]
[BINARY]
[DELIMITER [ AS ] '<delimiter_character>']
[NULL [ AS ] '<null string>']
[HEADER]
[ESCAPE [ AS ] '<escape>' | 'OFF']
[NEWLINE [ AS ] 'LF' | 'CR' | 'CRLF']
[CSV [QUOTE [ AS ] '<quote>']
[FORCE NOT NULL <column_name> [, ...]]
[FILL MISSING FIELDS]
[[LOG ERRORS]
SEGMENT REJECT LIMIT <count> [ROWS | PERCENT] ]
COPY { <table_name> [(<column_name> [, ...])] | (<query>)} TO {'<filename>' | PROGRAM '<command>' | STDOUT}
[ [WITH]
[ON SEGMENT]
[BINARY]
[DELIMITER [ AS ] 'delimiter_character']
[NULL [ AS ] 'null string']
[HEADER]
[ESCAPE [ AS ] '<escape>' | 'OFF']
[CSV [QUOTE [ AS ] 'quote']
[FORCE QUOTE <column_name> [, ...]] | * ]
[IGNORE EXTERNAL PARTITIONS ]
Note that in this syntax, BINARY
and CSV
are treated as independent keywords, not as arguments of a FORMAT
option.
Parent topic: SQL Commands