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
|
<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.0 Transitional//EN">
<HTML
><HEAD
><TITLE
> COPY
</TITLE
><META
NAME="GENERATOR"
CONTENT="Modular DocBook HTML Stylesheet version 1.19"><LINK
REL="HOME"
TITLE="PostgreSQL User's Guide"
HREF="user.html"><LINK
REL="UP"
TITLE="SQL Commands"
HREF="sql-commands.html"><LINK
REL="PREVIOUS"
TITLE=" COMMIT
"
HREF="sql-commit.html"><LINK
REL="NEXT"
TITLE=" CREATE AGGREGATE
"
HREF="sql-createaggregate.html"></HEAD
><BODY
BGCOLOR="#FFFFFF"
TEXT="#000000"
><DIV
CLASS="NAVHEADER"
><TABLE
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TH
COLSPAN="3"
ALIGN="center"
>PostgreSQL User's Guide</TH
></TR
><TR
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="bottom"
><A
HREF="sql-commit.html"
>Prev</A
></TD
><TD
WIDTH="80%"
ALIGN="center"
VALIGN="bottom"
></TD
><TD
WIDTH="10%"
ALIGN="right"
VALIGN="bottom"
><A
HREF="sql-createaggregate.html"
>Next</A
></TD
></TR
></TABLE
><HR
ALIGN="LEFT"
WIDTH="100%"></DIV
><H1
>COPY</H1
><DIV
CLASS="REFNAMEDIV"
><H2
>Name</H2
> COPY
— Copies data between files and tables
</DIV
><DIV
CLASS="REFSYNOPSISDIV"
><PRE
CLASS="SYNOPSIS"
>COPY [ BINARY ] <TT
CLASS="REPLACEABLE"
><I
>table</I
></TT
> [ WITH OIDS ]
FROM { '<TT
CLASS="REPLACEABLE"
><I
>filename</I
></TT
>' | <TT
CLASS="FILENAME"
>stdin</TT
> }
[ USING DELIMITERS '<TT
CLASS="REPLACEABLE"
><I
>delimiter</I
></TT
>' ]
COPY [ BINARY ] <TT
CLASS="REPLACEABLE"
><I
>table</I
></TT
> [ WITH OIDS ]
TO { '<TT
CLASS="REPLACEABLE"
><I
>filename</I
></TT
>' | <TT
CLASS="FILENAME"
>stdout</TT
> }
[ USING DELIMITERS '<TT
CLASS="REPLACEABLE"
><I
>delimiter</I
></TT
>' ]
</PRE
><DIV
CLASS="REFSECT2"
><H3
> Inputs
</H3
><P
> <P
></P
></P><DL
><DT
>BINARY</DT
><DD
><P
> Changes the behavior of field formatting, forcing all data to be
stored or read as binary objects rather than as text.
</P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>table</I
></TT
></DT
><DD
><P
>The name of an existing table.
</P
></DD
><DT
>WITH OIDS</DT
><DD
><P
>Copies the internal unique object id (OID) for each row.
</P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>filename</I
></TT
></DT
><DD
><P
>The absolute Unix pathname of the input or output file.
</P
></DD
><DT
><TT
CLASS="FILENAME"
>stdin</TT
></DT
><DD
><P
>Specifies that input comes from a pipe or terminal.
</P
></DD
><DT
><TT
CLASS="FILENAME"
>stdout</TT
></DT
><DD
><P
>Specifies that output goes to a pipe or terminal.
</P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>delimiter</I
></TT
></DT
><DD
><P
> A character that delimits the input or output fields.
</P
></DD
></DL
><P>
</P
></DIV
><DIV
CLASS="REFSECT2"
><H3
> Outputs
</H3
><P
> <P
></P
></P><DL
><DT
><SPAN
CLASS="RETURNVALUE"
>COPY</SPAN
></DT
><DD
><P
> The copy completed successfully.
</P
></DD
><DT
><SPAN
CLASS="RETURNVALUE"
>ERROR: <TT
CLASS="REPLACEABLE"
><I
>error message</I
></TT
></SPAN
></DT
><DD
><P
> The copy failed for the reason stated in the error message.
</P
></DD
></DL
><P>
</P
></DIV
></DIV
><DIV
CLASS="REFSECT1"
><H2
> Description
</H2
><P
> <B
CLASS="COMMAND"
>COPY</B
> moves data between
<SPAN
CLASS="PRODUCTNAME"
>Postgres</SPAN
> tables and
standard Unix files. </P
><P
><B
CLASS="COMMAND"
>COPY</B
> instructs
the <SPAN
CLASS="PRODUCTNAME"
>Postgres</SPAN
> backend
to directly read from or write to a file. The file must be directly visible to
the backend and the name must be specified from the viewpoint of the backend.
If <TT
CLASS="FILENAME"
>stdin</TT
> or <TT
CLASS="FILENAME"
>stdout</TT
> are specified, data flows through the client frontend to
the backend.
</P
><DIV
CLASS="REFSECT2"
><H3
> Notes
</H3
><P
> The BINARY keyword will force all data to be
stored/read as binary objects rather than as text. It is
somewhat faster than the normal copy command, but is not
generally portable, and the files generated are somewhat larger,
although this factor is highly dependent on the data itself. By
default, a text copy uses a tab ("\t") character as a delimiter.
The delimiter may also be changed to any other single character
with the keyword phrase USING DELIMITERS. Characters
in data fields which happen to match the delimiter character will
be quoted.
</P
><P
> You must have select access on any table whose values are read by
<B
CLASS="COMMAND"
>COPY</B
>, and either insert or update access to a
table into which values are being inserted by <B
CLASS="COMMAND"
>COPY</B
>.
The backend also needs appropriate Unix permissions for any file read
or written by <B
CLASS="COMMAND"
>COPY</B
>.
</P
><P
> The keyword phrase USING DELIMITERS specifies a single character
to be used for all delimiters between columns. If multiple characters
are specified in the delimiter string, only the first character is
used.
<BLOCKQUOTE
CLASS="TIP"
><P
><B
>Tip: </B
> Do not confuse <B
CLASS="COMMAND"
>COPY</B
> with the
<SPAN
CLASS="APPLICATION"
>psql</SPAN
> instruction <B
CLASS="COMMAND"
>\copy</B
>.</P
></BLOCKQUOTE
>
</P
></DIV
></DIV
><DIV
CLASS="REFSECT1"
><H2
>File Formats</H2
><DIV
CLASS="REFSECT2"
><H3
>Text Format</H3
><P
> When <B
CLASS="COMMAND"
>COPY TO</B
> is used without the BINARY option,
the file generated will have each row (instance) on a single line, with each
column (attribute) separated by the delimiter character. Embedded
delimiter characters will be preceded by a backslash character
("\"). The attribute values themselves are strings generated by the
output function associated with each attribute type. The output
function for a type should not try to generate the backslash
character; this will be handled by <B
CLASS="COMMAND"
>COPY</B
> itself.
</P
><P
> The actual format for each instance is
<PRE
CLASS="PROGRAMLISTING"
><attr1><<TT
CLASS="REPLACEABLE"
><I
>separator</I
></TT
>><attr2><<TT
CLASS="REPLACEABLE"
><I
>separator</I
></TT
>>...<<TT
CLASS="REPLACEABLE"
><I
>separator</I
></TT
>><attr<TT
CLASS="REPLACEABLE"
><I
>n</I
></TT
>><newline></PRE
>
The oid is placed on the beginning of the line
if WITH OIDS is specified.
</P
><P
> If <B
CLASS="COMMAND"
>COPY</B
> is sending its output to standard
output instead of a file, it will send a backslash("\") and a period
(".") followed immediately by a newline, on a separate line,
when it is done. Similarly, if <B
CLASS="COMMAND"
>COPY</B
> is reading
from standard input, it will expect a backslash ("\") and a period
(".") followed by a newline, as the first three characters on a
line to denote end-of-file. However, <B
CLASS="COMMAND"
>COPY</B
>
will terminate (followed by the backend itself) if a true EOF is
encountered before this special end-of-file pattern is found.
</P
><P
> The backslash character has other special meanings. NULL attributes are
output as "\N". A literal backslash character is output as two
consecutive backslashes ("\\"). A literal tab character is represented
as a backslash and a tab. A literal newline character is
represented as a backslash and a newline. When loading text data
not generated by <SPAN
CLASS="ACRONYM"
>Postgres</SPAN
>,
you will need to convert backslash
characters ("\") to double-backslashes ("\\") to ensure that they are loaded
properly.
</P
></DIV
><DIV
CLASS="REFSECT2"
><H3
>Binary Format</H3
><P
> In the case of <B
CLASS="COMMAND"
>COPY BINARY</B
>, the first four
bytes in the file will be the number of instances in the file. If
this number is zero, the <B
CLASS="COMMAND"
>COPY BINARY</B
> command
will read until end of file is encountered. Otherwise, it will
stop reading when this number of instances has been read.
Remaining data in the file will be ignored.
</P
><P
> The format for each instance in the file is as follows. Note that
this format must be followed <I
CLASS="EMPHASIS"
>exactly</I
>.
Unsigned four-byte integer quantities are called uint32 in the
table below.
</P
><DIV
CLASS="TABLE"
><P
><B
>Table 16-1. Contents of a binary copy file</B
></P
><TABLE
BORDER="1"
CLASS="CALSTABLE"
><TR
><TD
COLSPAN="2"
ALIGN="CENTER"
VALIGN="TOP"
>At the start of the file</TD
></TR
><TR
><TD
ALIGN="CENTER"
VALIGN="TOP"
>uint32</TD
><TD
ALIGN="CENTER"
VALIGN="TOP"
>number of tuples</TD
></TR
><TR
><TD
COLSPAN="2"
ALIGN="CENTER"
VALIGN="TOP"
>For each tuple</TD
></TR
><TR
><TD
ALIGN="CENTER"
VALIGN="TOP"
>uint32</TD
><TD
ALIGN="CENTER"
VALIGN="TOP"
>total length of tuple data</TD
></TR
><TR
><TD
ALIGN="CENTER"
VALIGN="TOP"
>uint32</TD
><TD
ALIGN="CENTER"
VALIGN="TOP"
>oid (if specified)</TD
></TR
><TR
><TD
ALIGN="CENTER"
VALIGN="TOP"
>uint32</TD
><TD
ALIGN="CENTER"
VALIGN="TOP"
>number of null attributes</TD
></TR
><TR
><TD
ALIGN="CENTER"
VALIGN="TOP"
>[uint32,...,uint32]</TD
><TD
ALIGN="CENTER"
VALIGN="TOP"
>attribute numbers of attributes, counting from 0</TD
></TR
><TR
><TD
ALIGN="CENTER"
VALIGN="TOP"
>-</TD
><TD
ALIGN="CENTER"
VALIGN="TOP"
><tuple data></TD
></TR
></TABLE
></DIV
></DIV
><DIV
CLASS="REFSECT2"
><H3
>Alignment of Binary Data</H3
><P
> On Sun-3s, 2-byte attributes are aligned on two-byte boundaries,
and all larger attributes are aligned on four-byte boundaries.
Character attributes are aligned on single-byte boundaries. On
most other machines, all attributes larger than 1 byte are aligned on
four-byte boundaries. Note that variable length attributes are
preceded by the attribute's length; arrays are simply contiguous
streams of the array element type.
</P
></DIV
></DIV
><DIV
CLASS="REFSECT1"
><H2
> Usage
</H2
><P
>The following example copies a table to standard output,
using a vertical bar ("|") as the field
delimiter:
</P
><PRE
CLASS="PROGRAMLISTING"
>COPY country TO <TT
CLASS="FILENAME"
>stdout</TT
> USING DELIMITERS '|';
</PRE
><P
> To copy data from a Unix file into a table "country":
</P
><PRE
CLASS="PROGRAMLISTING"
>COPY country FROM '/usr1/proj/bray/sql/country_data';
</PRE
><P
> Here is a sample of data suitable for copying into a table
from <TT
CLASS="FILENAME"
>stdin</TT
> (so it
has the termination sequence on the last line):
</P
><PRE
CLASS="PROGRAMLISTING"
> AF AFGHANISTAN
AL ALBANIA
DZ ALGERIA
...
ZM ZAMBIA
ZW ZIMBABWE
\.
</PRE
><P
> The same data, output in binary format on a Linux/i586 machine.
The data is shown after filtering through
the Unix utility <B
CLASS="COMMAND"
>od -c</B
>. The table has
three fields; the first is <TT
CLASS="CLASSNAME"
>char(2)</TT
>
and the second is <TT
CLASS="CLASSNAME"
>text</TT
>. All the
rows have a null value in the third field.
Notice how the <TT
CLASS="CLASSNAME"
>char(2)</TT
>
field is padded with nulls to four bytes and the text field is
preceded by its length:
</P
><PRE
CLASS="PROGRAMLISTING"
> 355 \0 \0 \0 027 \0 \0 \0 001 \0 \0 \0 002 \0 \0 \0
006 \0 \0 \0 A F \0 \0 017 \0 \0 \0 A F G H
A N I S T A N 023 \0 \0 \0 001 \0 \0 \0 002
\0 \0 \0 006 \0 \0 \0 A L \0 \0 \v \0 \0 \0 A
L B A N I A 023 \0 \0 \0 001 \0 \0 \0 002 \0
\0 \0 006 \0 \0 \0 D Z \0 \0 \v \0 \0 \0 A L
G E R I A
... \n \0 \0 \0 Z A M B I A 024 \0
\0 \0 001 \0 \0 \0 002 \0 \0 \0 006 \0 \0 \0 Z W
\0 \0 \f \0 \0 \0 Z I M B A B W E
</PRE
></DIV
><DIV
CLASS="REFSECT1"
><H2
>Bugs</H2
><P
> <B
CLASS="COMMAND"
>COPY</B
> stops operation at the first error. This
should not lead to problems in the event of
a <B
CLASS="COMMAND"
>COPY FROM</B
>, but the
target relation will, of course, be partially modified in a
<B
CLASS="COMMAND"
>COPY TO</B
>.
The <B
CLASS="COMMAND"
>VACUUM</B
> query should be used to clean up
after a failed copy.
</P
><P
> Because the Postgres backend's current working directory
is not usually the same as the user's
working directory, the result of copying to a file
"<TT
CLASS="FILENAME"
>foo</TT
>" (without
additional path information) may yield unexpected results for the
naive user. In this case, <TT
CLASS="FILENAME"
>foo</TT
>
will wind up in <TT
CLASS="FILENAME"
>$PGDATA/foo</TT
>. In
general, the full pathname as it would appear to the backend server machine
should be used when specifying files to
be copied.
</P
><P
> Files used as arguments to <B
CLASS="COMMAND"
>COPY</B
>
must reside on or be
accessible to the database server machine by being either on
local disks or on a networked file system.
</P
><P
> When a TCP/IP connection from one machine to another is used, and a
target file is specified, the target file will be written on the
machine where the backend is running rather than the user's
machine.
</P
></DIV
><DIV
CLASS="REFSECT1"
><H2
> Compatibility
</H2
><P
> </P
><DIV
CLASS="REFSECT2"
><H3
> SQL92
</H3
><P
> There is no <B
CLASS="COMMAND"
>COPY</B
> statement in SQL92.
</P
></DIV
></DIV
><DIV
CLASS="NAVFOOTER"
><HR
ALIGN="LEFT"
WIDTH="100%"><TABLE
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
><A
HREF="sql-commit.html"
>Prev</A
></TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="user.html"
>Home</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
><A
HREF="sql-createaggregate.html"
>Next</A
></TD
></TR
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
>COMMIT</TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="sql-commands.html"
>Up</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
>CREATE AGGREGATE</TD
></TR
></TABLE
></DIV
></BODY
></HTML
>
|