2 41.13. Porting from Oracle PL/SQL #
4 41.13.1. Porting Examples
5 41.13.2. Other Things to Watch For
8 This section explains differences between PostgreSQL's PL/pgSQL
9 language and Oracle's PL/SQL language, to help developers who port
10 applications from Oracle® to PostgreSQL.
12 PL/pgSQL is similar to PL/SQL in many aspects. It is a
13 block-structured, imperative language, and all variables have to be
14 declared. Assignments, loops, and conditionals are similar. The main
15 differences you should keep in mind when porting from PL/SQL to
17 * If a name used in an SQL command could be either a column name of a
18 table used in the command or a reference to a variable of the
19 function, PL/SQL treats it as a column name. By default, PL/pgSQL
20 will throw an error complaining that the name is ambiguous. You can
21 specify plpgsql.variable_conflict = use_column to change this
22 behavior to match PL/SQL, as explained in Section 41.11.1. It's
23 often best to avoid such ambiguities in the first place, but if you
24 have to port a large amount of code that depends on this behavior,
25 setting variable_conflict may be the best solution.
26 * In PostgreSQL the function body must be written as a string
27 literal. Therefore you need to use dollar quoting or escape single
28 quotes in the function body. (See Section 41.12.1.)
29 * Data type names often need translation. For example, in Oracle
30 string values are commonly declared as being of type varchar2,
31 which is a non-SQL-standard type. In PostgreSQL, use type varchar
32 or text instead. Similarly, replace type number with numeric, or
33 use some other numeric data type if there's a more appropriate one.
34 * Instead of packages, use schemas to organize your functions into
36 * Since there are no packages, there are no package-level variables
37 either. This is somewhat annoying. You can keep per-session state
38 in temporary tables instead.
39 * Integer FOR loops with REVERSE work differently: PL/SQL counts down
40 from the second number to the first, while PL/pgSQL counts down
41 from the first number to the second, requiring the loop bounds to
42 be swapped when porting. This incompatibility is unfortunate but is
43 unlikely to be changed. (See Section 41.6.5.5.)
44 * FOR loops over queries (other than cursors) also work differently:
45 the target variable(s) must have been declared, whereas PL/SQL
46 always declares them implicitly. An advantage of this is that the
47 variable values are still accessible after the loop exits.
48 * There are various notational differences for the use of cursor
51 41.13.1. Porting Examples #
53 Example 41.9 shows how to port a simple function from PL/SQL to
56 Example 41.9. Porting a Simple Function from PL/SQL to PL/pgSQL
58 Here is an Oracle PL/SQL function:
59 CREATE OR REPLACE FUNCTION cs_fmt_browser_version(v_name varchar2,
63 IF v_version IS NULL THEN
66 RETURN v_name || '/' || v_version;
71 Let's go through this function and see the differences compared to
73 * The type name varchar2 has to be changed to varchar or text. In the
74 examples in this section, we'll use varchar, but text is often a
75 better choice if you do not need specific string length limits.
76 * The RETURN key word in the function prototype (not the function
77 body) becomes RETURNS in PostgreSQL. Also, IS becomes AS, and you
78 need to add a LANGUAGE clause because PL/pgSQL is not the only
79 possible function language.
80 * In PostgreSQL, the function body is considered to be a string
81 literal, so you need to use quote marks or dollar quotes around it.
82 This substitutes for the terminating / in the Oracle approach.
83 * The show errors command does not exist in PostgreSQL, and is not
84 needed since errors are reported automatically.
86 This is how this function would look when ported to PostgreSQL:
87 CREATE OR REPLACE FUNCTION cs_fmt_browser_version(v_name varchar,
91 IF v_version IS NULL THEN
94 RETURN v_name || '/' || v_version;
98 Example 41.10 shows how to port a function that creates another
99 function and how to handle the ensuing quoting problems.
101 Example 41.10. Porting a Function that Creates Another Function from
104 The following procedure grabs rows from a SELECT statement and builds a
105 large function with the results in IF statements, for the sake of
108 This is the Oracle version:
109 CREATE OR REPLACE PROCEDURE cs_update_referrer_type_proc IS
110 CURSOR referrer_keys IS
111 SELECT * FROM cs_referrer_keys
113 func_cmd VARCHAR(4000);
115 func_cmd := 'CREATE OR REPLACE FUNCTION cs_find_referrer_type(v_host IN VARC
117 v_domain IN VARCHAR2, v_url IN VARCHAR2) RETURN VARCHAR2 IS BEG
120 FOR referrer_key IN referrer_keys LOOP
121 func_cmd := func_cmd ||
122 ' IF v_' || referrer_key.kind
123 || ' LIKE ''' || referrer_key.key_string
124 || ''' THEN RETURN ''' || referrer_key.referrer_type
128 func_cmd := func_cmd || ' RETURN NULL; END;';
130 EXECUTE IMMEDIATE func_cmd;
135 Here is how this function would end up in PostgreSQL:
136 CREATE OR REPLACE PROCEDURE cs_update_referrer_type_proc() AS $func$
138 referrer_keys CURSOR IS
139 SELECT * FROM cs_referrer_keys
144 func_body := 'BEGIN';
146 FOR referrer_key IN referrer_keys LOOP
147 func_body := func_body ||
148 ' IF v_' || referrer_key.kind
149 || ' LIKE ' || quote_literal(referrer_key.key_string)
150 || ' THEN RETURN ' || quote_literal(referrer_key.referrer_type)
154 func_body := func_body || ' RETURN NULL; END;';
157 'CREATE OR REPLACE FUNCTION cs_find_referrer_type(v_host varchar,
161 || quote_literal(func_body)
162 || ' LANGUAGE plpgsql;' ;
166 $func$ LANGUAGE plpgsql;
168 Notice how the body of the function is built separately and passed
169 through quote_literal to double any quote marks in it. This technique
170 is needed because we cannot safely use dollar quoting for defining the
171 new function: we do not know for sure what strings will be interpolated
172 from the referrer_key.key_string field. (We are assuming here that
173 referrer_key.kind can be trusted to always be host, domain, or url, but
174 referrer_key.key_string might be anything, in particular it might
175 contain dollar signs.) This function is actually an improvement on the
176 Oracle original, because it will not generate broken code when
177 referrer_key.key_string or referrer_key.referrer_type contain quote
180 Example 41.11 shows how to port a function with OUT parameters and
181 string manipulation. PostgreSQL does not have a built-in instr
182 function, but you can create one using a combination of other
183 functions. In Section 41.13.3 there is a PL/pgSQL implementation of
184 instr that you can use to make your porting easier.
186 Example 41.11. Porting a Procedure With String Manipulation and OUT
187 Parameters from PL/SQL to PL/pgSQL
189 The following Oracle PL/SQL procedure is used to parse a URL and return
190 several elements (host, path, and query).
192 This is the Oracle version:
193 CREATE OR REPLACE PROCEDURE cs_parse_url(
195 v_host OUT VARCHAR2, -- This will be passed back
196 v_path OUT VARCHAR2, -- This one too
197 v_query OUT VARCHAR2) -- And this one
205 a_pos1 := instr(v_url, '//');
210 a_pos2 := instr(v_url, '/', a_pos1 + 2);
212 v_host := substr(v_url, a_pos1 + 2);
217 v_host := substr(v_url, a_pos1 + 2, a_pos2 - a_pos1 - 2);
218 a_pos1 := instr(v_url, '?', a_pos2 + 1);
221 v_path := substr(v_url, a_pos2);
225 v_path := substr(v_url, a_pos2, a_pos1 - a_pos2);
226 v_query := substr(v_url, a_pos1 + 1);
231 Here is a possible translation into PL/pgSQL:
232 CREATE OR REPLACE FUNCTION cs_parse_url(
234 v_host OUT VARCHAR, -- This will be passed back
235 v_path OUT VARCHAR, -- This one too
236 v_query OUT VARCHAR) -- And this one
245 a_pos1 := instr(v_url, '//');
250 a_pos2 := instr(v_url, '/', a_pos1 + 2);
252 v_host := substr(v_url, a_pos1 + 2);
257 v_host := substr(v_url, a_pos1 + 2, a_pos2 - a_pos1 - 2);
258 a_pos1 := instr(v_url, '?', a_pos2 + 1);
261 v_path := substr(v_url, a_pos2);
265 v_path := substr(v_url, a_pos2, a_pos1 - a_pos2);
266 v_query := substr(v_url, a_pos1 + 1);
270 This function could be used like this:
271 SELECT * FROM cs_parse_url('http://foobar.com/query.cgi?baz');
273 Example 41.12 shows how to port a procedure that uses numerous features
274 that are specific to Oracle.
276 Example 41.12. Porting a Procedure from PL/SQL to PL/pgSQL
279 CREATE OR REPLACE PROCEDURE cs_create_job(v_job_id IN INTEGER) IS
280 a_running_job_count INTEGER;
282 LOCK TABLE cs_jobs IN EXCLUSIVE MODE;
284 SELECT count(*) INTO a_running_job_count FROM cs_jobs WHERE end_stamp IS NUL
287 IF a_running_job_count > 0 THEN
289 raise_application_error(-20000,
290 'Unable to create a new job: a job is currently running.');
293 DELETE FROM cs_active_job;
294 INSERT INTO cs_active_job(job_id) VALUES (v_job_id);
297 INSERT INTO cs_jobs (job_id, start_stamp) VALUES (v_job_id, now());
299 WHEN dup_val_on_index THEN NULL; -- don't worry if it already exists
306 This is how we could port this procedure to PL/pgSQL:
307 CREATE OR REPLACE PROCEDURE cs_create_job(v_job_id integer) AS $$
309 a_running_job_count integer;
311 LOCK TABLE cs_jobs IN EXCLUSIVE MODE;
313 SELECT count(*) INTO a_running_job_count FROM cs_jobs WHERE end_stamp IS NUL
316 IF a_running_job_count > 0 THEN
318 RAISE EXCEPTION 'Unable to create a new job: a job is currently running'
322 DELETE FROM cs_active_job;
323 INSERT INTO cs_active_job(job_id) VALUES (v_job_id);
326 INSERT INTO cs_jobs (job_id, start_stamp) VALUES (v_job_id, now());
328 WHEN unique_violation THEN -- (2)
329 -- don't worry if it already exists
337 The syntax of RAISE is considerably different from Oracle's statement,
338 although the basic case RAISE exception_name works similarly.
342 The exception names supported by PL/pgSQL are different from Oracle's.
343 The set of built-in exception names is much larger (see Appendix A).
344 There is not currently a way to declare user-defined exception names,
345 although you can throw user-chosen SQLSTATE values instead.
347 41.13.2. Other Things to Watch For #
349 This section explains a few other things to watch for when porting
350 Oracle PL/SQL functions to PostgreSQL.
352 41.13.2.1. Implicit Rollback after Exceptions #
354 In PL/pgSQL, when an exception is caught by an EXCEPTION clause, all
355 database changes since the block's BEGIN are automatically rolled back.
356 That is, the behavior is equivalent to what you'd get in Oracle with:
369 If you are translating an Oracle procedure that uses SAVEPOINT and
370 ROLLBACK TO in this style, your task is easy: just omit the SAVEPOINT
371 and ROLLBACK TO. If you have a procedure that uses SAVEPOINT and
372 ROLLBACK TO in a different way then some actual thought will be
377 The PL/pgSQL version of EXECUTE works similarly to the PL/SQL version,
378 but you have to remember to use quote_literal and quote_ident as
379 described in Section 41.5.4. Constructs of the type EXECUTE 'SELECT *
380 FROM $1'; will not work reliably unless you use these functions.
382 41.13.2.3. Optimizing PL/pgSQL Functions #
384 PostgreSQL gives you two function creation modifiers to optimize
385 execution: “volatility” (whether the function always returns the same
386 result when given the same arguments) and “strictness” (whether the
387 function returns null if any argument is null). Consult the CREATE
388 FUNCTION reference page for details.
390 When making use of these optimization attributes, your CREATE FUNCTION
391 statement might look something like this:
392 CREATE FUNCTION foo(...) RETURNS integer AS $$
394 $$ LANGUAGE plpgsql STRICT IMMUTABLE;
398 This section contains the code for a set of Oracle-compatible instr
399 functions that you can use to simplify your porting efforts.
401 -- instr functions that mimic Oracle's counterpart
402 -- Syntax: instr(string1, string2 [, n [, m]])
403 -- where [] denotes optional parameters.
405 -- Search string1, beginning at the nth character, for the mth occurrence
406 -- of string2. If n is negative, search backwards, starting at the abs(n)'th
407 -- character from the end of string1.
408 -- If n is not passed, assume 1 (search starts at first character).
409 -- If m is not passed, assume 1 (find first occurrence).
410 -- Returns starting index of string2 in string1, or 0 if string2 is not found.
413 CREATE FUNCTION instr(varchar, varchar) RETURNS integer AS $$
415 RETURN instr($1, $2, 1);
417 $$ LANGUAGE plpgsql STRICT IMMUTABLE;
420 CREATE FUNCTION instr(string varchar, string_to_search_for varchar,
422 RETURNS integer AS $$
424 pos integer NOT NULL DEFAULT 0;
430 IF beg_index > 0 THEN
431 temp_str := substring(string FROM beg_index);
432 pos := position(string_to_search_for IN temp_str);
437 RETURN pos + beg_index - 1;
439 ELSIF beg_index < 0 THEN
440 ss_length := char_length(string_to_search_for);
441 length := char_length(string);
442 beg := length + 1 + beg_index;
445 temp_str := substring(string FROM beg FOR ss_length);
446 IF string_to_search_for = temp_str THEN
458 $$ LANGUAGE plpgsql STRICT IMMUTABLE;
461 CREATE FUNCTION instr(string varchar, string_to_search_for varchar,
462 beg_index integer, occur_index integer)
463 RETURNS integer AS $$
465 pos integer NOT NULL DEFAULT 0;
466 occur_number integer NOT NULL DEFAULT 0;
473 IF occur_index <= 0 THEN
474 RAISE 'argument ''%'' is out of range', occur_index
475 USING ERRCODE = '22003';
478 IF beg_index > 0 THEN
479 beg := beg_index - 1;
480 FOR i IN 1..occur_index LOOP
481 temp_str := substring(string FROM beg + 1);
482 pos := position(string_to_search_for IN temp_str);
490 ELSIF beg_index < 0 THEN
491 ss_length := char_length(string_to_search_for);
492 length := char_length(string);
493 beg := length + 1 + beg_index;
496 temp_str := substring(string FROM beg FOR ss_length);
497 IF string_to_search_for = temp_str THEN
498 occur_number := occur_number + 1;
499 IF occur_number = occur_index THEN
512 $$ LANGUAGE plpgsql STRICT IMMUTABLE;