1
0
mirror of https://github.com/postgres/postgres.git synced 2025-11-06 07:49:08 +03:00

Add support for piping COPY to/from an external program.

This includes backend "COPY TO/FROM PROGRAM '...'" syntax, and corresponding
psql \copy syntax. Like with reading/writing files, the backend version is
superuser-only, and in the psql version, the program is run in the client.

In the passing, the psql \copy STDIN/STDOUT syntax is subtly changed: if you
the stdin/stdout is quoted, it's now interpreted as a filename. For example,
"\copy foo from 'stdin'" now reads from a file called 'stdin', not from
standard input. Before this, there was no way to specify a filename called
stdin, stdout, pstdin or pstdout.

This creates a new function in pgport, wait_result_to_str(), which can
be used to convert the exit status of a process, as returned by wait(3),
to a human-readable string.

Etsuro Fujita, reviewed by Amit Kapila.
This commit is contained in:
Heikki Linnakangas
2013-02-27 18:17:21 +02:00
parent 73dc003bee
commit 3d009e45bd
21 changed files with 584 additions and 152 deletions

View File

@@ -3513,6 +3513,13 @@
<entry>reserved</entry>
<entry>reserved</entry>
</row>
<row>
<entry><token>PROGRAM</token></entry>
<entry>non-reserved</entry>
<entry></entry>
<entry></entry>
<entry></entry>
</row>
<row>
<entry><token>PUBLIC</token></entry>
<entry></entry>

View File

@@ -23,11 +23,11 @@ PostgreSQL documentation
<refsynopsisdiv>
<synopsis>
COPY <replaceable class="parameter">table_name</replaceable> [ ( <replaceable class="parameter">column_name</replaceable> [, ...] ) ]
FROM { '<replaceable class="parameter">filename</replaceable>' | STDIN }
FROM { '<replaceable class="parameter">filename</replaceable>' | PROGRAM '<replaceable class="parameter">command</replaceable>' | STDIN }
[ [ WITH ] ( <replaceable class="parameter">option</replaceable> [, ...] ) ]
COPY { <replaceable class="parameter">table_name</replaceable> [ ( <replaceable class="parameter">column_name</replaceable> [, ...] ) ] | ( <replaceable class="parameter">query</replaceable> ) }
TO { '<replaceable class="parameter">filename</replaceable>' | STDOUT }
TO { '<replaceable class="parameter">filename</replaceable>' | PROGRAM '<replaceable class="parameter">command</replaceable>' | STDOUT }
[ [ WITH ] ( <replaceable class="parameter">option</replaceable> [, ...] ) ]
<phrase>where <replaceable class="parameter">option</replaceable> can be one of:</phrase>
@@ -72,6 +72,10 @@ COPY { <replaceable class="parameter">table_name</replaceable> [ ( <replaceable
<productname>PostgreSQL</productname> 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
<literal>PROGRAM</literal> is specified, the server executes the
given command, and reads from its standard input, or writes to its
standard output. The command must be specified from the viewpoint of the
server, and be executable by the <literal>postgres</> user. When
<literal>STDIN</literal> or <literal>STDOUT</literal> is
specified, data is transmitted via the connection between the
client and the server.
@@ -125,6 +129,25 @@ COPY { <replaceable class="parameter">table_name</replaceable> [ ( <replaceable
</listitem>
</varlistentry>
<varlistentry>
<term><literal>PROGRAM</literal></term>
<listitem>
<para>
A command to execute. In <command>COPY FROM</command>, the input is
read from standard output of the command, and in <command>COPY TO</>,
the output is written to the standard input of the command.
</para>
<para>
Note that the command is invoked by the shell, so if you need to pass
any arguments to shell command 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 passing any user input
in it.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>STDIN</literal></term>
<listitem>
@@ -367,9 +390,13 @@ COPY <replaceable class="parameter">count</replaceable>
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 <productname>PostgreSQL</productname> user (the user ID the
server runs as), not the client. <command>COPY</command> naming a
file is only allowed to database superusers, since it allows reading
or writing any file that the server has privileges to access.
server runs as), not the client. Similarly,
the command specified with <literal>PROGRAM</literal> is executed directly
by the server, not by the client application, must be executable by the
<productname>PostgreSQL</productname> user.
<command>COPY</command> naming a file or command is only allowed to
database superusers, since it allows reading or writing any file that the
server has privileges to access.
</para>
<para>
@@ -393,6 +420,11 @@ COPY <replaceable class="parameter">count</replaceable>
the cluster's data directory), not the client's working directory.
</para>
<para>
Executing a command with <literal>PROGRAM</literal> might be restricted
by operating system's access control mechanisms, such as the SELinux.
</para>
<para>
<command>COPY FROM</command> will invoke any triggers and check
constraints on the destination table. However, it will not invoke rules.
@@ -841,6 +873,14 @@ COPY (SELECT * FROM country WHERE country_name LIKE 'A%') TO '/usr1/proj/bray/sq
</programlisting>
</para>
<para>
To copy into a compressed file, you can pipe the output through an external
compression program:
<programlisting>
COPY country TO PROGRAM 'gzip > /usr1/proj/bray/sql/country_data.gz';
</programlisting>
</para>
<para>
Here is a sample of data suitable for copying into a table from
<literal>STDIN</literal>:

View File

@@ -830,7 +830,7 @@ testdb=&gt;
<varlistentry id="APP-PSQL-meta-commands-copy">
<term><literal>\copy { <replaceable class="parameter">table</replaceable> [ ( <replaceable class="parameter">column_list</replaceable> ) ] | ( <replaceable class="parameter">query</replaceable> ) }
{ <literal>from</literal> | <literal>to</literal> }
{ <replaceable class="parameter">filename</replaceable> | stdin | stdout | pstdin | pstdout }
{ <replaceable class="parameter">'filename'</replaceable> | program <replaceable class="parameter">'command'</replaceable> | stdin | stdout | pstdin | pstdout }
[ [ with ] ( <replaceable class="parameter">option</replaceable> [, ...] ) ]</literal></term>
<listitem>
@@ -847,16 +847,14 @@ testdb=&gt;
</para>
<para>
The syntax of the command is similar to that of the
<acronym>SQL</acronym> <xref linkend="sql-copy">
command, and
<replaceable class="parameter">option</replaceable>
must indicate one of the options of the
<acronym>SQL</acronym> <xref linkend="sql-copy"> command.
Note that, because of this,
special parsing rules apply to the <command>\copy</command>
command. In particular, the variable substitution rules and
backslash escapes do not apply.
When <literal>program</> is specified,
<replaceable class="parameter">command</replaceable> is
executed by <application>psql</application> and the data from
or to <replaceable class="parameter">command</replaceable> is
routed between the server and the client.
This means that the execution privileges are those of
the local user, not the server, and no SQL superuser
privileges are required.
</para>
<para><literal>\copy ... from stdin | to stdout</literal>
@@ -870,6 +868,19 @@ testdb=&gt;
for populating tables in-line within a SQL script file.
</para>
<para>
The syntax of the command is similar to that of the
<acronym>SQL</acronym> <xref linkend="sql-copy">
command, and
<replaceable class="parameter">option</replaceable>
must indicate one of the options of the
<acronym>SQL</acronym> <xref linkend="sql-copy"> command.
Note that, because of this,
special parsing rules apply to the <command>\copy</command>
command. In particular, the variable substitution rules and
backslash escapes do not apply.
</para>
<tip>
<para>
This operation is not as efficient as the <acronym>SQL</acronym>