From 8295c27c8923c5815eba9685cc200681a3ba524c Mon Sep 17 00:00:00 2001 From: Neil Conway Date: Sun, 16 May 2004 23:22:08 +0000 Subject: [PATCH] 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. --- doc/src/sgml/plperl.sgml | 44 ++-- doc/src/sgml/plpgsql.sgml | 308 +++++++++++++++----------- doc/src/sgml/plpython.sgml | 6 +- doc/src/sgml/pltcl.sgml | 46 ++-- doc/src/sgml/queries.sgml | 6 +- doc/src/sgml/ref/create_function.sgml | 30 ++- doc/src/sgml/ref/create_type.sgml | 7 +- doc/src/sgml/ref/select.sgml | 10 +- doc/src/sgml/rules.sgml | 6 +- doc/src/sgml/syntax.sgml | 80 ++++++- doc/src/sgml/xfunc.sgml | 81 +++---- 11 files changed, 371 insertions(+), 253 deletions(-) diff --git a/doc/src/sgml/plperl.sgml b/doc/src/sgml/plperl.sgml index a4d053b746..5a134c75bb 100644 --- a/doc/src/sgml/plperl.sgml +++ b/doc/src/sgml/plperl.sgml @@ -1,5 +1,5 @@ @@ -46,11 +46,17 @@ $PostgreSQL: pgsql/doc/src/sgml/plperl.sgml,v 2.22 2003/12/14 00:10:32 neilc Exp To create a function in the PL/Perl language, use the standard syntax: -CREATE FUNCTION funcname (argument-types) RETURNS return-type AS ' +CREATE FUNCTION funcname +(argument-types) RETURNS return-type AS $$ # PL/Perl function body -' LANGUAGE plperl; +$$ LANGUAGE plperl; - 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 + PostgreSQL, it can be specified using + dollar quoting (as shown above), or via the usual single quote + syntax (see for more + information). @@ -65,10 +71,10 @@ CREATE FUNCTION funcname (argument-types could be defined as: -CREATE FUNCTION perl_max (integer, integer) RETURNS integer AS ' +CREATE FUNCTION perl_max (integer, integer) RETURNS integer AS $$ if ($_[0] > $_[1]) { return $_[0]; } return $_[1]; -' LANGUAGE plperl; +$$ LANGUAGE plperl; @@ -88,7 +94,7 @@ CREATE FUNCTION perl_max (integer, integer) RETURNS integer AS ' rather than a null value: -CREATE FUNCTION perl_max (integer, integer) RETURNS integer AS ' +CREATE FUNCTION perl_max (integer, integer) RETURNS integer AS $$ my ($a,$b) = @_; if (! defined $a) { if (! defined $b) { return undef; } @@ -97,7 +103,7 @@ CREATE FUNCTION perl_max (integer, integer) RETURNS integer AS ' if (! defined $b) { return $a; } if ($a > $b) { return $a; } return $b; -' LANGUAGE plperl; +$$ LANGUAGE plperl; @@ -119,10 +125,10 @@ CREATE TABLE employee ( bonus integer ); -CREATE FUNCTION empcomp(employee) RETURNS integer AS ' +CREATE FUNCTION empcomp(employee) RETURNS integer AS $$ my ($emp) = @_; - return $emp->{''basesalary''} + $emp->{''bonus''}; -' LANGUAGE plperl; + return $emp->{'basesalary'} + $emp->{'bonus'}; +$$ LANGUAGE plperl; SELECT name, empcomp(employee) FROM employee; @@ -136,12 +142,12 @@ SELECT name, empcomp(employee) FROM employee; Because the function body is passed as an SQL string literal to - CREATE FUNCTION, you have to escape single - quotes and backslashes within your Perl source, typically by - doubling them as shown in the above example. Another possible - approach is to avoid writing single quotes by using Perl's - extended quoting operators (q[], - qq[], qw[]). + CREATE FUNCTION, you have to use dollar quoting + or escape single quotes and backslashes within your Perl source, + typically by doubling them. Another possible approach is to avoid + writing single quotes by using Perl's extended quoting operators + (q[], qq[], + qw[]). @@ -226,11 +232,11 @@ SELECT name, empcomp(employee) FROM employee; Here is an example of a function that will not work because file system operations are not allowed for security reasons: -CREATE FUNCTION badfunc() RETURNS integer AS ' +CREATE FUNCTION badfunc() RETURNS integer AS $$ open(TEMP, ">/tmp/badfile"); print TEMP "Gotcha!\n"; return 1; -' LANGUAGE plperl; +$$ LANGUAGE plperl; The creation of the function will succeed, but executing it will not. diff --git a/doc/src/sgml/plpgsql.sgml b/doc/src/sgml/plpgsql.sgml index af521f3072..b8eadd0455 100644 --- a/doc/src/sgml/plpgsql.sgml +++ b/doc/src/sgml/plpgsql.sgml @@ -1,5 +1,5 @@ @@ -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: -CREATE FUNCTION populate() RETURNS integer AS ' +CREATE FUNCTION populate() RETURNS integer AS $$ DECLARE -- declarations BEGIN PERFORM my_function(); END; -' LANGUAGE plpgsql; +$$ LANGUAGE plpgsql; If you execute the above function, it will reference the OID for @@ -261,13 +261,17 @@ end; Since the code of a PL/pgSQL function is specified in CREATE FUNCTION as a string literal, single - quotes inside the function body must be escaped by doubling them. - This can lead to - rather complicated code at times, especially if you are writing a - function that generates other functions, as in the example in . This chart may be useful - as a summary of the needed numbers of quotation marks in - various situations. + quotes inside the function body must be escaped by doubling them + unless the string literal comprising the function body is dollar + quoted. + + + + Doubling can lead to incomprehensible code at times, especially if + you are writing a function that generates other functions, as in the + example in . This + chart may be useful when translating pre-dollar quoting code into + something that is comprehensible. @@ -418,11 +422,11 @@ END; block are initialized to their default values every time the block is entered, not only once per function call. For example: -CREATE FUNCTION somefunc() RETURNS integer AS ' +CREATE FUNCTION somefunc() RETURNS integer AS $$ DECLARE quantity integer := 30; BEGIN - RAISE NOTICE ''Quantity here is %'', quantity; -- Quantity here is 30 + RAISE NOTICE 'Quantity here is %', quantity; -- Quantity here is 30 quantity := 50; -- -- Create a subblock @@ -430,14 +434,14 @@ BEGIN DECLARE quantity integer := 80; BEGIN - RAISE NOTICE ''Quantity here is %'', quantity; -- Quantity here is 80 + RAISE NOTICE 'Quantity here is %', quantity; -- Quantity here is 80 END; - RAISE NOTICE ''Quantity here is %'', quantity; -- Quantity here is 50 + RAISE NOTICE 'Quantity here is %', quantity; -- Quantity here is 50 RETURN quantity; END; -' LANGUAGE plpgsql; +$$ LANGUAGE plpgsql; @@ -510,7 +514,7 @@ arow RECORD; Examples: quantity integer DEFAULT 32; -url varchar := ''http://mysite.com''; +url varchar := 'http://mysite.com'; user_id CONSTANT integer := 10; @@ -531,32 +535,32 @@ user_id CONSTANT integer := 10; numeric identifier can then be used to refer to the parameter value. Some examples: -CREATE FUNCTION sales_tax(real) RETURNS real AS ' +CREATE FUNCTION sales_tax(real) RETURNS real AS $$ DECLARE subtotal ALIAS FOR $1; BEGIN RETURN subtotal * 0.06; END; -' LANGUAGE plpgsql; +$$ LANGUAGE plpgsql; -CREATE FUNCTION instr(varchar, integer) RETURNS integer AS ' +CREATE FUNCTION instr(varchar, integer) RETURNS integer AS $$ DECLARE v_string ALIAS FOR $1; index ALIAS FOR $2; BEGIN -- some computations here END; -' LANGUAGE plpgsql; +$$ LANGUAGE plpgsql; -CREATE FUNCTION concat_selected_fields(tablename) RETURNS text AS ' +CREATE FUNCTION concat_selected_fields(tablename) RETURNS text AS $$ DECLARE in_t ALIAS FOR $1; BEGIN RETURN in_t.f1 || in_t.f3 || in_t.f5 || in_t.f7; END; -' LANGUAGE plpgsql; +$$ LANGUAGE plpgsql; @@ -576,7 +580,7 @@ END; that has a + operator: CREATE FUNCTION add_three_values(anyelement, anyelement, anyelement) -RETURNS anyelement AS ' +RETURNS anyelement AS $$ DECLARE result ALIAS FOR $0; first ALIAS FOR $1; @@ -586,7 +590,7 @@ BEGIN result := first + second + third; RETURN result; END; -' LANGUAGE plpgsql; +$$ LANGUAGE plpgsql; @@ -677,7 +681,7 @@ user_id users.user_id%TYPE; Here is an example of using composite types: -CREATE FUNCTION use_two_tables(tablename) RETURNS text AS ' +CREATE FUNCTION use_two_tables(tablename) RETURNS text AS $$ DECLARE in_t ALIAS FOR $1; use_t table2name%ROWTYPE; @@ -685,7 +689,7 @@ BEGIN SELECT * INTO use_t FROM table2name WHERE ... ; RETURN in_t.f1 || use_t.f3 || in_t.f5 || use_t.f7; END; -' LANGUAGE plpgsql; +$$ LANGUAGE plpgsql; SELECT use_two_tables(t.*) FROM tablename t WHERE ... ; @@ -788,29 +792,29 @@ SELECT expression is a difference between what these two functions do: -CREATE FUNCTION logfunc1(text) RETURNS timestamp AS ' +CREATE FUNCTION logfunc1(text) RETURNS timestamp AS $$ DECLARE logtxt ALIAS FOR $1; BEGIN - INSERT INTO logtable VALUES (logtxt, ''now''); - RETURN ''now''; + INSERT INTO logtable VALUES (logtxt, 'now'); + RETURN 'now'; END; -' LANGUAGE plpgsql; +$$ LANGUAGE plpgsql; and -CREATE FUNCTION logfunc2(text) RETURNS timestamp AS ' +CREATE FUNCTION logfunc2(text) RETURNS timestamp AS $$ DECLARE logtxt ALIAS FOR $1; curtime timestamp; BEGIN - curtime := ''now''; + curtime := 'now'; INSERT INTO logtable VALUES (logtxt, curtime); RETURN curtime; END; -' LANGUAGE plpgsql; +$$ LANGUAGE plpgsql; @@ -870,7 +874,7 @@ CREATE FUNCTION logfunc2(text) RETURNS timestamp AS ' PL/pgSQL, but they are not specifically listed here. - + Assignment @@ -968,11 +972,11 @@ SELECT INTO target select_expressionsFOUND immediately after a SELECT INTO statement to determine whether the assignment was successful (that is, at least one row was was returned by the query). For example: - + SELECT INTO myrec * FROM emp WHERE empname = myname; IF NOT FOUND THEN - RAISE EXCEPTION ''employee % not found'', myname; + RAISE EXCEPTION 'employee % not found', myname; END IF; @@ -991,7 +995,7 @@ BEGIN IF users_rec.homepage IS NULL THEN -- user entered no homepage, return "http://" - RETURN ''http://''; + RETURN 'http://'; END IF; END; @@ -1032,14 +1036,14 @@ PERFORM query; An example: -PERFORM create_mv(''cs_session_page_requests_mv'', my_query); +PERFORM create_mv('cs_session_page_requests_mv', my_query); - + Executing Dynamic Commands - + Oftentimes you will want to generate dynamic commands inside your PL/pgSQL functions, that is, commands @@ -1066,12 +1070,14 @@ EXECUTE command-string; - When working with dynamic commands you will have to face - escaping of single quotes in PL/pgSQL. Please refer to the - overview in , - which can save you some effort. + When working with dynamic commands you will have to face escaping + of single quotes in PL/pgSQL. The recommended method + is dollar quoting. If you have legacy code which does + not use dollar quoting, please refer to the + overview in , which can save you + some effort when translating said code to a more reasonable scheme. - + Unlike all other commands in PL/pgSQL, a command run by an EXECUTE statement is not prepared @@ -1080,7 +1086,7 @@ EXECUTE command-string; string can be dynamically created within the function to perform actions on variable tables and columns. - + The results from SELECT commands are discarded by EXECUTE, and SELECT INTO @@ -1093,13 +1099,15 @@ EXECUTE command-string; - An example: + An example (except where noted, all examples herein assume that + you are using dollar quoting): + -EXECUTE ''UPDATE tbl SET '' +EXECUTE 'UPDATE tbl SET ' || quote_ident(colname) - || '' = '' + || ' = ' || quote_literal(newvalue) - || '' WHERE ...''; + || ' WHERE ...'; @@ -1144,12 +1152,46 @@ BEGIN || referrer_keys.key_string || '''''''''' THEN RETURN '''''' || referrer_keys.referrer_type || ''''''; END IF;''; END LOOP; - + a_output := a_output || '' RETURN NULL; END; '''' LANGUAGE plpgsql;''; - + EXECUTE a_output; -END; +END; ' LANGUAGE plpgsql; + + +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. + + +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 <record> 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; @@ -1252,7 +1294,7 @@ GET DIAGNOSTICS integer_var = ROW_COUNT; you can manipulate PostgreSQL data in a very flexible and powerful way. - + Returning From a Function @@ -1362,7 +1404,7 @@ SELECT * FROM some_func(); - + Conditionals @@ -1434,20 +1476,20 @@ END IF; Examples: -IF parentid IS NULL OR parentid = '''' +IF parentid IS NULL OR parentid = '' THEN RETURN fullname; ELSE - RETURN hp_true_filename(parentid) || ''/'' || fullname; + RETURN hp_true_filename(parentid) || '/' || fullname; END IF; IF v_count > 0 THEN INSERT INTO users_count (count) VALUES (v_count); - RETURN ''t''; + RETURN 't'; ELSE - RETURN ''f''; + RETURN 'f'; END IF; @@ -1461,11 +1503,11 @@ END IF; following example: -IF demo_row.sex = ''m'' THEN - pretty_sex := ''man''; +IF demo_row.sex = 'm' THEN + pretty_sex := 'man'; ELSE - IF demo_row.sex = ''f'' THEN - pretty_sex := ''woman''; + IF demo_row.sex = 'f' THEN + pretty_sex := 'woman'; END IF; END IF; @@ -1514,14 +1556,14 @@ END IF; IF number = 0 THEN - result := ''zero''; + result := 'zero'; ELSIF number > 0 THEN - result := ''positive''; + result := 'positive'; ELSIF number < 0 THEN - result := ''negative''; + result := 'negative'; ELSE -- hmm, the only other possibility is that number is null - result := ''NULL''; + result := 'NULL'; END IF; @@ -1666,7 +1708,7 @@ END LOOP; FOR i IN 1..10 LOOP -- some computations here - RAISE NOTICE ''i is %'', i; + RAISE NOTICE 'i is %', i; END LOOP; FOR i IN REVERSE 10..1 LOOP @@ -1704,18 +1746,18 @@ CREATE FUNCTION cs_refresh_mviews() RETURNS integer AS ' DECLARE mviews RECORD; 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 -- Now "mviews" has one record from cs_materialized_views - PERFORM cs_log(''Refreshing materialized view '' || quote_ident(mviews.mv_name) || ''...''); - EXECUTE ''TRUNCATE TABLE '' || quote_ident(mviews.mv_name); - EXECUTE ''INSERT INTO '' || quote_ident(mviews.mv_name) || '' '' || mviews.mv_query; + PERFORM cs_log('Refreshing materialized view ' || 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; - PERFORM cs_log(''Done refreshing materialized views.''); + PERFORM cs_log('Done refreshing materialized views.'); RETURN 1; END; ' LANGUAGE plpgsql; @@ -1778,7 +1820,7 @@ END LOOP; caller to read the rows. This provides an efficient way to return large row sets from functions. - + Declaring Cursor Variables @@ -1877,7 +1919,7 @@ OPEN unbound-cursor FOR EXECUTE level 'level ' Porting a Function that Creates Another Function from <application>PL/SQL</> to <application>PL/pgSQL</> @@ -2577,40 +2619,38 @@ show errors; Here is how this function would end up in PostgreSQL: -CREATE FUNCTION cs_update_referrer_type_proc() RETURNS integer AS ' +CREATE or replace FUNCTION cs_update_referrer_type_proc() RETURNS +text AS $func$ DECLARE - referrer_keys RECORD; -- Declare a generic record to be used in a FOR - a_output varchar(4000); + referrer_keys RECORD; -- declare a generic record to be used in a FOR + a_output TEXT; BEGIN - a_output := ''CREATE FUNCTION cs_find_referrer_type(varchar, varchar, varchar) - RETURNS varchar AS '''' + 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 ''; + BEGIN '; - -- Notice how we scan through the results of a query in a FOR loop - -- using the FOR <record> construct. + -- Notice how we scan through the results of a query in a FOR loop + -- using the FOR <record> 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; '''' LANGUAGE plpgsql;''; - - -- EXECUTE will work because we are not substituting any variables. - -- Otherwise it would fail. Look at PERFORM for another way to run functions. - - EXECUTE a_output; + 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;'; + + return a_output; END; -' LANGUAGE plpgsql; +$func$ LANGUAGE plpgsql; - + shows how to port a function with OUT parameters and string manipulation. @@ -2686,7 +2726,7 @@ show errors; the host part could look like: -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 v_url ALIAS FOR $1; v_host varchar; @@ -2696,23 +2736,23 @@ DECLARE a_pos3 integer; BEGIN v_host := NULL; - a_pos1 := instr(v_url, ''//''); + a_pos1 := instr(v_url, '//'); IF a_pos1 = 0 THEN - RETURN ''''; -- Return a blank + RETURN ''; -- Return a blank END IF; - a_pos2 := instr(v_url,''/'',a_pos1 + 2); + a_pos2 := instr(v_url,'/',a_pos1 + 2); IF a_pos2 = 0 THEN v_host := substr(v_url, a_pos1 + 2); - v_path := ''/''; + v_path := '/'; RETURN v_host; END IF; v_host := substr(v_url, a_pos1 + 2, a_pos2 - a_pos1 - 2 ); RETURN v_host; END; -' LANGUAGE plpgsql; +$$ LANGUAGE plpgsql; @@ -2797,7 +2837,7 @@ show errors This is how we could port this procedure to PL/pgSQL: -CREATE OR REPLACE FUNCTION cs_create_job(integer) RETURNS integer AS ' +CREATE OR REPLACE FUNCTION cs_create_job(integer) RETURNS integer AS $$ DECLARE v_job_id ALIAS FOR $1; a_running_job_count integer; @@ -2808,7 +2848,7 @@ BEGIN IF a_running_job_count > 0 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; DELETE FROM cs_active_job; @@ -2820,12 +2860,12 @@ BEGIN INSERT INTO cs_jobs(job_id, start_stamp) VALUES (v_job_id, current_timestamp); RETURN 1; ELSE - RAISE NOTICE ''Job already running.''; + RAISE NOTICE 'Job already running.'; END IF; RETURN 0; END; -' LANGUAGE plpgsql; +$$ LANGUAGE plpgsql; @@ -2858,7 +2898,7 @@ END; quote_literal(text) and quote_string(text) as described in . Constructs of the - type EXECUTE ''SELECT * FROM $1''; will not + type EXECUTE 'SELECT * FROM $1'; will not work unless you use these functions. @@ -2881,9 +2921,9 @@ END; like this: -CREATE FUNCTION foo(...) RETURNS integer AS ' +CREATE FUNCTION foo(...) RETURNS integer AS $$ ... -' LANGUAGE plpgsql STRICT IMMUTABLE; +$$ LANGUAGE plpgsql STRICT IMMUTABLE; @@ -2908,17 +2948,17 @@ CREATE FUNCTION foo(...) RETURNS integer AS ' -- assume 1 (search starts at first character). -- -CREATE FUNCTION instr(varchar, varchar) RETURNS integer AS ' +CREATE FUNCTION instr(varchar, varchar) RETURNS integer AS $$ DECLARE pos integer; BEGIN pos:= instr($1, $2, 1); RETURN pos; END; -' LANGUAGE plpgsql; +$$ LANGUAGE plpgsql; -CREATE FUNCTION instr(varchar, varchar, varchar) RETURNS integer AS ' +CREATE FUNCTION instr(varchar, varchar, varchar) RETURNS integer AS $$ DECLARE string ALIAS FOR $1; string_to_search ALIAS FOR $2; @@ -2957,10 +2997,10 @@ BEGIN RETURN 0; END IF; 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 string ALIAS FOR $1; string_to_search ALIAS FOR $2; @@ -3018,10 +3058,10 @@ BEGIN RETURN 0; END IF; END; -' LANGUAGE plpgsql; +$$ LANGUAGE plpgsql; - + diff --git a/doc/src/sgml/plpython.sgml b/doc/src/sgml/plpython.sgml index 8dada25692..a19b4a3585 100644 --- a/doc/src/sgml/plpython.sgml +++ b/doc/src/sgml/plpython.sgml @@ -1,4 +1,4 @@ - + PL/Python - Python Procedural Language @@ -230,14 +230,14 @@ rv = plpy.execute(plan, [ "name" ], 5) SD or GD (see ). For example: -CREATE FUNCTION usesavedplan() RETURNS trigger AS ' +CREATE FUNCTION usesavedplan() RETURNS trigger AS $$ if SD.has_key("plan"): plan = SD["plan"] else: plan = plpy.prepare("SELECT 1") SD["plan"] = plan # rest of function -' LANGUAGE plpythonu; +$$ LANGUAGE plpythonu; diff --git a/doc/src/sgml/pltcl.sgml b/doc/src/sgml/pltcl.sgml index 2e7b9f88e1..d790a04570 100644 --- a/doc/src/sgml/pltcl.sgml +++ b/doc/src/sgml/pltcl.sgml @@ -1,5 +1,5 @@ @@ -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 PL/Tcl language, use the standard syntax: -CREATE FUNCTION funcname (argument-types) RETURNS return-type AS ' +CREATE FUNCTION funcname +(argument-types) RETURNS return-type AS $$ # PL/Tcl function body -' LANGUAGE pltcl; +$$ LANGUAGE pltcl; PL/TclU is the same, except that the language has to be specified as @@ -100,10 +101,10 @@ CREATE FUNCTION funcname (argument-types returning the greater of two integer values could be defined as: -CREATE FUNCTION tcl_max(integer, integer) RETURNS integer AS ' +CREATE FUNCTION tcl_max(integer, integer) RETURNS integer AS $$ if {$1 > $2} {return $1} return $2 -' LANGUAGE pltcl STRICT; +$$ LANGUAGE pltcl STRICT; Note the clause STRICT, which saves us from @@ -122,7 +123,7 @@ CREATE FUNCTION tcl_max(integer, integer) RETURNS integer AS ' argument, rather than null: -CREATE FUNCTION tcl_max(integer, integer) RETURNS integer AS ' +CREATE FUNCTION tcl_max(integer, integer) RETURNS integer AS $$ if {[argisnull 1]} { if {[argisnull 2]} { return_null } return $2 @@ -130,7 +131,7 @@ CREATE FUNCTION tcl_max(integer, integer) RETURNS integer AS ' if {[argisnull 2]} { return $1 } if {$1 > $2} {return $1} return $2 -' LANGUAGE pltcl; +$$ LANGUAGE pltcl; @@ -154,7 +155,7 @@ CREATE TABLE employee ( age integer ); -CREATE FUNCTION overpaid(employee) RETURNS boolean AS ' +CREATE FUNCTION overpaid(employee) RETURNS boolean AS $$ if {200000.0 < $1(salary)} { return "t" } @@ -162,7 +163,7 @@ CREATE FUNCTION overpaid(employee) RETURNS boolean AS ' return "t" } return "f" -' LANGUAGE pltcl; +$$ LANGUAGE pltcl; @@ -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: -CREATE FUNCTION t1_count(integer, integer) RETURNS integer AS ' +CREATE FUNCTION t1_count(integer, integer) RETURNS integer AS $$ if {![ info exists GD(plan) ]} { # prepare the saved plan on the first call - set GD(plan) [ spi_prepare \\ - "SELECT count(*) AS cnt FROM t1 WHERE num >= \\$1 AND num <= \\$2" \\ + set GD(plan) [ spi_prepare \ + "SELECT count(*) AS cnt FROM t1 WHERE num >= \$1 AND num <= \$2" \ [ list int4 int4 ] ] } spi_execp -count 1 $GD(plan) [ list $1 $2 ] return $cnt -' LANGUAGE pltcl; +$$ LANGUAGE pltcl; - Note that each backslash that Tcl should see must be doubled when - we type in the function, since the main parser processes - backslashes, too, in CREATE FUNCTION. We need backslashes inside - the query string given to spi_prepare to ensure that - the $n markers will be passed through to - spi_prepare as-is, and not - replaced by Tcl variable substitution. + We need backslashes inside the query string given to + spi_prepare to ensure that the + $n markers will be passed + through to spi_prepare as-is, and not replaced by Tcl + variable substitution. + @@ -425,7 +425,7 @@ SELECT 'doesn't' AS ret The submitted command should contain -SELECT 'doesn''t' AS ret +SELECT $q$doesn't$q$ AS ret which can be formed in PL/Tcl using @@ -611,7 +611,7 @@ SELECT 'doesn''t' AS ret incremented on every update operation. -CREATE FUNCTION trigfunc_modcount() RETURNS trigger AS ' +CREATE FUNCTION trigfunc_modcount() RETURNS trigger AS $$ switch $TG_op { INSERT { set NEW($1) 0 @@ -625,7 +625,7 @@ CREATE FUNCTION trigfunc_modcount() RETURNS trigger AS ' } } return [array get NEW] -' LANGUAGE pltcl; +$$ LANGUAGE pltcl; CREATE TABLE mytab (num integer, description text, modcnt integer); diff --git a/doc/src/sgml/queries.sgml b/doc/src/sgml/queries.sgml index 185602c151..7acc36b378 100644 --- a/doc/src/sgml/queries.sgml +++ b/doc/src/sgml/queries.sgml @@ -1,4 +1,4 @@ - + Queries @@ -631,9 +631,9 @@ FROM (SELECT * FROM table1) AS alias_name 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; -' LANGUAGE SQL; +$$ LANGUAGE SQL; SELECT * FROM getfoo(1) AS t1; diff --git a/doc/src/sgml/ref/create_function.sgml b/doc/src/sgml/ref/create_function.sgml index 8b29d83082..4929524cff 100644 --- a/doc/src/sgml/ref/create_function.sgml +++ b/doc/src/sgml/ref/create_function.sgml @@ -1,5 +1,5 @@ @@ -54,10 +54,10 @@ CREATE [ OR REPLACE ] FUNCTION name To update the definition of an existing function, use CREATE OR REPLACE FUNCTION. It is not possible 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, - CREATE OR REPLACE FUNCTION will not let you - change the return type of an existing function. To do that, you - must drop and recreate the function. + tried, you would actually be creating a new, distinct function). + Also, CREATE OR REPLACE FUNCTION will not let + you change the return type of an existing function. To do that, + you must drop and recreate the function. @@ -250,7 +250,14 @@ CREATE [ OR REPLACE ] FUNCTION name A string defining the function; the meaning depends on the 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 . @@ -350,13 +357,14 @@ CREATE [ OR REPLACE ] FUNCTION name - Use DROP FUNCTION - to remove user-defined functions. + Use to remove user-defined + functions. - Any single quotes or backslashes in the function definition must be - escaped by doubling them. + Unless dollar quoting is used, any single quotes or backslashes in + the function definition must be escaped by doubling them. @@ -374,7 +382,7 @@ CREATE [ OR REPLACE ] FUNCTION name information and examples, see . CREATE FUNCTION add(integer, integer) RETURNS integer - AS 'select $1 + $2;' + AS $$select $1 + $2;$$ LANGUAGE SQL IMMUTABLE RETURNS NULL ON NULL INPUT; diff --git a/doc/src/sgml/ref/create_type.sgml b/doc/src/sgml/ref/create_type.sgml index ba63f4378b..348d267380 100644 --- a/doc/src/sgml/ref/create_type.sgml +++ b/doc/src/sgml/ref/create_type.sgml @@ -1,5 +1,5 @@ @@ -466,8 +466,9 @@ CREATE TYPE name ( a function definition: CREATE TYPE compfoo AS (f1 int, f2 text); -CREATE FUNCTION getfoo() RETURNS SETOF compfoo AS - 'SELECT fooid, fooname FROM foo' LANGUAGE SQL; +CREATE FUNCTION getfoo() RETURNS SETOF compfoo AS $$ + SELECT fooid, fooname FROM foo +$$ LANGUAGE SQL; diff --git a/doc/src/sgml/ref/select.sgml b/doc/src/sgml/ref/select.sgml index a98efcabd8..5c6206a303 100644 --- a/doc/src/sgml/ref/select.sgml +++ b/doc/src/sgml/ref/select.sgml @@ -1,5 +1,5 @@ @@ -938,18 +938,18 @@ SELECT actors.name clause, both with and without a column definition list: -CREATE FUNCTION distributors(int) RETURNS SETOF distributors AS ' +CREATE FUNCTION distributors(int) RETURNS SETOF distributors AS $$ SELECT * FROM distributors WHERE did = $1; -' LANGUAGE SQL; +$$ LANGUAGE SQL; SELECT * FROM distributors(111); did | name -----+------------- 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; -' LANGUAGE SQL; +$$ LANGUAGE SQL; SELECT * FROM distributors_2(111) AS (f1 int, f2 text); f1 | f2 diff --git a/doc/src/sgml/rules.sgml b/doc/src/sgml/rules.sgml index a764dcfc5f..d98661b45d 100644 --- a/doc/src/sgml/rules.sgml +++ b/doc/src/sgml/rules.sgml @@ -1,4 +1,4 @@ - + The Rule System @@ -343,9 +343,9 @@ For the example, we need a little min function that returns the lower of 2 integer values. We create that as -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 -' LANGUAGE SQL STRICT; +$$ LANGUAGE SQL STRICT; diff --git a/doc/src/sgml/syntax.sgml b/doc/src/sgml/syntax.sgml index 24a01891d3..18eaac0aec 100644 --- a/doc/src/sgml/syntax.sgml +++ b/doc/src/sgml/syntax.sgml @@ -1,5 +1,5 @@ @@ -240,15 +240,73 @@ UPDATE "my_table" SET "a" = 5; quotation marks escaping - A string constant in SQL is an arbitrary sequence of characters - bounded by single quotes ('), e.g., 'This - is a string'. SQL allows single quotes to be embedded - in strings by typing two adjacent single quotes, e.g., - 'Dianne''s horse'. In - PostgreSQL single quotes may - alternatively be escaped with a backslash (\), - e.g., 'Dianne\'s horse'. - + + dollar quoting + + PostgreSQL provides two ways to + specify a string constant. The first way is to enclose the + sequence of characters that constitute the string in single + quotes ('), e.g. 'This is a + string'. 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. 'Dianne''s + house'. In addition, + PostgreSQL allows single quotes + to be escaped with a backslash (\), + e.g. 'Dianne\'s horse'. + + + + 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, + PostgreSQL allows another way to + specify string constants known as dollar + quoting. A string constant specified via dollar quoting + consists of a dollar sign ($), an optional + tag 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: + +$$Dianne's horse$$ +$SomeTag$Dianne's horse$SomeTag$ + + Note that inside the dollar-quoted string, single quotes can be + used without needing to be escaped. + + + + Dollar quotes are case sensitive, so $tag$String + content$tag$ is valid, but $TAG$String + content$tag$ is not. Also, dollar quotes can + nest. For example: + +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; + + 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 PostgreSQL. + + + + 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. + C-style backslash escapes are also available: @@ -1008,7 +1066,7 @@ $number CREATE FUNCTION dept(text) RETURNS dept - AS 'SELECT * FROM dept WHERE name = $1' + AS $$SELECT * FROM dept WHERE name = $1$$ LANGUAGE SQL; diff --git a/doc/src/sgml/xfunc.sgml b/doc/src/sgml/xfunc.sgml index ed2a502c69..6ec5836047 100644 --- a/doc/src/sgml/xfunc.sgml +++ b/doc/src/sgml/xfunc.sgml @@ -1,5 +1,5 @@ @@ -104,13 +104,13 @@ $PostgreSQL: pgsql/doc/src/sgml/xfunc.sgml,v 1.83 2004/05/14 21:42:27 neilc Exp The body of an SQL function should be a list of one or more SQL - statements separated by semicolons. Note that because the syntax - of the CREATE FUNCTION command requires the body of the - function to be enclosed in single quotes, single quote marks - (') used - in the body of the function must be escaped, by writing two single - quotes ('') or a backslash (\') where each - quote is desired. + statements separated by semicolons. Although dollar quoting + obviates this, note that because the syntax of the CREATE + FUNCTION command, if you choose not to use dollar + quoting, i.e. the body of the function is enclosed in single quotes, + you must escape single quote marks (') used in the body of + the function, either by writing two single quotes ('') or + with a backslash (\') where you desire each quote to be. @@ -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 integer: +CREATE FUNCTION one() RETURNS integer AS $$ + SELECT 1 AS result; +$$ LANGUAGE SQL; + +-- Alternative syntax: CREATE FUNCTION one() RETURNS integer AS ' SELECT 1 AS result; ' LANGUAGE SQL; @@ -156,9 +161,9 @@ SELECT one(); and $2. -CREATE FUNCTION add_em(integer, integer) RETURNS integer AS ' +CREATE FUNCTION add_em(integer, integer) RETURNS integer AS $$ SELECT $1 + $2; -' LANGUAGE SQL; +$$ LANGUAGE SQL; SELECT add_em(1, 2) AS answer; @@ -173,12 +178,12 @@ SELECT add_em(1, 2) AS answer; bank account: -CREATE FUNCTION tf1 (integer, numeric) RETURNS integer AS ' +CREATE FUNCTION tf1 (integer, numeric) RETURNS integer AS $$ UPDATE bank SET balance = balance - $2 WHERE accountno = $1; SELECT 1; -' LANGUAGE SQL; +$$ LANGUAGE SQL; A user could execute this function to debit account 17 by $100.00 as @@ -195,12 +200,12 @@ SELECT tf1(17, 100.0); is -CREATE FUNCTION tf1 (integer, numeric) RETURNS numeric AS ' +CREATE FUNCTION tf1 (integer, numeric) RETURNS numeric AS $$ UPDATE bank SET balance = balance - $2 WHERE accountno = $1; SELECT balance FROM bank WHERE accountno = $1; -' LANGUAGE SQL; +$$ LANGUAGE SQL; which adjusts the balance and returns the new balance. @@ -221,10 +226,10 @@ CREATE FUNCTION tf1 (integer, numeric) RETURNS numeric AS ' For example: -CREATE FUNCTION clean_emp() RETURNS void AS ' +CREATE FUNCTION clean_emp() RETURNS void AS $$ DELETE FROM emp WHERE salary <= 0; -' LANGUAGE SQL; +$$ LANGUAGE SQL; SELECT clean_emp(); @@ -258,9 +263,9 @@ CREATE TABLE emp ( cubicle point ); -CREATE FUNCTION double_salary(emp) RETURNS numeric AS ' +CREATE FUNCTION double_salary(emp) RETURNS numeric AS $$ SELECT $1.salary * 2 AS salary; -' LANGUAGE SQL; +$$ LANGUAGE SQL; SELECT name, double_salary(emp.*) AS dream FROM emp @@ -304,12 +309,12 @@ SELECT name, double_salary(row(name, salary*1.1, age, cubicle)) AS dream that returns a single emp row: -CREATE FUNCTION new_emp() RETURNS emp AS ' - SELECT text ''None'' AS name, +CREATE FUNCTION new_emp() RETURNS emp AS $$ + SELECT text 'None' AS name, 1000 AS salary, 25 AS age, - point ''(2,2)'' AS cubicle; -' LANGUAGE SQL; + point '(2,2)' AS cubicle; +$$ LANGUAGE SQL; 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: -CREATE FUNCTION getname(emp) RETURNS text AS ' +CREATE FUNCTION getname(emp) RETURNS text AS $$ SELECT $1.name; -' LANGUAGE SQL; +$$ LANGUAGE SQL; SELECT getname(new_emp()); getname @@ -439,9 +444,9 @@ INSERT INTO foo VALUES (1, 1, 'Joe'); INSERT INTO foo VALUES (1, 2, 'Ed'); 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; -' LANGUAGE SQL; +$$ LANGUAGE SQL; SELECT *, upper(fooname) FROM getfoo(1) AS t1; @@ -478,9 +483,9 @@ SELECT *, upper(fooname) FROM getfoo(1) AS t1; table foo has the same contents as above, and we say: -CREATE FUNCTION getfoo(int) RETURNS SETOF foo AS ' +CREATE FUNCTION getfoo(int) RETURNS SETOF foo AS $$ SELECT * FROM foo WHERE fooid = $1; -' LANGUAGE SQL; +$$ LANGUAGE SQL; SELECT * FROM getfoo(1) AS t1; @@ -505,9 +510,9 @@ SELECT * FROM getfoo(1) AS t1; select list: -CREATE FUNCTION listchildren(text) RETURNS SETOF text AS -'SELECT name FROM nodes WHERE parent = $1' -LANGUAGE SQL; +CREATE FUNCTION listchildren(text) RETURNS SETOF text AS $$ + SELECT name FROM nodes WHERE parent = $1 +$$ LANGUAGE SQL; SELECT * FROM nodes; name | parent @@ -558,9 +563,9 @@ SELECT name, listchildren(name) FROM nodes; function make_array that builds up an array from two arbitrary data type elements: -CREATE FUNCTION make_array(anyelement, anyelement) RETURNS anyarray AS ' +CREATE FUNCTION make_array(anyelement, anyelement) RETURNS anyarray AS $$ SELECT ARRAY[$1, $2]; -' LANGUAGE SQL; +$$ LANGUAGE SQL; SELECT make_array(1, 2) AS intarray, make_array('a'::text, 'b') AS 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 return type, but the converse is not. For example: -CREATE FUNCTION is_greater(anyelement, anyelement) RETURNS boolean AS ' +CREATE FUNCTION is_greater(anyelement, anyelement) RETURNS boolean AS $$ SELECT $1 > $2; -' LANGUAGE SQL; +$$ LANGUAGE SQL; SELECT is_greater(1, 2); is_greater @@ -599,9 +604,9 @@ SELECT is_greater(1, 2); f (1 row) -CREATE FUNCTION invalid_func() RETURNS anyelement AS ' +CREATE FUNCTION invalid_func() RETURNS anyelement AS $$ SELECT 1; -' LANGUAGE SQL; +$$ LANGUAGE SQL; ERROR: cannot determine result data type DETAIL: A function returning "anyarray" or "anyelement" must have at least one argument of either type. @@ -659,7 +664,7 @@ DETAIL: A function returning "anyarray" or "anyelement" must have at least one create an alias for the sqrt function: CREATE FUNCTION square_root(double precision) RETURNS double precision - AS 'dsqrt' + AS $$dsqrt$$ LANGUAGE internal STRICT; -- GitLab