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.
This commit is contained in:
Neil Conway 2004-05-16 23:22:08 +00:00
parent 2871f60f23
commit 8295c27c89
11 changed files with 371 additions and 253 deletions

View File

@ -1,5 +1,5 @@
<!-- <!--
$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
<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
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 '
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 '
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 (
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;
<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;
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>

View File

@ -1,5 +1,5 @@
<!-- <!--
$PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.37 2004/03/26 03:18:28 neilc Exp $ $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.38 2004/05/16 23:22:06 neilc Exp $
--> -->
<chapter id="plpgsql"> <chapter id="plpgsql">
@ -89,13 +89,13 @@ $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.37 2004/03/26 03:18:28 neilc Ex
alter your database schema. For example: alter your database schema. For example:
<programlisting> <programlisting>
CREATE FUNCTION populate() RETURNS integer AS ' CREATE FUNCTION populate() RETURNS integer AS $$
DECLARE DECLARE
-- declarations -- declarations
BEGIN BEGIN
PERFORM my_function(); PERFORM my_function();
END; END;
' LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
</programlisting> </programlisting>
If you execute the above function, it will reference the OID for If you execute the above function, it will reference the OID for
@ -261,13 +261,17 @@ end;
<para> <para>
Since the code of a <application>PL/pgSQL</> function is specified in Since the code of a <application>PL/pgSQL</> function is specified in
<command>CREATE FUNCTION</command> as a string literal, single <command>CREATE FUNCTION</command> as a string literal, single
quotes inside the function body must be escaped by doubling them. quotes inside the function body must be escaped by doubling them
This can lead to unless the string literal comprising the function body is dollar
rather complicated code at times, especially if you are writing a quoted.
function that generates other functions, as in the example in <xref </para>
linkend="plpgsql-statements-executing-dyn">. This chart may be useful
as a summary of the needed numbers of quotation marks in <para>
various situations. Doubling can lead to incomprehensible code at times, especially if
you are writing a function that generates other functions, as in the
example in <xref linkend="plpgsql-statements-executing-dyn">. This
chart may be useful when translating pre-dollar quoting code into
something that is comprehensible.
</para> </para>
<variablelist> <variablelist>
@ -418,11 +422,11 @@ END;
block are initialized to their default values every time the block are initialized to their default values every time the
block is entered, not only once per function call. For example: block is entered, not only once per function call. For example:
<programlisting> <programlisting>
CREATE FUNCTION somefunc() RETURNS integer AS ' CREATE FUNCTION somefunc() RETURNS integer AS $$
DECLARE DECLARE
quantity integer := 30; quantity integer := 30;
BEGIN BEGIN
RAISE NOTICE ''Quantity here is %'', quantity; -- Quantity here is 30 RAISE NOTICE 'Quantity here is %', quantity; -- Quantity here is 30
quantity := 50; quantity := 50;
-- --
-- Create a subblock -- Create a subblock
@ -430,14 +434,14 @@ BEGIN
DECLARE DECLARE
quantity integer := 80; quantity integer := 80;
BEGIN BEGIN
RAISE NOTICE ''Quantity here is %'', quantity; -- Quantity here is 80 RAISE NOTICE 'Quantity here is %', quantity; -- Quantity here is 80
END; END;
RAISE NOTICE ''Quantity here is %'', quantity; -- Quantity here is 50 RAISE NOTICE 'Quantity here is %', quantity; -- Quantity here is 50
RETURN quantity; RETURN quantity;
END; END;
' LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
</programlisting> </programlisting>
</para> </para>
@ -510,7 +514,7 @@ arow RECORD;
Examples: Examples:
<programlisting> <programlisting>
quantity integer DEFAULT 32; quantity integer DEFAULT 32;
url varchar := ''http://mysite.com''; url varchar := 'http://mysite.com';
user_id CONSTANT integer := 10; user_id CONSTANT integer := 10;
</programlisting> </programlisting>
</para> </para>
@ -531,32 +535,32 @@ user_id CONSTANT integer := 10;
numeric identifier can then be used to refer to the parameter value. numeric identifier can then be used to refer to the parameter value.
Some examples: Some examples:
<programlisting> <programlisting>
CREATE FUNCTION sales_tax(real) RETURNS real AS ' CREATE FUNCTION sales_tax(real) RETURNS real AS $$
DECLARE DECLARE
subtotal ALIAS FOR $1; subtotal ALIAS FOR $1;
BEGIN BEGIN
RETURN subtotal * 0.06; RETURN subtotal * 0.06;
END; END;
' LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE FUNCTION instr(varchar, integer) RETURNS integer AS ' CREATE FUNCTION instr(varchar, integer) RETURNS integer AS $$
DECLARE DECLARE
v_string ALIAS FOR $1; v_string ALIAS FOR $1;
index ALIAS FOR $2; index ALIAS FOR $2;
BEGIN BEGIN
-- some computations here -- some computations here
END; END;
' LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE FUNCTION concat_selected_fields(tablename) RETURNS text AS ' CREATE FUNCTION concat_selected_fields(tablename) RETURNS text AS $$
DECLARE DECLARE
in_t ALIAS FOR $1; in_t ALIAS FOR $1;
BEGIN BEGIN
RETURN in_t.f1 || in_t.f3 || in_t.f5 || in_t.f7; RETURN in_t.f1 || in_t.f3 || in_t.f5 || in_t.f7;
END; END;
' LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
</programlisting> </programlisting>
</para> </para>
@ -576,7 +580,7 @@ END;
that has a <literal>+</> operator: that has a <literal>+</> operator:
<programlisting> <programlisting>
CREATE FUNCTION add_three_values(anyelement, anyelement, anyelement) CREATE FUNCTION add_three_values(anyelement, anyelement, anyelement)
RETURNS anyelement AS ' RETURNS anyelement AS $$
DECLARE DECLARE
result ALIAS FOR $0; result ALIAS FOR $0;
first ALIAS FOR $1; first ALIAS FOR $1;
@ -586,7 +590,7 @@ BEGIN
result := first + second + third; result := first + second + third;
RETURN result; RETURN result;
END; END;
' LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
</programlisting> </programlisting>
</para> </para>
</sect2> </sect2>
@ -677,7 +681,7 @@ user_id users.user_id%TYPE;
<para> <para>
Here is an example of using composite types: Here is an example of using composite types:
<programlisting> <programlisting>
CREATE FUNCTION use_two_tables(tablename) RETURNS text AS ' CREATE FUNCTION use_two_tables(tablename) RETURNS text AS $$
DECLARE DECLARE
in_t ALIAS FOR $1; in_t ALIAS FOR $1;
use_t table2name%ROWTYPE; use_t table2name%ROWTYPE;
@ -685,7 +689,7 @@ BEGIN
SELECT * INTO use_t FROM table2name WHERE ... ; SELECT * INTO use_t FROM table2name WHERE ... ;
RETURN in_t.f1 || use_t.f3 || in_t.f5 || use_t.f7; RETURN in_t.f1 || use_t.f3 || in_t.f5 || use_t.f7;
END; END;
' LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
SELECT use_two_tables(t.*) FROM tablename t WHERE ... ; SELECT use_two_tables(t.*) FROM tablename t WHERE ... ;
</programlisting> </programlisting>
@ -788,29 +792,29 @@ SELECT <replaceable>expression</replaceable>
is a difference between what these two functions do: is a difference between what these two functions do:
<programlisting> <programlisting>
CREATE FUNCTION logfunc1(text) RETURNS timestamp AS ' CREATE FUNCTION logfunc1(text) RETURNS timestamp AS $$
DECLARE DECLARE
logtxt ALIAS FOR $1; logtxt ALIAS FOR $1;
BEGIN BEGIN
INSERT INTO logtable VALUES (logtxt, ''now''); INSERT INTO logtable VALUES (logtxt, 'now');
RETURN ''now''; RETURN 'now';
END; END;
' LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
</programlisting> </programlisting>
and and
<programlisting> <programlisting>
CREATE FUNCTION logfunc2(text) RETURNS timestamp AS ' CREATE FUNCTION logfunc2(text) RETURNS timestamp AS $$
DECLARE DECLARE
logtxt ALIAS FOR $1; logtxt ALIAS FOR $1;
curtime timestamp; curtime timestamp;
BEGIN BEGIN
curtime := ''now''; curtime := 'now';
INSERT INTO logtable VALUES (logtxt, curtime); INSERT INTO logtable VALUES (logtxt, curtime);
RETURN curtime; RETURN curtime;
END; END;
' LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
</programlisting> </programlisting>
</para> </para>
@ -972,7 +976,7 @@ SELECT INTO <replaceable>target</replaceable> <replaceable>select_expressions</r
<programlisting> <programlisting>
SELECT INTO myrec * FROM emp WHERE empname = myname; SELECT INTO myrec * FROM emp WHERE empname = myname;
IF NOT FOUND THEN IF NOT FOUND THEN
RAISE EXCEPTION ''employee % not found'', myname; RAISE EXCEPTION 'employee % not found', myname;
END IF; END IF;
</programlisting> </programlisting>
</para> </para>
@ -991,7 +995,7 @@ BEGIN
IF users_rec.homepage IS NULL THEN IF users_rec.homepage IS NULL THEN
-- user entered no homepage, return "http://" -- user entered no homepage, return "http://"
RETURN ''http://''; RETURN 'http://';
END IF; END IF;
END; END;
</programlisting> </programlisting>
@ -1032,7 +1036,7 @@ PERFORM <replaceable>query</replaceable>;
<para> <para>
An example: An example:
<programlisting> <programlisting>
PERFORM create_mv(''cs_session_page_requests_mv'', my_query); PERFORM create_mv('cs_session_page_requests_mv', my_query);
</programlisting> </programlisting>
</para> </para>
</sect2> </sect2>
@ -1066,10 +1070,12 @@ EXECUTE <replaceable class="command">command-string</replaceable>;
</para> </para>
<para> <para>
When working with dynamic commands you will have to face When working with dynamic commands you will have to face escaping
escaping of single quotes in <application>PL/pgSQL</>. Please refer to the of single quotes in <application>PL/pgSQL</>. The recommended method
overview in <xref linkend="plpgsql-quote-tips">, is dollar quoting. If you have legacy code which does
which can save you some effort. <emphasis>not</emphasis> use dollar quoting, please refer to the
overview in <xref linkend="plpgsql-quote-tips">, which can save you
some effort when translating said code to a more reasonable scheme.
</para> </para>
<para> <para>
@ -1093,13 +1099,15 @@ EXECUTE <replaceable class="command">command-string</replaceable>;
</para> </para>
<para> <para>
An example: An example (except where noted, all examples herein assume that
you are using dollar quoting):
<programlisting> <programlisting>
EXECUTE ''UPDATE tbl SET '' EXECUTE 'UPDATE tbl SET '
|| quote_ident(colname) || quote_ident(colname)
|| '' = '' || ' = '
|| quote_literal(newvalue) || quote_literal(newvalue)
|| '' WHERE ...''; || ' WHERE ...';
</programlisting> </programlisting>
</para> </para>
@ -1150,6 +1158,40 @@ BEGIN
EXECUTE a_output; EXECUTE a_output;
END; END;
' LANGUAGE plpgsql; ' LANGUAGE plpgsql;
</programlisting>
And here is an equivalent using dollar quoting. At least it is more
legible than the above, although both versions show that the design,
rather than merely the formatting, needs to be re-thought.
<programlisting>
CREATE or replace FUNCTION cs_update_referrer_type_proc2() RETURNS integer AS $func$
DECLARE
referrer_keys RECORD; -- declare a generic record to be used in a FOR
a_output varchar(4000);
BEGIN
a_output := 'CREATE FUNCTION cs_find_referrer_type(varchar, varchar, varchar)
RETURNS varchar AS $innerfunc$
DECLARE
v_host ALIAS FOR $1;
v_domain ALIAS FOR $2;
v_url ALIAS FOR $3;
BEGIN ';
-- Notice how we scan through the results of a query in a FOR loop
-- using the FOR &lt;record&gt; construct.
FOR referrer_keys IN SELECT * FROM cs_referrer_keys ORDER BY try_order LOOP
a_output := a_output || ' IF v_' || referrer_keys.kind || ' LIKE $$'
|| referrer_keys.key_string || '$$ THEN RETURN $$'
|| referrer_keys.referrer_type || '$$; END IF;';
END LOOP;
a_output := a_output || ' RETURN NULL; END; $innerfunc$ LANGUAGE plpgsql;';
EXECUTE a_output;
RETURN
END;
$func$ LANGUAGE plpgsql;
</programlisting> </programlisting>
</para> </para>
</sect2> </sect2>
@ -1434,20 +1476,20 @@ END IF;
<para> <para>
Examples: Examples:
<programlisting> <programlisting>
IF parentid IS NULL OR parentid = '''' IF parentid IS NULL OR parentid = ''
THEN THEN
RETURN fullname; RETURN fullname;
ELSE ELSE
RETURN hp_true_filename(parentid) || ''/'' || fullname; RETURN hp_true_filename(parentid) || '/' || fullname;
END IF; END IF;
</programlisting> </programlisting>
<programlisting> <programlisting>
IF v_count > 0 THEN IF v_count > 0 THEN
INSERT INTO users_count (count) VALUES (v_count); INSERT INTO users_count (count) VALUES (v_count);
RETURN ''t''; RETURN 't';
ELSE ELSE
RETURN ''f''; RETURN 'f';
END IF; END IF;
</programlisting> </programlisting>
</para> </para>
@ -1461,11 +1503,11 @@ END IF;
following example: following example:
<programlisting> <programlisting>
IF demo_row.sex = ''m'' THEN IF demo_row.sex = 'm' THEN
pretty_sex := ''man''; pretty_sex := 'man';
ELSE ELSE
IF demo_row.sex = ''f'' THEN IF demo_row.sex = 'f' THEN
pretty_sex := ''woman''; pretty_sex := 'woman';
END IF; END IF;
END IF; END IF;
</programlisting> </programlisting>
@ -1514,14 +1556,14 @@ END IF;
<programlisting> <programlisting>
IF number = 0 THEN IF number = 0 THEN
result := ''zero''; result := 'zero';
ELSIF number &gt; 0 THEN ELSIF number &gt; 0 THEN
result := ''positive''; result := 'positive';
ELSIF number &lt; 0 THEN ELSIF number &lt; 0 THEN
result := ''negative''; result := 'negative';
ELSE ELSE
-- hmm, the only other possibility is that number is null -- hmm, the only other possibility is that number is null
result := ''NULL''; result := 'NULL';
END IF; END IF;
</programlisting> </programlisting>
</para> </para>
@ -1666,7 +1708,7 @@ END LOOP;
<programlisting> <programlisting>
FOR i IN 1..10 LOOP FOR i IN 1..10 LOOP
-- some computations here -- some computations here
RAISE NOTICE ''i is %'', i; RAISE NOTICE 'i is %', i;
END LOOP; END LOOP;
FOR i IN REVERSE 10..1 LOOP FOR i IN REVERSE 10..1 LOOP
@ -1704,18 +1746,18 @@ CREATE FUNCTION cs_refresh_mviews() RETURNS integer AS '
DECLARE DECLARE
mviews RECORD; mviews RECORD;
BEGIN BEGIN
PERFORM cs_log(''Refreshing materialized views...''); PERFORM cs_log('Refreshing materialized views...');
FOR mviews IN SELECT * FROM cs_materialized_views ORDER BY sort_key LOOP FOR mviews IN SELECT * FROM cs_materialized_views ORDER BY sort_key LOOP
-- Now "mviews" has one record from cs_materialized_views -- Now "mviews" has one record from cs_materialized_views
PERFORM cs_log(''Refreshing materialized view '' || quote_ident(mviews.mv_name) || ''...''); PERFORM cs_log('Refreshing materialized view ' || quote_ident(mviews.mv_name) || '...');
EXECUTE ''TRUNCATE TABLE '' || quote_ident(mviews.mv_name); EXECUTE 'TRUNCATE TABLE ' || quote_ident(mviews.mv_name);
EXECUTE ''INSERT INTO '' || quote_ident(mviews.mv_name) || '' '' || mviews.mv_query; EXECUTE 'INSERT INTO ' || quote_ident(mviews.mv_name) || ' ' || mviews.mv_query;
END LOOP; END LOOP;
PERFORM cs_log(''Done refreshing materialized views.''); PERFORM cs_log('Done refreshing materialized views.');
RETURN 1; RETURN 1;
END; END;
' LANGUAGE plpgsql; ' LANGUAGE plpgsql;
@ -1877,7 +1919,7 @@ OPEN <replaceable>unbound-cursor</replaceable> FOR EXECUTE <replaceable class="c
<para> <para>
An example: An example:
<programlisting> <programlisting>
OPEN curs1 FOR EXECUTE ''SELECT * FROM '' || quote_ident($1); OPEN curs1 FOR EXECUTE 'SELECT * FROM ' || quote_ident($1);
</programlisting> </programlisting>
</para> </para>
</sect3> </sect3>
@ -2103,7 +2145,7 @@ RAISE <replaceable class="parameter">level</replaceable> '<replaceable class="pa
<!-- <!--
This example should work, but does not: This example should work, but does not:
RAISE NOTICE ''Id number '' || key || '' not found!''; RAISE NOTICE 'Id number ' || key || ' not found!';
Put it back when we allow non-string-literal formats. Put it back when we allow non-string-literal formats.
--> -->
@ -2111,14 +2153,14 @@ RAISE <replaceable class="parameter">level</replaceable> '<replaceable class="pa
In this example, the value of <literal>v_job_id</> will replace the In this example, the value of <literal>v_job_id</> will replace the
<literal>%</literal> in the string: <literal>%</literal> in the string:
<programlisting> <programlisting>
RAISE NOTICE ''Calling cs_create_job(%)'', v_job_id; RAISE NOTICE 'Calling cs_create_job(%)', v_job_id;
</programlisting> </programlisting>
</para> </para>
<para> <para>
This example will abort the transaction with the given error message: This example will abort the transaction with the given error message:
<programlisting> <programlisting>
RAISE EXCEPTION ''Inexistent ID --> %'', user_id; RAISE EXCEPTION 'Nonexistent ID --> %', user_id;
</programlisting> </programlisting>
</para> </para>
@ -2334,27 +2376,27 @@ CREATE TABLE emp (
last_user text last_user text
); );
CREATE FUNCTION emp_stamp() RETURNS trigger AS ' CREATE FUNCTION emp_stamp() RETURNS trigger AS $emp_stamp$
BEGIN BEGIN
-- Check that empname and salary are given -- Check that empname and salary are given
IF NEW.empname IS NULL THEN IF NEW.empname IS NULL THEN
RAISE EXCEPTION ''empname cannot be null''; RAISE EXCEPTION 'empname cannot be null';
END IF; END IF;
IF NEW.salary IS NULL THEN IF NEW.salary IS NULL THEN
RAISE EXCEPTION ''% cannot have null salary'', NEW.empname; RAISE EXCEPTION '% cannot have null salary', NEW.empname;
END IF; END IF;
-- Who works for us when she must pay for it? -- Who works for us when she must pay for it?
IF NEW.salary &lt; 0 THEN IF NEW.salary &lt; 0 THEN
RAISE EXCEPTION ''% cannot have a negative salary'', NEW.empname; RAISE EXCEPTION '% cannot have a negative salary', NEW.empname;
END IF; END IF;
-- Remember who changed the payroll when -- Remember who changed the payroll when
NEW.last_date := ''now''; NEW.last_date := 'now';
NEW.last_user := current_user; NEW.last_user := current_user;
RETURN NEW; RETURN NEW;
END; END;
' LANGUAGE plpgsql; $emp_stamp$ LANGUAGE plpgsql;
CREATE TRIGGER emp_stamp BEFORE INSERT OR UPDATE ON emp CREATE TRIGGER emp_stamp BEFORE INSERT OR UPDATE ON emp
FOR EACH ROW EXECUTE PROCEDURE emp_stamp(); FOR EACH ROW EXECUTE PROCEDURE emp_stamp();
@ -2514,7 +2556,7 @@ show errors;
<programlisting> <programlisting>
CREATE OR REPLACE FUNCTION cs_fmt_browser_version(varchar, varchar) CREATE OR REPLACE FUNCTION cs_fmt_browser_version(varchar, varchar)
RETURNS varchar AS ' RETURNS varchar AS $$
DECLARE DECLARE
v_name ALIAS FOR $1; v_name ALIAS FOR $1;
v_version ALIAS FOR $2; v_version ALIAS FOR $2;
@ -2522,9 +2564,9 @@ BEGIN
IF v_version IS NULL THEN IF v_version IS NULL THEN
return v_name; return v_name;
END IF; END IF;
RETURN v_name || ''/'' || v_version; RETURN v_name || '/' || v_version;
END; END;
' LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
</programlisting> </programlisting>
</para> </para>
</example> </example>
@ -2577,36 +2619,34 @@ show errors;
Here is how this function would end up in <productname>PostgreSQL</>: Here is how this function would end up in <productname>PostgreSQL</>:
<programlisting> <programlisting>
CREATE FUNCTION cs_update_referrer_type_proc() RETURNS integer AS ' CREATE or replace FUNCTION cs_update_referrer_type_proc() RETURNS
text AS $func$
DECLARE DECLARE
referrer_keys RECORD; -- Declare a generic record to be used in a FOR referrer_keys RECORD; -- declare a generic record to be used in a FOR
a_output varchar(4000); a_output TEXT;
BEGIN BEGIN
a_output := ''CREATE FUNCTION cs_find_referrer_type(varchar, varchar, varchar) a_output := 'CREATE FUNCTION cs_find_referrer_type(varchar, varchar, varchar)
RETURNS varchar AS '''' RETURNS varchar AS $innerfunc$
DECLARE DECLARE
v_host ALIAS FOR $1; v_host ALIAS FOR $1;
v_domain ALIAS FOR $2; v_domain ALIAS FOR $2;
v_url ALIAS FOR $3; v_url ALIAS FOR $3;
BEGIN ''; BEGIN ';
-- Notice how we scan through the results of a query in a FOR loop -- Notice how we scan through the results of a query in a FOR loop
-- using the FOR &lt;record&gt; construct. -- using the FOR &lt;record&gt; construct.
FOR referrer_keys IN SELECT * FROM cs_referrer_keys ORDER BY try_order LOOP FOR referrer_keys IN SELECT * FROM cs_referrer_keys ORDER BY try_order LOOP
a_output := a_output || '' IF v_'' || referrer_keys.kind || '' LIKE '''''''''' a_output := a_output || ' IF v_' || referrer_keys.kind || ' LIKE $$'
|| referrer_keys.key_string || '''''''''' THEN RETURN '''''' || referrer_keys.key_string || '$$ THEN RETURN $$'
|| referrer_keys.referrer_type || ''''''; END IF;''; || referrer_keys.referrer_type || '$$; END IF;';
END LOOP; END LOOP;
a_output := a_output || '' RETURN NULL; END; '''' LANGUAGE plpgsql;''; a_output := a_output || ' RETURN NULL; END; $innerfunc$ LANGUAGE plpgsql;';
-- EXECUTE will work because we are not substituting any variables. return a_output;
-- Otherwise it would fail. Look at PERFORM for another way to run functions.
EXECUTE a_output;
END; END;
' LANGUAGE plpgsql; $func$ LANGUAGE plpgsql;
</programlisting> </programlisting>
</para> </para>
</example> </example>
@ -2686,7 +2726,7 @@ show errors;
the host part could look like: the host part could look like:
<programlisting> <programlisting>
CREATE OR REPLACE FUNCTION cs_parse_url_host(varchar) RETURNS varchar AS ' CREATE OR REPLACE FUNCTION cs_parse_url_host(varchar) RETURNS varchar AS $$
DECLARE DECLARE
v_url ALIAS FOR $1; v_url ALIAS FOR $1;
v_host varchar; v_host varchar;
@ -2696,23 +2736,23 @@ DECLARE
a_pos3 integer; a_pos3 integer;
BEGIN BEGIN
v_host := NULL; v_host := NULL;
a_pos1 := instr(v_url, ''//''); a_pos1 := instr(v_url, '//');
IF a_pos1 = 0 THEN IF a_pos1 = 0 THEN
RETURN ''''; -- Return a blank RETURN ''; -- Return a blank
END IF; END IF;
a_pos2 := instr(v_url,''/'',a_pos1 + 2); a_pos2 := instr(v_url,'/',a_pos1 + 2);
IF a_pos2 = 0 THEN IF a_pos2 = 0 THEN
v_host := substr(v_url, a_pos1 + 2); v_host := substr(v_url, a_pos1 + 2);
v_path := ''/''; v_path := '/';
RETURN v_host; RETURN v_host;
END IF; END IF;
v_host := substr(v_url, a_pos1 + 2, a_pos2 - a_pos1 - 2 ); v_host := substr(v_url, a_pos1 + 2, a_pos2 - a_pos1 - 2 );
RETURN v_host; RETURN v_host;
END; END;
' LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
</programlisting> </programlisting>
</para> </para>
</example> </example>
@ -2797,7 +2837,7 @@ show errors
This is how we could port this procedure to <application>PL/pgSQL</>: This is how we could port this procedure to <application>PL/pgSQL</>:
<programlisting> <programlisting>
CREATE OR REPLACE FUNCTION cs_create_job(integer) RETURNS integer AS ' CREATE OR REPLACE FUNCTION cs_create_job(integer) RETURNS integer AS $$
DECLARE DECLARE
v_job_id ALIAS FOR $1; v_job_id ALIAS FOR $1;
a_running_job_count integer; a_running_job_count integer;
@ -2808,7 +2848,7 @@ BEGIN
IF a_running_job_count > 0 IF a_running_job_count > 0
THEN THEN
RAISE EXCEPTION ''Unable to create a new job: a job is currently running.''; RAISE EXCEPTION 'Unable to create a new job: a job is currently running.';
END IF; END IF;
DELETE FROM cs_active_job; DELETE FROM cs_active_job;
@ -2820,12 +2860,12 @@ BEGIN
INSERT INTO cs_jobs(job_id, start_stamp) VALUES (v_job_id, current_timestamp); INSERT INTO cs_jobs(job_id, start_stamp) VALUES (v_job_id, current_timestamp);
RETURN 1; RETURN 1;
ELSE ELSE
RAISE NOTICE ''Job already running.'';<co id="co.plpgsql-porting-raise"> RAISE NOTICE 'Job already running.';<co id="co.plpgsql-porting-raise">
END IF; END IF;
RETURN 0; RETURN 0;
END; END;
' LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
</programlisting> </programlisting>
<calloutlist> <calloutlist>
@ -2858,7 +2898,7 @@ END;
<function>quote_literal(text)</function> and <function>quote_literal(text)</function> and
<function>quote_string(text)</function> as described in <xref <function>quote_string(text)</function> as described in <xref
linkend="plpgsql-statements-executing-dyn">. Constructs of the linkend="plpgsql-statements-executing-dyn">. Constructs of the
type <literal>EXECUTE ''SELECT * FROM $1'';</literal> will not type <literal>EXECUTE 'SELECT * FROM $1';</literal> will not
work unless you use these functions. work unless you use these functions.
</para> </para>
</sect3> </sect3>
@ -2881,9 +2921,9 @@ END;
like this: like this:
<programlisting> <programlisting>
CREATE FUNCTION foo(...) RETURNS integer AS ' CREATE FUNCTION foo(...) RETURNS integer AS $$
... ...
' LANGUAGE plpgsql STRICT IMMUTABLE; $$ LANGUAGE plpgsql STRICT IMMUTABLE;
</programlisting> </programlisting>
</para> </para>
</sect3> </sect3>
@ -2908,17 +2948,17 @@ CREATE FUNCTION foo(...) RETURNS integer AS '
-- assume 1 (search starts at first character). -- assume 1 (search starts at first character).
-- --
CREATE FUNCTION instr(varchar, varchar) RETURNS integer AS ' CREATE FUNCTION instr(varchar, varchar) RETURNS integer AS $$
DECLARE DECLARE
pos integer; pos integer;
BEGIN BEGIN
pos:= instr($1, $2, 1); pos:= instr($1, $2, 1);
RETURN pos; RETURN pos;
END; END;
' LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE FUNCTION instr(varchar, varchar, varchar) RETURNS integer AS ' CREATE FUNCTION instr(varchar, varchar, varchar) RETURNS integer AS $$
DECLARE DECLARE
string ALIAS FOR $1; string ALIAS FOR $1;
string_to_search ALIAS FOR $2; string_to_search ALIAS FOR $2;
@ -2957,10 +2997,10 @@ BEGIN
RETURN 0; RETURN 0;
END IF; END IF;
END; END;
' LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
CREATE FUNCTION instr(varchar, varchar, integer, integer) RETURNS integer AS ' CREATE FUNCTION instr(varchar, varchar, integer, integer) RETURNS integer AS $$
DECLARE DECLARE
string ALIAS FOR $1; string ALIAS FOR $1;
string_to_search ALIAS FOR $2; string_to_search ALIAS FOR $2;
@ -3018,7 +3058,7 @@ BEGIN
RETURN 0; RETURN 0;
END IF; END IF;
END; END;
' LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
</programlisting> </programlisting>
</sect2> </sect2>

View File

@ -1,4 +1,4 @@
<!-- $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)
<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>

View File

@ -1,5 +1,5 @@
<!-- <!--
$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 $
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
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 '
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 '
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 (
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 '
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" {
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
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
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 '
} }
} }
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);

View File

@ -1,4 +1,4 @@
<!-- $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
<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;

View File

@ -1,5 +1,5 @@
<!-- <!--
$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>
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>
<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>
</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>
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;

View File

@ -1,5 +1,5 @@
<!-- <!--
$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> (
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>

View File

@ -1,5 +1,5 @@
<!-- <!--
$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
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

View File

@ -1,4 +1,4 @@
<!-- $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
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>

View File

@ -1,5 +1,5 @@
<!-- <!--
$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,14 +240,72 @@ 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
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> <para>
@ -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>

View File

@ -1,5 +1,5 @@
<!-- <!--
$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
<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
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();
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;
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);
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 '
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 (
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
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
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');
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;
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;
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;
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
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);
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
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>