Commit 0e1f6d81 authored by Bruce Momjian's avatar Bruce Momjian

PL/pgSQL docs: recommend format() for query construction

Previously only concatenation was recommended.

Report by Pavel Stehule
parent 376a0c45
...@@ -2998,14 +2998,15 @@ ...@@ -2998,14 +2998,15 @@
<para> <para>
<literal>I</literal> treats the argument value as an SQL <literal>I</literal> treats the argument value as an SQL
identifier, double-quoting it if necessary. identifier, double-quoting it if necessary.
It is an error for the value to be null. It is an error for the value to be null (equivalent to
<function>quote_ident</>).
</para> </para>
</listitem> </listitem>
<listitem> <listitem>
<para> <para>
<literal>L</literal> quotes the argument value as an SQL literal. <literal>L</literal> quotes the argument value as an SQL literal.
A null value is displayed as the string <literal>NULL</>, without A null value is displayed as the string <literal>NULL</>, without
quotes. quotes (equivalent to <function>quote_nullable</function>).
</para> </para>
</listitem> </listitem>
</itemizedlist> </itemizedlist>
......
...@@ -1217,10 +1217,19 @@ EXECUTE 'SELECT count(*) FROM mytable WHERE inserted_by = $1 AND inserted &lt;= ...@@ -1217,10 +1217,19 @@ EXECUTE 'SELECT count(*) FROM mytable WHERE inserted_by = $1 AND inserted &lt;=
dynamically selected table, you could do this: dynamically selected table, you could do this:
<programlisting> <programlisting>
EXECUTE 'SELECT count(*) FROM ' EXECUTE 'SELECT count(*) FROM '
|| tabname::regclass || quote_ident(tabname)
|| ' WHERE inserted_by = $1 AND inserted &lt;= $2' || ' WHERE inserted_by = $1 AND inserted &lt;= $2'
INTO c INTO c
USING checked_user, checked_date; USING checked_user, checked_date;
</programlisting>
A cleaner approach is to use <function>format()</>'s <literal>%I</>
specification for table or column names (strings separated by a
newline are concatenated):
<programlisting>
EXECUTE format('SELECT count(*) FROM %I '
'WHERE inserted_by = $1 AND inserted &lt;= $2', tabname)
INTO c
USING checked_user, checked_date;
</programlisting> </programlisting>
Another restriction on parameter symbols is that they only work in Another restriction on parameter symbols is that they only work in
<command>SELECT</>, <command>INSERT</>, <command>UPDATE</>, and <command>SELECT</>, <command>INSERT</>, <command>UPDATE</>, and
...@@ -1297,11 +1306,15 @@ EXECUTE 'SELECT count(*) FROM ' ...@@ -1297,11 +1306,15 @@ EXECUTE 'SELECT count(*) FROM '
</para> </para>
<para> <para>
Dynamic values that are to be inserted into the constructed Dynamic values require careful handling since they might contain
query require careful handling since they might themselves contain
quote characters. quote characters.
An example (this assumes that you are using dollar quoting for the An example using <function>format()</> (this assumes that you are
function as a whole, so the quote marks need not be doubled): dollar quoting the function body so quote marks need not be doubled):
<programlisting>
EXECUTE format('UPDATE tbl SET %I = $1 '
'WHERE key = $2', colname) USING newvalue, keyvalue;
</programlisting>
It is also possible to call the quoting functions directly:
<programlisting> <programlisting>
EXECUTE 'UPDATE tbl SET ' EXECUTE 'UPDATE tbl SET '
|| quote_ident(colname) || quote_ident(colname)
...@@ -1391,17 +1404,20 @@ EXECUTE 'UPDATE tbl SET ' ...@@ -1391,17 +1404,20 @@ EXECUTE 'UPDATE tbl SET '
<function>format</function> function (see <xref <function>format</function> function (see <xref
linkend="functions-string">). For example: linkend="functions-string">). For example:
<programlisting> <programlisting>
EXECUTE format('UPDATE tbl SET %I = %L WHERE key = %L', colname, newvalue, keyvalue); EXECUTE format('UPDATE tbl SET %I = %L '
'WHERE key = %L', colname, newvalue, keyvalue);
</programlisting> </programlisting>
<literal>%I</> is equivalent to <function>quote_ident</>, and
<literal>%L</> is equivalent to <function>quote_nullable</function>.
The <function>format</function> function can be used in conjunction with The <function>format</function> function can be used in conjunction with
the <literal>USING</literal> clause: the <literal>USING</literal> clause:
<programlisting> <programlisting>
EXECUTE format('UPDATE tbl SET %I = $1 WHERE key = $2', colname) EXECUTE format('UPDATE tbl SET %I = $1 WHERE key = $2', colname)
USING newvalue, keyvalue; USING newvalue, keyvalue;
</programlisting> </programlisting>
This form is more efficient, because the parameters This form is better because the variables are handled in their native
<literal>newvalue</literal> and <literal>keyvalue</literal> are not data type format, rather than unconditionally converting them to
converted to text. text and quoting them via <literal>%L</>. It is also more efficient.
</para> </para>
</example> </example>
...@@ -2352,10 +2368,8 @@ BEGIN ...@@ -2352,10 +2368,8 @@ BEGIN
-- Now "mviews" has one record from cs_materialized_views -- Now "mviews" has one record from cs_materialized_views
RAISE NOTICE 'Refreshing materialized view %s ...', quote_ident(mviews.mv_name); RAISE NOTICE 'Refreshing materialized view %s ...', quote_ident(mviews.mv_name);
EXECUTE 'TRUNCATE TABLE ' || quote_ident(mviews.mv_name); EXECUTE format('TRUNCATE TABLE %I', mviews.mv_name);
EXECUTE 'INSERT INTO ' EXECUTE format('INSERT INTO %I %s', mviews.mv_name, mviews.mv_query);
|| quote_ident(mviews.mv_name) || ' '
|| mviews.mv_query;
END LOOP; END LOOP;
RAISE NOTICE 'Done refreshing materialized views.'; RAISE NOTICE 'Done refreshing materialized views.';
...@@ -2968,7 +2982,8 @@ OPEN <replaceable>unbound_cursorvar</replaceable> <optional> <optional> NO </opt ...@@ -2968,7 +2982,8 @@ OPEN <replaceable>unbound_cursorvar</replaceable> <optional> <optional> NO </opt
from one run to the next (see <xref linkend="plpgsql-plan-caching">), from one run to the next (see <xref linkend="plpgsql-plan-caching">),
and it also means that variable substitution is not done on the and it also means that variable substitution is not done on the
command string. As with <command>EXECUTE</command>, parameter values command string. As with <command>EXECUTE</command>, parameter values
can be inserted into the dynamic command via <literal>USING</>. can be inserted into the dynamic command via
<literal>format()</> and <literal>USING</>.
The <literal>SCROLL</> and The <literal>SCROLL</> and
<literal>NO SCROLL</> options have the same meanings as for a bound <literal>NO SCROLL</> options have the same meanings as for a bound
cursor. cursor.
...@@ -2977,13 +2992,12 @@ OPEN <replaceable>unbound_cursorvar</replaceable> <optional> <optional> NO </opt ...@@ -2977,13 +2992,12 @@ OPEN <replaceable>unbound_cursorvar</replaceable> <optional> <optional> NO </opt
<para> <para>
An example: An example:
<programlisting> <programlisting>
OPEN curs1 FOR EXECUTE 'SELECT * FROM ' || quote_ident(tabname) OPEN curs1 FOR EXECUTE format('SELECT * FROM %I WHERE col1 = $1',tabname) USING keyvalue;
|| ' WHERE col1 = $1' USING keyvalue;
</programlisting> </programlisting>
In this example, the table name is inserted into the query textually, In this example, the table name is inserted into the query via
so use of <function>quote_ident()</> is recommended to guard against <function>format()</>. The comparison value for <literal>col1</>
SQL injection. The comparison value for <literal>col1</> is inserted is inserted via a <literal>USING</> parameter, so it needs
via a <literal>USING</> parameter, so it needs no quoting. no quoting.
</para> </para>
</sect3> </sect3>
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment