1 <?xml version="1.0" encoding="UTF-8" standalone="no"?>
2 <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>F.15. file_fdw — access data files in the server's file system</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets Vsnapshot" /><link rel="prev" href="earthdistance.html" title="F.14. earthdistance — calculate great-circle distances" /><link rel="next" href="fuzzystrmatch.html" title="F.16. fuzzystrmatch — determine string similarities and distance" /></head><body id="docContent" class="container-fluid col-10"><div class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">F.15. file_fdw — access data files in the server's file system</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="earthdistance.html" title="F.14. earthdistance — calculate great-circle distances">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="contrib.html" title="Appendix F. Additional Supplied Modules and Extensions">Up</a></td><th width="60%" align="center">Appendix F. Additional Supplied Modules and Extensions</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="fuzzystrmatch.html" title="F.16. fuzzystrmatch — determine string similarities and distance">Next</a></td></tr></table><hr /></div><div class="sect1" id="FILE-FDW"><div class="titlepage"><div><div><h2 class="title" style="clear: both">F.15. file_fdw — access data files in the server's file system <a href="#FILE-FDW" class="id_link">#</a></h2></div></div></div><a id="id-1.11.7.25.2" class="indexterm"></a><p>
3 The <code class="filename">file_fdw</code> module provides the foreign-data wrapper
4 <code class="function">file_fdw</code>, which can be used to access data
5 files in the server's file system, or to execute programs on the server
6 and read their output. The data file or program output must be in a format
7 that can be read by <code class="command">COPY FROM</code>;
8 see <a class="xref" href="sql-copy.html" title="COPY"><span class="refentrytitle">COPY</span></a> for details.
9 Access to data files is currently read-only.
11 A foreign table created using this wrapper can have the following options:
12 </p><div class="variablelist"><dl class="variablelist"><dt><span class="term"><code class="literal">filename</code></span></dt><dd><p>
13 Specifies the file to be read. Relative paths are relative to the
15 Either <code class="literal">filename</code> or <code class="literal">program</code> must be
16 specified, but not both.
17 </p></dd><dt><span class="term"><code class="literal">program</code></span></dt><dd><p>
18 Specifies the command to be executed. The standard output of this
19 command will be read as though <code class="command">COPY FROM PROGRAM</code> were used.
20 Either <code class="literal">program</code> or <code class="literal">filename</code> must be
21 specified, but not both.
22 </p></dd><dt><span class="term"><code class="literal">format</code></span></dt><dd><p>
23 Specifies the data format,
24 the same as <code class="command">COPY</code>'s <code class="literal">FORMAT</code> option.
25 </p></dd><dt><span class="term"><code class="literal">header</code></span></dt><dd><p>
26 Specifies whether the data has a header line,
27 the same as <code class="command">COPY</code>'s <code class="literal">HEADER</code> option.
28 </p></dd><dt><span class="term"><code class="literal">delimiter</code></span></dt><dd><p>
29 Specifies the data delimiter character,
30 the same as <code class="command">COPY</code>'s <code class="literal">DELIMITER</code> option.
31 </p></dd><dt><span class="term"><code class="literal">quote</code></span></dt><dd><p>
32 Specifies the data quote character,
33 the same as <code class="command">COPY</code>'s <code class="literal">QUOTE</code> option.
34 </p></dd><dt><span class="term"><code class="literal">escape</code></span></dt><dd><p>
35 Specifies the data escape character,
36 the same as <code class="command">COPY</code>'s <code class="literal">ESCAPE</code> option.
37 </p></dd><dt><span class="term"><code class="literal">null</code></span></dt><dd><p>
38 Specifies the data null string,
39 the same as <code class="command">COPY</code>'s <code class="literal">NULL</code> option.
40 </p></dd><dt><span class="term"><code class="literal">encoding</code></span></dt><dd><p>
41 Specifies the data encoding,
42 the same as <code class="command">COPY</code>'s <code class="literal">ENCODING</code> option.
43 </p></dd><dt><span class="term"><code class="literal">on_error</code></span></dt><dd><p>
44 Specifies how to behave when encountering an error converting a column's
45 input value into its data type,
46 the same as <code class="command">COPY</code>'s <code class="literal">ON_ERROR</code> option.
47 </p></dd><dt><span class="term"><code class="literal">reject_limit</code></span></dt><dd><p>
48 Specifies the maximum number of errors tolerated while converting a column's
49 input value to its data type, the same as <code class="command">COPY</code>'s
50 <code class="literal">REJECT_LIMIT</code> option.
51 </p></dd><dt><span class="term"><code class="literal">log_verbosity</code></span></dt><dd><p>
52 Specifies the amount of messages emitted by <code class="literal">file_fdw</code>,
53 the same as <code class="command">COPY</code>'s <code class="literal">LOG_VERBOSITY</code> option.
54 </p></dd></dl></div><p>
55 Note that while <code class="command">COPY</code> allows options such as <code class="literal">HEADER</code>
56 to be specified without a corresponding value, the foreign table option
57 syntax requires a value to be present in all cases. To activate
58 <code class="command">COPY</code> options typically written without a value, you can pass
59 the value TRUE, since all such options are Booleans.
61 A column of a foreign table created using this wrapper can have the
63 </p><div class="variablelist"><dl class="variablelist"><dt><span class="term"><code class="literal">force_not_null</code></span></dt><dd><p>
64 This is a Boolean option. If true, it specifies that values of the
65 column should not be matched against the null string (that is, the
66 table-level <code class="literal">null</code> option). This has the same effect
67 as listing the column in <code class="command">COPY</code>'s
68 <code class="literal">FORCE_NOT_NULL</code> option.
69 </p></dd><dt><span class="term"><code class="literal">force_null</code></span></dt><dd><p>
70 This is a Boolean option. If true, it specifies that values of the
71 column which match the null string are returned as <code class="literal">NULL</code>
72 even if the value is quoted. Without this option, only unquoted
73 values matching the null string are returned as <code class="literal">NULL</code>.
74 This has the same effect as listing the column in
75 <code class="command">COPY</code>'s <code class="literal">FORCE_NULL</code> option.
76 </p></dd></dl></div><p>
77 <code class="command">COPY</code>'s <code class="literal">FORCE_QUOTE</code> option is
78 currently not supported by <code class="literal">file_fdw</code>.
80 These options can only be specified for a foreign table or its columns, not
81 in the options of the <code class="literal">file_fdw</code> foreign-data wrapper, nor in the
82 options of a server or user mapping using the wrapper.
84 Changing table-level options requires being a superuser or having the privileges
85 of the role <code class="literal">pg_read_server_files</code> (to use a filename) or
86 the role <code class="literal">pg_execute_server_program</code> (to use a program),
87 for security reasons: only certain users should be able to control which file is
88 read or which program is run. In principle regular users could be allowed to
89 change the other options, but that's not supported at present.
91 When specifying the <code class="literal">program</code> option, keep in mind that the option
92 string is executed by the shell. If you need to pass any arguments to the
93 command that come from an untrusted source, you must be careful to strip or
94 escape any characters that might have special meaning to the shell.
95 For security reasons, it is best to use a fixed command string, or at least
96 avoid passing any user input in it.
98 For a foreign table using <code class="literal">file_fdw</code>, <code class="command">EXPLAIN</code> shows
99 the name of the file to be read or program to be run.
100 For a file, unless <code class="literal">COSTS OFF</code> is
101 specified, the file size (in bytes) is shown as well.
102 </p><div class="example" id="id-1.11.7.25.14"><p class="title"><strong>Example F.1. Create a Foreign Table for PostgreSQL CSV Logs</strong></p><div class="example-contents"><p>
103 One of the obvious uses for <code class="literal">file_fdw</code> is to make
104 the PostgreSQL activity log available as a table for querying. To
105 do this, first you must be <a class="link" href="runtime-config-logging.html#RUNTIME-CONFIG-LOGGING-CSVLOG" title="19.8.4. Using CSV-Format Log Output">logging to a CSV file,</a>
107 will call <code class="literal">pglog.csv</code>. First, install <code class="literal">file_fdw</code>
109 </p><pre class="programlisting">
110 CREATE EXTENSION file_fdw;
112 Then create a foreign server:
114 </p><pre class="programlisting">
115 CREATE SERVER pglog FOREIGN DATA WRAPPER file_fdw;
118 Now you are ready to create the foreign data table. Using the
119 <code class="command">CREATE FOREIGN TABLE</code> command, you will need to define
120 the columns for the table, the CSV file name, and its format:
122 </p><pre class="programlisting">
123 CREATE FOREIGN TABLE pglog (
124 log_time timestamp(3) with time zone,
128 connection_from text,
130 session_line_num bigint,
132 session_start_time timestamp with time zone,
133 virtual_transaction_id text,
134 transaction_id bigint,
141 internal_query_pos integer,
146 application_name text,
151 OPTIONS ( filename 'log/pglog.csv', format 'csv' );
154 That's it — now you can query your log directly. In production, of
155 course, you would need to define some way to deal with log rotation.
156 </p></div></div><br class="example-break" /><div class="example" id="id-1.11.7.25.15"><p class="title"><strong>Example F.2. Create a Foreign Table with an Option on a Column</strong></p><div class="example-contents"><p>
157 To set the <code class="literal">force_null</code> option for a column, use the
158 <code class="literal">OPTIONS</code> keyword.
159 </p><pre class="programlisting">
160 CREATE FOREIGN TABLE films (
161 code char(5) NOT NULL,
163 rating text OPTIONS (force_null 'true')
165 OPTIONS ( filename 'films/db.csv', format 'csv' );
166 </pre></div></div><br class="example-break" /></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="earthdistance.html" title="F.14. earthdistance — calculate great-circle distances">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="contrib.html" title="Appendix F. Additional Supplied Modules and Extensions">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="fuzzystrmatch.html" title="F.16. fuzzystrmatch — determine string similarities and distance">Next</a></td></tr><tr><td width="40%" align="left" valign="top">F.14. earthdistance — calculate great-circle distances </td><td width="20%" align="center"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="40%" align="right" valign="top"> F.16. fuzzystrmatch — determine string similarities and distance</td></tr></table></div></body></html>