1COPY(7)                 PostgreSQL 9.2.24 Documentation                COPY(7)
2
3
4

NAME

6       COPY - copy data between a file and a table
7

SYNOPSIS

9       COPY table_name [ ( column_name [, ...] ) ]
10           FROM { 'filename' | STDIN }
11           [ [ WITH ] ( option [, ...] ) ]
12
13       COPY { table_name [ ( column_name [, ...] ) ] | ( query ) }
14           TO { 'filename' | STDOUT }
15           [ [ WITH ] ( option [, ...] ) ]
16
17       where option can be one of:
18
19           FORMAT format_name
20           OIDS [ boolean ]
21           DELIMITER 'delimiter_character'
22           NULL 'null_string'
23           HEADER [ boolean ]
24           QUOTE 'quote_character'
25           ESCAPE 'escape_character'
26           FORCE_QUOTE { ( column_name [, ...] ) | * }
27           FORCE_NOT_NULL ( column_name [, ...] )
28           ENCODING 'encoding_name'
29

DESCRIPTION

31       COPY moves data between PostgreSQL tables and standard file-system
32       files.  COPY TO copies the contents of a table to a file, while COPY
33       FROM copies data from a file to a table (appending the data to whatever
34       is in the table already).  COPY TO can also copy the results of a
35       SELECT query.
36
37       If a list of columns is specified, COPY will only copy the data in the
38       specified columns to or from the file. If there are any columns in the
39       table that are not in the column list, COPY FROM will insert the
40       default values for those columns.
41
42       COPY with a file name instructs the PostgreSQL server to directly read
43       from or write to a file. The file must be accessible to the server and
44       the name must be specified from the viewpoint of the server. When STDIN
45       or STDOUT is specified, data is transmitted via the connection between
46       the client and the server.
47

PARAMETERS

49       table_name
50           The name (optionally schema-qualified) of an existing table.
51
52       column_name
53           An optional list of columns to be copied. If no column list is
54           specified, all columns of the table will be copied.
55
56       query
57           A SELECT(7) or VALUES(7) command whose results are to be copied.
58           Note that parentheses are required around the query.
59
60       filename
61           The absolute path name of the input or output file. Windows users
62           might need to use an E'' string and double any backslashes used in
63           the path name.
64
65       STDIN
66           Specifies that input comes from the client application.
67
68       STDOUT
69           Specifies that output goes to the client application.
70
71       boolean
72           Specifies whether the selected option should be turned on or off.
73           You can write TRUE, ON, or 1 to enable the option, and FALSE, OFF,
74           or 0 to disable it. The boolean value can also be omitted, in which
75           case TRUE is assumed.
76
77       FORMAT
78           Selects the data format to be read or written: text, csv (Comma
79           Separated Values), or binary. The default is text.
80
81       OIDS
82           Specifies copying the OID for each row. (An error is raised if OIDS
83           is specified for a table that does not have OIDs, or in the case of
84           copying a query.)
85
86       DELIMITER
87           Specifies the character that separates columns within each row
88           (line) of the file. The default is a tab character in text format,
89           a comma in CSV format. This must be a single one-byte character.
90           This option is not allowed when using binary format.
91
92       NULL
93           Specifies the string that represents a null value. The default is
94           \N (backslash-N) in text format, and an unquoted empty string in
95           CSV format. You might prefer an empty string even in text format
96           for cases where you don't want to distinguish nulls from empty
97           strings. This option is not allowed when using binary format.
98
99               Note
100               When using COPY FROM, any data item that matches this string
101               will be stored as a null value, so you should make sure that
102               you use the same string as you used with COPY TO.
103
104       HEADER
105           Specifies that the file contains a header line with the names of
106           each column in the file. On output, the first line contains the
107           column names from the table, and on input, the first line is
108           ignored. This option is allowed only when using CSV format.
109
110       QUOTE
111           Specifies the quoting character to be used when a data value is
112           quoted. The default is double-quote. This must be a single one-byte
113           character. This option is allowed only when using CSV format.
114
115       ESCAPE
116           Specifies the character that should appear before a data character
117           that matches the QUOTE value. The default is the same as the QUOTE
118           value (so that the quoting character is doubled if it appears in
119           the data). This must be a single one-byte character. This option is
120           allowed only when using CSV format.
121
122       FORCE_QUOTE
123           Forces quoting to be used for all non-NULL values in each specified
124           column.  NULL output is never quoted. If * is specified, non-NULL
125           values will be quoted in all columns. This option is allowed only
126           in COPY TO, and only when using CSV format.
127
128       FORCE_NOT_NULL
129           Do not match the specified columns' values against the null string.
130           In the default case where the null string is empty, this means that
131           empty values will be read as zero-length strings rather than nulls,
132           even when they are not quoted. This option is allowed only in COPY
133           FROM, and only when using CSV format.
134
135       ENCODING
136           Specifies that the file is encoded in the encoding_name. If this
137           option is omitted, the current client encoding is used. See the
138           Notes below for more details.
139

OUTPUTS

141       On successful completion, a COPY command returns a command tag of the
142       form
143
144           COPY count
145
146       The count is the number of rows copied.
147

NOTES

149       COPY can only be used with plain tables, not with views. However, you
150       can write COPY (SELECT * FROM viewname) TO ....
151
152       COPY only deals with the specific table named; it does not copy data to
153       or from child tables. Thus for example COPY table TO shows the same
154       data as SELECT * FROM ONLY table. But COPY (SELECT * FROM table) TO ...
155       can be used to dump all of the data in an inheritance hierarchy.
156
157       You must have select privilege on the table whose values are read by
158       COPY TO, and insert privilege on the table into which values are
159       inserted by COPY FROM. It is sufficient to have column privileges on
160       the column(s) listed in the command.
161
162       Files named in a COPY command are read or written directly by the
163       server, not by the client application. Therefore, they must reside on
164       or be accessible to the database server machine, not the client. They
165       must be accessible to and readable or writable by the PostgreSQL user
166       (the user ID the server runs as), not the client.  COPY naming a file
167       is only allowed to database superusers, since it allows reading or
168       writing any file that the server has privileges to access.
169
170       Do not confuse COPY with the psql instruction \copy invokes COPY FROM
171       STDIN or COPY TO STDOUT, and then fetches/stores the data in a file
172       accessible to the psql client. Thus, file accessibility and access
173       rights depend on the client rather than the server when \copy is used.
174
175       It is recommended that the file name used in COPY always be specified
176       as an absolute path. This is enforced by the server in the case of COPY
177       TO, but for COPY FROM you do have the option of reading from a file
178       specified by a relative path. The path will be interpreted relative to
179       the working directory of the server process (normally the cluster's
180       data directory), not the client's working directory.
181
182       COPY FROM will invoke any triggers and check constraints on the
183       destination table. However, it will not invoke rules.
184
185       COPY input and output is affected by DateStyle. To ensure portability
186       to other PostgreSQL installations that might use non-default DateStyle
187       settings, DateStyle should be set to ISO before using COPY TO. It is
188       also a good idea to avoid dumping data with IntervalStyle set to
189       sql_standard, because negative interval values might be misinterpreted
190       by a server that has a different setting for IntervalStyle.
191
192       Input data is interpreted according to ENCODING option or the current
193       client encoding, and output data is encoded in ENCODING or the current
194       client encoding, even if the data does not pass through the client but
195       is read from or written to a file directly by the server.
196
197       COPY stops operation at the first error. This should not lead to
198       problems in the event of a COPY TO, but the target table will already
199       have received earlier rows in a COPY FROM. These rows will not be
200       visible or accessible, but they still occupy disk space. This might
201       amount to a considerable amount of wasted disk space if the failure
202       happened well into a large copy operation. You might wish to invoke
203       VACUUM to recover the wasted space.
204

FILE FORMATS

206   Text Format
207       When the text format is used, the data read or written is a text file
208       with one line per table row. Columns in a row are separated by the
209       delimiter character. The column values themselves are strings generated
210       by the output function, or acceptable to the input function, of each
211       attribute's data type. The specified null string is used in place of
212       columns that are null.  COPY FROM will raise an error if any line of
213       the input file contains more or fewer columns than are expected. If
214       OIDS is specified, the OID is read or written as the first column,
215       preceding the user data columns.
216
217       End of data can be represented by a single line containing just
218       backslash-period (\.). An end-of-data marker is not necessary when
219       reading from a file, since the end of file serves perfectly well; it is
220       needed only when copying data to or from client applications using
221       pre-3.0 client protocol.
222
223       Backslash characters (\) can be used in the COPY data to quote data
224       characters that might otherwise be taken as row or column delimiters.
225       In particular, the following characters must be preceded by a backslash
226       if they appear as part of a column value: backslash itself, newline,
227       carriage return, and the current delimiter character.
228
229       The specified null string is sent by COPY TO without adding any
230       backslashes; conversely, COPY FROM matches the input against the null
231       string before removing backslashes. Therefore, a null string such as \N
232       cannot be confused with the actual data value \N (which would be
233       represented as \\N).
234
235       The following special backslash sequences are recognized by COPY FROM:
236
237       ┌─────────┬────────────────────────────┐
238Sequence Represents                 
239       ├─────────┼────────────────────────────┤
240       │\b       │ Backspace (ASCII 8)        │
241       ├─────────┼────────────────────────────┤
242       │\f       │ Form feed (ASCII 12)       │
243       ├─────────┼────────────────────────────┤
244       │\n       │ Newline (ASCII 10)         │
245       ├─────────┼────────────────────────────┤
246       │\r       │ Carriage return (ASCII 13) │
247       ├─────────┼────────────────────────────┤
248       │\t       │ Tab (ASCII 9)              │
249       ├─────────┼────────────────────────────┤
250       │\v       │ Vertical tab (ASCII 11)    │
251       ├─────────┼────────────────────────────┤
252       │\digits  │ Backslash followed by one  │
253       │         │ to three octal digits      │
254       │         │ specifies                  │
255       │         │        the character with  │
256       │         │ that numeric code          │
257       ├─────────┼────────────────────────────┤
258       │\xdigits │ Backslash x followed by    │
259       │         │ one or two hex digits      │
260       │         │ specifies                  │
261       │         │        the character with  │
262       │         │ that numeric code          │
263       └─────────┴────────────────────────────┘
264       Presently, COPY TO will never emit an octal or hex-digits backslash
265       sequence, but it does use the other sequences listed above for those
266       control characters.
267
268       Any other backslashed character that is not mentioned in the above
269       table will be taken to represent itself. However, beware of adding
270       backslashes unnecessarily, since that might accidentally produce a
271       string matching the end-of-data marker (\.) or the null string (\N by
272       default). These strings will be recognized before any other backslash
273       processing is done.
274
275       It is strongly recommended that applications generating COPY data
276       convert data newlines and carriage returns to the \n and \r sequences
277       respectively. At present it is possible to represent a data carriage
278       return by a backslash and carriage return, and to represent a data
279       newline by a backslash and newline. However, these representations
280       might not be accepted in future releases. They are also highly
281       vulnerable to corruption if the COPY file is transferred across
282       different machines (for example, from Unix to Windows or vice versa).
283
284       COPY TO will terminate each row with a Unix-style newline (“\n”).
285       Servers running on Microsoft Windows instead output carriage
286       return/newline (“\r\n”), but only for COPY to a server file; for
287       consistency across platforms, COPY TO STDOUT always sends “\n”
288       regardless of server platform.  COPY FROM can handle lines ending with
289       newlines, carriage returns, or carriage return/newlines. To reduce the
290       risk of error due to un-backslashed newlines or carriage returns that
291       were meant as data, COPY FROM will complain if the line endings in the
292       input are not all alike.
293
294   CSV Format
295       This format option is used for importing and exporting the Comma
296       Separated Value (CSV) file format used by many other programs, such as
297       spreadsheets. Instead of the escaping rules used by PostgreSQL's
298       standard text format, it produces and recognizes the common CSV
299       escaping mechanism.
300
301       The values in each record are separated by the DELIMITER character. If
302       the value contains the delimiter character, the QUOTE character, the
303       NULL string, a carriage return, or line feed character, then the whole
304       value is prefixed and suffixed by the QUOTE character, and any
305       occurrence within the value of a QUOTE character or the ESCAPE
306       character is preceded by the escape character. You can also use
307       FORCE_QUOTE to force quotes when outputting non-NULL values in specific
308       columns.
309
310       The CSV format has no standard way to distinguish a NULL value from an
311       empty string.  PostgreSQL's COPY handles this by quoting. A NULL is
312       output as the NULL parameter string and is not quoted, while a non-NULL
313       value matching the NULL parameter string is quoted. For example, with
314       the default settings, a NULL is written as an unquoted empty string,
315       while an empty string data value is written with double quotes ("").
316       Reading values follows similar rules. You can use FORCE_NOT_NULL to
317       prevent NULL input comparisons for specific columns.
318
319       Because backslash is not a special character in the CSV format, \., the
320       end-of-data marker, could also appear as a data value. To avoid any
321       misinterpretation, a \.  data value appearing as a lone entry on a line
322       is automatically quoted on output, and on input, if quoted, is not
323       interpreted as the end-of-data marker. If you are loading a file
324       created by another application that has a single unquoted column and
325       might have a value of \., you might need to quote that value in the
326       input file.
327
328           Note
329           In CSV format, all characters are significant. A quoted value
330           surrounded by white space, or any characters other than DELIMITER,
331           will include those characters. This can cause errors if you import
332           data from a system that pads CSV lines with white space out to some
333           fixed width. If such a situation arises you might need to
334           preprocess the CSV file to remove the trailing white space, before
335           importing the data into PostgreSQL.
336
337           Note
338           CSV format will both recognize and produce CSV files with quoted
339           values containing embedded carriage returns and line feeds. Thus
340           the files are not strictly one line per table row like text-format
341           files.
342
343           Note
344           Many programs produce strange and occasionally perverse CSV files,
345           so the file format is more a convention than a standard. Thus you
346           might encounter some files that cannot be imported using this
347           mechanism, and COPY might produce files that other programs cannot
348           process.
349
350   Binary Format
351       The binary format option causes all data to be stored/read as binary
352       format rather than as text. It is somewhat faster than the text and CSV
353       formats, but a binary-format file is less portable across machine
354       architectures and PostgreSQL versions. Also, the binary format is very
355       data type specific; for example it will not work to output binary data
356       from a smallint column and read it into an integer column, even though
357       that would work fine in text format.
358
359       The binary file format consists of a file header, zero or more tuples
360       containing the row data, and a file trailer. Headers and data are in
361       network byte order.
362
363           Note
364           PostgreSQL releases before 7.4 used a different binary file format.
365
366       File Header
367           The file header consists of 15 bytes of fixed fields, followed by a
368           variable-length header extension area. The fixed fields are:
369
370           Signature
371               11-byte sequence PGCOPY\n\377\r\n\0 — note that the zero byte
372               is a required part of the signature. (The signature is designed
373               to allow easy identification of files that have been munged by
374               a non-8-bit-clean transfer. This signature will be changed by
375               end-of-line-translation filters, dropped zero bytes, dropped
376               high bits, or parity changes.)
377
378           Flags field
379               32-bit integer bit mask to denote important aspects of the file
380               format. Bits are numbered from 0 (LSB) to 31 (MSB). Note that
381               this field is stored in network byte order (most significant
382               byte first), as are all the integer fields used in the file
383               format. Bits 16-31 are reserved to denote critical file format
384               issues; a reader should abort if it finds an unexpected bit set
385               in this range. Bits 0-15 are reserved to signal
386               backwards-compatible format issues; a reader should simply
387               ignore any unexpected bits set in this range. Currently only
388               one flag bit is defined, and the rest must be zero:
389
390               Bit 16
391                   if 1, OIDs are included in the data; if 0, not
392
393           Header extension area length
394               32-bit integer, length in bytes of remainder of header, not
395               including self. Currently, this is zero, and the first tuple
396               follows immediately. Future changes to the format might allow
397               additional data to be present in the header. A reader should
398               silently skip over any header extension data it does not know
399               what to do with.
400
401           The header extension area is envisioned to contain a sequence of
402           self-identifying chunks. The flags field is not intended to tell
403           readers what is in the extension area. Specific design of header
404           extension contents is left for a later release.
405
406           This design allows for both backwards-compatible header additions
407           (add header extension chunks, or set low-order flag bits) and
408           non-backwards-compatible changes (set high-order flag bits to
409           signal such changes, and add supporting data to the extension area
410           if needed).
411
412       Tuples
413           Each tuple begins with a 16-bit integer count of the number of
414           fields in the tuple. (Presently, all tuples in a table will have
415           the same count, but that might not always be true.) Then, repeated
416           for each field in the tuple, there is a 32-bit length word followed
417           by that many bytes of field data. (The length word does not include
418           itself, and can be zero.) As a special case, -1 indicates a NULL
419           field value. No value bytes follow in the NULL case.
420
421           There is no alignment padding or any other extra data between
422           fields.
423
424           Presently, all data values in a binary-format file are assumed to
425           be in binary format (format code one). It is anticipated that a
426           future extension might add a header field that allows per-column
427           format codes to be specified.
428
429           To determine the appropriate binary format for the actual tuple
430           data you should consult the PostgreSQL source, in particular the
431           *send and *recv functions for each column's data type (typically
432           these functions are found in the src/backend/utils/adt/ directory
433           of the source distribution).
434
435           If OIDs are included in the file, the OID field immediately follows
436           the field-count word. It is a normal field except that it's not
437           included in the field-count. In particular it has a length word —
438           this will allow handling of 4-byte vs. 8-byte OIDs without too much
439           pain, and will allow OIDs to be shown as null if that ever proves
440           desirable.
441
442       File Trailer
443           The file trailer consists of a 16-bit integer word containing -1.
444           This is easily distinguished from a tuple's field-count word.
445
446           A reader should report an error if a field-count word is neither -1
447           nor the expected number of columns. This provides an extra check
448           against somehow getting out of sync with the data.
449

EXAMPLES

451       The following example copies a table to the client using the vertical
452       bar (|) as the field delimiter:
453
454           COPY country TO STDOUT (DELIMITER '|');
455
456       To copy data from a file into the country table:
457
458           COPY country FROM '/usr1/proj/bray/sql/country_data';
459
460       To copy into a file just the countries whose names start with 'A':
461
462           COPY (SELECT * FROM country WHERE country_name LIKE 'A%') TO '/usr1/proj/bray/sql/a_list_countries.copy';
463
464       Here is a sample of data suitable for copying into a table from STDIN:
465
466           AF      AFGHANISTAN
467           AL      ALBANIA
468           DZ      ALGERIA
469           ZM      ZAMBIA
470           ZW      ZIMBABWE
471
472       Note that the white space on each line is actually a tab character.
473
474       The following is the same data, output in binary format. The data is
475       shown after filtering through the Unix utility od -c. The table has
476       three columns; the first has type char(2), the second has type text,
477       and the third has type integer. All the rows have a null value in the
478       third column.
479
480           0000000   P   G   C   O   P   Y  \n 377  \r  \n  \0  \0  \0  \0  \0  \0
481           0000020  \0  \0  \0  \0 003  \0  \0  \0 002   A   F  \0  \0  \0 013   A
482           0000040   F   G   H   A   N   I   S   T   A   N 377 377 377 377  \0 003
483           0000060  \0  \0  \0 002   A   L  \0  \0  \0 007   A   L   B   A   N   I
484           0000100   A 377 377 377 377  \0 003  \0  \0  \0 002   D   Z  \0  \0  \0
485           0000120 007   A   L   G   E   R   I   A 377 377 377 377  \0 003  \0  \0
486           0000140  \0 002   Z   M  \0  \0  \0 006   Z   A   M   B   I   A 377 377
487           0000160 377 377  \0 003  \0  \0  \0 002   Z   W  \0  \0  \0  \b   Z   I
488           0000200   M   B   A   B   W   E 377 377 377 377 377 377
489

COMPATIBILITY

491       There is no COPY statement in the SQL standard.
492
493       The following syntax was used before PostgreSQL version 9.0 and is
494       still supported:
495
496           COPY table_name [ ( column_name [, ...] ) ]
497               FROM { 'filename' | STDIN }
498               [ [ WITH ]
499                     [ BINARY ]
500                     [ OIDS ]
501                     [ DELIMITER [ AS ] 'delimiter' ]
502                     [ NULL [ AS ] 'null string' ]
503                     [ CSV [ HEADER ]
504                           [ QUOTE [ AS ] 'quote' ]
505                           [ ESCAPE [ AS ] 'escape' ]
506                           [ FORCE NOT NULL column_name [, ...] ] ] ]
507
508           COPY { table_name [ ( column_name [, ...] ) ] | ( query ) }
509               TO { 'filename' | STDOUT }
510               [ [ WITH ]
511                     [ BINARY ]
512                     [ OIDS ]
513                     [ DELIMITER [ AS ] 'delimiter' ]
514                     [ NULL [ AS ] 'null string' ]
515                     [ CSV [ HEADER ]
516                           [ QUOTE [ AS ] 'quote' ]
517                           [ ESCAPE [ AS ] 'escape' ]
518                           [ FORCE QUOTE { column_name [, ...] | * } ] ] ]
519
520       Note that in this syntax, BINARY and CSV are treated as independent
521       keywords, not as arguments of a FORMAT option.
522
523       The following syntax was used before PostgreSQL version 7.3 and is
524       still supported:
525
526           COPY [ BINARY ] table_name [ WITH OIDS ]
527               FROM { 'filename' | STDIN }
528               [ [USING] DELIMITERS 'delimiter' ]
529               [ WITH NULL AS 'null string' ]
530
531           COPY [ BINARY ] table_name [ WITH OIDS ]
532               TO { 'filename' | STDOUT }
533               [ [USING] DELIMITERS 'delimiter' ]
534               [ WITH NULL AS 'null string' ]
535
536
537
538
539PostgreSQL 9.2.24                 2017-11-06                           COPY(7)
Impressum