PostgreSQL 7.4.8 Documentation | ||||
---|---|---|---|---|
Prev | Fast Backward | Chapter 37. PL/pgSQL - SQL Procedural Language | Fast Forward | Next |
This section explains differences between PostgreSQL's PL/pgSQL language and Oracle's PL/SQL language, to help developers who port applications from Oracle to PostgreSQL.
PL/pgSQL is similar to PL/SQL in many aspects. It is a block-structured, imperative language, and all variables have to be declared. Assignments, loops, conditionals are similar. The main differences you should keep in mind when porting from PL/SQL to PL/pgSQL are:
There are no default values for parameters in PostgreSQL.
You can overload function names in PostgreSQL. This is often used to work around the lack of default parameters.
No need for cursors in PL/pgSQL, just put the query in the FOR statement. (See Example 37-3.)
In PostgreSQL you need to escape single quotes in the function body. See Section 37.2.1.
Instead of packages, use schemas to organize your functions into groups.
Example 37-2 shows how to port a simple function from PL/SQL to PL/pgSQL.
Example 37-2. Porting a Simple Function from PL/SQL to PL/pgSQL
Here is an Oracle PL/SQL function:
CREATE OR REPLACE FUNCTION cs_fmt_browser_version(v_name IN varchar, v_version IN varchar) RETURN varchar IS BEGIN IF v_version IS NULL THEN RETURN v_name; END IF; RETURN v_name || '/' || v_version; END; / show errors;
Let's go through this function and see the differences to PL/pgSQL:
PostgreSQL does not have named parameters. You have to explicitly alias them inside your function.
Oracle can have IN, OUT, and INOUT parameters passed to functions. INOUT, for example, means that the parameter will receive a value and return another. PostgreSQL only has IN parameters.
The RETURN key word in the function prototype (not the function body) becomes RETURNS in PostgreSQL.
In PostgreSQL, functions are created using single quotes as the delimiters of the function body, so you have to escape single quotes inside the function body.
The /show errors command does not exist in PostgreSQL.
This is how this function would look when ported to PostgreSQL:
CREATE OR REPLACE FUNCTION cs_fmt_browser_version(varchar, varchar) RETURNS varchar AS ' DECLARE v_name ALIAS FOR $1; v_version ALIAS FOR $2; BEGIN IF v_version IS NULL THEN return v_name; END IF; RETURN v_name || ''/'' || v_version; END; ' LANGUAGE plpgsql;
Example 37-3 shows how to port a function that creates another function and how to handle to ensuing quoting problems.
Example 37-3. Porting a Function that Creates Another Function from PL/SQL to PL/pgSQL
The following procedure grabs rows from a SELECT statement and builds a large function with the results in IF statements, for the sake of efficiency. Notice particularly the differences in the cursor and the FOR loop,
This is the Oracle version:
CREATE OR REPLACE PROCEDURE cs_update_referrer_type_proc IS CURSOR referrer_keys IS SELECT * FROM cs_referrer_keys ORDER BY try_order; a_output VARCHAR(4000); BEGIN a_output := 'CREATE OR REPLACE FUNCTION cs_find_referrer_type(v_host IN VARCHAR, v_domain IN VARCHAR, v_url IN VARCHAR) RETURN VARCHAR IS BEGIN'; FOR referrer_key IN referrer_keys LOOP a_output := a_output || ' IF v_' || referrer_key.kind || ' LIKE ''' || referrer_key.key_string || ''' THEN RETURN ''' || referrer_key.referrer_type || '''; END IF;'; END LOOP; a_output := a_output || ' RETURN NULL; END;'; EXECUTE IMMEDIATE a_output; END; / show errors;
Here is how this function would end up in PostgreSQL:
CREATE FUNCTION cs_update_referrer_type_proc() RETURNS integer AS ' 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 '''' 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; '''' 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; END; ' LANGUAGE plpgsql;
Example 37-4 shows how to port a function
with OUT parameters and string manipulation.
PostgreSQL does not have an
instr
function, but you can work around it
using a combination of other
functions. In Section 37.11.3 there is a
PL/pgSQL implementation of
instr
that you can use to make your porting
easier.
Example 37-4. Porting a Procedure With String Manipulation and OUT Parameters from PL/SQL to PL/pgSQL
The following Oracle PL/SQL procedure is used to parse a URL and return several elements (host, path, and query). PL/pgSQL functions can return only one value. In PostgreSQL, one way to work around this is to split the procedure in three different functions: one to return the host, another for the path, and another for the query.
This is the Oracle version:
CREATE OR REPLACE PROCEDURE cs_parse_url( v_url IN VARCHAR, v_host OUT VARCHAR, -- This will be passed back v_path OUT VARCHAR, -- This one too v_query OUT VARCHAR) -- And this one IS a_pos1 INTEGER; a_pos2 INTEGER; BEGIN v_host := NULL; v_path := NULL; v_query := NULL; a_pos1 := instr(v_url, '//'); IF a_pos1 = 0 THEN RETURN; END IF; a_pos2 := instr(v_url, '/', a_pos1 + 2); IF a_pos2 = 0 THEN v_host := substr(v_url, a_pos1 + 2); v_path := '/'; RETURN; END IF; v_host := substr(v_url, a_pos1 + 2, a_pos2 - a_pos1 - 2); a_pos1 := instr(v_url, '?', a_pos2 + 1); IF a_pos1 = 0 THEN v_path := substr(v_url, a_pos2); RETURN; END IF; v_path := substr(v_url, a_pos2, a_pos1 - a_pos2); v_query := substr(v_url, a_pos1 + 1); END; / show errors;
Here is how the PL/pgSQL function that returns the host part could look like:
CREATE OR REPLACE FUNCTION cs_parse_url_host(varchar) RETURNS varchar AS ' DECLARE v_url ALIAS FOR $1; v_host varchar; v_path varchar; a_pos1 integer; a_pos2 integer; a_pos3 integer; BEGIN v_host := NULL; a_pos1 := instr(v_url, ''//''); IF a_pos1 = 0 THEN RETURN ''''; -- Return a blank END IF; a_pos2 := instr(v_url,''/'',a_pos1 + 2); IF a_pos2 = 0 THEN v_host := substr(v_url, a_pos1 + 2); 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;
Example 37-5 shows how to port a procedure that uses numerous features that are specific to Oracle.
Example 37-5. Porting a Procedure from PL/SQL to PL/pgSQL
The Oracle version:
CREATE OR REPLACE PROCEDURE cs_create_job(v_job_id IN INTEGER) IS a_running_job_count INTEGER; PRAGMA AUTONOMOUS_TRANSACTION;(1) BEGIN LOCK TABLE cs_jobs IN EXCLUSIVE MODE;(2) SELECT count(*) INTO a_running_job_count FROM cs_jobs WHERE end_stamp IS NULL; IF a_running_job_count > 0 THEN COMMIT; -- free lock(3) raise_application_error(-20000, 'Unable to create a new job: a job is currently running.'); END IF; DELETE FROM cs_active_job; INSERT INTO cs_active_job(job_id) VALUES (v_job_id); BEGIN INSERT INTO cs_jobs (job_id, start_stamp) VALUES (v_job_id, sysdate); EXCEPTION WHEN dup_val_on_index THEN NULL; -- don't worry if it already exists(4) END; COMMIT; END; / show errors
Procedures like this can be easily converted into PostgreSQL functions returning an integer. This procedure in particular is interesting because it can teach us some things:
This is how we could port this procedure to PL/pgSQL:
CREATE OR REPLACE FUNCTION cs_create_job(integer) RETURNS integer AS ' DECLARE v_job_id ALIAS FOR $1; a_running_job_count integer; a_num integer; BEGIN LOCK TABLE cs_jobs IN EXCLUSIVE MODE; SELECT count(*) INTO a_running_job_count FROM cs_jobs WHERE end_stamp IS NULL; IF a_running_job_count > 0 THEN RAISE EXCEPTION ''Unable to create a new job: a job is currently running.''; END IF; DELETE FROM cs_active_job; INSERT INTO cs_active_job(job_id) VALUES (v_job_id); SELECT count(*) INTO a_num FROM cs_jobs WHERE job_id=v_job_id; IF NOT FOUND THEN -- If nothing was returned in the last query -- This job is not in the table so lets insert it. INSERT INTO cs_jobs(job_id, start_stamp) VALUES (v_job_id, current_timestamp); RETURN 1; ELSE RAISE NOTICE ''Job already running.'';(1) END IF; RETURN 0; END; ' LANGUAGE plpgsql;
This section explains a few other things to watch for when porting Oracle PL/SQL functions to PostgreSQL.
The PL/pgSQL version of
EXECUTE works similarly to the
PL/SQL version, but you have to remember to use
quote_literal(text)
and
quote_string(text)
as described in Section 37.6.4. Constructs of the
type EXECUTE ''SELECT * FROM $1''; will not
work unless you use these functions.
PostgreSQL gives you two function creation modifiers to optimize execution: the volatility (whether the function always returns the same result when given the same arguments) and the "strictness" (whether the function returns null if any argument is null). Consult the description of CREATE FUNCTION for details.
To make use of these optimization attributes, your CREATE FUNCTION statement could look something like this:
CREATE FUNCTION foo(...) RETURNS integer AS ' ... ' LANGUAGE plpgsql STRICT IMMUTABLE;
This section contains the code for an Oracle-compatible
instr
function that you can use to simplify
your porting efforts.
-- -- instr functions that mimic Oracle's counterpart -- Syntax: instr(string1, string2, [n], [m]) where [] denotes optional parameters. -- -- Searches string1 beginning at the nth character for the mth occurrence -- of string2. If n is negative, search backwards. If m is not passed, -- assume 1 (search starts at first character). -- CREATE FUNCTION instr(varchar, varchar) RETURNS integer AS ' DECLARE pos integer; BEGIN pos:= instr($1, $2, 1); RETURN pos; END; ' LANGUAGE plpgsql; CREATE FUNCTION instr(varchar, varchar, varchar) RETURNS integer AS ' DECLARE string ALIAS FOR $1; string_to_search ALIAS FOR $2; beg_index ALIAS FOR $3; pos integer NOT NULL DEFAULT 0; temp_str varchar; beg integer; length integer; ss_length integer; BEGIN IF beg_index > 0 THEN temp_str := substring(string FROM beg_index); pos := position(string_to_search IN temp_str); IF pos = 0 THEN RETURN 0; ELSE RETURN pos + beg_index - 1; END IF; ELSE ss_length := char_length(string_to_search); length := char_length(string); beg := length + beg_index - ss_length + 2; WHILE beg > 0 LOOP temp_str := substring(string FROM beg FOR ss_length); pos := position(string_to_search IN temp_str); IF pos > 0 THEN RETURN beg; END IF; beg := beg - 1; END LOOP; RETURN 0; END IF; END; ' LANGUAGE plpgsql; CREATE FUNCTION instr(varchar, varchar, integer, integer) RETURNS integer AS ' DECLARE string ALIAS FOR $1; string_to_search ALIAS FOR $2; beg_index ALIAS FOR $3; occur_index ALIAS FOR $4; pos integer NOT NULL DEFAULT 0; occur_number integer NOT NULL DEFAULT 0; temp_str varchar; beg integer; i integer; length integer; ss_length integer; BEGIN IF beg_index > 0 THEN beg := beg_index; temp_str := substring(string FROM beg_index); FOR i IN 1..occur_index LOOP pos := position(string_to_search IN temp_str); IF i = 1 THEN beg := beg + pos - 1; ELSE beg := beg + pos; END IF; temp_str := substring(string FROM beg + 1); END LOOP; IF pos = 0 THEN RETURN 0; ELSE RETURN beg; END IF; ELSE ss_length := char_length(string_to_search); length := char_length(string); beg := length + beg_index - ss_length + 2; WHILE beg > 0 LOOP temp_str := substring(string FROM beg FOR ss_length); pos := position(string_to_search IN temp_str); IF pos > 0 THEN occur_number := occur_number + 1; IF occur_number = occur_index THEN RETURN beg; END IF; END IF; beg := beg - 1; END LOOP; RETURN 0; END IF; END; ' LANGUAGE plpgsql;