1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
|
'\" t
.\" Title: COPY
.\" Author: The PostgreSQL Global Development Group
.\" Generator: DocBook XSL Stylesheets vsnapshot <http://docbook.sf.net/>
.\" Date: 2024
.\" Manual: PostgreSQL 16.2 Documentation
.\" Source: PostgreSQL 16.2
.\" Language: English
.\"
.TH "COPY" "7" "2024" "PostgreSQL 16.2" "PostgreSQL 16.2 Documentation"
.\" -----------------------------------------------------------------
.\" * Define some portability stuff
.\" -----------------------------------------------------------------
.\" ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
.\" http://bugs.debian.org/507673
.\" http://lists.gnu.org/archive/html/groff/2009-02/msg00013.html
.\" ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
.ie \n(.g .ds Aq \(aq
.el .ds Aq '
.\" -----------------------------------------------------------------
.\" * set default formatting
.\" -----------------------------------------------------------------
.\" disable hyphenation
.nh
.\" disable justification (adjust text to left margin only)
.ad l
.\" -----------------------------------------------------------------
.\" * MAIN CONTENT STARTS HERE *
.\" -----------------------------------------------------------------
.SH "NAME"
COPY \- copy data between a file and a table
.SH "SYNOPSIS"
.sp
.nf
COPY \fItable_name\fR [ ( \fIcolumn_name\fR [, \&.\&.\&.] ) ]
FROM { \*(Aq\fIfilename\fR\*(Aq | PROGRAM \*(Aq\fIcommand\fR\*(Aq | STDIN }
[ [ WITH ] ( \fIoption\fR [, \&.\&.\&.] ) ]
[ WHERE \fIcondition\fR ]
COPY { \fItable_name\fR [ ( \fIcolumn_name\fR [, \&.\&.\&.] ) ] | ( \fIquery\fR ) }
TO { \*(Aq\fIfilename\fR\*(Aq | PROGRAM \*(Aq\fIcommand\fR\*(Aq | STDOUT }
[ [ WITH ] ( \fIoption\fR [, \&.\&.\&.] ) ]
where \fIoption\fR can be one of:
FORMAT \fIformat_name\fR
FREEZE [ \fIboolean\fR ]
DELIMITER \*(Aq\fIdelimiter_character\fR\*(Aq
NULL \*(Aq\fInull_string\fR\*(Aq
DEFAULT \*(Aq\fIdefault_string\fR\*(Aq
HEADER [ \fIboolean\fR | MATCH ]
QUOTE \*(Aq\fIquote_character\fR\*(Aq
ESCAPE \*(Aq\fIescape_character\fR\*(Aq
FORCE_QUOTE { ( \fIcolumn_name\fR [, \&.\&.\&.] ) | * }
FORCE_NOT_NULL ( \fIcolumn_name\fR [, \&.\&.\&.] )
FORCE_NULL ( \fIcolumn_name\fR [, \&.\&.\&.] )
ENCODING \*(Aq\fIencoding_name\fR\*(Aq
.fi
.SH "DESCRIPTION"
.PP
\fBCOPY\fR
moves data between
PostgreSQL
tables and standard file\-system files\&.
\fBCOPY TO\fR
copies the contents of a table
\fIto\fR
a file, while
\fBCOPY FROM\fR
copies data
\fIfrom\fR
a file to a table (appending the data to whatever is in the table already)\&.
\fBCOPY TO\fR
can also copy the results of a
\fBSELECT\fR
query\&.
.PP
If a column list is specified,
\fBCOPY TO\fR
copies only the data in the specified columns to the file\&. For
\fBCOPY FROM\fR, each field in the file is inserted, in order, into the specified column\&. Table columns not specified in the
\fBCOPY FROM\fR
column list will receive their default values\&.
.PP
\fBCOPY\fR
with a file name instructs the
PostgreSQL
server to directly read from or write to a file\&. The file must be accessible by the
PostgreSQL
user (the user ID the server runs as) and the name must be specified from the viewpoint of the server\&. When
PROGRAM
is specified, the server executes 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
PostgreSQL
user\&. When
STDIN
or
STDOUT
is specified, data is transmitted via the connection between the client and the server\&.
.PP
Each backend running
\fBCOPY\fR
will report its progress in the
pg_stat_progress_copy
view\&. See
Section\ \&28.4.3
for details\&.
.SH "PARAMETERS"
.PP
\fItable_name\fR
.RS 4
The name (optionally schema\-qualified) of an existing table\&.
.RE
.PP
\fIcolumn_name\fR
.RS 4
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\&.
.RE
.PP
\fIquery\fR
.RS 4
A
\fBSELECT\fR,
\fBVALUES\fR,
\fBINSERT\fR,
\fBUPDATE\fR, or
\fBDELETE\fR
command whose results are to be copied\&. Note that parentheses are required around the query\&.
.sp
For
\fBINSERT\fR,
\fBUPDATE\fR
and
\fBDELETE\fR
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\&.
.RE
.PP
\fIfilename\fR
.RS 4
The path name of the input or output file\&. An input file name can be an absolute or relative path, but an output file name must be an absolute path\&. Windows users might need to use an
E\*(Aq\*(Aq
string and double any backslashes used in the path name\&.
.RE
.PP
PROGRAM
.RS 4
A command to execute\&. In
\fBCOPY FROM\fR, the input is read from standard output of the command, and in
\fBCOPY TO\fR, the output is written to the standard input of the command\&.
.sp
Note that the command is invoked by the shell, so if you need to pass any arguments that come from an untrusted source, you must be careful to strip or escape any special characters that might have a special meaning for the shell\&. For security reasons, it is best to use a fixed command string, or at least avoid including any user input in it\&.
.RE
.PP
STDIN
.RS 4
Specifies that input comes from the client application\&.
.RE
.PP
STDOUT
.RS 4
Specifies that output goes to the client application\&.
.RE
.PP
\fIboolean\fR
.RS 4
Specifies whether the selected option should be turned on or off\&. You can write
TRUE,
ON, or
1
to enable the option, and
FALSE,
OFF, or
0
to disable it\&. The
\fIboolean\fR
value can also be omitted, in which case
TRUE
is assumed\&.
.RE
.PP
FORMAT
.RS 4
Selects the data format to be read or written:
text,
csv
(Comma Separated Values), or
binary\&. The default is
text\&.
.RE
.PP
FREEZE
.RS 4
Requests copying the data with rows already frozen, just as they would be after running the
\fBVACUUM FREEZE\fR
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 currently not possible to perform a
\fBCOPY FREEZE\fR
on a partitioned table\&.
.sp
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 should be aware of the potential problems this might cause\&.
.RE
.PP
DELIMITER
.RS 4
Specifies the character that separates columns within each row (line) of the file\&. The default is a tab character in text format, a comma in
CSV
format\&. This must be a single one\-byte character\&. This option is not allowed when using
binary
format\&.
.RE
.PP
NULL
.RS 4
Specifies the string that represents a null value\&. The default is
\eN
(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\*(Aqt want to distinguish nulls from empty strings\&. This option is not allowed when using
binary
format\&.
.if n \{\
.sp
.\}
.RS 4
.it 1 an-trap
.nr an-no-space-flag 1
.nr an-break-flag 1
.br
.ps +1
\fBNote\fR
.ps -1
.br
When using
\fBCOPY FROM\fR, 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
\fBCOPY TO\fR\&.
.sp .5v
.RE
.RE
.PP
DEFAULT
.RS 4
Specifies the string that represents a default value\&. Each time the string is found in the input file, the default value of the corresponding column will be used\&. This option is allowed only in
\fBCOPY FROM\fR, and only when not using
binary
format\&.
.RE
.PP
HEADER
.RS 4
Specifies that the 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\&. On input, the first line is discarded when this option is set to
true
(or equivalent Boolean value)\&. If this option is set to
MATCH, the number and names of the columns in the header line must match the actual column names of the table, in order; otherwise an error is raised\&. This option is not allowed when using
binary
format\&. The
MATCH
option is only valid for
\fBCOPY FROM\fR
commands\&.
.RE
.PP
QUOTE
.RS 4
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\&.
.RE
.PP
ESCAPE
.RS 4
Specifies the character that should appear before a data character that matches the
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\&.
.RE
.PP
FORCE_QUOTE
.RS 4
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 in
\fBCOPY TO\fR, and only when using
CSV
format\&.
.RE
.PP
FORCE_NOT_NULL
.RS 4
Do not match the specified columns\*(Aq 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
\fBCOPY FROM\fR, and only when using
CSV
format\&.
.RE
.PP
FORCE_NULL
.RS 4
Match the specified columns\*(Aq 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 into NULL\&. This option is allowed only in
\fBCOPY FROM\fR, and only when using
CSV
format\&.
.RE
.PP
ENCODING
.RS 4
Specifies that the file is encoded in the
\fIencoding_name\fR\&. If this option is omitted, the current client encoding is used\&. See the Notes below for more details\&.
.RE
.PP
WHERE
.RS 4
The optional
WHERE
clause has the general form
.sp
.if n \{\
.RS 4
.\}
.nf
WHERE \fIcondition\fR
.fi
.if n \{\
.RE
.\}
.sp
where
\fIcondition\fR
is any expression that evaluates to a result of type
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\&.
.sp
Currently, subqueries are not allowed in
WHERE
expressions, and the evaluation does not see any changes made by the
\fBCOPY\fR
itself (this matters when the expression contains calls to
VOLATILE
functions)\&.
.RE
.SH "OUTPUTS"
.PP
On successful completion, a
\fBCOPY\fR
command returns a command tag of the form
.sp
.if n \{\
.RS 4
.\}
.nf
COPY \fIcount\fR
.fi
.if n \{\
.RE
.\}
.sp
The
\fIcount\fR
is the number of rows copied\&.
.if n \{\
.sp
.\}
.RS 4
.it 1 an-trap
.nr an-no-space-flag 1
.nr an-break-flag 1
.br
.ps +1
\fBNote\fR
.ps -1
.br
.PP
psql
will print this command tag only if the command was not
COPY \&.\&.\&. TO STDOUT, or the equivalent
psql
meta\-command
\ecopy \&.\&.\&. to stdout\&. This is to prevent confusing the command tag with the data that was just printed\&.
.sp .5v
.RE
.SH "NOTES"
.PP
\fBCOPY TO\fR
can be used only with plain tables, not views, and does not copy rows from child tables or child partitions\&. For example,
COPY \fItable\fR TO
copies the same rows as
SELECT * FROM ONLY \fItable\fR\&. The syntax
COPY (SELECT * FROM \fItable\fR) TO \&.\&.\&.
can be used to dump all of the rows in an inheritance hierarchy, partitioned table, or view\&.
.PP
\fBCOPY FROM\fR
can be used with plain, foreign, or partitioned tables or with views that have
INSTEAD OF INSERT
triggers\&.
.PP
You must have select privilege on the table whose values are read by
\fBCOPY TO\fR, and insert privilege on the table into which values are inserted by
\fBCOPY FROM\fR\&. It is sufficient to have column privileges on the column(s) listed in the command\&.
.PP
If row\-level security is enabled for the table, the relevant
\fBSELECT\fR
policies will apply to
COPY \fItable\fR TO
statements\&. Currently,
\fBCOPY FROM\fR
is not supported for tables with row\-level security\&. Use equivalent
\fBINSERT\fR
statements instead\&.
.PP
Files named in a
\fBCOPY\fR
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
PostgreSQL
user (the user ID the server runs as), not the client\&. Similarly, the command specified with
PROGRAM
is executed directly by the server, not by the client application, must be executable by the
PostgreSQL
user\&.
\fBCOPY\fR
naming a file or command is only allowed to database superusers or users who are granted one of the roles
pg_read_server_files,
pg_write_server_files, or
pg_execute_server_program, since it allows reading or writing any file or running a program that the server has privileges to access\&.
.PP
Do not confuse
\fBCOPY\fR
with the
psql
instruction
\fB\ecopy\fR\&.
\fB\ecopy\fR
invokes
\fBCOPY FROM STDIN\fR
or
\fBCOPY TO STDOUT\fR, 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
\fB\ecopy\fR
is used\&.
.PP
It is recommended that the file name used in
\fBCOPY\fR
always be specified as an absolute path\&. This is enforced by the server in the case of
\fBCOPY TO\fR, but for
\fBCOPY FROM\fR
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\*(Aqs data directory), not the client\*(Aqs working directory\&.
.PP
Executing a command with
PROGRAM
might be restricted by the operating system\*(Aqs access control mechanisms, such as SELinux\&.
.PP
\fBCOPY FROM\fR
will invoke any triggers and check constraints on the destination table\&. However, it will not invoke rules\&.
.PP
For identity columns, the
\fBCOPY FROM\fR
command will always write the column values provided in the input data, like the
\fBINSERT\fR
option
OVERRIDING SYSTEM VALUE\&.
.PP
\fBCOPY\fR
input and output is affected by
\fIDateStyle\fR\&. To ensure portability to other
PostgreSQL
installations that might use non\-default
\fIDateStyle\fR
settings,
\fIDateStyle\fR
should be set to
ISO
before using
\fBCOPY TO\fR\&. It is also a good idea to avoid dumping data with
\fIIntervalStyle\fR
set to
sql_standard, because negative interval values might be misinterpreted by a server that has a different setting for
\fIIntervalStyle\fR\&.
.PP
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\&.
.PP
\fBCOPY\fR
stops operation at the first error\&. This should not lead to problems in the event of a
\fBCOPY TO\fR, but the target table will already have received earlier rows in a
\fBCOPY FROM\fR\&. These rows will not be visible or accessible, but they still occupy disk space\&. This might amount to a considerable amount of wasted disk space if the failure happened well into a large copy operation\&. You might wish to invoke
\fBVACUUM\fR
to recover the wasted space\&.
.PP
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\&.
.SH "FILE FORMATS"
.SS "Text Format"
.PP
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\&. The column values themselves are strings generated by the output function, or acceptable to the input function, of each attribute\*(Aqs data type\&. The specified null string is used in place of columns that are null\&.
\fBCOPY FROM\fR
will raise an error if any line of the input file contains more or fewer columns than are expected\&.
.PP
End of data can be represented by a single line containing just backslash\-period (\e\&.)\&. 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\&.
.PP
Backslash characters (\e) can be used in the
\fBCOPY\fR
data to quote data characters that might otherwise be taken as row or column delimiters\&. In particular, the following characters
\fImust\fR
be preceded by a backslash if they appear as part of a column value: backslash itself, newline, carriage return, and the current delimiter character\&.
.PP
The specified null string is sent by
\fBCOPY TO\fR
without adding any backslashes; conversely,
\fBCOPY FROM\fR
matches the input against the null string before removing backslashes\&. Therefore, a null string such as
\eN
cannot be confused with the actual data value
\eN
(which would be represented as
\e\eN)\&.
.PP
The following special backslash sequences are recognized by
\fBCOPY FROM\fR:
.TS
allbox tab(:);
lB lB.
T{
Sequence
T}:T{
Represents
T}
.T&
l l
l l
l l
l l
l l
l l
l l
l l.
T{
\eb
T}:T{
Backspace (ASCII 8)
T}
T{
\ef
T}:T{
Form feed (ASCII 12)
T}
T{
\en
T}:T{
Newline (ASCII 10)
T}
T{
\er
T}:T{
Carriage return (ASCII 13)
T}
T{
\et
T}:T{
Tab (ASCII 9)
T}
T{
\ev
T}:T{
Vertical tab (ASCII 11)
T}
T{
\e\fIdigits\fR
T}:T{
Backslash followed by one to three octal digits specifies
the byte with that numeric code
T}
T{
\ex\fIdigits\fR
T}:T{
Backslash x followed by one or two hex digits specifies
the byte with that numeric code
T}
.TE
.sp 1
Presently,
\fBCOPY TO\fR
will never emit an octal or hex\-digits backslash sequence, but it does use the other sequences listed above for those control characters\&.
.PP
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 (\e\&.) or the null string (\eN
by default)\&. These strings will be recognized before any other backslash processing is done\&.
.PP
It is strongly recommended that applications generating
\fBCOPY\fR
data convert data newlines and carriage returns to the
\en
and
\er
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
\fBCOPY\fR
file is transferred across different machines (for example, from Unix to Windows or vice versa)\&.
.PP
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\&.
.PP
\fBCOPY TO\fR
will terminate each row with a Unix\-style newline (\(lq\en\(rq)\&. Servers running on Microsoft Windows instead output carriage return/newline (\(lq\er\en\(rq), but only for
\fBCOPY\fR
to a server file; for consistency across platforms,
\fBCOPY TO STDOUT\fR
always sends
\(lq\en\(rq
regardless of server platform\&.
\fBCOPY FROM\fR
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,
\fBCOPY FROM\fR
will complain if the line endings in the input are not all alike\&.
.SS "CSV Format"
.PP
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
PostgreSQL\*(Aqs standard text format, it produces and recognizes the common
CSV
escaping mechanism\&.
.PP
The values in each record are separated by the
DELIMITER
character\&. If the value contains the delimiter character, the
QUOTE
character, the
NULL
string, a carriage return, or line feed character, then the whole value is prefixed and suffixed by the
QUOTE
character, and any occurrence within the value of a
QUOTE
character or the
ESCAPE
character is preceded by the escape character\&. You can also use
FORCE_QUOTE
to force quotes when outputting non\-NULL
values in specific columns\&.
.PP
The
CSV
format has no standard way to distinguish a
NULL
value from an empty string\&.
PostgreSQL\*(Aqs
\fBCOPY\fR
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
parameter 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\&.
.PP
Because backslash is not a special character in the
CSV
format,
\e\&., the end\-of\-data marker, could also appear as a data value\&. To avoid any misinterpretation, a
\e\&.
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
\e\&., you might need to quote that value in the input file\&.
.if n \{\
.sp
.\}
.RS 4
.it 1 an-trap
.nr an-no-space-flag 1
.nr an-break-flag 1
.br
.ps +1
\fBNote\fR
.ps -1
.br
.PP
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
PostgreSQL\&.
.sp .5v
.RE
.if n \{\
.sp
.\}
.RS 4
.it 1 an-trap
.nr an-no-space-flag 1
.nr an-break-flag 1
.br
.ps +1
\fBNote\fR
.ps -1
.br
.PP
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\&.
.sp .5v
.RE
.if n \{\
.sp
.\}
.RS 4
.it 1 an-trap
.nr an-no-space-flag 1
.nr an-break-flag 1
.br
.ps +1
\fBNote\fR
.ps -1
.br
.PP
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
\fBCOPY\fR
might produce files that other programs cannot process\&.
.sp .5v
.RE
.SS "Binary Format"
.PP
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
PostgreSQL
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\&.
.PP
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\&.
.if n \{\
.sp
.\}
.RS 4
.it 1 an-trap
.nr an-no-space-flag 1
.nr an-break-flag 1
.br
.ps +1
\fBNote\fR
.ps -1
.br
.PP
PostgreSQL
releases before 7\&.4 used a different binary file format\&.
.sp .5v
.RE
.sp
.it 1 an-trap
.nr an-no-space-flag 1
.nr an-break-flag 1
.br
.ps +1
\fBFile Header\fR
.RS 4
.PP
The file header consists of 15 bytes of fixed fields, followed by a variable\-length header extension area\&. The fixed fields are:
.PP
Signature
.RS 4
11\-byte sequence
PGCOPY\en\e377\er\en\e0
\(em 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\&.)
.RE
.PP
Flags field
.RS 4
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\(en31 are reserved to denote critical file format issues; a reader should abort if it finds an unexpected bit set in this range\&. Bits 0\(en15 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:
.PP
Bit 16
.RS 4
If 1, OIDs are included in the data; if 0, not\&. Oid system columns are not supported in
PostgreSQL
anymore, but the format still contains the indicator\&.
.RE
.RE
.PP
Header extension area length
.RS 4
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\&.
.RE
.PP
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\&.
.PP
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)\&.
.RE
.sp
.it 1 an-trap
.nr an-no-space-flag 1
.nr an-break-flag 1
.br
.ps +1
\fBTuples\fR
.RS 4
.PP
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\&.
.PP
There is no alignment padding or any other extra data between fields\&.
.PP
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 might add a header field that allows per\-column format codes to be specified\&.
.PP
To determine the appropriate binary format for the actual tuple data you should consult the
PostgreSQL
source, in particular the
\fB*send\fR
and
\fB*recv\fR
functions for each column\*(Aqs data type (typically these functions are found in the
src/backend/utils/adt/
directory of the source distribution)\&.
.PP
If OIDs are included in the file, the OID field immediately follows the field\-count word\&. It is a normal field except that it\*(Aqs not included in the field\-count\&. Note that oid system columns are not supported in current versions of
PostgreSQL\&.
.RE
.sp
.it 1 an-trap
.nr an-no-space-flag 1
.nr an-break-flag 1
.br
.ps +1
\fBFile Trailer\fR
.RS 4
.PP
The file trailer consists of a 16\-bit integer word containing \-1\&. This is easily distinguished from a tuple\*(Aqs field\-count word\&.
.PP
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\&.
.RE
.SH "EXAMPLES"
.PP
The following example copies a table to the client using the vertical bar (|) as the field delimiter:
.sp
.if n \{\
.RS 4
.\}
.nf
COPY country TO STDOUT (DELIMITER \*(Aq|\*(Aq);
.fi
.if n \{\
.RE
.\}
.PP
To copy data from a file into the
country
table:
.sp
.if n \{\
.RS 4
.\}
.nf
COPY country FROM \*(Aq/usr1/proj/bray/sql/country_data\*(Aq;
.fi
.if n \{\
.RE
.\}
.PP
To copy into a file just the countries whose names start with \*(AqA\*(Aq:
.sp
.if n \{\
.RS 4
.\}
.nf
COPY (SELECT * FROM country WHERE country_name LIKE \*(AqA%\*(Aq) TO \*(Aq/usr1/proj/bray/sql/a_list_countries\&.copy\*(Aq;
.fi
.if n \{\
.RE
.\}
.PP
To copy into a compressed file, you can pipe the output through an external compression program:
.sp
.if n \{\
.RS 4
.\}
.nf
COPY country TO PROGRAM \*(Aqgzip > /usr1/proj/bray/sql/country_data\&.gz\*(Aq;
.fi
.if n \{\
.RE
.\}
.PP
Here is a sample of data suitable for copying into a table from
STDIN:
.sp
.if n \{\
.RS 4
.\}
.nf
AF AFGHANISTAN
AL ALBANIA
DZ ALGERIA
ZM ZAMBIA
ZW ZIMBABWE
.fi
.if n \{\
.RE
.\}
.sp
Note that the white space on each line is actually a tab character\&.
.PP
The following is the same data, output in binary format\&. The data is shown after filtering through the Unix utility
\fBod \-c\fR\&. The table has three columns; the first has type
char(2), the second has type
text, and the third has type
integer\&. All the rows have a null value in the third column\&.
.sp
.if n \{\
.RS 4
.\}
.nf
0000000 P G C O P Y \en 377 \er \en \e0 \e0 \e0 \e0 \e0 \e0
0000020 \e0 \e0 \e0 \e0 003 \e0 \e0 \e0 002 A F \e0 \e0 \e0 013 A
0000040 F G H A N I S T A N 377 377 377 377 \e0 003
0000060 \e0 \e0 \e0 002 A L \e0 \e0 \e0 007 A L B A N I
0000100 A 377 377 377 377 \e0 003 \e0 \e0 \e0 002 D Z \e0 \e0 \e0
0000120 007 A L G E R I A 377 377 377 377 \e0 003 \e0 \e0
0000140 \e0 002 Z M \e0 \e0 \e0 006 Z A M B I A 377 377
0000160 377 377 \e0 003 \e0 \e0 \e0 002 Z W \e0 \e0 \e0 \eb Z I
0000200 M B A B W E 377 377 377 377 377 377
.fi
.if n \{\
.RE
.\}
.SH "COMPATIBILITY"
.PP
There is no
\fBCOPY\fR
statement in the SQL standard\&.
.PP
The following syntax was used before
PostgreSQL
version 9\&.0 and is still supported:
.sp
.if n \{\
.RS 4
.\}
.nf
COPY \fItable_name\fR [ ( \fIcolumn_name\fR [, \&.\&.\&.] ) ]
FROM { \*(Aq\fIfilename\fR\*(Aq | STDIN }
[ [ WITH ]
[ BINARY ]
[ DELIMITER [ AS ] \*(Aq\fIdelimiter_character\fR\*(Aq ]
[ NULL [ AS ] \*(Aq\fInull_string\fR\*(Aq ]
[ CSV [ HEADER ]
[ QUOTE [ AS ] \*(Aq\fIquote_character\fR\*(Aq ]
[ ESCAPE [ AS ] \*(Aq\fIescape_character\fR\*(Aq ]
[ FORCE NOT NULL \fIcolumn_name\fR [, \&.\&.\&.] ] ] ]
COPY { \fItable_name\fR [ ( \fIcolumn_name\fR [, \&.\&.\&.] ) ] | ( \fIquery\fR ) }
TO { \*(Aq\fIfilename\fR\*(Aq | STDOUT }
[ [ WITH ]
[ BINARY ]
[ DELIMITER [ AS ] \*(Aq\fIdelimiter_character\fR\*(Aq ]
[ NULL [ AS ] \*(Aq\fInull_string\fR\*(Aq ]
[ CSV [ HEADER ]
[ QUOTE [ AS ] \*(Aq\fIquote_character\fR\*(Aq ]
[ ESCAPE [ AS ] \*(Aq\fIescape_character\fR\*(Aq ]
[ FORCE QUOTE { \fIcolumn_name\fR [, \&.\&.\&.] | * } ] ] ]
.fi
.if n \{\
.RE
.\}
.sp
Note that in this syntax,
BINARY
and
CSV
are treated as independent keywords, not as arguments of a
FORMAT
option\&.
.PP
The following syntax was used before
PostgreSQL
version 7\&.3 and is still supported:
.sp
.if n \{\
.RS 4
.\}
.nf
COPY [ BINARY ] \fItable_name\fR
FROM { \*(Aq\fIfilename\fR\*(Aq | STDIN }
[ [USING] DELIMITERS \*(Aq\fIdelimiter_character\fR\*(Aq ]
[ WITH NULL AS \*(Aq\fInull_string\fR\*(Aq ]
COPY [ BINARY ] \fItable_name\fR
TO { \*(Aq\fIfilename\fR\*(Aq | STDOUT }
[ [USING] DELIMITERS \*(Aq\fIdelimiter_character\fR\*(Aq ]
[ WITH NULL AS \*(Aq\fInull_string\fR\*(Aq ]
.fi
.if n \{\
.RE
.\}
.SH "SEE ALSO"
Section\ \&28.4.3
|