On Thu, Mar 19, 2015 at 06:05:52PM -0700, David G. Johnston wrote:
> On Thu, Mar 19, 2015 at 5:18 PM, Bruce Momjian <[email protected]> wrote:
> There are other places later in the docs where we explain all the quote*
> functions and show examples of query construction using string
> concatenation, but I am not sure how we can remove those.
>
>
>
> Can you be more specific?
Yes. You can see the output of the attached patch here:
http://momjian.us/tmp/pgsql/plpgsql-statements.html#PLPGSQL-STATEMENTS-EXECUTING-DYN
Notice:
EXECUTE 'UPDATE tbl SET '
|| quote_ident(colname)
|| ' = '
|| quote_nullable(newvalue)
|| ' WHERE key = '
|| quote_nullable(keyvalue);
and
EXECUTE 'UPDATE tbl SET '
|| quote_ident(colname)
|| ' = $$'
|| newvalue
|| '$$ WHERE key = '
|| quote_literal(keyvalue);
It is making a point about nulls and stuff. There are later queries
that use format().
> On a related note:
>
> "If you are dealing with values that might be null, you should usually use
> quote_nullable in place of quote_literal."
>
> Its unclear why, aside from semantic uncleanliness, someone would use
> quote_literal given its identical behavior for non-null values and inferior
> behavior which passed NULL. The function table for the two could maybe be
> more
> clear since quote_nullable(NULL) returns a string representation of NULL
> without any quotes while quote_literal(NULL) returns an actual NULL that
> ultimately poisons the string concatenation that these functions are used
> with.
>
> <reads some more>
>
> The differences between the actual null and the string NULL are strictly in
> capitalization - which is not consistent even within the table. concat_ws
> states "NULL arguments are ignored" and so represents actual null with
> all-caps
> which is string NULL in the quote_* descriptions. Having read 40.5.4 and
> example 40-1 the difference is clear and obvious so maybe what is in the table
> is sufficient for this topic.
>
> I would suggest adding a comment to quote_ident and quote_nullable that
> corresponding format codes are %I and %L. Obviously there is no "quote_"
> function to correspond with %S. There is likewise nor corresponding format
> code for quote_literal since quote_nullable is superior in every way (that I
> can tell at least).
OK, I have added that tip --- good suggestion. Patch attached.
--
Bruce Momjian <[email protected]> http://momjian.us
EnterpriseDB http://enterprisedb.com
+ Everyone has their own god. +
diff --git a/doc/src/sgml/plpgsql.sgml b/doc/src/sgml/plpgsql.sgml
new file mode 100644
index 158d9d2..aee8264
*** a/doc/src/sgml/plpgsql.sgml
--- b/doc/src/sgml/plpgsql.sgml
*************** EXECUTE 'SELECT count(*) FROM '
*** 1222,1227 ****
--- 1222,1234 ----
INTO c
USING checked_user, checked_date;
</programlisting>
+ A cleaner approach is to use <function>format()</>'s <literal>%I</>
+ specification for table or column names:
+ <programlisting>
+ EXECUTE format('SELECT count(*) FROM %I WHERE inserted_by = $1 AND inserted <= $2', tabname)
+ INTO c
+ USING checked_user, checked_date;
+ </programlisting>
Another restriction on parameter symbols is that they only work in
<command>SELECT</>, <command>INSERT</>, <command>UPDATE</>, and
<command>DELETE</> commands. In other statement
*************** EXECUTE 'SELECT count(*) FROM '
*** 1297,1307 ****
</para>
<para>
! Dynamic values that are to be inserted into the constructed
! query require careful handling since they might themselves contain
quote characters.
! An example (this assumes that you are using dollar quoting for the
! function as a whole, so the quote marks need not be doubled):
<programlisting>
EXECUTE 'UPDATE tbl SET '
|| quote_ident(colname)
--- 1304,1317 ----
</para>
<para>
! Dynamic values require careful handling since they might contain
quote characters.
! An example using <function>format()</> (this assumes that you are
! 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>
EXECUTE 'UPDATE tbl SET '
|| quote_ident(colname)
*************** EXECUTE 'UPDATE tbl SET '
*** 1393,1407 ****
<programlisting>
EXECUTE format('UPDATE tbl SET %I = %L WHERE key = %L', colname, newvalue, keyvalue);
</programlisting>
The <function>format</function> function can be used in conjunction with
the <literal>USING</literal> clause:
<programlisting>
EXECUTE format('UPDATE tbl SET %I = $1 WHERE key = $2', colname)
USING newvalue, keyvalue;
</programlisting>
! This form is more efficient, because the parameters
! <literal>newvalue</literal> and <literal>keyvalue</literal> are not
! converted to text.
</para>
</example>
--- 1403,1419 ----
<programlisting>
EXECUTE format('UPDATE tbl SET %I = %L WHERE key = %L', colname, newvalue, keyvalue);
</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 <literal>USING</literal> clause:
<programlisting>
EXECUTE format('UPDATE tbl SET %I = $1 WHERE key = $2', colname)
USING newvalue, keyvalue;
</programlisting>
! This form is better because the variables are handled in their native
! data type format, rather than unconditionally converting them to
! text and quoting them via <literal>%L</>. It is also more efficient.
</para>
</example>
*************** BEGIN
*** 2352,2361 ****
-- Now "mviews" has one record from cs_materialized_views
RAISE NOTICE 'Refreshing materialized view %s ...', quote_ident(mviews.mv_name);
! EXECUTE 'TRUNCATE TABLE ' || quote_ident(mviews.mv_name);
! EXECUTE 'INSERT INTO '
! || quote_ident(mviews.mv_name) || ' '
! || mviews.mv_query;
END LOOP;
RAISE NOTICE 'Done refreshing materialized views.';
--- 2364,2371 ----
-- Now "mviews" has one record from cs_materialized_views
RAISE NOTICE 'Refreshing materialized view %s ...', quote_ident(mviews.mv_name);
! EXECUTE format('TRUNCATE TABLE %I', mviews.mv_name);
! EXECUTE format('INSERT INTO %I %s', mviews.mv_name, mviews.mv_query);
END LOOP;
RAISE NOTICE 'Done refreshing materialized views.';
*************** OPEN <replaceable>unbound_cursorvar</rep
*** 2968,2974 ****
from one run to the next (see <xref linkend="plpgsql-plan-caching">),
and it also means that variable substitution is not done on the
command string. As with <command>EXECUTE</command>, parameter values
! can be inserted into the dynamic command via <literal>USING</>.
The <literal>SCROLL</> and
<literal>NO SCROLL</> options have the same meanings as for a bound
cursor.
--- 2978,2985 ----
from one run to the next (see <xref linkend="plpgsql-plan-caching">),
and it also means that variable substitution is not done on the
command string. As with <command>EXECUTE</command>, parameter values
! can be inserted into the dynamic command via
! <literal>format()</> and <literal>USING</>.
The <literal>SCROLL</> and
<literal>NO SCROLL</> options have the same meanings as for a bound
cursor.
*************** OPEN <replaceable>unbound_cursorvar</rep
*** 2977,2989 ****
<para>
An example:
<programlisting>
! OPEN curs1 FOR EXECUTE 'SELECT * FROM ' || quote_ident(tabname)
! || ' WHERE col1 = $1' USING keyvalue;
</programlisting>
! In this example, the table name is inserted into the query textually,
! so use of <function>quote_ident()</> is recommended to guard against
! SQL injection. The comparison value for <literal>col1</> is inserted
! via a <literal>USING</> parameter, so it needs no quoting.
</para>
</sect3>
--- 2988,2999 ----
<para>
An example:
<programlisting>
! OPEN curs1 FOR EXECUTE format('SELECT * FROM %I WHERE col1 = $1',tabname) USING keyvalue;
</programlisting>
! In this example, the table name is inserted into the query via
! <function>format()</>. The comparison value for <literal>col1</>
! is inserted via a <literal>USING</> parameter, so it needs
! no quoting.
</para>
</sect3>
--
Sent via pgsql-hackers mailing list ([email protected])
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers