<application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language PL/pgSQL PL/pgSQL is a loadable procedural language for the PostgreSQL database system. The design goals of PL/pgSQL were to create a loadable procedural language that can be used to create functions and trigger procedures, adds control structures to the SQL language, can perform complex computations, inherits all user-defined types, functions, and operators, can be defined to be trusted by the server, is easy to use. Overview The PL/pgSQL call handler parses the function's source text and produces an internal binary instruction tree the first time the function is called (within each session). The instruction tree fully translates the PL/pgSQL statement structure, but individual SQL expressions and SQL commands used in the function are not translated immediately. As each expression and SQL command is first used in the function, the PL/pgSQL interpreter creates a prepared execution plan (using the SPI manager's SPI_prepare and SPI_saveplan functions).preparing a queryin PL/pgSQL Subsequent visits to that expression or command reuse the prepared plan. Thus, a function with conditional code that contains many statements for which execution plans might be required will only prepare and save those plans that are really used during the lifetime of the database connection. This can substantially reduce the total amount of time required to parse, and generate execution plans for the statements in a PL/pgSQL function. A disadvantage is that errors in a specific expression or command may not be detected until that part of the function is reached in execution. Once PL/pgSQL has made an execution plan for a particular command in a function, it will reuse that plan for the life of the database connection. This is usually a win for performance, but it can cause some problems if you dynamically alter your database schema. For example: CREATE FUNCTION populate() RETURNS integer AS ' DECLARE -- declarations BEGIN PERFORM my_function(); END; ' LANGUAGE plpgsql; If you execute the above function, it will reference the OID for my_function() in the execution plan produced for the PERFORM statement. Later, if you drop and recreate my_function(), then populate() will not be able to find my_function() anymore. You would then have to recreate populate(), or at least start a new database session so that it will be compiled afresh. Another way to avoid this problem is to use CREATE OR REPLACE FUNCTION when updating the definition of my_function (when a function is replaced, its OID is not changed). Because PL/pgSQL saves execution plans in this way, SQL commands that appear directly in a PL/pgSQL function must refer to the same tables and columns on every execution; that is, you cannot use a parameter as the name of a table or column in an SQL command. To get around this restriction, you can construct dynamic commands using the PL/pgSQL EXECUTE statement --- at the price of constructing a new execution plan on every execution. The PL/pgSQL EXECUTE statement is not related to the EXECUTE statement supported by the PostgreSQL server. The server's EXECUTE statement cannot be used within PL/pgSQL functions (and is not needed). Except for input/output conversion and calculation functions for user-defined types, anything that can be defined in C language functions can also be done with PL/pgSQL. For example, it is possible to create complex conditional computation functions and later use them to define operators or use them in index expressions. Advantages of Using <application>PL/pgSQL</application> SQL is the language PostgreSQL (and most other relational databases) use as query language. It's portable and easy to learn. But every SQL statement must be executed individually by the database server. That means that your client application must send each query to the database server, wait for it to be processed, receive the results, do some computation, then send other queries to the server. All this incurs interprocess communication and may also incur network overhead if your client is on a different machine than the database server. With PL/pgSQL you can group a block of computation and a series of queries inside the database server, thus having the power of a procedural language and the ease of use of SQL, but saving lots of time because you don't have the whole client/server communication overhead. This can make for a considerable performance increase. Also, with PL/pgSQL you can use all the data types, operators and functions of SQL. Supported Argument and Result Data Types Functions written in PL/pgSQL can accept as arguments any scalar or array data type supported by the server, and they can return a result of any of these types. They can also accept or return any composite type (row type) specified by name. It is also possible to declare a PL/pgSQL function as returning record, which means that the result is a row type whose columns are determined by specification in the calling query, as discussed in . PL/pgSQL functions may also be declared to accept and return the polymorphic types anyelement and anyarray. The actual data types handled by a polymorphic function can vary from call to call, as discussed in . An example is shown in . PL/pgSQL functions can also be declared to return a set, or table, of any data type they can return a single instance of. Such a function generates its output by executing RETURN NEXT for each desired element of the result set. Finally, a PL/pgSQL function may be declared to return void if it has no useful return value. Tips for Developing in <application>PL/pgSQL</application> One good way to develop in PL/pgSQL is to use the text editor of your choice to create your functions, and in another window, use psql to load and test those functions. If you are doing it this way, it is a good idea to write the function using CREATE OR REPLACE FUNCTION. That way you can just reload the file to update the function definition. For example: CREATE OR REPLACE FUNCTION testfunc(integer) RETURNS integer AS ' .... end; ' LANGUAGE plpgsql; While running psql, you can load or reload such a function definition file with \i filename.sql and then immediately issue SQL commands to test the function. Another good way to develop in PL/pgSQL is using a GUI database access tool that facilitates development in a procedural language. One example of such as a tool is PgAccess, although others exist. These tools often provide convenient features such as escaping single quotes and making it easier to recreate and debug functions. Handling of Quotation Marks 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. 1 quotation mark To begin and end the function body, for example: CREATE FUNCTION foo() RETURNS integer AS '...' LANGUAGE plpgsql; Anywhere within the function body, quotation marks must appear in pairs. 2 quotation marks For string literals inside the function body, for example: a_output := ''Blah''; SELECT * FROM users WHERE f_name=''foobar''; The second line is seen by PL/pgSQL as SELECT * FROM users WHERE f_name='foobar'; 4 quotation marks When you need a single quotation mark in a string constant inside the function body, for example: a_output := a_output || '' AND name LIKE ''''foobar'''' AND xyz'' The value actually appended to a_output would be: AND name LIKE 'foobar' AND xyz. 6 quotation marks When a single quotation mark in a string inside the function body is adjacent to the end of that string constant, for example: a_output := a_output || '' AND name LIKE ''''foobar'''''' The value appended to a_output would then be: AND name LIKE 'foobar'. 10 quotation marks When you want two single quotation marks in a string constant (which accounts for 8 quotation marks) and this is adjacent to the end of that string constant (2 more). You will probably only need that if you are writing a function that generates other functions. For example: a_output := a_output || '' if v_'' || referrer_keys.kind || '' like '''''''''' || referrer_keys.key_string || '''''''''' then return '''''' || referrer_keys.referrer_type || ''''''; end if;''; The value of a_output would then be: if v_... like ''...'' then return ''...''; end if; A different approach is to escape quotation marks in the function body with a backslash rather than by doubling them. With this method you'll find yourself writing things like \'\' instead of ''''. Some find this easier to keep track of, some do not. Structure of <application>PL/pgSQL</application> PL/pgSQL is a block-structured language. The complete text of a function definition must be a block. A block is defined as: <<label>> DECLARE declarations BEGIN statements END; Each declaration and each statement within a block is terminated by a semicolon. All key words and identifiers can be written in mixed upper and lower case. Identifiers are implicitly converted to lowercase unless double-quoted. There are two types of comments in PL/pgSQL. A double dash (--) starts a comment that extends to the end of the line. A /* starts a block comment that extends to the next occurrence of */. Block comments cannot be nested, but double dash comments can be enclosed into a block comment and a double dash can hide the block comment delimiters /* and */. Any statement in the statement section of a block can be a subblock. Subblocks can be used for logical grouping or to localize variables to a small group of statements. The variables declared in the declarations section preceding a 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 ' DECLARE quantity integer := 30; BEGIN RAISE NOTICE ''Quantity here is %'', quantity; -- Quantity here is 30 quantity := 50; -- -- Create a subblock -- DECLARE quantity integer := 80; BEGIN RAISE NOTICE ''Quantity here is %'', quantity; -- Quantity here is 80 END; RAISE NOTICE ''Quantity here is %'', quantity; -- Quantity here is 50 RETURN quantity; END; ' LANGUAGE plpgsql; It is important not to confuse the use of BEGIN/END for grouping statements in PL/pgSQL with the database commands for transaction control. PL/pgSQL's BEGIN/END are only for grouping; they do not start or end a transaction. Functions and trigger procedures are always executed within a transaction established by an outer query --- they cannot start or commit transactions, since PostgreSQL does not have nested transactions. Declarations All variables used in a block must be declared in the declarations section of the block. (The only exception is that the loop variable of a FOR loop iterating over a range of integer values is automatically declared as an integer variable.) PL/pgSQL variables can have any SQL data type, such as integer, varchar, and char. Here are some examples of variable declarations: user_id integer; quantity numeric(5); url varchar; myrow tablename%ROWTYPE; myfield tablename.columnname%TYPE; arow RECORD; The general syntax of a variable declaration is: name CONSTANT type NOT NULL { DEFAULT | := } expression ; The DEFAULT clause, if given, specifies the initial value assigned to the variable when the block is entered. If the DEFAULT clause is not given then the variable is initialized to the SQL null value. The CONSTANT option prevents the variable from being assigned to, so that its value remains constant for the duration of the block. If NOT NULL is specified, an assignment of a null value results in a run-time error. All variables declared as NOT NULL must have a nonnull default value specified. The default value is evaluated every time the block is entered. So, for example, assigning 'now' to a variable of type timestamp causes the variable to have the time of the current function call, not the time when the function was precompiled. Examples: quantity integer DEFAULT 32; url varchar := ''http://mysite.com''; user_id CONSTANT integer := 10; Aliases for Function Parameters name ALIAS FOR $n; Parameters passed to functions are named with the identifiers $1, $2, etc. Optionally, aliases can be declared for $n parameter names for increased readability. Either the alias or the numeric identifier can then be used to refer to the parameter value. Some examples: CREATE FUNCTION sales_tax(real) RETURNS real AS ' DECLARE subtotal ALIAS FOR $1; BEGIN RETURN subtotal * 0.06; END; ' LANGUAGE plpgsql; 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; 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; When the return type of a PL/pgSQL function is declared as a polymorphic type (anyelement or anyarray), a special parameter $0 is created. Its data type is the actual return type of the function, as deduced from the actual input types (see ). This allows the function to access its actual return type as shown in . $0 is initialized to null and can be modified by the function, so it can be used to hold the return value if desired, though that is not required. $0 can also be given an alias. For example, this function works on any data type that has a + operator: CREATE FUNCTION add_three_values(anyelement, anyelement, anyelement) RETURNS anyelement AS ' DECLARE result ALIAS FOR $0; first ALIAS FOR $1; second ALIAS FOR $2; third ALIAS FOR $3; BEGIN result := first + second + third; RETURN result; END; ' LANGUAGE plpgsql; Copying Types variable%TYPE %TYPE provides the data type of a variable or table column. You can use this to declare variables that will hold database values. For example, let's say you have a column named user_id in your users table. To declare a variable with the same data type as users.user_id you write: user_id users.user_id%TYPE; By using %TYPE you don't need to know the data type of the structure you are referencing, and most importantly, if the data type of the referenced item changes in the future (for instance: you change the type of user_id from integer to real), you may not need to change your function definition. %TYPE is particularly valuable in polymorphic functions, since the data types needed for internal variables may change from one call to the next. Appropriate variables can be created by applying %TYPE to the function's arguments or result placeholders. Row Types name table_name%ROWTYPE; name composite_type_name; A variable of a composite type is called a row variable (or row-type variable). Such a variable can hold a whole row of a SELECT or FOR query result, so long as that query's column set matches the declared type of the variable. The individual fields of the row value are accessed using the usual dot notation, for example rowvar.field. A row variable can be declared to have the same type as the rows of an existing table or view, by using the table_name%ROWTYPE notation; or it can be declared by giving a composite type's name. (Since every table has an associated composite type of the same name, it actually does not matter in PostgreSQL whether you write %ROWTYPE or not. But the form with %ROWTYPE is more portable.) Parameters to a function can be composite types (complete table rows). In that case, the corresponding identifier $n will be a row variable, and fields can be selected from it, for example $1.user_id. Only the user-defined columns of a table row are accessible in a row-type variable, not the OID or other system columns (because the row could be from a view). The fields of the row type inherit the table's field size or precision for data types such as char(n). Here is an example of using composite types: CREATE FUNCTION use_two_tables(tablename) RETURNS text AS ' DECLARE in_t ALIAS FOR $1; use_t table2name%ROWTYPE; BEGIN SELECT * INTO use_t FROM table2name WHERE ... ; RETURN in_t.f1 || use_t.f3 || in_t.f5 || use_t.f7; END; ' LANGUAGE plpgsql; SELECT use_two_tables(t.*) FROM tablename t WHERE ... ; Record Types name RECORD; Record variables are similar to row-type variables, but they have no predefined structure. They take on the actual row structure of the row they are assigned during a SELECT or FOR command. The substructure of a record variable can change each time it is assigned to. A consequence of this is that until a record variable is first assigned to, it has no substructure, and any attempt to access a field in it will draw a run-time error. Note that RECORD is not a true data type, only a placeholder. One should also realize that when a PL/pgSQL function is declared to return type record, this is not quite the same concept as a record variable, even though such a function may well use a record variable to hold its result. In both cases the actual row structure is unknown when the function is written, but for a function returning record the actual structure is determined when the calling query is parsed, whereas a record variable can change its row structure on-the-fly. <literal>RENAME</> RENAME oldname TO newname; Using the RENAME declaration you can change the name of a variable, record or row. This is primarily useful if NEW or OLD should be referenced by another name inside a trigger procedure. See also ALIAS. Examples: RENAME id TO user_id; RENAME this_var TO that_var; RENAME appears to be broken as of PostgreSQL 7.3. Fixing this is of low priority, since ALIAS covers most of the practical uses of RENAME. Expressions All expressions used in PL/pgSQL statements are processed using the server's regular SQL executor. Expressions that appear to contain constants may in fact require run-time evaluation (e.g., 'now' for the timestamp type) so it is impossible for the PL/pgSQL parser to identify real constant values other than the key word NULL. All expressions are evaluated internally by executing a query SELECT expression using the SPI manager. For evaluation, occurrences of PL/pgSQL variable identifiers are replaced by parameters, and the actual values from the variables are passed to the executor in the parameter array. This allows the query plan for the SELECT to be prepared just once and then reused for subsequent evaluations. The evaluation done by the PostgreSQL main parser has some side effects on the interpretation of constant values. In detail there is a difference between what these two functions do: CREATE FUNCTION logfunc1(text) RETURNS timestamp AS ' DECLARE logtxt ALIAS FOR $1; BEGIN INSERT INTO logtable VALUES (logtxt, ''now''); RETURN ''now''; END; ' LANGUAGE plpgsql; and CREATE FUNCTION logfunc2(text) RETURNS timestamp AS ' DECLARE logtxt ALIAS FOR $1; curtime timestamp; BEGIN curtime := ''now''; INSERT INTO logtable VALUES (logtxt, curtime); RETURN curtime; END; ' LANGUAGE plpgsql; In the case of logfunc1, the PostgreSQL main parser knows when preparing the plan for the INSERT, that the string 'now' should be interpreted as timestamp because the target column of logtable is of that type. Thus, it will make a constant from it at this time and this constant value is then used in all invocations of logfunc1 during the lifetime of the session. Needless to say that this isn't what the programmer wanted. In the case of logfunc2, the PostgreSQL main parser does not know what type 'now' should become and therefore it returns a data value of type text containing the string now. During the ensuing assignment to the local variable curtime, the PL/pgSQL interpreter casts this string to the timestamp type by calling the text_out and timestamp_in functions for the conversion. So, the computed time stamp is updated on each execution as the programmer expects. The mutable nature of record variables presents a problem in this connection. When fields of a record variable are used in expressions or statements, the data types of the fields must not change between calls of one and the same expression, since the expression will be planned using the data type that is present when the expression is first reached. Keep this in mind when writing trigger procedures that handle events for more than one table. (EXECUTE can be used to get around this problem when necessary.) Basic Statements In this section and the following ones, we describe all the statement types that are explicitly understood by PL/pgSQL. Anything not recognized as one of these statement types is presumed to be an SQL command and is sent to the main database engine to execute (after substitution of any PL/pgSQL variables used in the statement). Thus, for example, the SQL commands INSERT, UPDATE, and DELETE may be considered to be statements of PL/pgSQL, but they are not specifically listed here. Assignment An assignment of a value to a variable or row/record field is written as: identifier := expression; As explained above, the expression in such a statement is evaluated by means of an SQL SELECT command sent to the main database engine. The expression must yield a single value. If the expression's result data type doesn't match the variable's data type, or the variable has a specific size/precision (like char(20)), the result value will be implicitly converted by the PL/pgSQL interpreter using the result type's output-function and the variable type's input-function. Note that this could potentially result in run-time errors generated by the input function, if the string form of the result value is not acceptable to the input function. Examples: user_id := 20; tax := subtotal * 0.06; <command>SELECT INTO</command> SELECT INTO in PL/pgSQL The result of a SELECT command yielding multiple columns (but only one row) can be assigned to a record variable, row-type variable, or list of scalar variables. This is done by: SELECT INTO target select_expressions FROM ...; where target can be a record variable, a row variable, or a comma-separated list of simple variables and record/row fields. The select_expressions and the remainder of the command are the same as in regular SQL. Note that this is quite different from PostgreSQL's normal interpretation of SELECT INTO, where the INTO target is a newly created table. If you want to create a table from a SELECT result inside a PL/pgSQL function, use the syntax CREATE TABLE ... AS SELECT. If a row or a variable list is used as target, the selected values must exactly match the structure of the target, or a run-time error occurs. When a record variable is the target, it automatically configures itself to the row type of the query result columns. Except for the INTO clause, the SELECT statement is the same as a normal SQL SELECT command and can use its full power. If the query returns zero rows, null values are assigned to the target(s). If the query returns multiple rows, the first row is assigned to the target(s) and the rest are discarded. (Note that the first row is not well-defined unless you've used ORDER BY.) The INTO clause can appear almost anywhere in the SELECT statement. You can use FOUND 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; END IF; To test for whether a record/row result is null, you can use the IS NULL conditional. There is, however, no way to tell whether any additional rows might have been discarded. Here is an example that handles the case where no rows have been returned: DECLARE users_rec RECORD; BEGIN SELECT INTO users_rec * FROM users WHERE user_id=3; IF users_rec.homepage IS NULL THEN -- user entered no homepage, return "http://" RETURN ''http://''; END IF; END; Executing an Expression or Query With No Result Sometimes one wishes to evaluate an expression or query but discard the result (typically because one is calling a function that has useful side-effects but no useful result value). To do this in PL/pgSQL, use the PERFORM statement: PERFORM query; This executes query, which must be a SELECT statement, and discards the result. PL/pgSQL variables are substituted in the query as usual. Also, the special variable FOUND is set to true if the query produced at least one row or false if it produced no rows. One might expect that SELECT with no INTO clause would accomplish this result, but at present the only accepted way to do it is PERFORM. An example: 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 that will involve different tables or different data types each time they are executed. PL/pgSQL's normal attempts to cache plans for commands will not work in such scenarios. To handle this sort of problem, the EXECUTE statement is provided: EXECUTE command-string; where command-string is an expression yielding a string (of type text) containing the command to be executed. This string is fed literally to the SQL engine. Note in particular that no substitution of PL/pgSQL variables is done on the command string. The values of variables must be inserted in the command string as it is constructed. 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. Unlike all other commands in PL/pgSQL, a command run by an EXECUTE statement is not prepared and saved just once during the life of the session. Instead, the command is prepared each time the statement is run. The command 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 is not currently supported within EXECUTE. There are two ways to extract a result from a dynamically-created SELECT: one is to use the FOR-IN-EXECUTE loop form described in , and the other is to use a cursor with OPEN-FOR-EXECUTE, as described in . An example: EXECUTE ''UPDATE tbl SET '' || quote_ident(colname) || '' = '' || quote_literal(newvalue) || '' WHERE ...''; This example shows use of the functions quote_ident(text) and quote_literal(text).quote_identuse in PL/pgSQLquote_literaluse in PL/pgSQL For safety, variables containing column and table identifiers should be passed to function quote_ident. Variables containing values that should be literal strings in the constructed command should be passed to quote_literal. Both take the appropriate steps to return the input text enclosed in double or single quotes respectively, with any embedded special characters properly escaped. Here is a much larger example of a dynamic command and EXECUTE: 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 a_output; END; ' LANGUAGE plpgsql; Obtaining the Result Status There are several ways to determine the effect of a command. The first method is to use the GET DIAGNOSTICS command, which has the form: GET DIAGNOSTICS variable = item , ... ; This command allows retrieval of system status indicators. Each item is a key word identifying a state value to be assigned to the specified variable (which should be of the right data type to receive it). The currently available status items are ROW_COUNT, the number of rows processed by the last SQL command sent down to the SQL engine, and RESULT_OID, the OID of the last row inserted by the most recent SQL command. Note that RESULT_OID is only useful after an INSERT command. An example: GET DIAGNOSTICS integer_var = ROW_COUNT; The second method to determine the effects of a command is to check the special variable named FOUND, which is of type boolean. FOUND starts out false within each PL/pgSQL function call. It is set by each of the following types of statements: A SELECT INTO statement sets FOUND true if it returns a row, false if no row is returned. A PERFORM statement sets FOUND true if it produces (and discards) a row, false if no row is produced. UPDATE, INSERT, and DELETE statements set FOUND true if at least one row is affected, false if no row is affected. A FETCH statement sets FOUND true if it returns a row, false if no row is returned. A FOR statement sets FOUND true if it iterates one or more times, else false. This applies to all three variants of the FOR statement (integer FOR loops, record-set FOR loops, and dynamic record-set FOR loops). FOUND is only set when the FOR loop exits: inside the execution of the loop, FOUND is not modified by the FOR statement, although it may be changed by the execution of other statements within the loop body. FOUND is a local variable; any changes to it affect only the current PL/pgSQL function. Control Structures Control structures are probably the most useful (and important) part of PL/pgSQL. With PL/pgSQL's control structures, you can manipulate PostgreSQL data in a very flexible and powerful way. Returning From a Function There are two commands available that allow you to return data from a function: RETURN and RETURN NEXT. <command>RETURN</> RETURN expression; RETURN with an expression terminates the function and returns the value of expression to the caller. This form is to be used for PL/pgSQL functions that do not return a set. When returning a scalar type, any expression can be used. The expression's result will be automatically cast into the function's return type as described for assignments. To return a composite (row) value, you must write a record or row variable as the expression. The return value of a function cannot be left undefined. If control reaches the end of the top-level block of the function without hitting a RETURN statement, a run-time error will occur. If you have declared the function to return void, a RETURN statement must still be specified; but in this case the expression following RETURN is optional and will be ignored if present. <command>RETURN NEXT</> RETURN NEXT expression; When a PL/pgSQL function is declared to return SETOF sometype, the procedure to follow is slightly different. In that case, the individual items to return are specified in RETURN NEXT commands, and then a final RETURN command with no argument is used to indicate that the function has finished executing. RETURN NEXT can be used with both scalar and composite data types; in the latter case, an entire table of results will be returned. Functions that use RETURN NEXT should be called in the following fashion: SELECT * FROM some_func(); That is, the function is used as a table source in a FROM clause. RETURN NEXT does not actually return from the function; it simply saves away the value of the expression (or record or row variable, as appropriate for the data type being returned). Execution then continues with the next statement in the PL/pgSQL function. As successive RETURN NEXT commands are executed, the result set is built up. A final RETURN, which should have no argument, causes control to exit the function. The current implementation of RETURN NEXT for PL/pgSQL stores the entire result set before returning from the function, as discussed above. That means that if a PL/pgSQL function produces a very large result set, performance may be poor: data will be written to disk to avoid memory exhaustion, but the function itself will not return until the entire result set has been generated. A future version of PL/pgSQL may allow users to define set-returning functions that do not have this limitation. Currently, the point at which data begins being written to disk is controlled by the work_mem configuration variable. Administrators who have sufficient memory to store larger result sets in memory should consider increasing this parameter. Conditionals IF statements let you execute commands based on certain conditions. PL/pgSQL has four forms of IF: IF ... THEN IF ... THEN ... ELSE IF ... THEN ... ELSE IF IF ... THEN ... ELSIF ... THEN ... ELSE <literal>IF-THEN</> IF boolean-expression THEN statements END IF; IF-THEN statements are the simplest form of IF. The statements between THEN and END IF will be executed if the condition is true. Otherwise, they are skipped. Example: IF v_user_id <> 0 THEN UPDATE users SET email = v_email WHERE user_id = v_user_id; END IF; <literal>IF-THEN-ELSE</> IF boolean-expression THEN statements ELSE statements END IF; IF-THEN-ELSE statements add to IF-THEN by letting you specify an alternative set of statements that should be executed if the condition evaluates to false. Examples: IF parentid IS NULL OR parentid = '''' THEN RETURN fullname; ELSE RETURN hp_true_filename(parentid) || ''/'' || fullname; END IF; IF v_count > 0 THEN INSERT INTO users_count (count) VALUES (v_count); RETURN ''t''; ELSE RETURN ''f''; END IF; <literal>IF-THEN-ELSE IF</> IF statements can be nested, as in the following example: IF demo_row.sex = ''m'' THEN pretty_sex := ''man''; ELSE IF demo_row.sex = ''f'' THEN pretty_sex := ''woman''; END IF; END IF; When you use this form, you are actually nesting an IF statement inside the ELSE part of an outer IF statement. Thus you need one END IF statement for each nested IF and one for the parent IF-ELSE. This is workable but grows tedious when there are many alternatives to be checked. Hence the next form. <literal>IF-THEN-ELSIF-ELSE</> IF boolean-expression THEN statements ELSIF boolean-expression THEN statements ELSIF boolean-expression THEN statements ... ELSE statements END IF; IF-THEN-ELSIF-ELSE provides a more convenient method of checking many alternatives in one statement. Formally it is equivalent to nested IF-THEN-ELSE-IF-THEN commands, but only one END IF is needed. Here is an example: IF number = 0 THEN result := ''zero''; ELSIF number > 0 THEN result := ''positive''; ELSIF number < 0 THEN result := ''negative''; ELSE -- hmm, the only other possibility is that number is null result := ''NULL''; END IF; Simple Loops loop in PL/pgSQL With the LOOP, EXIT, WHILE, and FOR statements, you can arrange for your PL/pgSQL function to repeat a series of commands. <literal>LOOP</> <<label>> LOOP statements END LOOP; LOOP defines an unconditional loop that is repeated indefinitely until terminated by an EXIT or RETURN statement. The optional label can be used by EXIT statements in nested loops to specify which level of nesting should be terminated. <literal>EXIT</> EXIT label WHEN expression ; If no label is given, the innermost loop is terminated and the statement following END LOOP is executed next. If label is given, it must be the label of the current or some outer level of nested loop or block. Then the named loop or block is terminated and control continues with the statement after the loop's/block's corresponding END. If WHEN is present, loop exit occurs only if the specified condition is true, otherwise control passes to the statement after EXIT. Examples: LOOP -- some computations IF count > 0 THEN EXIT; -- exit loop END IF; END LOOP; LOOP -- some computations EXIT WHEN count > 0; -- same result as previous example END LOOP; BEGIN -- some computations IF stocks > 100000 THEN EXIT; -- invalid; cannot use EXIT outside of LOOP END IF; END; <literal>WHILE</> <<label>> WHILE expression LOOP statements END LOOP; The WHILE statement repeats a sequence of statements so long as the condition expression evaluates to true. The condition is checked just before each entry to the loop body. For example: WHILE amount_owed > 0 AND gift_certificate_balance > 0 LOOP -- some computations here END LOOP; WHILE NOT boolean_expression LOOP -- some computations here END LOOP; <literal>FOR</> (integer variant) <<label>> FOR name IN REVERSE expression .. expression LOOP statements END LOOP; This form of FOR creates a loop that iterates over a range of integer values. The variable name is automatically defined as type integer and exists only inside the loop. The two expressions giving the lower and upper bound of the range are evaluated once when entering the loop. The iteration step is normally 1, but is -1 when REVERSE is specified. Some examples of integer FOR loops: FOR i IN 1..10 LOOP -- some computations here RAISE NOTICE ''i is %'', i; END LOOP; FOR i IN REVERSE 10..1 LOOP -- some computations here END LOOP; If the lower bound is greater than the upper bound (or less than, in the REVERSE case), the loop body is not executed at all. No error is raised. Looping Through Query Results Using a different type of FOR loop, you can iterate through the results of a query and manipulate that data accordingly. The syntax is: <<label>> FOR record_or_row IN query LOOP statements END LOOP; The record or row variable is successively assigned each row resulting from the query (a SELECT command) and the loop body is executed for each row. Here is an example: CREATE FUNCTION cs_refresh_mviews() RETURNS integer AS ' DECLARE mviews RECORD; BEGIN 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; END LOOP; PERFORM cs_log(''Done refreshing materialized views.''); RETURN 1; END; ' LANGUAGE plpgsql; If the loop is terminated by an EXIT statement, the last assigned row value is still accessible after the loop. The FOR-IN-EXECUTE statement is another way to iterate over records: <<label>> FOR record_or_row IN EXECUTE text_expression LOOP statements END LOOP; This is like the previous form, except that the source SELECT statement is specified as a string expression, which is evaluated and replanned on each entry to the FOR loop. This allows the programmer to choose the speed of a preplanned query or the flexibility of a dynamic query, just as with a plain EXECUTE statement. The PL/pgSQL parser presently distinguishes the two kinds of FOR loops (integer or query result) by checking whether the target variable mentioned just after FOR has been declared as a record or row variable. If not, it's presumed to be an integer FOR loop. This can cause rather nonintuitive error messages when the true problem is, say, that one has misspelled the variable name after the FOR. Typically the complaint will be something like missing ".." at end of SQL expression. Cursors cursor in PL/pgSQL Rather than executing a whole query at once, it is possible to set up a cursor that encapsulates the query, and then read the query result a few rows at a time. One reason for doing this is to avoid memory overrun when the result contains a large number of rows. (However, PL/pgSQL users do not normally need to worry about that, since FOR loops automatically use a cursor internally to avoid memory problems.) A more interesting usage is to return a reference to a cursor that a function has created, allowing the caller to read the rows. This provides an efficient way to return large row sets from functions. Declaring Cursor Variables All access to cursors in PL/pgSQL goes through cursor variables, which are always of the special data type refcursor. One way to create a cursor variable is just to declare it as a variable of type refcursor. Another way is to use the cursor declaration syntax, which in general is: name CURSOR ( arguments ) FOR query ; (FOR may be replaced by IS for Oracle compatibility.) arguments, if specified, is a comma-separated list of pairs name datatype that define names to be replaced by parameter values in the given query. The actual values to substitute for these names will be specified later, when the cursor is opened. Some examples: DECLARE curs1 refcursor; curs2 CURSOR FOR SELECT * FROM tenk1; curs3 CURSOR (key integer) IS SELECT * FROM tenk1 WHERE unique1 = key; All three of these variables have the data type refcursor, but the first may be used with any query, while the second has a fully specified query already bound to it, and the last has a parameterized query bound to it. (key will be replaced by an integer parameter value when the cursor is opened.) The variable curs1 is said to be unbound since it is not bound to any particular query. Opening Cursors Before a cursor can be used to retrieve rows, it must be opened. (This is the equivalent action to the SQL command DECLARE CURSOR.) PL/pgSQL has three forms of the OPEN statement, two of which use unbound cursor variables while the third uses a bound cursor variable. <command>OPEN FOR SELECT</command> OPEN unbound-cursor FOR SELECT ...; The cursor variable is opened and given the specified query to execute. The cursor cannot be open already, and it must have been declared as an unbound cursor (that is, as a simple refcursor variable). The SELECT query is treated in the same way as other SELECT statements in PL/pgSQL: PL/pgSQL variable names are substituted, and the query plan is cached for possible reuse. An example: OPEN curs1 FOR SELECT * FROM foo WHERE key = mykey; <command>OPEN FOR EXECUTE</command> OPEN unbound-cursor FOR EXECUTE query-string; The cursor variable is opened and given the specified query to execute. The cursor cannot be open already, and it must have been declared as an unbound cursor (that is, as a simple refcursor variable). The query is specified as a string expression in the same way as in the EXECUTE command. As usual, this gives flexibility so the query can vary from one run to the next. An example: OPEN curs1 FOR EXECUTE ''SELECT * FROM '' || quote_ident($1); Opening a Bound Cursor OPEN bound-cursor ( argument_values ) ; This form of OPEN is used to open a cursor variable whose query was bound to it when it was declared. The cursor cannot be open already. A list of actual argument value expressions must appear if and only if the cursor was declared to take arguments. These values will be substituted in the query. The query plan for a bound cursor is always considered cacheable; there is no equivalent of EXECUTE in this case. Examples: OPEN curs2; OPEN curs3(42); Using Cursors Once a cursor has been opened, it can be manipulated with the statements described here. These manipulations need not occur in the same function that opened the cursor to begin with. You can return a refcursor value out of a function and let the caller operate on the cursor. (Internally, a refcursor value is simply the string name of a so-called portal containing the active query for the cursor. This name can be passed around, assigned to other refcursor variables, and so on, without disturbing the portal.) All portals are implicitly closed at transaction end. Therefore a refcursor value is usable to reference an open cursor only until the end of the transaction. <literal>FETCH</> FETCH cursor INTO target; FETCH retrieves the next row from the cursor into a target, which may be a row variable, a record variable, or a comma-separated list of simple variables, just like SELECT INTO. As with SELECT INTO, the special variable FOUND may be checked to see whether a row was obtained or not. An example: FETCH curs1 INTO rowvar; FETCH curs2 INTO foo, bar, baz; <literal>CLOSE</> CLOSE cursor; CLOSE closes the portal underlying an open cursor. This can be used to release resources earlier than end of transaction, or to free up the cursor variable to be opened again. An example: CLOSE curs1; Returning Cursors PL/pgSQL functions can return cursors to the caller. This is useful to return multiple rows or columns, especially with very large result sets. To do this, the function opens the cursor and returns the cursor name to the caller (or simply opens the cursor using a portal name specified by or otherwise known to the caller). The caller can then fetch rows from the cursor. The cursor can be closed by the caller, or it will be closed automatically when the transaction closes. The portal name used for a cursor can be specified by the programmer or automatically generated. To specify a portal name, simply assign a string to the refcursor variable before opening it. The string value of the refcursor variable will be used by OPEN as the name of the underlying portal. However, if the refcursor variable is null, OPEN automatically generates a name that does not conflict with any existing portal, and assigns it to the refcursor variable. A bound cursor variable is initialized to the string value representing its name, so that the portal name is the same as the cursor variable name, unless the programmer overrides it by assignment before opening the cursor. But an unbound cursor variable defaults to the null value initially , so it will receive an automatically-generated unique name, unless overridden. The following example shows one way a cursor name can be supplied by the caller: CREATE TABLE test (col text); INSERT INTO test VALUES ('123'); CREATE FUNCTION reffunc(refcursor) RETURNS refcursor AS ' BEGIN OPEN $1 FOR SELECT col FROM test; RETURN $1; END; ' LANGUAGE plpgsql; BEGIN; SELECT reffunc('funccursor'); FETCH ALL IN funccursor; COMMIT; The following example uses automatic cursor name generation: CREATE FUNCTION reffunc2() RETURNS refcursor AS ' DECLARE ref refcursor; BEGIN OPEN ref FOR SELECT col FROM test; RETURN ref; END; ' LANGUAGE plpgsql; BEGIN; SELECT reffunc2(); reffunc2 -------------------- <unnamed cursor 1> (1 row) FETCH ALL IN "<unnamed cursor 1>"; COMMIT; Errors and Messages Use the RAISE statement to report messages and raise errors. RAISE level 'format' , variable , ...; Possible levels are DEBUG, LOG, INFO, NOTICE, WARNING, and EXCEPTION. EXCEPTION raises an error and aborts the current transaction; the other levels only generate messages of different priority levels. Whether messages of a particular priority are reported to the client, written to the server log, or both is controlled by the log_min_messages and client_min_messages configuration variables. See for more information. Inside the format string, % is replaced by the next optional argument's string representation. Write %% to emit a literal %. Note that the optional arguments must presently be simple variables, not expressions, and the format must be a simple string literal. In this example, the value of v_job_id will replace the % in the string: RAISE NOTICE ''Calling cs_create_job(%)'', v_job_id; This example will abort the transaction with the given error message: RAISE EXCEPTION ''Inexistent ID --> %'', user_id; PostgreSQL does not have a very smart exception handling model. Whenever the parser, planner/optimizer or executor decide that a statement cannot be processed any longer, the whole transaction gets aborted and the system jumps back into the main loop to get the next command from the client application. It is possible to hook into the error mechanism to notice that this happens. But currently it is impossible to tell what really caused the abort (data type format error, floating-point error, parse error, etc.). And it is possible that the database server is in an inconsistent state at this point so returning to the upper executor or issuing more commands might corrupt the whole database. Thus, the only thing PL/pgSQL currently does when it encounters an abort during execution of a function or trigger procedure is to add some fields to the message telling in which function and where (line number and type of statement) the error happened. The error always stops execution of the function. Trigger Procedures trigger in PL/pgSQL PL/pgSQL can be used to define trigger procedures. A trigger procedure is created with the CREATE FUNCTION command, declaring it as a function with no arguments and a return type of trigger. Note that the function must be declared with no arguments even if it expects to receive arguments specified in CREATE TRIGGER --- trigger arguments are passed via TG_ARGV, as described below. When a PL/pgSQL function is called as a trigger, several special variables are created automatically in the top-level block. They are: NEW Data type RECORD; variable holding the new database row for INSERT/UPDATE operations in row-level triggers. This variable is NULL in statement-level triggers. OLD Data type RECORD; variable holding the old database row for UPDATE/DELETE operations in row-level triggers. This variable is NULL in statement-level triggers. TG_NAME Data type name; variable that contains the name of the trigger actually fired. TG_WHEN Data type text; a string of either BEFORE or AFTER depending on the trigger's definition. TG_LEVEL Data type text; a string of either ROW or STATEMENT depending on the trigger's definition. TG_OP Data type text; a string of INSERT, UPDATE, or DELETE telling for which operation the trigger was fired. TG_RELID Data type oid; the object ID of the table that caused the trigger invocation. TG_RELNAME Data type name; the name of the table that caused the trigger invocation. TG_NARGS Data type integer; the number of arguments given to the trigger procedure in the CREATE TRIGGER statement. TG_ARGV[] Data type array of text; the arguments from the CREATE TRIGGER statement. The index counts from 0. Invalid indices (less than 0 or greater than or equal to tg_nargs) result in a null value. A trigger function must return either NULL or a record/row value having exactly the structure of the table the trigger was fired for. Row-level triggers fired BEFORE may return null to signal the trigger manager to skip the rest of the operation for this row (i.e., subsequent triggers are not fired, and the INSERT/UPDATE/DELETE does not occur for this row). If a nonnull value is returned then the operation proceeds with that row value. Returning a row value different from the original value of NEW alters the row that will be inserted or updated (but has no direct effect in the DELETE case). To alter the row to be stored, it is possible to replace single values directly in NEW and return the modified NEW, or to build a complete new record/row to return. The return value of a BEFORE or AFTER statement-level trigger or an AFTER row-level trigger is always ignored; it may as well be null. However, any of these types of triggers can still abort the entire operation by raising an error. shows an example of a trigger procedure in PL/pgSQL. A <application>PL/pgSQL</application> Trigger Procedure This example trigger ensures that any time a row is inserted or updated in the table, the current user name and time are stamped into the row. And it checks that an employee's name is given and that the salary is a positive value. CREATE TABLE emp ( empname text, salary integer, last_date timestamp, last_user text ); CREATE FUNCTION emp_stamp() RETURNS trigger AS ' BEGIN -- Check that empname and salary are given IF NEW.empname IS NULL THEN RAISE EXCEPTION ''empname cannot be null''; END IF; IF NEW.salary IS NULL THEN RAISE EXCEPTION ''% cannot have null salary'', NEW.empname; END IF; -- Who works for us when she must pay for it? IF NEW.salary < 0 THEN RAISE EXCEPTION ''% cannot have a negative salary'', NEW.empname; END IF; -- Remember who changed the payroll when NEW.last_date := ''now''; NEW.last_user := current_user; RETURN NEW; END; ' LANGUAGE plpgsql; CREATE TRIGGER emp_stamp BEFORE INSERT OR UPDATE ON emp FOR EACH ROW EXECUTE PROCEDURE emp_stamp(); Porting from <productname>Oracle</productname> PL/SQL Oracle porting from PL/SQL to PL/pgSQL PL/SQL (Oracle) porting to PL/pgSQL 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 .) In PostgreSQL you need to escape single quotes in the function body. See . Instead of packages, use schemas to organize your functions into groups. Porting Examples shows how to port a simple function from PL/SQL to PL/pgSQL. Porting a Simple Function from <application>PL/SQL</> to <application>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; shows how to port a function that creates another function and how to handle to ensuing quoting problems. Porting a Function that Creates Another Function from <application>PL/SQL</> to <application>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; 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.instr In there is a PL/pgSQL implementation of instr that you can use to make your porting easier. Porting a Procedure With String Manipulation and <literal>OUT</> Parameters from <application>PL/SQL</> to <application>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; shows how to port a procedure that uses numerous features that are specific to Oracle. Porting a Procedure from <application>PL/SQL</> to <application>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; 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 COMMIT; -- free lock 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 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: There is no PRAGMA statement in PostgreSQL. If you do a LOCK TABLE in PL/pgSQL, the lock will not be released until the calling transaction is finished. You also cannot have transactions in PL/pgSQL functions. The entire function (and other functions called from therein) is executed in one transaction and PostgreSQL rolls back the transaction if something goes wrong. The exception when would have to be replaced by an IF statement. 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.''; END IF; RETURN 0; END; ' LANGUAGE plpgsql; Notice how you can raise notices (or errors) in PL/pgSQL. Other Things to Watch For This section explains a few other things to watch for when porting Oracle PL/SQL functions to PostgreSQL. <command>EXECUTE</command> 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 . Constructs of the type EXECUTE ''SELECT * FROM $1''; will not work unless you use these functions. Optimizing <application>PL/pgSQL</application> 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; Appendix 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;