2 41.12. Tips for Developing in PL/pgSQL #
4 41.12.1. Handling of Quotation Marks
5 41.12.2. Additional Compile-Time and Run-Time Checks
7 One good way to develop in PL/pgSQL is to use the text editor of your
8 choice to create your functions, and in another window, use psql to
9 load and test those functions. If you are doing it this way, it is a
10 good idea to write the function using CREATE OR REPLACE FUNCTION. That
11 way you can just reload the file to update the function definition. For
13 CREATE OR REPLACE FUNCTION testfunc(integer) RETURNS integer AS $$
17 While running psql, you can load or reload such a function definition
21 and then immediately issue SQL commands to test the function.
23 Another good way to develop in PL/pgSQL is with a GUI database access
24 tool that facilitates development in a procedural language. One example
25 of such a tool is pgAdmin, although others exist. These tools often
26 provide convenient features such as escaping single quotes and making
27 it easier to recreate and debug functions.
29 41.12.1. Handling of Quotation Marks #
31 The code of a PL/pgSQL function is specified in CREATE FUNCTION as a
32 string literal. If you write the string literal in the ordinary way
33 with surrounding single quotes, then any single quotes inside the
34 function body must be doubled; likewise any backslashes must be doubled
35 (assuming escape string syntax is used). Doubling quotes is at best
36 tedious, and in more complicated cases the code can become downright
37 incomprehensible, because you can easily find yourself needing half a
38 dozen or more adjacent quote marks. It's recommended that you instead
39 write the function body as a “dollar-quoted” string literal (see
40 Section 4.1.2.4). In the dollar-quoting approach, you never double any
41 quote marks, but instead take care to choose a different dollar-quoting
42 delimiter for each level of nesting you need. For example, you might
43 write the CREATE FUNCTION command as:
44 CREATE OR REPLACE FUNCTION testfunc(integer) RETURNS integer AS $PROC$
46 $PROC$ LANGUAGE plpgsql;
48 Within this, you might use quote marks for simple literal strings in
49 SQL commands and $$ to delimit fragments of SQL commands that you are
50 assembling as strings. If you need to quote text that includes $$, you
51 could use $Q$, and so on.
53 The following chart shows what you have to do when writing quote marks
54 without dollar quoting. It might be useful when translating pre-dollar
55 quoting code into something more comprehensible.
58 To begin and end the function body, for example:
60 CREATE FUNCTION foo() RETURNS integer AS '
64 Anywhere within a single-quoted function body, quote marks must
68 For string literals inside the function body, for example:
71 SELECT * FROM users WHERE f_name=''foobar'';
73 In the dollar-quoting approach, you'd just write:
76 SELECT * FROM users WHERE f_name='foobar';
78 which is exactly what the PL/pgSQL parser would see in either
82 When you need a single quotation mark in a string constant
83 inside the function body, for example:
85 a_output := a_output || '' AND name LIKE ''''foobar'''' AND xyz''
87 The value actually appended to a_output would be: AND name LIKE
90 In the dollar-quoting approach, you'd write:
92 a_output := a_output || $$ AND name LIKE 'foobar' AND xyz$$
94 being careful that any dollar-quote delimiters around this are
98 When a single quotation mark in a string inside the function
99 body is adjacent to the end of that string constant, for
102 a_output := a_output || '' AND name LIKE ''''foobar''''''
104 The value appended to a_output would then be: AND name LIKE
107 In the dollar-quoting approach, this becomes:
109 a_output := a_output || $$ AND name LIKE 'foobar'$$
112 When you want two single quotation marks in a string constant
113 (which accounts for 8 quotation marks) and this is adjacent to
114 the end of that string constant (2 more). You will probably only
115 need that if you are writing a function that generates other
116 functions, as in Example 41.10. For example:
118 a_output := a_output || '' if v_'' ||
119 referrer_keys.kind || '' like ''''''''''
120 || referrer_keys.key_string || ''''''''''
121 then return '''''' || referrer_keys.referrer_type
122 || ''''''; end if;'';
124 The value of a_output would then be:
126 if v_... like ''...'' then return ''...''; end if;
128 In the dollar-quoting approach, this becomes:
130 a_output := a_output || $$ if v_$$ || referrer_keys.kind || $$ like '$$
131 || referrer_keys.key_string || $$'
132 then return '$$ || referrer_keys.referrer_type
135 where we assume we only need to put single quote marks into
136 a_output, because it will be re-quoted before use.
138 41.12.2. Additional Compile-Time and Run-Time Checks #
140 To aid the user in finding instances of simple but common problems
141 before they cause harm, PL/pgSQL provides additional checks. When
142 enabled, depending on the configuration, they can be used to emit
143 either a WARNING or an ERROR during the compilation of a function. A
144 function which has received a WARNING can be executed without producing
145 further messages, so you are advised to test in a separate development
148 Setting plpgsql.extra_warnings, or plpgsql.extra_errors, as
149 appropriate, to "all" is encouraged in development and/or testing
152 These additional checks are enabled through the configuration variables
153 plpgsql.extra_warnings for warnings and plpgsql.extra_errors for
154 errors. Both can be set either to a comma-separated list of checks,
155 "none" or "all". The default is "none". Currently the list of available
159 Checks if a declaration shadows a previously defined variable.
161 strict_multi_assignment #
162 Some PL/pgSQL commands allow assigning values to more than one
163 variable at a time, such as SELECT INTO. Typically, the number
164 of target variables and the number of source variables should
165 match, though PL/pgSQL will use NULL for missing values and
166 extra variables are ignored. Enabling this check will cause
167 PL/pgSQL to throw a WARNING or ERROR whenever the number of
168 target variables and the number of source variables are
172 Enabling this check will cause PL/pgSQL to check if a given
173 query returns more than one row when an INTO clause is used. As
174 an INTO statement will only ever use one row, having a query
175 return multiple rows is generally either inefficient and/or
176 nondeterministic and therefore is likely an error.
178 The following example shows the effect of plpgsql.extra_warnings set to
180 SET plpgsql.extra_warnings TO 'shadowed_variables';
182 CREATE FUNCTION foo(f1 int) RETURNS int AS $$
189 WARNING: variable "f1" shadows a previously defined variable
194 The below example shows the effects of setting plpgsql.extra_warnings
195 to strict_multi_assignment:
196 SET plpgsql.extra_warnings TO 'strict_multi_assignment';
198 CREATE OR REPLACE FUNCTION public.foo()
207 SELECT 1, 2 INTO x, y;
208 SELECT 1, 2, 3 INTO x, y;
213 WARNING: number of source and target fields in assignment does not match
214 DETAIL: strict_multi_assignment check of extra_warnings is active.
215 HINT: Make sure the query returns the exact list of columns.
216 WARNING: number of source and target fields in assignment does not match
217 DETAIL: strict_multi_assignment check of extra_warnings is active.
218 HINT: Make sure the query returns the exact list of columns.