Home Explore Blog CI



postgresql

4th chunk of `doc/src/sgml/file-fdw.sgml`
98b7a6e16d3e65ef7a88314f47073cc94fb8ca639f0c81ee0000000100000c51
 control which file is
  read or which program is run.  In principle regular users could be allowed to
  change the other options, but that's not supported at present.
 </para>

 <para>
  When specifying the <literal>program</literal> option, keep in mind that the option
  string is executed by the shell.  If you need to pass any arguments to the
  command that come from an untrusted source, you must be careful to strip or
  escape any characters that might have special meaning to 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>

 <para>
  For a foreign table using <literal>file_fdw</literal>, <command>EXPLAIN</command> shows
  the name of the file to be read or program to be run.
  For a file, unless <literal>COSTS OFF</literal> is
  specified, the file size (in bytes) is shown as well.
 </para>

 <example>
  <title>Create a Foreign Table for PostgreSQL CSV Logs</title>

  <para>
   One of the obvious uses for <literal>file_fdw</literal> is to make
   the PostgreSQL activity log available as a table for querying.  To
   do this, first you must be <link
   linkend="runtime-config-logging-csvlog">logging to a CSV file,</link>
   which here we
   will call <literal>pglog.csv</literal>.  First, install <literal>file_fdw</literal>
   as an extension:
  </para>

<programlisting>
CREATE EXTENSION file_fdw;
</programlisting>

  <para>
   Then create a foreign server:

<programlisting>
CREATE SERVER pglog FOREIGN DATA WRAPPER file_fdw;
</programlisting>
  </para>

  <para>
   Now you are ready to create the foreign data table.  Using the
   <command>CREATE FOREIGN TABLE</command> command, you will need to define
   the columns for the table, the CSV file name, and its format:

<programlisting>
CREATE FOREIGN TABLE pglog (
  log_time timestamp(3) with time zone,
  user_name text,
  database_name text,
  process_id integer,
  connection_from text,
  session_id text,
  session_line_num bigint,
  command_tag text,
  session_start_time timestamp with time zone,
  virtual_transaction_id text,
  transaction_id bigint,
  error_severity text,
  sql_state_code text,
  message text,
  detail text,
  hint text,
  internal_query text,
  internal_query_pos integer,
  context text,
  query text,
  query_pos integer,
  location text,
  application_name text,
  backend_type text,
  leader_pid integer,
  query_id bigint
) SERVER pglog
OPTIONS ( filename 'log/pglog.csv', format 'csv' );
</programlisting>
  </para>

  <para>
   That's it &mdash; now you can query your log directly. In production, of
   course, you would need to define some way to deal with log rotation.
  </para>
 </example>

 <example>
  <title>Create a Foreign Table with an Option on a Column</title>
  <para>
   To set the <literal>force_null</literal> option for a column, use the
   <literal>OPTIONS</literal> keyword.
  </para>
<programlisting>
CREATE FOREIGN TABLE films (
 code char(5) NOT NULL,
 title text NOT NULL,
 rating text OPTIONS (force_null 'true')
) SERVER film_server
OPTIONS ( filename 'films/db.csv', format 'csv' );
</programlisting>
 </example>

</sect1>

Title: file_fdw: Security, EXPLAIN, and Examples (CSV Logs, Column Options)
Summary
Changing file_fdw options requires elevated privileges for security. The 'program' option executes through the shell, so sanitize inputs. EXPLAIN displays file/program info and size. Examples include creating a foreign table for PostgreSQL CSV logs and setting the force_null option on a column.