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
|
<html>
<head>
<meta http-equiv="Content-Type" content="text/html; charset=ISO-8859-1">
<title>COPY</title>
<link rel="stylesheet" href="stylesheet.css" type="text/css">
<link rev="made" href="pgsql-docs@postgresql.org">
<meta name="generator" content="DocBook XSL Stylesheets V1.70.0">
<link rel="start" href="index.html" title="PostgreSQL 8.1.4 Documentation">
<link rel="up" href="sql-commands.html" title="SQL Commands">
<link rel="prev" href="sql-commit-prepared.html" title="COMMIT PREPARED">
<link rel="next" href="sql-createaggregate.html" title="CREATE AGGREGATE">
<link rel="copyright" href="ln-legalnotice.html" title="Legal Notice">
</head>
<body bgcolor="white" text="black" link="#0000FF" vlink="#840084" alink="#0000FF"><div class="refentry" lang="en">
<a name="sql-copy"></a><div class="titlepage"></div>
<div class="refnamediv">
<h2>Name</h2>
<p>COPY — copy data between a file and a table</p>
</div>
<a name="id750381"></a><div class="refsynopsisdiv">
<h2>Synopsis</h2>
<pre class="synopsis">COPY <em class="replaceable"><code>tablename</code></em> [ ( <em class="replaceable"><code>column</code></em> [, ...] ) ]
FROM { '<em class="replaceable"><code>filename</code></em>' | STDIN }
[ [ WITH ]
[ BINARY ]
[ OIDS ]
[ DELIMITER [ AS ] '<em class="replaceable"><code>delimiter</code></em>' ]
[ NULL [ AS ] '<em class="replaceable"><code>null string</code></em>' ]
[ CSV [ HEADER ]
[ QUOTE [ AS ] '<em class="replaceable"><code>quote</code></em>' ]
[ ESCAPE [ AS ] '<em class="replaceable"><code>escape</code></em>' ]
[ FORCE NOT NULL <em class="replaceable"><code>column</code></em> [, ...] ]
COPY <em class="replaceable"><code>tablename</code></em> [ ( <em class="replaceable"><code>column</code></em> [, ...] ) ]
TO { '<em class="replaceable"><code>filename</code></em>' | STDOUT }
[ [ WITH ]
[ BINARY ]
[ HEADER ]
[ OIDS ]
[ DELIMITER [ AS ] '<em class="replaceable"><code>delimiter</code></em>' ]
[ NULL [ AS ] '<em class="replaceable"><code>null string</code></em>' ]
[ CSV [ HEADER ]
[ QUOTE [ AS ] '<em class="replaceable"><code>quote</code></em>' ]
[ ESCAPE [ AS ] '<em class="replaceable"><code>escape</code></em>' ]
[ FORCE QUOTE <em class="replaceable"><code>column</code></em> [, ...] ]</pre>
</div>
<div class="refsect1" lang="en">
<a name="id750515"></a><h2>Description</h2>
<p> <code class="command">COPY</code> moves data between
<span class="productname">PostgreSQL</span> tables and standard file-system
files. <code class="command">COPY TO</code> copies the contents of a table
<span class="emphasis"><em>to</em></span> a file, while <code class="command">COPY FROM</code> copies
data <span class="emphasis"><em>from</em></span> a file to a table (appending the data to
whatever is in the table already).
</p>
<p> If a list of columns is specified, <code class="command">COPY</code> will
only copy the data in the specified columns to or from the file.
If there are any columns in the table that are not in the column list,
<code class="command">COPY FROM</code> will insert the default values for
those columns.
</p>
<p> <code class="command">COPY</code> with a file name instructs the
<span class="productname">PostgreSQL</span> server to directly read from
or write to a file. The file must be accessible to the server and
the name must be specified from the viewpoint of the server. When
<code class="literal">STDIN</code> or <code class="literal">STDOUT</code> is
specified, data is transmitted via the connection between the
client and the server.
</p>
</div>
<div class="refsect1" lang="en">
<a name="id750612"></a><h2>Parameters</h2>
<div class="variablelist"><dl>
<dt><span class="term"><em class="replaceable"><code>tablename</code></em></span></dt>
<dd><p> The name (optionally schema-qualified) of an existing table.
</p></dd>
<dt><span class="term"><em class="replaceable"><code>column</code></em></span></dt>
<dd><p> An optional list of columns to be copied. If no column list is
specified, all columns will be used.
</p></dd>
<dt><span class="term"><em class="replaceable"><code>filename</code></em></span></dt>
<dd><p> The absolute path name of the input or output file. Windows users
might need to double backslashes used as path separators.
</p></dd>
<dt><span class="term"><code class="literal">STDIN</code></span></dt>
<dd><p> Specifies that input comes from the client application.
</p></dd>
<dt><span class="term"><code class="literal">STDOUT</code></span></dt>
<dd><p> Specifies that output goes to the client application.
</p></dd>
<dt><span class="term"><code class="literal">BINARY</code></span></dt>
<dd><p> Causes all data to be stored or read in binary format rather
than as text. You cannot specify the <code class="option">DELIMITER</code>,
<code class="option">NULL</code>, or <code class="option">CSV</code> options in binary mode.
</p></dd>
<dt><span class="term"><code class="literal">OIDS</code></span></dt>
<dd><p> Specifies copying the OID for each row. (An error is raised if
<code class="literal">OIDS</code> is specified for a table that does not
have OIDs.)
</p></dd>
<dt><span class="term"><em class="replaceable"><code>delimiter</code></em></span></dt>
<dd><p> The single character that separates columns within each row
(line) of the file. The default is a tab character in text mode,
a comma in <code class="literal">CSV</code> mode.
</p></dd>
<dt><span class="term"><em class="replaceable"><code>null string</code></em></span></dt>
<dd>
<p> The string that represents a null value. The default is
<code class="literal">\N</code> (backslash-N) in text mode, and a empty
value with no quotes in <code class="literal">CSV</code> mode. You might prefer an
empty string even in text mode for cases where you don't want to
distinguish nulls from empty strings.
</p>
<div class="note" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Note</h3>
<p> When using <code class="command">COPY FROM</code>, 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
<code class="command">COPY TO</code>.
</p>
</div>
</dd>
<dt><span class="term"><code class="literal">CSV</code></span></dt>
<dd><p> Selects Comma Separated Value (<code class="literal">CSV</code>) mode.
</p></dd>
<dt><span class="term"><code class="literal">HEADER</code></span></dt>
<dd><p> Specifies 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, and on input, the first line is ignored.
</p></dd>
<dt><span class="term"><em class="replaceable"><code>quote</code></em></span></dt>
<dd><p> Specifies the quotation character in <code class="literal">CSV</code> mode.
The default is double-quote.
</p></dd>
<dt><span class="term"><em class="replaceable"><code>escape</code></em></span></dt>
<dd><p> Specifies the character that should appear before a
<code class="literal">QUOTE</code> data character value in <code class="literal">CSV</code> mode.
The default is the <code class="literal">QUOTE</code> value (usually double-quote).
</p></dd>
<dt><span class="term"><code class="literal">FORCE QUOTE</code></span></dt>
<dd><p> In <code class="literal">CSV</code> <code class="command">COPY TO</code> mode, forces quoting to be
used for all non-<code class="literal">NULL</code> values in each specified column.
<code class="literal">NULL</code> output is never quoted.
</p></dd>
<dt><span class="term"><code class="literal">FORCE NOT NULL</code></span></dt>
<dd><p> In <code class="literal">CSV</code> <code class="command">COPY FROM</code> mode, process each
specified column as though it were quoted and hence not a
<code class="literal">NULL</code> value. For the default null string in
<code class="literal">CSV</code> mode (<code class="literal">''</code>), this causes missing
values to be input as zero-length strings.
</p></dd>
</dl></div>
</div>
<div class="refsect1" lang="en">
<a name="id750969"></a><h2>Notes</h2>
<p> <code class="command">COPY</code> can only be used with plain tables, not
with views.
</p>
<p> The <code class="literal">BINARY</code> key word 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
<span class="productname">PostgreSQL</span> versions.
</p>
<p> You must have select privilege on the table
whose values are read by <code class="command">COPY TO</code>, and
insert privilege on the table into which values
are inserted by <code class="command">COPY FROM</code>.
</p>
<p> Files named in a <code class="command">COPY</code> 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 <span class="productname">PostgreSQL</span> user (the user ID the
server runs as), not the client. <code class="command">COPY</code> naming a
file is only allowed to database superusers, since it allows reading
or writing any file that the server has privileges to access.
</p>
<p> Do not confuse <code class="command">COPY</code> with the
<span class="application">psql</span> instruction
<code class="command">\copy</code>. <code class="command">\copy</code> invokes
<code class="command">COPY FROM STDIN</code> or <code class="command">COPY TO
STDOUT</code>, and then fetches/stores the data in a file
accessible to the <span class="application">psql</span> client. Thus,
file accessibility and access rights depend on the client rather
than the server when <code class="command">\copy</code> is used.
</p>
<p> It is recommended that the file name used in <code class="command">COPY</code>
always be specified as an absolute path. This is enforced by the
server in the case of <code class="command">COPY TO</code>, but for
<code class="command">COPY FROM</code> 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 (somewhere below
the data directory), not the client's working directory.
</p>
<p> <code class="command">COPY FROM</code> will invoke any triggers and check
constraints on the destination table. However, it will not invoke rules.
</p>
<p> <code class="command">COPY</code> input and output is affected by
<code class="varname">DateStyle</code>. To ensure portability to other
<span class="productname">PostgreSQL</span> installations that might use
non-default <code class="varname">DateStyle</code> settings,
<code class="varname">DateStyle</code> should be set to <code class="literal">ISO</code> before
using <code class="command">COPY TO</code>.
</p>
<p> <code class="command">COPY</code> stops operation at the first error. This
should not lead to problems in the event of a <code class="command">COPY
TO</code>, but the target table will already have received
earlier rows in a <code class="command">COPY FROM</code>. 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 operation. You may wish to invoke
<code class="command">VACUUM</code> to recover the wasted space.
</p>
</div>
<div class="refsect1" lang="en">
<a name="id751229"></a><h2>File Formats</h2>
<div class="refsect2" lang="en">
<a name="id751233"></a><h3>Text Format</h3>
<p> When <code class="command">COPY</code> is used without the <code class="literal">BINARY</code>
or <code class="literal">CSV</code> options,
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's data type. The specified null string is used in
place of columns that are null.
<code class="command">COPY FROM</code> will raise an error if any line of the
input file contains more or fewer columns than are expected.
If <code class="literal">OIDS</code> is specified, the OID is read or written as the first column,
preceding the user data columns.
</p>
<p> End of data can be represented by a single line containing just
backslash-period (<code class="literal">\.</code>). 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.
</p>
<p> Backslash characters (<code class="literal">\</code>) may be used in the
<code class="command">COPY</code> data to quote data characters that might
otherwise be taken as row or column delimiters. In particular, the
following characters <span class="emphasis"><em>must</em></span> be preceded by a backslash if
they appear as part of a column value: backslash itself,
newline, carriage return, and the current delimiter character.
</p>
<p> The specified null string is sent by <code class="command">COPY TO</code> without
adding any backslashes; conversely, <code class="command">COPY FROM</code> matches
the input against the null string before removing backslashes. Therefore,
a null string such as <code class="literal">\N</code> cannot be confused with
the actual data value <code class="literal">\N</code> (which would be represented
as <code class="literal">\\N</code>).
</p>
<p> The following special backslash sequences are recognized by
<code class="command">COPY FROM</code>:
</p>
<div class="informaltable"><table border="1">
<colgroup>
<col>
<col>
</colgroup>
<thead><tr>
<th>Sequence</th>
<th>Represents</th>
</tr></thead>
<tbody>
<tr>
<td><code class="literal">\b</code></td>
<td>Backspace (ASCII 8)</td>
</tr>
<tr>
<td><code class="literal">\f</code></td>
<td>Form feed (ASCII 12)</td>
</tr>
<tr>
<td><code class="literal">\n</code></td>
<td>Newline (ASCII 10)</td>
</tr>
<tr>
<td><code class="literal">\r</code></td>
<td>Carriage return (ASCII 13)</td>
</tr>
<tr>
<td><code class="literal">\t</code></td>
<td>Tab (ASCII 9)</td>
</tr>
<tr>
<td><code class="literal">\v</code></td>
<td>Vertical tab (ASCII 11)</td>
</tr>
<tr>
<td>
<code class="literal">\</code><em class="replaceable"><code>digits</code></em>
</td>
<td>Backslash followed by one to three octal digits specifies
the character with that numeric code</td>
</tr>
<tr>
<td>
<code class="literal">\x</code><em class="replaceable"><code>digits</code></em>
</td>
<td>Backslash <code class="literal">x</code> followed by one or two hex digits specifies
the character with that numeric code</td>
</tr>
</tbody>
</table></div>
<p>
Presently, <code class="command">COPY TO</code> will never emit an octal or
hex-digits backslash sequence, but it does use the other sequences
listed above for those control characters.
</p>
<p> 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 (<code class="literal">\.</code>) or the null string (<code class="literal">\N</code> by
default). These strings will be recognized before any other backslash
processing is done.
</p>
<p> It is strongly recommended that applications generating <code class="command">COPY</code> data convert
data newlines and carriage returns to the <code class="literal">\n</code> and
<code class="literal">\r</code> 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 <code class="command">COPY</code> file is
transferred across different machines (for example, from Unix to Windows
or vice versa).
</p>
<p> <code class="command">COPY TO</code> will terminate each row with a Unix-style
newline (“<span class="quote"><code class="literal">\n</code></span>”). Servers running on Microsoft Windows instead
output carriage return/newline (“<span class="quote"><code class="literal">\r\n</code></span>”), but only for
<code class="command">COPY</code> to a server file; for consistency across platforms,
<code class="command">COPY TO STDOUT</code> always sends “<span class="quote"><code class="literal">\n</code></span>”
regardless of server platform.
<code class="command">COPY FROM</code> 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, <code class="command">COPY FROM</code> will complain if the line
endings in the input are not all alike.
</p>
</div>
<div class="refsect2" lang="en">
<a name="id751612"></a><h3>CSV Format</h3>
<p> This format is used for importing and exporting the Comma
Separated Value (<code class="literal">CSV</code>) file format used by many other
programs, such as spreadsheets. Instead of the escaping used by
<span class="productname">PostgreSQL</span>'s standard text mode, it
produces and recognizes the common CSV escaping mechanism.
</p>
<p> The values in each record are separated by the <code class="literal">DELIMITER</code>
character. If the value contains the delimiter character, the
<code class="literal">QUOTE</code> character, the <code class="literal">NULL</code> string, a carriage
return, or line feed character, then the whole value is prefixed and
suffixed by the <code class="literal">QUOTE</code> character, and any occurrence
within the value of a <code class="literal">QUOTE</code> character or the
<code class="literal">ESCAPE</code> character is preceded by the escape character.
You can also use <code class="literal">FORCE QUOTE</code> to force quotes when outputting
non-<code class="literal">NULL</code> values in specific columns.
</p>
<p>
The <code class="literal">CSV</code> format has no standard way to distinguish a
<code class="literal">NULL</code> value from an empty string.
<span class="productname">PostgreSQL</span>'s <code class="command">COPY</code> handles this by
quoting. A <code class="literal">NULL</code> is output as the <code class="literal">NULL</code>
string and is not quoted, while a data value matching the
<code class="literal">NULL</code> string is quoted. Therefore, using the default
settings, a <code class="literal">NULL</code> is written as an unquoted empty
string, while an empty string is written with double quotes
(<code class="literal">""</code>). Reading values follows similar rules. You can
use <code class="literal">FORCE NOT NULL</code> to prevent <code class="literal">NULL</code> input
comparisons for specific columns.
</p>
<p>
Because backslash is not a special character in the <code class="literal">CSV</code>
format, <code class="literal">\.</code>, the end-of-data marker, could also appear
as a data value. To avoid any misinterpretation, a <code class="literal">\.</code>
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 <code class="literal">\.</code>, you might need to quote that value in the
input file.
</p>
<div class="note" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Note</h3>
<p> In <code class="literal">CSV</code> mode, all characters are significant. A quoted value
surrounded by white space, or any characters other than
<code class="literal">DELIMITER</code>, will include those characters. This can cause
errors if you import data from a system that pads <code class="literal">CSV</code>
lines with white space out to some fixed width. If such a situation
arises you might need to preprocess the <code class="literal">CSV</code> file to remove
the trailing white space, before importing the data into
<span class="productname">PostgreSQL</span>.
</p>
</div>
<div class="note" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Note</h3>
<p> CSV mode 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-mode
files.
</p>
</div>
<div class="note" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Note</h3>
<p> 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 <code class="command">COPY</code> might produce files that other
programs cannot process.
</p>
</div>
</div>
<div class="refsect2" lang="en">
<a name="id751883"></a><h3>Binary Format</h3>
<p> The file format used for <code class="command">COPY BINARY</code> changed in
<span class="productname">PostgreSQL</span> 7.4. The new format consists
of a file header, zero or more tuples containing the row data, and
a file trailer. Headers and data are now in network byte order.
</p>
<div class="refsect3" lang="en">
<a name="id751906"></a><h4>File Header</h4>
<p> The file header consists of 15 bytes of fixed fields, followed
by a variable-length header extension area. The fixed fields are:
</p>
<div class="variablelist"><dl>
<dt><span class="term">Signature</span></dt>
<dd><p>11-byte sequence <code class="literal">PGCOPY\n\377\r\n\0</code> [mdash ] 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.)
</p></dd>
<dt><span class="term">Flags field</span></dt>
<dd>
<p>32-bit integer bit mask to denote important aspects of the file format. Bits
are numbered from 0 (<acronym class="acronym">LSB</acronym>) to 31 (<acronym class="acronym">MSB</acronym>). Note that
this field is stored in network byte order (most significant byte first),
as are all the integer fields used in the file format. Bits
16-31 are reserved to denote critical file format issues; a reader
should abort if it finds an unexpected bit set in this range. Bits 0-15
are reserved to signal backwards-compatible format issues; a reader
should simply ignore any unexpected bits set in this range. Currently
only one flag bit is defined, and the rest must be zero:
</p>
<div class="variablelist"><dl>
<dt><span class="term">Bit 16</span></dt>
<dd><p> if 1, OIDs are included in the data; if 0, not
</p></dd>
</dl></div>
<p>
</p>
</dd>
<dt><span class="term">Header extension area length</span></dt>
<dd><p>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.
</p></dd>
</dl></div>
<p>
</p>
<p>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.
</p>
<p> 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).
</p>
</div>
<div class="refsect3" lang="en">
<a name="id752003"></a><h4>Tuples</h4>
<p>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.
</p>
<p>There is no alignment padding or any other extra data between fields.
</p>
<p>Presently, all data values in a <code class="command">COPY BINARY</code> 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.
</p>
<p>To determine the appropriate binary format for the actual tuple data you
should consult the <span class="productname">PostgreSQL</span> source, in
particular the <code class="function">*send</code> and <code class="function">*recv</code> functions for
each column's data type (typically these functions are found in the
<code class="filename">src/backend/utils/adt/</code> directory of the source
distribution).
</p>
<p>If OIDs are included in the file, the OID field immediately follows the
field-count word. It is a normal field except that it's not included
in the field-count. In particular it has a length word [mdash ] this will allow
handling of 4-byte vs. 8-byte OIDs without too much pain, and will allow
OIDs to be shown as null if that ever proves desirable.
</p>
</div>
<div class="refsect3" lang="en">
<a name="id752075"></a><h4>File Trailer</h4>
<p> The file trailer consists of a 16-bit integer word containing -1. This
is easily distinguished from a tuple's field-count word.
</p>
<p> 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.
</p>
</div>
</div>
</div>
<div class="refsect1" lang="en">
<a name="id752090"></a><h2>Examples</h2>
<p> The following example copies a table to the client
using the vertical bar (<code class="literal">|</code>) as the field delimiter:
</p>
<pre class="programlisting">COPY country TO STDOUT WITH DELIMITER '|';</pre>
<p>
</p>
<p> To copy data from a file into the <code class="literal">country</code> table:
</p>
<pre class="programlisting">COPY country FROM '/usr1/proj/bray/sql/country_data';</pre>
<p>
</p>
<p> To copy into a file just the countries whose names start with 'A'
using a temporary table which is automatically deleted:
</p>
<pre class="programlisting">BEGIN;
CREATE TEMP TABLE a_list_countries AS
SELECT * FROM country WHERE country_name LIKE 'A%';
COPY a_list_countries TO '/usr1/proj/bray/sql/a_list_countries.copy';
ROLLBACK;</pre>
<p>
</p>
<p> Here is a sample of data suitable for copying into a table from
<code class="literal">STDIN</code>:
</p>
<pre class="programlisting">AF AFGHANISTAN
AL ALBANIA
DZ ALGERIA
ZM ZAMBIA
ZW ZIMBABWE</pre>
<p>
Note that the white space on each line is actually a tab character.
</p>
<p> The following is the same data, output in binary format.
The data is shown after filtering through the
Unix utility <code class="command">od -c</code>. The table has three columns;
the first has type <code class="type">char(2)</code>, the second has type <code class="type">text</code>,
and the third has type <code class="type">integer</code>. All the rows have a null value
in the third column.
</p>
<pre class="programlisting">0000000 P G C O P Y \n 377 \r \n \0 \0 \0 \0 \0 \0
0000020 \0 \0 \0 \0 003 \0 \0 \0 002 A F \0 \0 \0 013 A
0000040 F G H A N I S T A N 377 377 377 377 \0 003
0000060 \0 \0 \0 002 A L \0 \0 \0 007 A L B A N I
0000100 A 377 377 377 377 \0 003 \0 \0 \0 002 D Z \0 \0 \0
0000120 007 A L G E R I A 377 377 377 377 \0 003 \0 \0
0000140 \0 002 Z M \0 \0 \0 006 Z A M B I A 377 377
0000160 377 377 \0 003 \0 \0 \0 002 Z W \0 \0 \0 \b Z I
0000200 M B A B W E 377 377 377 377 377 377</pre>
<p>
</p>
</div>
<div class="refsect1" lang="en">
<a name="id752205"></a><h2>Compatibility</h2>
<p> There is no <code class="command">COPY</code> statement in the SQL standard.
</p>
<p> The following syntax was used before <span class="productname">PostgreSQL</span>
version 7.3 and is still supported:
</p>
<pre class="synopsis">COPY [ BINARY ] <em class="replaceable"><code>tablename</code></em> [ WITH OIDS ]
FROM { '<em class="replaceable"><code>filename</code></em>' | STDIN }
[ [USING] DELIMITERS '<em class="replaceable"><code>delimiter</code></em>' ]
[ WITH NULL AS '<em class="replaceable"><code>null string</code></em>' ]
COPY [ BINARY ] <em class="replaceable"><code>tablename</code></em> [ WITH OIDS ]
TO { '<em class="replaceable"><code>filename</code></em>' | STDOUT }
[ [USING] DELIMITERS '<em class="replaceable"><code>delimiter</code></em>' ]
[ WITH NULL AS '<em class="replaceable"><code>null string</code></em>' ]</pre>
<p>
</p>
</div>
</div></body>
</html>
|