Commit 8295c27c authored by Neil Conway's avatar Neil Conway

Add documentation for the new "dollar quoting" feature, and update existing

examples to use dollar quoting when appropriate. Original patch from David
Fetter, additional work and editorializing by Neil Conway.
parent 2871f60f
<!-- <!--
$PostgreSQL: pgsql/doc/src/sgml/plperl.sgml,v 2.22 2003/12/14 00:10:32 neilc Exp $ $PostgreSQL: pgsql/doc/src/sgml/plperl.sgml,v 2.23 2004/05/16 23:22:06 neilc Exp $
--> -->
<chapter id="plperl"> <chapter id="plperl">
...@@ -46,11 +46,17 @@ $PostgreSQL: pgsql/doc/src/sgml/plperl.sgml,v 2.22 2003/12/14 00:10:32 neilc Exp ...@@ -46,11 +46,17 @@ $PostgreSQL: pgsql/doc/src/sgml/plperl.sgml,v 2.22 2003/12/14 00:10:32 neilc Exp
<para> <para>
To create a function in the PL/Perl language, use the standard syntax: To create a function in the PL/Perl language, use the standard syntax:
<programlisting> <programlisting>
CREATE FUNCTION <replaceable>funcname</replaceable> (<replaceable>argument-types</replaceable>) RETURNS <replaceable>return-type</replaceable> AS ' CREATE FUNCTION <replaceable>funcname</replaceable>
(<replaceable>argument-types</replaceable>) RETURNS <replaceable>return-type</replaceable> AS $$
# PL/Perl function body # PL/Perl function body
' LANGUAGE plperl; $$ LANGUAGE plperl;
</programlisting> </programlisting>
The body of the function is ordinary Perl code. The body of the function is ordinary Perl code. Since the body of
the function is treated as a string by
<productname>PostgreSQL</productname>, it can be specified using
dollar quoting (as shown above), or via the usual single quote
syntax (see <xref linkend="sql-syntax-strings"> for more
information).
</para> </para>
<para> <para>
...@@ -65,10 +71,10 @@ CREATE FUNCTION <replaceable>funcname</replaceable> (<replaceable>argument-types ...@@ -65,10 +71,10 @@ CREATE FUNCTION <replaceable>funcname</replaceable> (<replaceable>argument-types
could be defined as: could be defined as:
<programlisting> <programlisting>
CREATE FUNCTION perl_max (integer, integer) RETURNS integer AS ' CREATE FUNCTION perl_max (integer, integer) RETURNS integer AS $$
if ($_[0] > $_[1]) { return $_[0]; } if ($_[0] > $_[1]) { return $_[0]; }
return $_[1]; return $_[1];
' LANGUAGE plperl; $$ LANGUAGE plperl;
</programlisting> </programlisting>
</para> </para>
...@@ -88,7 +94,7 @@ CREATE FUNCTION perl_max (integer, integer) RETURNS integer AS ' ...@@ -88,7 +94,7 @@ CREATE FUNCTION perl_max (integer, integer) RETURNS integer AS '
rather than a null value: rather than a null value:
<programlisting> <programlisting>
CREATE FUNCTION perl_max (integer, integer) RETURNS integer AS ' CREATE FUNCTION perl_max (integer, integer) RETURNS integer AS $$
my ($a,$b) = @_; my ($a,$b) = @_;
if (! defined $a) { if (! defined $a) {
if (! defined $b) { return undef; } if (! defined $b) { return undef; }
...@@ -97,7 +103,7 @@ CREATE FUNCTION perl_max (integer, integer) RETURNS integer AS ' ...@@ -97,7 +103,7 @@ CREATE FUNCTION perl_max (integer, integer) RETURNS integer AS '
if (! defined $b) { return $a; } if (! defined $b) { return $a; }
if ($a > $b) { return $a; } if ($a > $b) { return $a; }
return $b; return $b;
' LANGUAGE plperl; $$ LANGUAGE plperl;
</programlisting> </programlisting>
</para> </para>
...@@ -119,10 +125,10 @@ CREATE TABLE employee ( ...@@ -119,10 +125,10 @@ CREATE TABLE employee (
bonus integer bonus integer
); );
CREATE FUNCTION empcomp(employee) RETURNS integer AS ' CREATE FUNCTION empcomp(employee) RETURNS integer AS $$
my ($emp) = @_; my ($emp) = @_;
return $emp->{''basesalary''} + $emp->{''bonus''}; return $emp->{'basesalary'} + $emp->{'bonus'};
' LANGUAGE plperl; $$ LANGUAGE plperl;
SELECT name, empcomp(employee) FROM employee; SELECT name, empcomp(employee) FROM employee;
</programlisting> </programlisting>
...@@ -136,12 +142,12 @@ SELECT name, empcomp(employee) FROM employee; ...@@ -136,12 +142,12 @@ SELECT name, empcomp(employee) FROM employee;
<tip> <tip>
<para> <para>
Because the function body is passed as an SQL string literal to Because the function body is passed as an SQL string literal to
<command>CREATE FUNCTION</command>, you have to escape single <command>CREATE FUNCTION</command>, you have to use dollar quoting
quotes and backslashes within your Perl source, typically by or escape single quotes and backslashes within your Perl source,
doubling them as shown in the above example. Another possible typically by doubling them. Another possible approach is to avoid
approach is to avoid writing single quotes by using Perl's writing single quotes by using Perl's extended quoting operators
extended quoting operators (<literal>q[]</literal>, (<literal>q[]</literal>, <literal>qq[]</literal>,
<literal>qq[]</literal>, <literal>qw[]</literal>). <literal>qw[]</literal>).
</para> </para>
</tip> </tip>
</sect1> </sect1>
...@@ -226,11 +232,11 @@ SELECT name, empcomp(employee) FROM employee; ...@@ -226,11 +232,11 @@ SELECT name, empcomp(employee) FROM employee;
Here is an example of a function that will not work because file Here is an example of a function that will not work because file
system operations are not allowed for security reasons: system operations are not allowed for security reasons:
<programlisting> <programlisting>
CREATE FUNCTION badfunc() RETURNS integer AS ' CREATE FUNCTION badfunc() RETURNS integer AS $$
open(TEMP, ">/tmp/badfile"); open(TEMP, ">/tmp/badfile");
print TEMP "Gotcha!\n"; print TEMP "Gotcha!\n";
return 1; return 1;
' LANGUAGE plperl; $$ LANGUAGE plperl;
</programlisting> </programlisting>
The creation of the function will succeed, but executing it will not. The creation of the function will succeed, but executing it will not.
</para> </para>
......
This diff is collapsed.
<!-- $PostgreSQL: pgsql/doc/src/sgml/plpython.sgml,v 1.22 2003/11/29 19:51:37 pgsql Exp $ --> <!-- $PostgreSQL: pgsql/doc/src/sgml/plpython.sgml,v 1.23 2004/05/16 23:22:07 neilc Exp $ -->
<chapter id="plpython"> <chapter id="plpython">
<title>PL/Python - Python Procedural Language</title> <title>PL/Python - Python Procedural Language</title>
...@@ -230,14 +230,14 @@ rv = plpy.execute(plan, [ "name" ], 5) ...@@ -230,14 +230,14 @@ rv = plpy.execute(plan, [ "name" ], 5)
<literal>SD</literal> or <literal>GD</literal> (see <literal>SD</literal> or <literal>GD</literal> (see
<xref linkend="plpython-funcs">). For example: <xref linkend="plpython-funcs">). For example:
<programlisting> <programlisting>
CREATE FUNCTION usesavedplan() RETURNS trigger AS ' CREATE FUNCTION usesavedplan() RETURNS trigger AS $$
if SD.has_key("plan"): if SD.has_key("plan"):
plan = SD["plan"] plan = SD["plan"]
else: else:
plan = plpy.prepare("SELECT 1") plan = plpy.prepare("SELECT 1")
SD["plan"] = plan SD["plan"] = plan
# rest of function # rest of function
' LANGUAGE plpythonu; $$ LANGUAGE plpythonu;
</programlisting> </programlisting>
</para> </para>
</sect1> </sect1>
......
<!-- <!--
$PostgreSQL: pgsql/doc/src/sgml/pltcl.sgml,v 2.29 2004/01/24 23:06:29 tgl Exp $ $PostgreSQL: pgsql/doc/src/sgml/pltcl.sgml,v 2.30 2004/05/16 23:22:07 neilc Exp $
--> -->
<chapter id="pltcl"> <chapter id="pltcl">
...@@ -77,9 +77,10 @@ $PostgreSQL: pgsql/doc/src/sgml/pltcl.sgml,v 2.29 2004/01/24 23:06:29 tgl Exp $ ...@@ -77,9 +77,10 @@ $PostgreSQL: pgsql/doc/src/sgml/pltcl.sgml,v 2.29 2004/01/24 23:06:29 tgl Exp $
To create a function in the <application>PL/Tcl</> language, use the standard syntax: To create a function in the <application>PL/Tcl</> language, use the standard syntax:
<programlisting> <programlisting>
CREATE FUNCTION <replaceable>funcname</replaceable> (<replaceable>argument-types</replaceable>) RETURNS <replaceable>return-type</replaceable> AS ' CREATE FUNCTION <replaceable>funcname</replaceable>
(<replaceable>argument-types</replaceable>) RETURNS <replaceable>return-type</replaceable> AS $$
# PL/Tcl function body # PL/Tcl function body
' LANGUAGE pltcl; $$ LANGUAGE pltcl;
</programlisting> </programlisting>
<application>PL/TclU</> is the same, except that the language has to be specified as <application>PL/TclU</> is the same, except that the language has to be specified as
...@@ -100,10 +101,10 @@ CREATE FUNCTION <replaceable>funcname</replaceable> (<replaceable>argument-types ...@@ -100,10 +101,10 @@ CREATE FUNCTION <replaceable>funcname</replaceable> (<replaceable>argument-types
returning the greater of two integer values could be defined as: returning the greater of two integer values could be defined as:
<programlisting> <programlisting>
CREATE FUNCTION tcl_max(integer, integer) RETURNS integer AS ' CREATE FUNCTION tcl_max(integer, integer) RETURNS integer AS $$
if {$1 > $2} {return $1} if {$1 > $2} {return $1}
return $2 return $2
' LANGUAGE pltcl STRICT; $$ LANGUAGE pltcl STRICT;
</programlisting> </programlisting>
Note the clause <literal>STRICT</>, which saves us from Note the clause <literal>STRICT</>, which saves us from
...@@ -122,7 +123,7 @@ CREATE FUNCTION tcl_max(integer, integer) RETURNS integer AS ' ...@@ -122,7 +123,7 @@ CREATE FUNCTION tcl_max(integer, integer) RETURNS integer AS '
argument, rather than null: argument, rather than null:
<programlisting> <programlisting>
CREATE FUNCTION tcl_max(integer, integer) RETURNS integer AS ' CREATE FUNCTION tcl_max(integer, integer) RETURNS integer AS $$
if {[argisnull 1]} { if {[argisnull 1]} {
if {[argisnull 2]} { return_null } if {[argisnull 2]} { return_null }
return $2 return $2
...@@ -130,7 +131,7 @@ CREATE FUNCTION tcl_max(integer, integer) RETURNS integer AS ' ...@@ -130,7 +131,7 @@ CREATE FUNCTION tcl_max(integer, integer) RETURNS integer AS '
if {[argisnull 2]} { return $1 } if {[argisnull 2]} { return $1 }
if {$1 > $2} {return $1} if {$1 > $2} {return $1}
return $2 return $2
' LANGUAGE pltcl; $$ LANGUAGE pltcl;
</programlisting> </programlisting>
</para> </para>
...@@ -154,7 +155,7 @@ CREATE TABLE employee ( ...@@ -154,7 +155,7 @@ CREATE TABLE employee (
age integer age integer
); );
CREATE FUNCTION overpaid(employee) RETURNS boolean AS ' CREATE FUNCTION overpaid(employee) RETURNS boolean AS $$
if {200000.0 < $1(salary)} { if {200000.0 < $1(salary)} {
return "t" return "t"
} }
...@@ -162,7 +163,7 @@ CREATE FUNCTION overpaid(employee) RETURNS boolean AS ' ...@@ -162,7 +163,7 @@ CREATE FUNCTION overpaid(employee) RETURNS boolean AS '
return "t" return "t"
} }
return "f" return "f"
' LANGUAGE pltcl; $$ LANGUAGE pltcl;
</programlisting> </programlisting>
</para> </para>
...@@ -359,25 +360,24 @@ spi_exec -array C "SELECT * FROM pg_class" { ...@@ -359,25 +360,24 @@ spi_exec -array C "SELECT * FROM pg_class" {
Here's an example of a PL/Tcl function using a prepared plan: Here's an example of a PL/Tcl function using a prepared plan:
<programlisting> <programlisting>
CREATE FUNCTION t1_count(integer, integer) RETURNS integer AS ' CREATE FUNCTION t1_count(integer, integer) RETURNS integer AS $$
if {![ info exists GD(plan) ]} { if {![ info exists GD(plan) ]} {
# prepare the saved plan on the first call # prepare the saved plan on the first call
set GD(plan) [ spi_prepare \\ set GD(plan) [ spi_prepare \
"SELECT count(*) AS cnt FROM t1 WHERE num &gt;= \\$1 AND num &lt;= \\$2" \\ "SELECT count(*) AS cnt FROM t1 WHERE num &gt;= \$1 AND num &lt;= \$2" \
[ list int4 int4 ] ] [ list int4 int4 ] ]
} }
spi_execp -count 1 $GD(plan) [ list $1 $2 ] spi_execp -count 1 $GD(plan) [ list $1 $2 ]
return $cnt return $cnt
' LANGUAGE pltcl; $$ LANGUAGE pltcl;
</programlisting> </programlisting>
Note that each backslash that Tcl should see must be doubled when We need backslashes inside the query string given to
we type in the function, since the main parser processes <function>spi_prepare</> to ensure that the
backslashes, too, in <command>CREATE FUNCTION</>. We need backslashes inside <literal>$<replaceable>n</replaceable></> markers will be passed
the query string given to <function>spi_prepare</> to ensure that through to <function>spi_prepare</> as-is, and not replaced by Tcl
the <literal>$<replaceable>n</replaceable></> markers will be passed through to variable substitution.
<function>spi_prepare</> as-is, and not
replaced by Tcl variable substitution.
</para> </para>
</listitem> </listitem>
</varlistentry> </varlistentry>
...@@ -425,7 +425,7 @@ SELECT 'doesn't' AS ret ...@@ -425,7 +425,7 @@ SELECT 'doesn't' AS ret
The submitted command should contain The submitted command should contain
<programlisting> <programlisting>
SELECT 'doesn''t' AS ret SELECT $q$doesn't$q$ AS ret
</programlisting> </programlisting>
which can be formed in PL/Tcl using which can be formed in PL/Tcl using
...@@ -611,7 +611,7 @@ SELECT 'doesn''t' AS ret ...@@ -611,7 +611,7 @@ SELECT 'doesn''t' AS ret
incremented on every update operation. incremented on every update operation.
<programlisting> <programlisting>
CREATE FUNCTION trigfunc_modcount() RETURNS trigger AS ' CREATE FUNCTION trigfunc_modcount() RETURNS trigger AS $$
switch $TG_op { switch $TG_op {
INSERT { INSERT {
set NEW($1) 0 set NEW($1) 0
...@@ -625,7 +625,7 @@ CREATE FUNCTION trigfunc_modcount() RETURNS trigger AS ' ...@@ -625,7 +625,7 @@ CREATE FUNCTION trigfunc_modcount() RETURNS trigger AS '
} }
} }
return [array get NEW] return [array get NEW]
' LANGUAGE pltcl; $$ LANGUAGE pltcl;
CREATE TABLE mytab (num integer, description text, modcnt integer); CREATE TABLE mytab (num integer, description text, modcnt integer);
......
<!-- $PostgreSQL: pgsql/doc/src/sgml/queries.sgml,v 1.29 2004/03/03 22:22:24 neilc Exp $ --> <!-- $PostgreSQL: pgsql/doc/src/sgml/queries.sgml,v 1.30 2004/05/16 23:22:07 neilc Exp $ -->
<chapter id="queries"> <chapter id="queries">
<title>Queries</title> <title>Queries</title>
...@@ -631,9 +631,9 @@ FROM (SELECT * FROM table1) AS alias_name ...@@ -631,9 +631,9 @@ FROM (SELECT * FROM table1) AS alias_name
<programlisting> <programlisting>
CREATE TABLE foo (fooid int, foosubid int, fooname text); CREATE TABLE foo (fooid int, foosubid int, fooname text);
CREATE FUNCTION getfoo(int) RETURNS SETOF foo AS ' CREATE FUNCTION getfoo(int) RETURNS SETOF foo AS $$
SELECT * FROM foo WHERE fooid = $1; SELECT * FROM foo WHERE fooid = $1;
' LANGUAGE SQL; $$ LANGUAGE SQL;
SELECT * FROM getfoo(1) AS t1; SELECT * FROM getfoo(1) AS t1;
......
<!-- <!--
$PostgreSQL: pgsql/doc/src/sgml/ref/create_function.sgml,v 1.55 2003/11/29 19:51:38 pgsql Exp $ $PostgreSQL: pgsql/doc/src/sgml/ref/create_function.sgml,v 1.56 2004/05/16 23:22:07 neilc Exp $
--> -->
<refentry id="SQL-CREATEFUNCTION"> <refentry id="SQL-CREATEFUNCTION">
...@@ -54,10 +54,10 @@ CREATE [ OR REPLACE ] FUNCTION <replaceable class="parameter">name</replaceable> ...@@ -54,10 +54,10 @@ CREATE [ OR REPLACE ] FUNCTION <replaceable class="parameter">name</replaceable>
To update the definition of an existing function, use To update the definition of an existing function, use
<command>CREATE OR REPLACE FUNCTION</command>. It is not possible <command>CREATE OR REPLACE FUNCTION</command>. It is not possible
to change the name or argument types of a function this way (if you to change the name or argument types of a function this way (if you
tried, you'd just be creating a new, distinct function). Also, tried, you would actually be creating a new, distinct function).
<command>CREATE OR REPLACE FUNCTION</command> will not let you Also, <command>CREATE OR REPLACE FUNCTION</command> will not let
change the return type of an existing function. To do that, you you change the return type of an existing function. To do that,
must drop and recreate the function. you must drop and recreate the function.
</para> </para>
<para> <para>
...@@ -250,7 +250,14 @@ CREATE [ OR REPLACE ] FUNCTION <replaceable class="parameter">name</replaceable> ...@@ -250,7 +250,14 @@ CREATE [ OR REPLACE ] FUNCTION <replaceable class="parameter">name</replaceable>
<para> <para>
A string defining the function; the meaning depends on the A string defining the function; the meaning depends on the
language. It may be an internal function name, the path to an language. It may be an internal function name, the path to an
object file, an SQL command, or text in a procedural language. object file, an SQL command, or text in a procedural
language. When this string contains the text of a procedural
language function definition, it may be helpful to use dollar
quoting to specify this string, rather than the normal single
quote syntax (this avoids the need to escape any single quotes
that occur in the function definition itself). For more
information on dollar quoting, see <xref
linkend="sql-syntax-strings">.
</para> </para>
</listitem> </listitem>
</varlistentry> </varlistentry>
...@@ -350,13 +357,14 @@ CREATE [ OR REPLACE ] FUNCTION <replaceable class="parameter">name</replaceable> ...@@ -350,13 +357,14 @@ CREATE [ OR REPLACE ] FUNCTION <replaceable class="parameter">name</replaceable>
</para> </para>
<para> <para>
Use <command>DROP FUNCTION</command> Use <xref linkend="sql-dropfunction"
to remove user-defined functions. endterm="sql-dropfunction-title"> to remove user-defined
functions.
</para> </para>
<para> <para>
Any single quotes or backslashes in the function definition must be Unless dollar quoting is used, any single quotes or backslashes in
escaped by doubling them. the function definition must be escaped by doubling them.
</para> </para>
<para> <para>
...@@ -374,7 +382,7 @@ CREATE [ OR REPLACE ] FUNCTION <replaceable class="parameter">name</replaceable> ...@@ -374,7 +382,7 @@ CREATE [ OR REPLACE ] FUNCTION <replaceable class="parameter">name</replaceable>
information and examples, see <xref linkend="xfunc">. information and examples, see <xref linkend="xfunc">.
<programlisting> <programlisting>
CREATE FUNCTION add(integer, integer) RETURNS integer CREATE FUNCTION add(integer, integer) RETURNS integer
AS 'select $1 + $2;' AS $$select $1 + $2;$$
LANGUAGE SQL LANGUAGE SQL
IMMUTABLE IMMUTABLE
RETURNS NULL ON NULL INPUT; RETURNS NULL ON NULL INPUT;
......
<!-- <!--
$PostgreSQL: pgsql/doc/src/sgml/ref/create_type.sgml,v 1.49 2004/02/12 23:41:02 tgl Exp $ $PostgreSQL: pgsql/doc/src/sgml/ref/create_type.sgml,v 1.50 2004/05/16 23:22:07 neilc Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -466,8 +466,9 @@ CREATE TYPE <replaceable class="parameter">name</replaceable> ( ...@@ -466,8 +466,9 @@ CREATE TYPE <replaceable class="parameter">name</replaceable> (
a function definition: a function definition:
<programlisting> <programlisting>
CREATE TYPE compfoo AS (f1 int, f2 text); CREATE TYPE compfoo AS (f1 int, f2 text);
CREATE FUNCTION getfoo() RETURNS SETOF compfoo AS CREATE FUNCTION getfoo() RETURNS SETOF compfoo AS $$
'SELECT fooid, fooname FROM foo' LANGUAGE SQL; SELECT fooid, fooname FROM foo
$$ LANGUAGE SQL;
</programlisting> </programlisting>
</para> </para>
......
<!-- <!--
$PostgreSQL: pgsql/doc/src/sgml/ref/select.sgml,v 1.76 2004/03/09 16:57:47 neilc Exp $ $PostgreSQL: pgsql/doc/src/sgml/ref/select.sgml,v 1.77 2004/05/16 23:22:08 neilc Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -938,18 +938,18 @@ SELECT actors.name ...@@ -938,18 +938,18 @@ SELECT actors.name
clause, both with and without a column definition list: clause, both with and without a column definition list:
<programlisting> <programlisting>
CREATE FUNCTION distributors(int) RETURNS SETOF distributors AS ' CREATE FUNCTION distributors(int) RETURNS SETOF distributors AS $$
SELECT * FROM distributors WHERE did = $1; SELECT * FROM distributors WHERE did = $1;
' LANGUAGE SQL; $$ LANGUAGE SQL;
SELECT * FROM distributors(111); SELECT * FROM distributors(111);
did | name did | name
-----+------------- -----+-------------
111 | Walt Disney 111 | Walt Disney
CREATE FUNCTION distributors_2(int) RETURNS SETOF record AS ' CREATE FUNCTION distributors_2(int) RETURNS SETOF record AS $$
SELECT * FROM distributors WHERE did = $1; SELECT * FROM distributors WHERE did = $1;
' LANGUAGE SQL; $$ LANGUAGE SQL;
SELECT * FROM distributors_2(111) AS (f1 int, f2 text); SELECT * FROM distributors_2(111) AS (f1 int, f2 text);
f1 | f2 f1 | f2
......
<!-- $PostgreSQL: pgsql/doc/src/sgml/rules.sgml,v 1.34 2004/03/09 05:05:40 momjian Exp $ --> <!-- $PostgreSQL: pgsql/doc/src/sgml/rules.sgml,v 1.35 2004/05/16 23:22:07 neilc Exp $ -->
<Chapter Id="rules"> <Chapter Id="rules">
<Title>The Rule System</Title> <Title>The Rule System</Title>
...@@ -343,9 +343,9 @@ For the example, we need a little <literal>min</literal> function that ...@@ -343,9 +343,9 @@ For the example, we need a little <literal>min</literal> function that
returns the lower of 2 integer values. We create that as returns the lower of 2 integer values. We create that as
<ProgramListing> <ProgramListing>
CREATE FUNCTION min(integer, integer) RETURNS integer AS ' CREATE FUNCTION min(integer, integer) RETURNS integer AS $$
SELECT CASE WHEN $1 < $2 THEN $1 ELSE $2 END SELECT CASE WHEN $1 < $2 THEN $1 ELSE $2 END
' LANGUAGE SQL STRICT; $$ LANGUAGE SQL STRICT;
</ProgramListing> </ProgramListing>
</Para> </Para>
......
<!-- <!--
$PostgreSQL: pgsql/doc/src/sgml/syntax.sgml,v 1.91 2004/05/10 22:44:43 tgl Exp $ $PostgreSQL: pgsql/doc/src/sgml/syntax.sgml,v 1.92 2004/05/16 23:22:07 neilc Exp $
--> -->
<chapter id="sql-syntax"> <chapter id="sql-syntax">
...@@ -240,15 +240,73 @@ UPDATE "my_table" SET "a" = 5; ...@@ -240,15 +240,73 @@ UPDATE "my_table" SET "a" = 5;
<primary>quotation marks</primary> <primary>quotation marks</primary>
<secondary>escaping</secondary> <secondary>escaping</secondary>
</indexterm> </indexterm>
A string constant in SQL is an arbitrary sequence of characters <indexterm>
bounded by single quotes (<literal>'</literal>), e.g., <literal>'This <primary>dollar quoting</primary>
is a string'</literal>. SQL allows single quotes to be embedded </indexterm>
in strings by typing two adjacent single quotes, e.g., <productname>PostgreSQL</productname> provides two ways to
<literal>'Dianne''s horse'</literal>. In specify a string constant. The first way is to enclose the
<productname>PostgreSQL</productname> single quotes may sequence of characters that constitute the string in single
alternatively be escaped with a backslash (<literal>\</literal>), quotes (<literal>'</literal>), e.g. <literal>'This is a
e.g., <literal>'Dianne\'s horse'</literal>. string'</literal>. This method of specifying a string constant
</para> is defined by the SQL standard. The standard-compliant way of
embedding single-quotes these kinds of string constants is by
typing two adjacent single quotes, e.g. <literal>'Dianne''s
house'</literal>. In addition,
<productname>PostgreSQL</productname> allows single quotes
to be escaped with a backslash (<literal>\</literal>),
e.g. <literal>'Dianne\'s horse'</literal>.
</para>
<para>
While this syntax for specifying string constants is usually
convenient, it can be difficult to comprehend the content of the
string if it consists of many single quotes, each of which must
be doubled. To allows more readable queries in these situations,
<productname>PostgreSQL</productname> allows another way to
specify string constants known as <quote>dollar
quoting</quote>. A string constant specified via dollar quoting
consists of a dollar sign (<literal>$</literal>), an optional
<quote>tag</quote> of zero or more characters, another dollar
sign, an arbitrary sequence of characters that makes up the
string content, a dollar sign, the same tag that began this
dollar quote, and a dollar sign. For example, here are two
different ways to specify the previous example using dollar
quoting:
<programlisting>
$$Dianne's horse$$
$SomeTag$Dianne's horse$SomeTag$
</programlisting>
Note that inside the dollar-quoted string, single quotes can be
used without needing to be escaped.
</para>
<para>
Dollar quotes are case sensitive, so <literal>$tag$String
content$tag$</literal> is valid, but <literal>$TAG$String
content$tag$</literal> is not. Also, dollar quotes can
nest. For example:
<programlisting>
CREATE OR REPLACE FUNCTION has_bad_chars(text) RETURNS boolean AS
$function$
BEGIN
RETURN ($1 ~ $q$[\t\r\n\v|\\]$q$);
END;
$function$ LANGUAGE plpgsql;
</programlisting>
Note that nesting requires a different tag for each nested
dollar quote, as shown above. Furthermore, nested dollar quotes
can only be used when the content of the string that is being
quoted will be re-parsed by <productname>PostgreSQL</>.
</para>
<para>
Dollar quoting is not defined by the SQL standard, but it is
often a more convenient way to write long string literals (such
as procedural function definitions) than the standard-compliant
single quote syntax. Which quoting technique is most appropriate
for a particular circumstance is a decision that is left to the
user.
</para>
<para> <para>
C-style backslash escapes are also available: C-style backslash escapes are also available:
...@@ -1008,7 +1066,7 @@ $<replaceable>number</replaceable> ...@@ -1008,7 +1066,7 @@ $<replaceable>number</replaceable>
<programlisting> <programlisting>
CREATE FUNCTION dept(text) RETURNS dept CREATE FUNCTION dept(text) RETURNS dept
AS 'SELECT * FROM dept WHERE name = $1' AS $$SELECT * FROM dept WHERE name = $1$$
LANGUAGE SQL; LANGUAGE SQL;
</programlisting> </programlisting>
......
<!-- <!--
$PostgreSQL: pgsql/doc/src/sgml/xfunc.sgml,v 1.83 2004/05/14 21:42:27 neilc Exp $ $PostgreSQL: pgsql/doc/src/sgml/xfunc.sgml,v 1.84 2004/05/16 23:22:07 neilc Exp $
--> -->
<sect1 id="xfunc"> <sect1 id="xfunc">
...@@ -104,13 +104,13 @@ $PostgreSQL: pgsql/doc/src/sgml/xfunc.sgml,v 1.83 2004/05/14 21:42:27 neilc Exp ...@@ -104,13 +104,13 @@ $PostgreSQL: pgsql/doc/src/sgml/xfunc.sgml,v 1.83 2004/05/14 21:42:27 neilc Exp
<para> <para>
The body of an SQL function should be a list of one or more SQL The body of an SQL function should be a list of one or more SQL
statements separated by semicolons. Note that because the syntax statements separated by semicolons. Although dollar quoting
of the <command>CREATE FUNCTION</command> command requires the body of the obviates this, note that because the syntax of the <command>CREATE
function to be enclosed in single quotes, single quote marks FUNCTION</command> command, if you choose not to use dollar
(<literal>'</>) used quoting, i.e. the body of the function is enclosed in single quotes,
in the body of the function must be escaped, by writing two single you must escape single quote marks (<literal>'</>) used in the body of
quotes (<literal>''</>) or a backslash (<literal>\'</>) where each the function, either by writing two single quotes (<literal>''</>) or
quote is desired. with a backslash (<literal>\'</>) where you desire each quote to be.
</para> </para>
<para> <para>
...@@ -130,6 +130,11 @@ $PostgreSQL: pgsql/doc/src/sgml/xfunc.sgml,v 1.83 2004/05/14 21:42:27 neilc Exp ...@@ -130,6 +130,11 @@ $PostgreSQL: pgsql/doc/src/sgml/xfunc.sgml,v 1.83 2004/05/14 21:42:27 neilc Exp
simply returns a base type, such as <type>integer</type>: simply returns a base type, such as <type>integer</type>:
<screen> <screen>
CREATE FUNCTION one() RETURNS integer AS $$
SELECT 1 AS result;
$$ LANGUAGE SQL;
-- Alternative syntax:
CREATE FUNCTION one() RETURNS integer AS ' CREATE FUNCTION one() RETURNS integer AS '
SELECT 1 AS result; SELECT 1 AS result;
' LANGUAGE SQL; ' LANGUAGE SQL;
...@@ -156,9 +161,9 @@ SELECT one(); ...@@ -156,9 +161,9 @@ SELECT one();
and <literal>$2</>. and <literal>$2</>.
<screen> <screen>
CREATE FUNCTION add_em(integer, integer) RETURNS integer AS ' CREATE FUNCTION add_em(integer, integer) RETURNS integer AS $$
SELECT $1 + $2; SELECT $1 + $2;
' LANGUAGE SQL; $$ LANGUAGE SQL;
SELECT add_em(1, 2) AS answer; SELECT add_em(1, 2) AS answer;
...@@ -173,12 +178,12 @@ SELECT add_em(1, 2) AS answer; ...@@ -173,12 +178,12 @@ SELECT add_em(1, 2) AS answer;
bank account: bank account:
<programlisting> <programlisting>
CREATE FUNCTION tf1 (integer, numeric) RETURNS integer AS ' CREATE FUNCTION tf1 (integer, numeric) RETURNS integer AS $$
UPDATE bank UPDATE bank
SET balance = balance - $2 SET balance = balance - $2
WHERE accountno = $1; WHERE accountno = $1;
SELECT 1; SELECT 1;
' LANGUAGE SQL; $$ LANGUAGE SQL;
</programlisting> </programlisting>
A user could execute this function to debit account 17 by $100.00 as A user could execute this function to debit account 17 by $100.00 as
...@@ -195,12 +200,12 @@ SELECT tf1(17, 100.0); ...@@ -195,12 +200,12 @@ SELECT tf1(17, 100.0);
is is
<programlisting> <programlisting>
CREATE FUNCTION tf1 (integer, numeric) RETURNS numeric AS ' CREATE FUNCTION tf1 (integer, numeric) RETURNS numeric AS $$
UPDATE bank UPDATE bank
SET balance = balance - $2 SET balance = balance - $2
WHERE accountno = $1; WHERE accountno = $1;
SELECT balance FROM bank WHERE accountno = $1; SELECT balance FROM bank WHERE accountno = $1;
' LANGUAGE SQL; $$ LANGUAGE SQL;
</programlisting> </programlisting>
which adjusts the balance and returns the new balance. which adjusts the balance and returns the new balance.
...@@ -221,10 +226,10 @@ CREATE FUNCTION tf1 (integer, numeric) RETURNS numeric AS ' ...@@ -221,10 +226,10 @@ CREATE FUNCTION tf1 (integer, numeric) RETURNS numeric AS '
For example: For example:
<screen> <screen>
CREATE FUNCTION clean_emp() RETURNS void AS ' CREATE FUNCTION clean_emp() RETURNS void AS $$
DELETE FROM emp DELETE FROM emp
WHERE salary &lt;= 0; WHERE salary &lt;= 0;
' LANGUAGE SQL; $$ LANGUAGE SQL;
SELECT clean_emp(); SELECT clean_emp();
...@@ -258,9 +263,9 @@ CREATE TABLE emp ( ...@@ -258,9 +263,9 @@ CREATE TABLE emp (
cubicle point cubicle point
); );
CREATE FUNCTION double_salary(emp) RETURNS numeric AS ' CREATE FUNCTION double_salary(emp) RETURNS numeric AS $$
SELECT $1.salary * 2 AS salary; SELECT $1.salary * 2 AS salary;
' LANGUAGE SQL; $$ LANGUAGE SQL;
SELECT name, double_salary(emp.*) AS dream SELECT name, double_salary(emp.*) AS dream
FROM emp FROM emp
...@@ -304,12 +309,12 @@ SELECT name, double_salary(row(name, salary*1.1, age, cubicle)) AS dream ...@@ -304,12 +309,12 @@ SELECT name, double_salary(row(name, salary*1.1, age, cubicle)) AS dream
that returns a single <type>emp</type> row: that returns a single <type>emp</type> row:
<programlisting> <programlisting>
CREATE FUNCTION new_emp() RETURNS emp AS ' CREATE FUNCTION new_emp() RETURNS emp AS $$
SELECT text ''None'' AS name, SELECT text 'None' AS name,
1000 AS salary, 1000 AS salary,
25 AS age, 25 AS age,
point ''(2,2)'' AS cubicle; point '(2,2)' AS cubicle;
' LANGUAGE SQL; $$ LANGUAGE SQL;
</programlisting> </programlisting>
In this example we have specified each of the attributes In this example we have specified each of the attributes
...@@ -405,9 +410,9 @@ SELECT name(emp) AS youngster ...@@ -405,9 +410,9 @@ SELECT name(emp) AS youngster
result of the first function to it: result of the first function to it:
<screen> <screen>
CREATE FUNCTION getname(emp) RETURNS text AS ' CREATE FUNCTION getname(emp) RETURNS text AS $$
SELECT $1.name; SELECT $1.name;
' LANGUAGE SQL; $$ LANGUAGE SQL;
SELECT getname(new_emp()); SELECT getname(new_emp());
getname getname
...@@ -439,9 +444,9 @@ INSERT INTO foo VALUES (1, 1, 'Joe'); ...@@ -439,9 +444,9 @@ INSERT INTO foo VALUES (1, 1, 'Joe');
INSERT INTO foo VALUES (1, 2, 'Ed'); INSERT INTO foo VALUES (1, 2, 'Ed');
INSERT INTO foo VALUES (2, 1, 'Mary'); INSERT INTO foo VALUES (2, 1, 'Mary');
CREATE FUNCTION getfoo(int) RETURNS foo AS ' CREATE FUNCTION getfoo(int) RETURNS foo AS $$
SELECT * FROM foo WHERE fooid = $1; SELECT * FROM foo WHERE fooid = $1;
' LANGUAGE SQL; $$ LANGUAGE SQL;
SELECT *, upper(fooname) FROM getfoo(1) AS t1; SELECT *, upper(fooname) FROM getfoo(1) AS t1;
...@@ -478,9 +483,9 @@ SELECT *, upper(fooname) FROM getfoo(1) AS t1; ...@@ -478,9 +483,9 @@ SELECT *, upper(fooname) FROM getfoo(1) AS t1;
table <literal>foo</> has the same contents as above, and we say: table <literal>foo</> has the same contents as above, and we say:
<programlisting> <programlisting>
CREATE FUNCTION getfoo(int) RETURNS SETOF foo AS ' CREATE FUNCTION getfoo(int) RETURNS SETOF foo AS $$
SELECT * FROM foo WHERE fooid = $1; SELECT * FROM foo WHERE fooid = $1;
' LANGUAGE SQL; $$ LANGUAGE SQL;
SELECT * FROM getfoo(1) AS t1; SELECT * FROM getfoo(1) AS t1;
</programlisting> </programlisting>
...@@ -505,9 +510,9 @@ SELECT * FROM getfoo(1) AS t1; ...@@ -505,9 +510,9 @@ SELECT * FROM getfoo(1) AS t1;
select list: select list:
<screen> <screen>
CREATE FUNCTION listchildren(text) RETURNS SETOF text AS CREATE FUNCTION listchildren(text) RETURNS SETOF text AS $$
'SELECT name FROM nodes WHERE parent = $1' SELECT name FROM nodes WHERE parent = $1
LANGUAGE SQL; $$ LANGUAGE SQL;
SELECT * FROM nodes; SELECT * FROM nodes;
name | parent name | parent
...@@ -558,9 +563,9 @@ SELECT name, listchildren(name) FROM nodes; ...@@ -558,9 +563,9 @@ SELECT name, listchildren(name) FROM nodes;
function <function>make_array</function> that builds up an array function <function>make_array</function> that builds up an array
from two arbitrary data type elements: from two arbitrary data type elements:
<screen> <screen>
CREATE FUNCTION make_array(anyelement, anyelement) RETURNS anyarray AS ' CREATE FUNCTION make_array(anyelement, anyelement) RETURNS anyarray AS $$
SELECT ARRAY[$1, $2]; SELECT ARRAY[$1, $2];
' LANGUAGE SQL; $$ LANGUAGE SQL;
SELECT make_array(1, 2) AS intarray, make_array('a'::text, 'b') AS textarray; SELECT make_array(1, 2) AS intarray, make_array('a'::text, 'b') AS textarray;
intarray | textarray intarray | textarray
...@@ -589,9 +594,9 @@ ERROR: could not determine "anyarray"/"anyelement" type because input has type ...@@ -589,9 +594,9 @@ ERROR: could not determine "anyarray"/"anyelement" type because input has type
It is permitted to have polymorphic arguments with a deterministic It is permitted to have polymorphic arguments with a deterministic
return type, but the converse is not. For example: return type, but the converse is not. For example:
<screen> <screen>
CREATE FUNCTION is_greater(anyelement, anyelement) RETURNS boolean AS ' CREATE FUNCTION is_greater(anyelement, anyelement) RETURNS boolean AS $$
SELECT $1 > $2; SELECT $1 > $2;
' LANGUAGE SQL; $$ LANGUAGE SQL;
SELECT is_greater(1, 2); SELECT is_greater(1, 2);
is_greater is_greater
...@@ -599,9 +604,9 @@ SELECT is_greater(1, 2); ...@@ -599,9 +604,9 @@ SELECT is_greater(1, 2);
f f
(1 row) (1 row)
CREATE FUNCTION invalid_func() RETURNS anyelement AS ' CREATE FUNCTION invalid_func() RETURNS anyelement AS $$
SELECT 1; SELECT 1;
' LANGUAGE SQL; $$ LANGUAGE SQL;
ERROR: cannot determine result data type ERROR: cannot determine result data type
DETAIL: A function returning "anyarray" or "anyelement" must have at least one argument of either type. DETAIL: A function returning "anyarray" or "anyelement" must have at least one argument of either type.
</screen> </screen>
...@@ -659,7 +664,7 @@ DETAIL: A function returning "anyarray" or "anyelement" must have at least one ...@@ -659,7 +664,7 @@ DETAIL: A function returning "anyarray" or "anyelement" must have at least one
create an alias for the <function>sqrt</function> function: create an alias for the <function>sqrt</function> function:
<programlisting> <programlisting>
CREATE FUNCTION square_root(double precision) RETURNS double precision CREATE FUNCTION square_root(double precision) RETURNS double precision
AS 'dsqrt' AS $$dsqrt$$
LANGUAGE internal LANGUAGE internal
STRICT; STRICT;
</programlisting> </programlisting>
......
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