summaryrefslogtreecommitdiff
path: root/doc/src/sgml/file-fdw.sgml
blob: d3b39aa120b75bce429809a894e57b09fa6278e3 (plain)
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
<!-- doc/src/sgml/file-fdw.sgml -->

<sect1 id="file-fdw" xreflabel="file_fdw">
 <title>file_fdw</title>

 <indexterm zone="file-fdw">
  <primary>file_fdw</primary>
 </indexterm>

 <para>
  The <filename>file_fdw</> module provides the foreign-data wrapper
  <function>file_fdw</function>, which can be used to access data
  files in the server's file system.  Data files must be in a format
  that can be read by <command>COPY FROM</command>;
  see <xref linkend="sql-copy"> for details.
  Access to such data files is currently read-only.
 </para>

 <para>
  A foreign table created using this wrapper can have the following options:
 </para>

 <variablelist>

  <varlistentry>
   <term><literal>filename</literal></term>

   <listitem>
    <para>
     Specifies the file to be read.  Required.  Must be an absolute path name.
    </para>
   </listitem>
  </varlistentry>

  <varlistentry>
   <term><literal>format</literal></term>

   <listitem>
    <para>
     Specifies the file's format,
     the same as <command>COPY</>'s <literal>FORMAT</literal> option.
    </para>
   </listitem>
  </varlistentry>

  <varlistentry>
   <term><literal>header</literal></term>

   <listitem>
    <para>
     Specifies whether the file has a header line,
     the same as <command>COPY</>'s <literal>HEADER</literal> option.
    </para>
   </listitem>
  </varlistentry>

  <varlistentry>
   <term><literal>delimiter</literal></term>

   <listitem>
    <para>
     Specifies the file's delimiter character,
     the same as <command>COPY</>'s <literal>DELIMITER</literal> option.
    </para>
   </listitem>
  </varlistentry>

  <varlistentry>
   <term><literal>quote</literal></term>

   <listitem>
    <para>
     Specifies the file's quote character,
     the same as <command>COPY</>'s <literal>QUOTE</literal> option.
    </para>
   </listitem>
  </varlistentry>

  <varlistentry>
   <term><literal>escape</literal></term>

   <listitem>
    <para>
     Specifies the file's escape character,
     the same as <command>COPY</>'s <literal>ESCAPE</literal> option.
    </para>
   </listitem>
  </varlistentry>

  <varlistentry>
   <term><literal>null</literal></term>

   <listitem>
    <para>
     Specifies the file's null string,
     the same as <command>COPY</>'s <literal>NULL</literal> option.
    </para>
   </listitem>
  </varlistentry>

  <varlistentry>
   <term><literal>encoding</literal></term>

   <listitem>
    <para>
     Specifies the file's encoding,
     the same as <command>COPY</>'s <literal>ENCODING</literal> option.
    </para>
   </listitem>
  </varlistentry>

 </variablelist>

 <para>
  Note that while <command>COPY</> allows options such as OIDS and HEADER
  to be specified without a corresponding value, the foreign data wrapper
  syntax requires a value to be present in all cases.  To activate
  <command>COPY</> options normally supplied without a value, you can
  instead pass the value TRUE.
 </para>

 <para>
  A column of a foreign table created using this wrapper can have the
  following options:
 </para>

 <variablelist>

  <varlistentry>
   <term><literal>force_not_null</literal></term>

   <listitem>
    <para>
     This is a Boolean option.  If true, it specifies that values of the
     column should not be matched against the null string (that is, the
     file-level <literal>null</literal> option).  This has the same effect
     as listing the column in <command>COPY</>'s
     <literal>FORCE_NOT_NULL</literal> option.
    </para>
   </listitem>
  </varlistentry>

  <varlistentry>
   <term><literal>force_null</literal></term>

   <listitem>
    <para>
     This is a Boolean option.  If true, it specifies that values of the
     column which match the null string are returned as <literal>NULL</>
     even if the value is quoted. Without this option, only unquoted
     values matching the null string are returned as <literal>NULL</>.
     This has the same effect  as listing the column in
     <command>COPY</>'s <literal>FORCE_NULL</literal> option.
    </para>
   </listitem>
  </varlistentry>

 </variablelist>

 <para>
  <command>COPY</>'s <literal>OIDS</literal> and
  <literal>FORCE_QUOTE</literal> options are currently not supported by
  <literal>file_fdw</>.
 </para>

 <para>
  These options can only be specified for a foreign table or its columns, not
  in the options of the <literal>file_fdw</> foreign-data wrapper, nor in the
  options of a server or user mapping using the wrapper.
 </para>

 <para>
  Changing table-level options requires superuser privileges, for security
  reasons: only a superuser should be able to determine which file is read.
  In principle non-superusers could be allowed to change the other options,
  but that's not supported at present.
 </para>

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

 <example>
 <title id="csvlog-fdw">Create a Foreign Table for PostgreSQL CSV Logs</title>

  <para>
   One of the obvious uses for the <literal>file_fdw</> is to make
   the PostgreSQL activity log available as a table for querying.  To
   do this, first you must be logging to a CSV file, which here we
   will call <literal>pglog.csv</>.  First, install <literal>file_fdw</>
   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, 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
) SERVER pglog
OPTIONS ( filename '/home/josh/9.1/data/pg_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>

</sect1>