From 307e449e5fb704836290f817a458895d856414a7 Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Thu, 15 Nov 2001 06:25:22 +0000 Subject: [PATCH] Significant editorial overhaul of plpgsql documentation. --- doc/src/sgml/plsql.sgml | 945 +++++++++++++++++++++------------------- 1 file changed, 505 insertions(+), 440 deletions(-) diff --git a/doc/src/sgml/plsql.sgml b/doc/src/sgml/plsql.sgml index 58bb9ecd80..b60b652e82 100644 --- a/doc/src/sgml/plsql.sgml +++ b/doc/src/sgml/plsql.sgml @@ -1,5 +1,5 @@ @@ -62,27 +62,32 @@ $Header: /cvsroot/pgsql/doc/src/sgml/Attic/plsql.sgml,v 2.46 2001/11/08 23:41:12 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. The produced bytecode is identified - in the call handler by the object ID of the function. This ensures - that changing a function by a DROP/CREATE sequence will take effect - without establishing a new database connection. + function is called. The instruction tree fully translates the + PL/pgSQL statement structure, but individual + SQL expressions and SQL queries + used in the function are not translated immediately. - For all expressions and SQL statements used in - the function, the PL/pgSQL bytecode interpreter creates a - prepared execution plan using the SPI manager's - SPI_prepare() and - SPI_saveplan() functions. This is done the - first time the individual - statement is processed in the PL/pgSQL function. Thus, a function with - conditional code that contains many statements for which execution - plans would be required, will only prepare and save those plans + As each expression and SQL query 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). Subsequent visits + to that expression or query re-use 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. + connection. This can provide a considerable savings of parsing + activity. A disadvantage is that errors in a specific expression + or query may not be detected until that part of the function is + reached in execution. - This means that you have to be careful about your user-defined - functions. For example: + Once PL/pgSQL has made a query plan for a particular + query in a function, it will re-use 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 ' @@ -93,12 +98,14 @@ BEGIN END; ' LANGUAGE 'plpgsql'; - If you create the above function, it will reference the OID for - my_function() in its bytecode. Later, if you + If you execute the above function, it will reference the OID for + my_function() in the query plan produced for + the PERFORM statement. Later, if you drop and re-create my_function(), then populate() will not be able to find my_function() anymore. You would then have to - re-create populate(). + re-create populate(), or at least start a new + database session so that it will be compiled afresh. @@ -155,8 +162,8 @@ END; That means that your client application must send each query to the database server, wait for it to process it, receive the results, do some computation, then send - other queries to the server. All this incurs inter - process communication and may also incur network + other queries to the server. All this incurs inter-process communication + and may also incur network overhead if your client is on a different machine than the database server. @@ -167,8 +174,8 @@ END; 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. Your application will enjoy a - considerable performance increase by using PL/pgSQL. + communication overhead. This can make for a + considerable performance increase. @@ -222,14 +229,12 @@ END; One good way to develop in PL/pgSQL is to simply use the text editor of your choice to create your functions, and in another console, use psql (PostgreSQL's interactive monitor) to load - those functions. If you are doing it this way (and if you are - a PL/pgSQL novice or in debugging stage), it is a good idea to - always DROP your function before creating it. That way - when you reload the file, it'll drop your functions and then - re-create them. For example: + 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 reload the file to update + the function definition. For example: -DROP FUNCTION testfunc(integer); -CREATE FUNCTION testfunc(INTEGER) RETURNS INTEGER AS ' +CREATE OR REPLACE FUNCTION testfunc(INTEGER) RETURNS INTEGER AS ' .... end; ' LANGUAGE 'plpgsql'; @@ -237,13 +242,12 @@ end; - When you load the file for the first time, - PostgreSQL will raise a warning saying this - function doesn't exist and go on to create it. To load an SQL - file (e.g., filename.sql) into a database named dbname, use the command: + While running psql, you can load or reload such a + function definition file with -psql -f filename.sql dbname + \i filename.sql + and then immediately issue SQL commands to test the function. @@ -255,25 +259,18 @@ psql -f filename.sql dbname - - - - Description - - - - - Structure of <application>PL/pgSQL</application> + + Structure of <application>PL/pgSQL</application> - PL/pgSQL is a block structured language. All - keywords and identifiers can be used in mixed upper and - lower-case. A block is defined as: + 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 + <<label>> + DECLARE + declarations BEGIN statements END; @@ -281,9 +278,10 @@ END; - There can be any number of sub-blocks in the statement section - of a block. Sub-blocks can be used to hide variables from outside a - block of statements. + Any statement in the statement section of a block + can be a sub-block. Sub-blocks can be used for + logical grouping or to localize variables to a small group + of statements. @@ -323,10 +321,14 @@ END; --- they cannot start or commit transactions, since Postgres does not have nested transactions. - - Comments + Lexical Details + + + All keywords and identifiers can be used in mixed upper and + lower-case. + There are two types of comments in PL/pgSQL. A double dash -- @@ -337,23 +339,23 @@ END; the block comment delimiters /* and */. + - - - Variables and Constants + + Declarations - All variables, rows and records used in a block or its - sub-blocks must be declared in the declarations section of a block. - The exception being the loop variable of a FOR loop iterating over a range - of integer values. + All variables, rows and records 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. All variables have as default value the - SQL NULL value. + CHAR. @@ -365,44 +367,48 @@ url VARCHAR; - - Constants and Variables With Default Values - - - The declarations have the following syntax: + + The general syntax of a variable declaration is: -name CONSTANT type NOT NULL { DEFAULT | := } value ; +name CONSTANT type NOT NULL { DEFAULT | := } expression ; - The value of variables declared as CONSTANT cannot be changed. If NOT NULL - is specified, an assignment of a NULL value results in a runtime - error. Since the default value of all variables is the - SQL NULL value, all variables declared as NOT NULL - must also have a default value specified. + 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 default value is evaluated every time the function is called. So - assigning 'now' to a variable of type + 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 runtime + error. All variables declared as NOT NULL + must have a non-NULL default value specified. + + + + The default value is evaluated every time the function is called. So, + for example, assigning 'now' to a variable of type timestamp causes the variable to have the - time of the actual function call, not when the function was - precompiled into its bytecode. + time of the current function call, not when the function was + precompiled. Examples: -quantity INTEGER := 32; +quantity INTEGER DEFAULT 32; url varchar := ''http://mysite.com''; user_id CONSTANT INTEGER := 10; - - - Parameters Passed to Functions + + Aliases for Parameters Passed to Functions Parameters passed to functions are named with the identifiers @@ -429,9 +435,64 @@ END; ' LANGUAGE 'plpgsql'; - + - + + Rowtypes + + + +name table-datatype; + + + + + A variable declared with a composite type (referenced by the name of + the table that defines that type) is called a row + 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 + rowtype of the variable. The individual fields of the row value are + accessed using the usual dot notation, for example + rowvar.field. + + + + 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 attributes of a table row are accessible in a + rowtype variable, not OID or other system attributes (because the + row could be from a view). The fields of the rowtype inherit the + table's field size or precision for data types such as + char(n). + + + + + Records + + + +name RECORD; + + + + + Record variables are similar to rowtype 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 runtime error. + + + + Attributes @@ -465,8 +526,8 @@ user_id users.user_id%TYPE; the data type of the structure you are referencing, and most important, if the data type of the referenced item changes in the future (e.g: you - change your table definition of user_id to become a - REAL), you won't need to change your function + change your table definition of user_id from INTEGER to + REAL), you may not need to change your function definition. @@ -481,20 +542,11 @@ user_id users.user_id%TYPE; %ROWTYPE provides the composite data type corresponding to a whole row of the specified table. table must be an existing - table or view name of the database. The fields of the row are - accessed in the dot notation. Parameters to a function can be - composite types (complete table rows). In that case, the - corresponding identifier $n will be a rowtype, and fields can - be selected from it, for example $1.user_id. + table or view name of the database. A row variable declared + in this way acts the same as a row variable explicitly declared using + the same composite (row) datatype. - - Only the user-defined attributes of a table row are accessible in a - rowtype variable, not OID or other system attributes (because the - row could be from a view). The fields of the rowtype inherit the - table's field sizes or precision for char() - etc. data types. - DECLARE users_rec users%ROWTYPE; @@ -529,17 +581,17 @@ end; - + - + RENAME - Using RENAME you can change the name of a variable, record - or row. This is useful if NEW or OLD should be referenced - by another name inside a trigger procedure. + Using the RENAME declaration you can change the name of a variable, + record or row. This is useful if NEW or OLD should be referenced + by another name inside a trigger procedure. See also ALIAS. @@ -551,17 +603,16 @@ RENAME id TO user_id; RENAME this_var TO that_var; - - + + - - - - Expressions + + Expressions - All expressions used in PL/pgSQL statements are processed using - the executor of the server. Expressions that appear to contain + 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 @@ -571,17 +622,18 @@ RENAME this_var TO that_var; SELECT expression - using the SPI manager. In the expression, occurrences of variable - identifiers are substituted by parameters and the actual values from - the variables are passed to the executor in the parameter array. All - expressions used in a PL/pgSQL function are only prepared and - saved once. The only exception to this rule is an EXECUTE statement. + using the SPI manager. In the expression, 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 re-used for subsequent evaluations. - The type checking done by the Postgres + The evaluation done by the Postgres main parser has some side - effects to the interpretation of constant values. In detail there + effects on the interpretation of constant values. In detail there is a difference between what these two functions do: @@ -626,87 +678,191 @@ CREATE FUNCTION logfunc2 (TEXT) RETURNS TIMESTAMP AS ' In the case of logfunc2(), the Postgres main parser does not know what type 'now' should become and therefore - it returns a data type of text containing the string - 'now'. During the assignment - to the local variable curtime, the PL/pgSQL interpreter casts this + 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. + functions for the conversion. So, the computed timestamp is updated + on each execution as the programmer expects. - This type checking done by the Postgres main - parser got implemented after PL/pgSQL was nearly done. - It is a difference between 6.3 and 6.4 and affects all functions - using the prepared plan feature of the SPI manager. - Using a local - variable in the above manner is currently the only way in PL/pgSQL to get - those values interpreted correctly. - - - - If record fields are used in expressions or statements, the data types of - fields should not change between calls of one and the same expression. + 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 datatype 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. + for more than one table. (EXECUTE can be used to get around this + problem when necessary.) - + - - - - Statements + + Statements - Anything not understood by the PL/pgSQL parser as specified below - will be put into a query and sent down to the database engine - to execute. The resulting query should not return any data. + This section describes 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 + query, and is sent to the main database engine to execute (after + substitution for any PL/pgSQL variables + used in the statement). Thus, + for example, SQL INSERT, UPDATE, and + DELETE commands may be considered to be statements of + PL/pgSQL. - + Assignment + An assignment of a value to a variable or row/record field is written as: identifier := expression; - - If the expressions result data type doesn't match the variables - data type, or the variable has a size/precision that is known - (as for char(20)), the result value will be implicitly cast by - the PL/pgSQL bytecode interpreter using the result types output- and - the variables type input-functions. Note that this could potentially - result in runtime errors generated by the types input functions. + 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 + (as for 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 runtime 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; - + + - - Calling another function + + Query Assignments - All functions defined in a Postgres - database return a value. Thus, the normal way to call a function - is to execute a SELECT query or doing an assignment (resulting - in a PL/pgSQL internal SELECT). + The result of a SELECT command yielding multiple columns (but + only one row) can be assigned to a record variable, rowtype + variable, or list of scalar variables. This is done by: + + +SELECT INTO target expressions FROM ...; + + + where target can be a record variable, a row + variable, or a comma-separated list of simple variables and + record/row fields. Note that this is quite different from + Postgres' normal interpretation of SELECT INTO, which is that 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 + equivalent syntax CREATE TABLE AS SELECT.) - But there are cases where someone is not interested in the - function's result. In these cases, use the PERFORM - statement. + If a row or a variable list is used as target, the selected values + must exactly match the structure of the target(s), or a runtime error + occurs. When a record variable is the target, it automatically + configures itself to the rowtype of the query result columns. + + + + Except for the INTO clause, the SELECT command is the same as a normal + SQL SELECT query and can use the full power of SELECT. + + + + If the SELECT query returns zero rows, NULLs are assigned to the + target(s). If the SELECT 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.) + + + + At present, the INTO clause can appear almost anywhere in the SELECT + query, but it is recommended to place it immediately after the SELECT + keyword as depicted above. Future versions of + PL/pgSQL may be less forgiving about + placement of the INTO clause. + + + + There is a special variable named FOUND of type + boolean that can be used immediately after a SELECT + INTO to check if an assignment had success (that is, at least one + row was returned by the SELECT). For example, + + +SELECT INTO myrec * FROM EMP WHERE empname = myname; +IF NOT FOUND THEN + RAISE EXCEPTION ''employee % not found'', myname; +END IF; + + + Alternatively, you can use the IS NULL (or ISNULL) conditional to + test for NULLity of a RECORD/ROW result. Note that there is no + way to tell whether any additional rows might have been discarded. + + + + +DECLARE + users_rec RECORD; + full_name varchar; +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 a SELECT query over the - SPI manager and discards the result. Identifiers like local - variables are still substituted into parameters. + + This executes a SELECT + query and discards the + result. PL/pgSQL variables are substituted + into the query as usual. + + + + 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'','' SELECT session_id, page_id, count(*) AS n_hits, @@ -714,31 +870,41 @@ PERFORM create_mv(''cs_session_page_requests_mv'','' FROM cs_fact_table GROUP BY session_id, page_id ''); - + + - + Executing dynamic queries - Often times you will want to generate dynamic queries inside - your PL/pgSQL functions. Or you have functions that will - generate other functions. PL/pgSQL provides the EXECUTE - statement for these occasions. - + Oftentimes you will want to generate dynamic queries inside + your PL/pgSQL functions, that is, + queries that will involve different tables or different datatypes + each time they are executed. PL/pgSQL's + normal attempts to cache plans for queries will not work in such + scenarios. To handle this sort of problem, the EXECUTE statement + is provided: - EXECUTE query-string - where query-string is a string of type - text containing the query - to be executed. + + where query-string is an expression + yielding a string (of type + text) containing the query + 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 query string. The values of variables must + be inserted into the query string as it is constructed. When working with dynamic queries you will have to face escaping of single quotes in PL/pgSQL. Please refer to the - table available at the + table in for a detailed explanation that will save you some effort. @@ -757,7 +923,7 @@ EXECUTE query-string The results from SELECT queries are discarded by EXECUTE, and SELECT INTO is not currently supported within EXECUTE. So, the only way to extract a result from a dynamically-created SELECT is - to use the FOR ... EXECUTE form described later. + to use the FOR-IN-EXECUTE form described later. @@ -781,7 +947,8 @@ EXECUTE ''UPDATE tbl SET '' string should be passed to quote_literal(). Both take the appropriate steps to return the input text enclosed in single - or double quotes and with any embedded special characters. + or double quotes and with any embedded special characters + properly escaped. @@ -797,7 +964,8 @@ BEGIN DECLARE v_host ALIAS FOR $1; v_domain ALIAS FOR $2; - v_url ALIAS FOR $3; ''; + v_url ALIAS FOR $3; + BEGIN ''; -- -- Notice how we scan through the results of a query in a FOR loop @@ -820,10 +988,10 @@ END; ' LANGUAGE 'plpgsql'; - + - - Obtaining other results status + + Obtaining result status @@ -841,7 +1009,20 @@ GET DIAGNOSTICS variable = itemSQL query. Note that RESULT_OID is only useful after an INSERT query. - + + + + + + + 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 @@ -852,40 +1033,27 @@ RETURN expression The function terminates and the value of expression will be returned to the - upper executor. The return value of a function cannot be - undefined. If control reaches the end of the top-level block of - the function without hitting a RETURN statement, a runtime error - will occur. + upper executor. + The expression's result will be automatically casted into the + function's return type as described for assignments. - The expressions result will be automatically casted into the - function's return type as described for assignments. + 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 runtime error + will occur. - - - - - - - Control Structures - - Control structures are probably the most useful (and - important) part of PL/SQL. With PL/pgSQL's control structures, - you can manipulate PostgreSQL data in a very - flexible and powerful way. - - + Conditional Control: IF statements 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. NOTE: All PL/PgSQL IF statements need - a corresponding END IF clause. With ELSE-IF statements, - you need two: one for the first IF and one for the second (ELSE IF). + certain conditions. + PL/pgSQL has four forms of IF: IF-THEN, IF-THEN-ELSE, + IF-THEN-ELSE IF, IF-THEN-ELSIF-THEN-ELSE. @@ -896,10 +1064,10 @@ RETURN expression - IF-THEN statements is the simplest form of an IF. The + 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, the statements - following END IF will be executed. + the condition is true. Otherwise, they are skipped. + IF v_user_id <> 0 THEN UPDATE users SET email = v_email WHERE user_id = v_user_id; @@ -916,9 +1084,10 @@ END IF; - IF-THEN-ELSE statements adds to IF-THEN by letting you - specify the statements that should be executed if the + IF-THEN-ELSE statements add to IF-THEN by letting you + specify a group of statements that should be executed if the condition evaluates to FALSE. + IF parentid IS NULL or parentid = '''' THEN @@ -934,20 +1103,6 @@ IF v_count > 0 THEN ELSE return ''f''; END IF; - - - - - IF statements can be nested and 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; @@ -960,22 +1115,25 @@ END IF; - When you use the ELSE IF statement, you are actually - nesting an IF statement inside the ELSE - statement. Thus you need one END IF statement for each - nested IF and one for the parent IF-ELSE. + 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; + - For 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. @@ -987,10 +1145,10 @@ END IF; - IF-THEN-ELSIF-ELSE allows you test multiple conditions - in one statement. Internally it is handled as nested - IF-THEN-ELSE-IF-THEN commands. The optional ELSE - branch is executed when none of the conditions are met. + 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. @@ -1009,6 +1167,10 @@ ELSE END IF; + + + The final ELSE section is optional. + @@ -1016,13 +1178,13 @@ END IF; - + Iterative Control: LOOP, WHILE, FOR and EXIT - With the LOOP, WHILE, FOR and EXIT statements, you can - control the flow of execution of your PL/pgSQL program - iteractively. + With the LOOP, WHILE, FOR and EXIT statements, you can arrange + for your PL/pgSQL function to repeat + a series of commands. @@ -1061,12 +1223,17 @@ EXIT label WHEN label is given, it - must be the label of the current or an upper level of nested loop + must be the label of the current or an outer level of nested loop blocks. Then the named loop or block is terminated and control - continues with the statement after the loops/blocks corresponding + 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. + + Examples: @@ -1100,9 +1267,10 @@ END; - With the WHILE statement, you can loop through a - sequence of statements as long as the evaluation of - the condition expression is true. + With the WHILE statement, you can repeat 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. <<label>> WHILE expression LOOP @@ -1130,6 +1298,7 @@ END LOOP; + <<label>> FOR name IN REVERSE expression .. expression LOOP @@ -1139,14 +1308,13 @@ END LOOP; A loop that iterates over a range of integer values. The variable name is automatically created as type integer and exists only inside the loop. The two expressions giving - the lower and upper bound of the range are evaluated only when entering - the loop. The iteration step is always 1. + 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 FOR loops (see for iterating over - records in FOR loops): + Some examples of integer FOR loops: FOR i IN 1..10 LOOP -- some expressions here @@ -1162,129 +1330,24 @@ END LOOP; - - - - - - - Working with RECORDs - - - Records are similar to rowtypes, but they have no predefined structure. - They are used in selections and FOR loops to hold one actual - database row from a SELECT operation. - - - - Declaration - - - One variables of type RECORD can be used for different - selections. Accessing a record or an attempt to assign - a value to a record field when there is no actual row in it results - in a runtime error. They can be declared like this: - - - - -name RECORD; - - - - Assignments - - - An assignment of a complete selection into a record or row can - be done by: - -SELECT INTO target expressions FROM ...; - - target can be a record, a row variable - or a comma separated list of variables and - record-/row-fields. Note that this is quite different from - Postgres' normal interpretation of SELECT INTO, which is that 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 - equivalent 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(s) or a runtime error - occurs. The FROM keyword can be followed by any valid qualification, - grouping, sorting etc. that can be given for a SELECT statement. - - - - Once a record or row has been assigned to a RECORD variable, - you can use the . (dot) notation to access fields in that - record: - -DECLARE - users_rec RECORD; - full_name varchar; -BEGIN - SELECT INTO users_rec * FROM users WHERE user_id=3; - - full_name := users_rec.first_name || '' '' || users_rec.last_name; - - - - - There is a special variable named FOUND of type - boolean that can be used immediately after a SELECT - INTO to check if an assignment had success. - - -SELECT INTO myrec * FROM EMP WHERE empname = myname; -IF NOT FOUND THEN - RAISE EXCEPTION ''employee % not found'', myname; -END IF; - - - You can also use the IS NULL (or ISNULL) conditionals to - test for NULLity of a RECORD/ROW. If the selection returns - multiple rows, only the first is moved into the target - fields. All others are silently discarded. - - - - -DECLARE - users_rec RECORD; - full_name varchar; -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; - - - - - + Iterating Through Records - Using a special type of FOR loop, you can iterate through + Using a different type of FOR loop, you can iterate through the results of a query and manipulate that data - accordingly. The syntax is as follow: + accordingly. The syntax is as follows: <<label>> -FOR record | row IN select_clause LOOP +FOR record | row IN select_query LOOP statements END LOOP; - The record or row is assigned all the rows - resulting from the SELECT clause and the loop body executed - for each. Here is an example: + The record or row variable is successively assigned all the rows + resulting from the SELECT query and the loop body is executed + for each row. Here is an example: @@ -1292,11 +1355,6 @@ END LOOP; CREATE FUNCTION cs_refresh_mviews () RETURNS INTEGER AS ' DECLARE mviews RECORD; - - -- Instead, if you did: - -- mviews cs_materialized_views%ROWTYPE; - -- this record would ONLY be usable for the cs_materialized_views table - BEGIN PERFORM cs_log(''Refreshing materialized views...''); @@ -1315,12 +1373,12 @@ end; ' LANGUAGE 'plpgsql'; - If the loop is terminated with an EXIT statement, the last - assigned row is still accessible after the loop. + 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 + The FOR-IN-EXECUTE statement is another way to iterate over records: <<label>> @@ -1335,15 +1393,27 @@ END LOOP; 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 record-returning) by checking + whether the target variable mentioned just after FOR has been + declared as a record/row variable. If not, it's presumed to be + an integer FOR loop. This can cause rather unintuitive error + messages when the true problem is, say, that one has + misspelled the FOR variable. + + + - - Aborting and Messages + + Errors and Messages - Use the RAISE statement to throw messages into the - Postgres elog mechanism. + Use the RAISE statement to report messages and raise errors. RAISE level 'format' , variable ...; @@ -1353,6 +1423,9 @@ RAISE level 'level ' + Exceptions Postgres does not have a very smart @@ -1410,39 +1481,37 @@ RAISE EXCEPTION ''Inexistent ID --> %'',user_id; an abort during execution of a function or trigger procedure is to write some additional NOTICE level log messages telling in which function and where (line number and type of - statement) this happened. + statement) this happened. The error always stops execution of + the function. - + - - - Trigger Procedures - PL/pgSQL can be used to define trigger procedures. They are created - with the usual CREATE FUNCTION command as a function with no - arguments and a return type of OPAQUE. + PL/pgSQL can be used to define trigger + procedures. A trigger procedure is created with the CREATE + FUNCTION command as a function with no arguments and a return + type of OPAQUE. 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. - There are some Postgres specific details - in functions used as trigger procedures. - - - - First they have some special variables created automatically in the - top-level blocks declaration section. They are + 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 on INSERT/UPDATE - operations on ROW level triggers. + Data type RECORD; variable holding the new database row for INSERT/UPDATE + operations in ROW level triggers. @@ -1451,8 +1520,8 @@ RAISE EXCEPTION ''Inexistent ID --> %'',user_id; OLD - Data type RECORD; variable holding the old database row on UPDATE/DELETE - operations on ROW level triggers. + Data type RECORD; variable holding the old database row for UPDATE/DELETE + operations in ROW level triggers. @@ -1473,7 +1542,7 @@ RAISE EXCEPTION ''Inexistent ID --> %'',user_id; Data type text; a string of either BEFORE or AFTER - depending on the triggers definition. + depending on the trigger's definition. @@ -1484,7 +1553,7 @@ RAISE EXCEPTION ''Inexistent ID --> %'',user_id; Data type text; a string of either ROW or STATEMENT depending on the - triggers definition. + trigger's definition. @@ -1496,7 +1565,7 @@ RAISE EXCEPTION ''Inexistent ID --> %'',user_id; Data type text; a string of INSERT, UPDATE or DELETE telling - for which operation the trigger is actually fired. + for which operation the trigger is fired. @@ -1546,24 +1615,32 @@ RAISE EXCEPTION ''Inexistent ID --> %'',user_id; - Second they must return either NULL or a record/row containing - exactly the structure of the table the trigger was fired for. - Triggers fired AFTER might always return a NULL value with no - effect. Triggers fired BEFORE signal the trigger manager - to skip the operation for this actual row when returning NULL. - Otherwise, the returned record/row replaces the inserted/updated - row in the operation. It is possible to replace single values directly - in NEW and return that or to build a complete new record/row to + A trigger function must return either NULL or a record/row value + having exactly the structure of the table the trigger was fired for. + Triggers fired BEFORE may return NULL to signal the trigger manager + to skip the rest of the operation for this row (ie, subsequent triggers + are not fired, and the INSERT/UPDATE/DELETE does not occur for this + row). If a non-NULL value is returned then the operation proceeds with + that row value. Note that returning a row value different from the + original value of NEW alters the row that will be inserted or updated. + It is possible to replace single values directly + in NEW and return that, or to build a complete new record/row to return. + + The return value of a trigger fired AFTER is ignored; it may as well + always return a NULL value. But an AFTER trigger can still abort the + operation by raising an error. + + A <application>PL/pgSQL</application> Trigger Procedure Example - This trigger ensures, that any time a row is inserted or updated + 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 ensures that an employees name is given and that the + row. And it ensures that an employee's name is given and that the salary is a positive value. @@ -1617,7 +1694,7 @@ CREATE TRIGGER emp_stamp BEFORE INSERT OR UPDATE ON emp One painful detail in writing functions in PL/pgSQL is the handling - of single quotes. The function's source text on CREATE FUNCTION must + of single quotes. The function's source text in CREATE FUNCTION must be a literal string. Single quotes inside of literal strings must be either doubled or quoted with a backslash. We are still looking for an elegant alternative. In the meantime, doubling the single quotes @@ -1941,14 +2018,6 @@ SHOW ERRORS; Let's go through this function and see the differences to PL/pgSQL: - - - The OR REPLACE clause is not allowed. You - will have to explicitly drop the function before creating it - to achieve similar results. - - - PostgreSQL does not have named @@ -1995,12 +2064,11 @@ SHOW ERRORS; - So let's see how this function would be look like ported to + So let's see how this function would look when ported to PostgreSQL: -DROP FUNCTION cs_fmt_browser_version(VARCHAR, VARCHAR); -CREATE FUNCTION cs_fmt_browser_version(VARCHAR, VARCHAR) +CREATE OR REPLACE FUNCTION cs_fmt_browser_version(VARCHAR, VARCHAR) RETURNS VARCHAR AS ' DECLARE v_name ALIAS FOR $1; @@ -2068,7 +2136,8 @@ BEGIN DECLARE v_host ALIAS FOR $1; v_domain ALIAS FOR $2; - v_url ALIAS FOR $3; ''; + v_url ALIAS FOR $3; + BEGIN ''; -- -- Notice how we scan through the results of a query in a FOR loop @@ -2152,8 +2221,7 @@ show errors; Here is how this procedure could be translated for PostgreSQL: -DROP FUNCTION cs_parse_url_host(VARCHAR); -CREATE FUNCTION cs_parse_url_host(VARCHAR) RETURNS VARCHAR AS ' +CREATE OR REPLACE FUNCTION cs_parse_url_host(VARCHAR) RETURNS VARCHAR AS ' DECLARE v_url ALIAS FOR $1; v_host VARCHAR; @@ -2282,8 +2350,8 @@ show errors So let's see one of the ways we could port this procedure to PL/pgSQL: -DROP FUNCTION cs_create_job(INTEGER); -CREATE FUNCTION cs_create_job(INTEGER) RETURNS INTEGER AS ' DECLARE +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; @@ -2479,7 +2547,6 @@ WITH (isstrict, iscachable); -- Licensed under the GPL v2 or later. -- -DROP FUNCTION instr(varchar,varchar); CREATE FUNCTION instr(VARCHAR,VARCHAR) RETURNS INTEGER AS ' DECLARE pos integer; @@ -2490,7 +2557,6 @@ END; ' LANGUAGE 'plpgsql'; -DROP FUNCTION instr(VARCHAR,VARCHAR,INTEGER); CREATE FUNCTION instr(VARCHAR,VARCHAR,INTEGER) RETURNS INTEGER AS ' DECLARE string ALIAS FOR $1; @@ -2536,7 +2602,6 @@ END; -- Written by Robert Gaszewski (graszew@poland.com) -- Licensed under the GPL v2 or later. -- -DROP FUNCTION instr(VARCHAR,VARCHAR,INTEGER,INTEGER); CREATE FUNCTION instr(VARCHAR,VARCHAR,INTEGER,INTEGER) RETURNS INTEGER AS ' DECLARE string ALIAS FOR $1;