- 7.7 Writing the Body Code
- 7.7.1 Assignment Statements
- 7.7.2 Management Statements in PSQL
- 7.7.3
DECLARE VARIABLE
- 7.7.4
DECLARE .. CURSOR
- 7.7.5
DECLARE FUNCTION
- 7.7.6
DECLARE PROCEDURE
- 7.7.7
BEGIN … END
- 7.7.8
IF … THEN … ELSE
- 7.7.9
WHILE … DO
- 7.7.10
BREAK
- 7.7.11
LEAVE
- 7.7.12
CONTINUE
- 7.7.13
EXIT
- 7.7.14
SUSPEND
- 7.7.15
EXECUTE STATEMENT
- 7.7.16
FOR SELECT
- 7.7.17
FOR EXECUTE STATEMENT
- 7.7.18
OPEN
- 7.7.19
FETCH
- 7.7.20
CLOSE
- 7.7.21
IN AUTONOMOUS TRANSACTION
- 7.7.22
POST_EVENT
- 7.7.23
RETURN
7.7 Writing the Body Code
This section takes a closer look at the procedural SQL language constructs and statements that are available for coding the body of a stored procedure, trigger or anonymous PSQL block.
Colon Marker (:
)
The colon marker prefix (:
) is used in PSQL to mark a reference to a variable in a DML statement. The colon marker is not required before variable names in other PSQL code.
Since Firebird 3.0, the colon prefix can also be used for the NEW
and OLD
contexts, and for cursor variables.
7.7.1 Assignment Statements
Used forAssigning a value to a variable
Available inPSQL
Syntax
varname = <value_expr>;
Table 7.7.1.1 Assignment Statement Parameters
Argument | Description |
---|---|
varname | Name of a parameter or local variable |
value_expr | An expression, constant or variable whose value resolves to the same data type as varname |
PSQL uses the equal symbol (=
) as its assignment operator. The assignment statement assigns an SQL expression value on the right to the variable on the left of the operator. The expression can be any valid SQL expression: it may contain literals, internal variable names, arithmetic, logical and string operations, calls to internal functions, stored functions or external functions (UDFs).
7.7.1.1 Example using assignment statements
CREATE PROCEDURE MYPROC (
a INTEGER,
b INTEGER,
name VARCHAR (30)
)
RETURNS (
c INTEGER,
str VARCHAR(100))
AS
BEGIN
-- assigning a constant
c = 0;
str = '';
SUSPEND;
-- assigning expression values
c = a + b;
str = name || CAST(b AS VARCHAR(10));
SUSPEND;
-- assigning expression value
-- built by a query
c = (SELECT 1 FROM rdb$database);
-- assigning a value from a context variable
str = CURRENT_USER;
SUSPEND;
END
See alsoSection 7.7.3, DECLARE VARIABLE
7.7.2 Management Statements in PSQL
Management statement are allowed in PSQL blocks (triggers, procedures, functions and EXECUTE BLOCK
), which is especially helpful for applications that need some management statements to be executed at the start of a session, specifically in ON CONNECT
triggers.
The management statements permitted in PSQL are:
7.7.2.1 Example of Management Statements in PSQL
create or alter trigger on_connect on connect
as
begin
set bind of decfloat to double precision;
set time zone 'America/Sao_Paulo';
end
Caution
Although useful as a workaround, using ON CONNECT
triggers to configure bind and time zone is usually not the right approach.
See alsoManagement Statements
7.7.3 DECLARE VARIABLE
Used forDeclaring a local variable
Available inPSQL
Syntax
DECLARE [VARIABLE] varname
<domain_or_non_array_type> [NOT NULL] [COLLATE collation]
[{DEFAULT | = } <initvalue>];
<domain_or_non_array_type> ::=
!! See Scalar Data Types Syntax !!
<initvalue> ::= <literal> | <context_var>
Table 7.7.3.1 DECLARE VARIABLE
Statement Parameters
Argument | Description |
---|---|
varname | Name of the local variable |
collation | Collation sequence |
initvalue | Initial value for this variable |
literal | Literal of a type compatible with the type of the local variable |
context_var | Any context variable whose type is compatible with the type of the local variable |
The statement DECLARE [VARIABLE]
is used for declaring a local variable. The keyword VARIABLE
can be omitted. One DECLARE [VARIABLE]
statement is required for each local variable. Any number of DECLARE [VARIABLE]
statements can be included and in any order. The name of a local variable must be unique among the names of local variables and input and output parameters declared for the module.
Note
A special case of DECLARE [VARIABLE]
— declaring cursors — is covered separately in Section 7.7.4, DECLARE .. CURSOR
7.7.3.1 Data Type for Variables
A local variable can be of any SQL type other than an array.
A domain name can be specified as the type; the variable will inherit all of its attributes.
If the
TYPE OF *domain*
clause is used instead, the variable will inherit only the domain’s data type, and, if applicable, its character set and collation attributes. Any default value or constraints such asNOT NULL
orCHECK
constraints are not inherited.If the
TYPE OF COLUMN *relation*.*column*>
option is used to borrow from a column in a table or view, the variable will inherit only the column’s data type, and, if applicable, its character set and collation attributes. Any other attributes are ignored.
7.7.3.2 NOT NULL
Constraint
For local variables, you can specify the NOT NULL
constraint, disallowing NULL
values for the variable. If a domain has been specified as the data type and the domain already has the NOT NULL
constraint, the declaration is unnecessary. For other forms, including use of a domain that is nullable, the NOT NULL
constraint can be included if needed.
7.7.3.3 CHARACTER SET
and COLLATE
clauses
Unless specified, the character set and collation sequence of a string variable will be the database defaults. A CHARACTER SET
clause can be included, if required, to handle string data that is going to be in a different character set. A valid collation sequence (COLLATE
clause) can also be included, with or without the character set clause.
7.7.3.4 Initializing a Variable
Local variables are NULL
when execution of the module begins. They can be initialized so that a starting or default value is available when they are first referenced. The DEFAULT <initvalue>
form can be used, or just the assignment operator, =
: = <initvalue>
. The value can be any type-compatible literal or context variable, including NULL
.
Tip
Be sure to use this clause for any variables that have a NOT NULL
constraint and do not otherwise have a default value available.
7.7.3.5 Examples of various ways to declare local variables
CREATE OR ALTER PROCEDURE SOME_PROC
AS
-- Declaring a variable of the INT type
DECLARE I INT;
-- Declaring a variable of the INT type that does not allow NULL
DECLARE VARIABLE J INT NOT NULL;
-- Declaring a variable of the INT type with the default value of 0
DECLARE VARIABLE K INT DEFAULT 0;
-- Declaring a variable of the INT type with the default value of 1
DECLARE VARIABLE L INT = 1;
-- Declaring a variable based on the COUNTRYNAME domain
DECLARE FARM_COUNTRY COUNTRYNAME;
-- Declaring a variable of the type equal to the COUNTRYNAME domain
DECLARE FROM_COUNTRY TYPE OF COUNTRYNAME;
-- Declaring a variable with the type of the CAPITAL column in the COUNTRY table
DECLARE CAPITAL TYPE OF COLUMN COUNTRY.CAPITAL;
BEGIN
/* PSQL statements */
END
See alsoData Types and Subtypes, Custom Data Types — Domains, CREATE DOMAIN
7.7.4 DECLARE .. CURSOR
Used forDeclaring a named cursor
Available inPSQL
Syntax
DECLARE [VARIABLE] cursor_name
[[NO] SCROLL] CURSOR
FOR (<select>);
Table 7.7.4.1 DECLARE … CURSOR
Statement Parameters
Argument | Description |
---|---|
cursor_name | Cursor name |
select |
|
The DECLARE … CURSOR … FOR
statement binds a named cursor to the result set obtained in the SELECT
statement specified in the FOR
clause. In the body code, the cursor can be opened, used to iterate row-by-row through the result set, and closed. While the cursor is open, the code can perform positioned updates and deletes using the WHERE CURRENT OF
in the UPDATE
or DELETE
statement.
Note
Syntactically, the DECLARE … CURSOR
statement is a special case of Section 7.7.3, DECLARE VARIABLE.
7.7.4.1 Forward-Only and Scrollable Cursors
The cursor can be forward-only (unidirectional) or scrollable. The optional clause SCROLL
makes the cursor scrollable, the NO SCROLL
clause, forward-only. By default, cursors are forward-only.
Forward-only cursors can — as the name implies — only move forward in the dataset. Forward-only cursors only support the FETCH [NEXT FROM]
statement, other commands raise an error. Scrollable cursors allow you to move not only forward in the dataset, but also back, asl well as N positions relative to the current position.
Warning
Scrollable cursors are materialized as a temporary dataset, as such, they consume additional memory or disk space, so use them only when you really need them.
7.7.4.2 Cursor Idiosyncrasies
The optional
FOR UPDATE
clause can be included in theSELECT
statement, but its absence does not prevent successful execution of a positioned update or deleteCare should be taken to ensure that the names of declared cursors do not conflict with any names used subsequently in statements for
AS CURSOR
clausesIf the cursor is needed only to walk the result set, it is nearly always easier and less error-prone to use a
FOR SELECT
statement with theAS CURSOR
clause. Declared cursors must be explicitly opened, used to fetch data, and closed. The context variableROW_COUNT
has to be checked after each fetch and, if its value is zero, the loop has to be terminated. AFOR SELECT
statement does this automatically.Nevertheless, declared cursors provide a high level of control over sequential events and allow several cursors to be managed in parallel.
The
SELECT
statement may contain parameters. For instance:SELECT NAME || :SFX FROM NAMES WHERE NUMBER = :NUM
Each parameter has to have been declared beforehand as a PSQL variable, even if they originate as input and output parameters. When the cursor is opened, the parameter is assigned the current value of the variable.
Unstable Variables and Cursors
If the value of the PSQL variable used in the SELECT
statement of the cursor changes during the execution of the loop, then its new value may — but not always — be used when selecting the next rows. It is better to avoid such situations. If you really need this behaviour, then you should thoroughly test your code and make sure you understand how changes to the variable affect the query results.
Note particularly that the behaviour may depend on the query plan, specifically on the indexes being used. Currently, there are no strict rules for this behaviour, and this may change in future versions of Firebird.
7.7.4.3 Examples Using Named Cursors
Declaring a named cursor in the trigger.
CREATE OR ALTER TRIGGER TBU_STOCK
BEFORE UPDATE ON STOCK
AS
DECLARE C_COUNTRY CURSOR FOR (
SELECT
COUNTRY,
CAPITAL
FROM COUNTRY
);
BEGIN
/* PSQL statements */
END
Declaring a scrollable cursor
EXECUTE BLOCK
RETURNS (
N INT,
RNAME CHAR(63))
AS
- Declaring a scrollable cursor
DECLARE C SCROLL CURSOR FOR (
SELECT
ROW_NUMBER() OVER (ORDER BY RDB$RELATION_NAME) AS N,
RDB$RELATION_NAME
FROM RDB$RELATIONS
ORDER BY RDB$RELATION_NAME);
BEGIN
/ * PSQL statements * /
END
A collection of scripts for creating views with a PSQL block using named cursors.
EXECUTE BLOCK
RETURNS (
SCRIPT BLOB SUB_TYPE TEXT)
AS
DECLARE VARIABLE FIELDS VARCHAR(8191);
DECLARE VARIABLE FIELD_NAME TYPE OF RDB$FIELD_NAME;
DECLARE VARIABLE RELATION RDB$RELATION_NAME;
DECLARE VARIABLE SOURCE TYPE OF COLUMN RDB$RELATIONS.RDB$VIEW_SOURCE;
DECLARE VARIABLE CUR_R CURSOR FOR (
SELECT
RDB$RELATION_NAME,
RDB$VIEW_SOURCE
FROM
RDB$RELATIONS
WHERE
RDB$VIEW_SOURCE IS NOT NULL);
-- Declaring a named cursor where
-- a local variable is used
DECLARE CUR_F CURSOR FOR (
SELECT
RDB$FIELD_NAME
FROM
RDB$RELATION_FIELDS
WHERE
-- It is important that the variable must be declared earlier
RDB$RELATION_NAME = :RELATION);
BEGIN
OPEN CUR_R;
WHILE (1 = 1) DO
BEGIN
FETCH CUR_R
INTO :RELATION, :SOURCE;
IF (ROW_COUNT = 0) THEN
LEAVE;
FIELDS = NULL;
-- The CUR_F cursor will use the value
-- of the RELATION variable initiated above
OPEN CUR_F;
WHILE (1 = 1) DO
BEGIN
FETCH CUR_F
INTO :FIELD_NAME;
IF (ROW_COUNT = 0) THEN
LEAVE;
IF (FIELDS IS NULL) THEN
FIELDS = TRIM(FIELD_NAME);
ELSE
FIELDS = FIELDS || ', ' || TRIM(FIELD_NAME);
END
CLOSE CUR_F;
SCRIPT = 'CREATE VIEW ' || RELATION;
IF (FIELDS IS NOT NULL) THEN
SCRIPT = SCRIPT || ' (' || FIELDS || ')';
SCRIPT = SCRIPT || ' AS ' || ASCII_CHAR(13);
SCRIPT = SCRIPT || SOURCE;
SUSPEND;
END
CLOSE CUR_R;
END
See alsoSection 7.7.18, OPEN, Section 7.7.19, FETCH, Section 7.7.20, CLOSE
7.7.5 DECLARE FUNCTION
Used forDeclaring a sub-function
Available inPSQL
Syntax
<declare-subfunc> ::= <subfunc-forward> | <subfunc-def>
<subfunc-forward> ::= <subfunc-header>;
<subfunc-def> ::= <subfunc-header> <psql-module-body>
<subfunc-header> ::=
DECLARE FUNCTION subfuncname [ ( [ <in_params> ] ) ]
RETURNS <domain_or_non_array_type> [COLLATE collation]
[DETERMINISTIC]
<in_params> ::=
!! See CREATE FUNCTION Syntax !!
<domain_or_non_array_type> ::=
!! See Scalar Data Types Syntax !!
<psql-module-body> ::=
!! See Syntax of Module Body !!
Table 7.7.5.1 DECLARE FUNCTION
Statement Parameters
Argument | Description |
---|---|
subfuncname | Sub-function name |
collation | Collation name |
The DECLARE FUNCTION
statement declares a sub-function. A sub-function is only visible to the PSQL module that defined the sub-function.
Sub-functions have a number of restrictions:
A sub-function cannot be nested in another subroutine. Subroutines are only supported in top-level PSQL modules (stored procedures, stored functions, triggers and anonymous PSQL blocks). This restriction is not enforced by the syntax, but attempts to create nested sub-functions will raise an error feature is not supported with detail message nested sub function.
Currently, the sub-function has no direct access to use variables and cursors from its parent module. However, it can access other routines from its parent modules, including recursive calls to itself. In some cases a forward declaration of the routine may be necessary.
A sub-function can be forward declared to resolve mutual dependencies between subroutine, and must be followed by its actual definition. When a sub-function is forward declared and has parameters with default values, the default values should only be specified in the forward declaration, and should not be repeated in subfunc_def.
Note
Declaring a sub-function with the same name as a stored function will hide that stored function from your module. It will not be possible to call that stored function.
Note
Contrary to DECLARE [VARIABLE]
, a DECLARE FUNCTION
is not terminated by a semicolon. The END
of its main BEGIN … END
block is considered its terminator.
7.7.5.1 Examples of Sub-Functions
Subfunction within a stored function
CREATE OR ALTER FUNCTION FUNC1 (n1 INTEGER, n2 INTEGER)
RETURNS INTEGER
AS
- Subfunction
DECLARE FUNCTION SUBFUNC (n1 INTEGER, n2 INTEGER)
RETURNS INTEGER
AS
BEGIN
RETURN n1 + n2;
END
BEGIN
RETURN SUBFUNC (n1, n2);
END
Recursive function call
execute block returns (i integer, o integer)
as
-- Recursive function without forward declaration.
declare function fibonacci(n integer) returns integer
as
begin
if (n = 0 or n = 1) then
return n;
else
return fibonacci(n - 1) + fibonacci(n - 2);
end
begin
i = 0;
while (i < 10)
do
begin
o = fibonacci(i);
suspend;
i = i + 1;
end
end
See alsoSection 7.7.6, DECLARE PROCEDURE, CREATE FUNCTION
7.7.6 DECLARE PROCEDURE
Used forDeclaring a sub-procedure
Available inPSQL
Syntax
<declare-subproc> ::= <subproc-forward> | <subproc-def>
<subproc-forward> ::= <subproc-header>;
<subproc-def> ::= <subproc-header> <psql-module-body>
<subproc-header> ::=
DECLARE subprocname [ ( [ <in_params> ] ) ]
[RETURNS (<out_params>)]
<in_params> ::=
!! See CREATE PROCEDURE Syntax !!
<domain_or_non_array_type> ::=
!! See Scalar Data Types Syntax !!
<psql-module-body> ::=
!! See Syntax of Module Body !!
Table 7.7.6.1 DECLARE PROCEDURE
Statement Parameters
Argument | Description |
---|---|
subprocname | Sub-procedure name |
collation | Collation name |
The DECLARE PROCEDURE
statement declares a sub-procedure. A sub-procedure is only visible to the PSQL module that defined the sub-procedure.
Sub-procedures have a number of restrictions:
A sub-procedure cannot be nested in another subroutine. Subroutines are only supported in top-level PSQL modules (stored procedures, stored functions, triggers and anonymous PSQL blocks). This restriction is not enforced by the syntax, but attempts to create nested sub-procedures will raise an error feature is not supported with detail message nested sub procedure.
Currently, the sub-procedure has no direct access to use variables and cursors from its parent module. It can access other routines from its parent modules. In some cases a forward declaration may be necessary.
A sub-procedure can be forward declared to resolve mutual dependencies between subroutines, and must be followed by its actual definition. When a sub-procedure is forward declared and has parameters with default values, the default values should only be specified in the forward declaration, and should not be repeated in subproc_def.
Note
Declaring a sub-procedure with the same name as a stored procedure, table or view will hide that stored procedure, table or view from your module. It will not be possible to call that stored procedure, table or view.
Note
Contrary to DECLARE [VARIABLE]
, a DECLARE PROCEDURE
is not terminated by a semicolon. The END
of its main BEGIN … END
block is considered its terminator.
7.7.6.1 Examples of Sub-Procedures
Subroutines in
EXECUTE BLOCK
EXECUTE BLOCK
RETURNS (name VARCHAR(63))
AS
-- Sub-procedure returning a list of tables
DECLARE PROCEDURE get_tables
RETURNS (table_name VARCHAR(63))
AS
BEGIN
FOR SELECT RDB$RELATION_NAME
FROM RDB$RELATIONS
WHERE RDB$VIEW_BLR IS NULL
INTO table_name
DO SUSPEND;
END
-- Sub-procedure returning a list of views
DECLARE PROCEDURE get_views
RETURNS (view_name VARCHAR(63))
AS
BEGIN
FOR SELECT RDB$RELATION_NAME
FROM RDB$RELATIONS
WHERE RDB$VIEW_BLR IS NOT NULL
INTO view_name
DO SUSPEND;
END
BEGIN
FOR SELECT table_name
FROM get_tables
UNION ALL
SELECT view_name
FROM get_views
INTO name
DO SUSPEND;
END
With forward declaration and parameter with default value
execute block returns (o integer)
as
-- Forward declaration of P1.
declare procedure p1(i integer = 1) returns (o integer);
-- Forward declaration of P2.
declare procedure p2(i integer) returns (o integer);
-- Implementation of P1 should not re-declare parameter default value.
declare procedure p1(i integer) returns (o integer)
as
begin
execute procedure p2(i) returning_values o;
end
declare procedure p2(i integer) returns (o integer)
as
begin
o = i;
end
begin
execute procedure p1 returning_values o;
suspend;
end
See alsoSection 7.7.5, DECLARE FUNCTION, CREATE PROCEDURE
7.7.7 BEGIN … END
Used forDelimiting a block of statements
Available inPSQL
Syntax
<block> ::=
BEGIN
[<compound_statement> ...]
END
<compound_statement> ::= {<block> | <statement>}
The BEGIN … END
construct is a two-part statement that wraps a block of statements that are executed as one unit of code. Each block starts with the half-statement BEGIN
and ends with the other half-statement END
. Blocks can be nested a maximum depth of 512 nested blocks. A block can be empty, allowing them to act as stubs, without the need to write dummy statements.
The BEGIN and END statements have no line terminators (semicolon). However, when defining or altering a PSQL module in the isql utility, that application requires that the last END
statement be followed by its own terminator character, that was previously switched — using SET TERM
— to some string other than a semicolon. That terminator is not part of the PSQL syntax.
The final, or outermost, END
statement in a trigger terminates the trigger. What the final END
statement does in a stored procedure depends on the type of procedure:
In a selectable procedure, the final
END
statement returns control to the caller, returning SQLCODE 100, indicating that there are no more rows to retrieveIn an executable procedure, the final
END
statement returns control to the caller, along with the current values of any output parameters defined.
7.7.7.1 BEGIN … END
Examples
A sample procedure from the employee.fdb database, showing simple usage of BEGIN…END blocks:
SET TERM ^;
CREATE OR ALTER PROCEDURE DEPT_BUDGET (
DNO CHAR(3))
RETURNS (
TOT DECIMAL(12,2))
AS
DECLARE VARIABLE SUMB DECIMAL(12,2);
DECLARE VARIABLE RDNO CHAR(3);
DECLARE VARIABLE CNT INTEGER;
BEGIN
TOT = 0;
SELECT BUDGET
FROM DEPARTMENT
WHERE DEPT_NO = :DNO
INTO :TOT;
SELECT COUNT(BUDGET)
FROM DEPARTMENT
WHERE HEAD_DEPT = :DNO
INTO :CNT;
IF (CNT = 0) THEN
SUSPEND;
FOR SELECT DEPT_NO
FROM DEPARTMENT
WHERE HEAD_DEPT = :DNO
INTO :RDNO
DO
BEGIN
EXECUTE PROCEDURE DEPT_BUDGET(:RDNO)
RETURNING_VALUES :SUMB;
TOT = TOT + SUMB;
END
SUSPEND;
END^
SET TERM ;^
See alsoSection 7.7.13, EXIT, SET TERM
7.7.8 IF … THEN … ELSE
Used forConditional branching
Available inPSQL
Syntax
IF (<condition>)
THEN <compound_statement>
[ELSE <compound_statement>]
Table 7.7.8.1 IF … THEN … ELSE
Parameters
Argument | Description |
---|---|
condition | A logical condition returning TRUE, FALSE or UNKNOWN |
compound_statement | A single statement, or two or more statements wrapped in |
The conditional branch statement IF … THEN
is used to branch the execution process in a PSQL module. The condition is always enclosed in parentheses. If the condition returns the value TRUE, execution branches to the statement or the block of statements after the keyword THEN
. If an ELSE
is present, and the condition returns FALSE or UNKNOWN, execution branches to the statement or the block of statements after it.
Multi-Branch Decisions
PSQL does not provide more advanced multi-branch jumps, such as CASE
or SWITCH
. However, it is possible to chain IF … THEN … ELSE
statements, see the example section below. Alternatively, the CASE
statement from DSQL is available in PSQL and is able to satisfy at least some use cases in the manner of a switch:
CASE <test_expr>
WHEN <expr> THEN <result>
[WHEN <expr> THEN <result> ...]
[ELSE <defaultresult>]
END
CASE
WHEN <bool_expr> THEN <result>
[WHEN <bool_expr> THEN <result> ...]
[ELSE <defaultresult>]
END
Example in PSQL
...
C = CASE
WHEN A=2 THEN 1
WHEN A=1 THEN 3
ELSE 0
END;
...
7.7.8.1 IF
Examples
An example using the
IF
statement. Assume that theFIRST
,LINE2
andLAST
variables were declared earlier....
IF (FIRST IS NOT NULL) THEN
LINE2 = FIRST || ' ' || LAST;
ELSE
LINE2 = LAST;
...
Given
IF … THEN … ELSE
is a statement, it is possible to chain them together. Assume that theINT_VALUE
andSTRING_VALUE
variables were declared earlier.IF (INT_VALUE = 1) THEN
STRING_VALUE = 'one';
ELSE IF (INT_VALUE = 2) THEN
STRING_VALUE = 'two';
ELSE IF (INT_VALUE = 3) THEN
STRING_VALUE = 'three';
ELSE
STRING_VALUE = 'too much';
This specific example can be replaced with a simple CASE or the DECODE function.
See alsoSection 7.7.9, WHILE … DO, CASE
7.7.9 WHILE … DO
Used forLooping constructs
Available inPSQL
Syntax
[label:]
WHILE <condition> DO
<compound_statement>
Table 7.7.9.1 WHILE … DO
Parameters
Argument | Description |
---|---|
label | Optional label for |
condition | A logical condition returning TRUE, FALSE or UNKNOWN |
compound_statement | A single statement, or two or more statements wrapped in |
A WHILE
statement implements the looping construct in PSQL. The statement or the block of statements will be executed until the condition returns TRUE. Loops can be nested to any depth.
7.7.9.1 WHILE … DO
Examples
A procedure calculating the sum of numbers from 1 to I shows how the looping construct is used.
CREATE PROCEDURE SUM_INT (I INTEGER)
RETURNS (S INTEGER)
AS
BEGIN
s = 0;
WHILE (i > 0) DO
BEGIN
s = s + i;
i = i - 1;
END
END
Executing the procedure in isql:
EXECUTE PROCEDURE SUM_INT(4);
the result is:
S
==========
10
See alsoSection 7.7.8, IF … THEN … ELSE, Section 7.7.10, BREAK, Section 7.7.11, LEAVE, Section 7.7.12, CONTINUE, Section 7.7.13, EXIT, Section 7.7.16, FOR SELECT, Section 7.7.17, FOR EXECUTE STATEMENT
7.7.10 BREAK
Used forExiting a loop
Available inPSQL
Syntax
[label:]
<loop_stmt>
BEGIN
...
BREAK;
...
END
<loop_stmt> ::=
FOR <select_stmt> INTO <var_list> DO
| FOR EXECUTE STATEMENT ... INTO <var_list> DO
| WHILE (<condition>)} DO
Table 7.7.10.1 BREAK
Statement Parameters
Argument | Description |
---|---|
label | Label |
select_stmt |
|
condition | A logical condition returning TRUE, FALSE or UNKNOWN |
The BREAK
statement immediately terminates the inner loop of a WHILE
or FOR
looping statement. Code continues to be executed from the first statement after the terminated loop block.
BREAK
is similar to LEAVE
, except it doesn’t support a label.
See alsoSection 7.7.11, LEAVE
7.7.11 LEAVE
Used forExiting a loop
Available inPSQL
Syntax
[label:]
<loop_stmt>
BEGIN
...
LEAVE [label];
...
END
<loop_stmt> ::=
FOR <select_stmt> INTO <var_list> DO
| FOR EXECUTE STATEMENT ... INTO <var_list> DO
| WHILE (<condition>)} DO
Table 7.7.11.1 LEAVE
Statement Parameters
Argument | Description |
---|---|
label | Label |
select_stmt |
|
condition | A logical condition returning TRUE, FALSE or UNKNOWN |
The LEAVE
statement immediately terminates the inner loop of a WHILE
or FOR
looping statement. Using the optional label parameter, LEAVE
can also exit an outer loop, that is, the loop labelled with label. Code continues to be executed from the first statement after the terminated loop block.
7.7.11.1 LEAVE
Examples
Leaving a loop if an error occurs on an insert into the
NUMBERS
table. The code continues to be executed from the lineC = 0
....
WHILE (B < 10) DO
BEGIN
INSERT INTO NUMBERS(B)
VALUES (:B);
B = B + 1;
WHEN ANY DO
BEGIN
EXECUTE PROCEDURE LOG_ERROR (
CURRENT_TIMESTAMP,
'ERROR IN B LOOP');
LEAVE;
END
END
C = 0;
...
An example using labels in the
LEAVE
statement.LEAVE LOOPA
terminates the outer loop andLEAVE LOOPB
terminates the inner loop. Note that the plainLEAVE
statement would be enough to terminate the inner loop....
STMT1 = 'SELECT NAME FROM FARMS';
LOOPA:
FOR EXECUTE STATEMENT :STMT1
INTO :FARM DO
BEGIN
STMT2 = 'SELECT NAME ' || 'FROM ANIMALS WHERE FARM = ''';
LOOPB:
FOR EXECUTE STATEMENT :STMT2 || :FARM || ''''
INTO :ANIMAL DO
BEGIN
IF (ANIMAL = 'FLUFFY') THEN
LEAVE LOOPB;
ELSE IF (ANIMAL = FARM) THEN
LEAVE LOOPA;
ELSE
SUSPEND;
END
END
...
See alsoSection 7.7.10, BREAK, Section 7.7.12, CONTINUE, Section 7.7.13, EXIT
7.7.12 CONTINUE
Used forContinuing with the next iteration of a loop
Available inPSQL
Syntax
[label:]
<loop_stmt>
BEGIN
...
CONTINUE [label];
...
END
<loop_stmt> ::=
FOR <select_stmt> INTO <var_list> DO
| FOR EXECUTE STATEMENT ... INTO <var_list> DO
| WHILE (<condition>)} DO
Table 7.7.12.1 CONTINUE
Statement Parameters
Argument | Description |
---|---|
label | Label |
select_stmt |
|
condition | A logical condition returning TRUE, FALSE or UNKNOWN |
The CONTINUE
statement skips the remainer of the current block of a loop and starts the next iteration of the current WHILE
or FOR
loop. Using the optional label parameter, CONTINUE
can also start the next iteration of an outer loop, that is, the loop labelled with label.
7.7.12.1 CONTINUE
Examples
Using the CONTINUE statement
FOR SELECT A, D
FROM ATABLE INTO achar, ddate
DO
BEGIN
IF (ddate < current_date - 30) THEN
CONTINUE;
ELSE
BEGIN
/* do stuff */
END
END
See alsoSection 7.7.10, BREAK, Section 7.7.11, LEAVE, Section 7.7.13, EXIT
7.7.13 EXIT
Used forTerminating module execution
Available inPSQL
Syntax
EXIT;
The EXIT
statement causes execution of the current PSQL module to jump to the final END
statement from any point in the code, thus terminating the program.
Calling EXIT
in a function will result in the function returning NULL
.
7.7.13.1 EXIT
Examples
Using the EXIT statement in a selectable procedure
CREATE PROCEDURE GEN_100
RETURNS (I INTEGER)
AS
BEGIN
I = 1;
WHILE (1=1) DO
BEGIN
SUSPEND;
IF (I=100) THEN
EXIT;
I = I + 1;
END
END
See alsoSection 7.7.10, BREAK, Section 7.7.11, LEAVE, Section 7.7.12, CONTINUE, Section 7.7.14, SUSPEND
7.7.14 SUSPEND
Used forPassing output to the buffer and suspending execution while waiting for caller to fetch it
Available inPSQL
Syntax
SUSPEND;
The SUSPEND
statement is used in a selectable stored procedure to pass the values of output parameters to a buffer and suspend execution. Execution remains suspended until the calling application fetches the contents of the buffer. Execution resumes from the statement directly after the SUSPEND
statement. In practice, this is likely to be a new iteration of a looping process.
Important Notes
The
SUSPEND
statement can only occur in stored procedures or sub-proceduresThe presence of the
SUSPEND
keyword defines a stored procedure as a selectable procedureApplications using interfaces that wrap the API perform the fetches from selectable procedures transparently.
If a selectable procedure is executed using
EXECUTE PROCEDURE
, it behaves as an executable procedure. When aSUSPEND
statement is executed in such a stored procedure, it is the same as executing theEXIT
statement, resulting in immediate termination of the procedure.SUSPEND
breaks the atomicity of the block in which it is located. If an error occurs in a selectable procedure, statements executed after the finalSUSPEND
statement will be rolled back. Statements that executed before the finalSUSPEND
statement will not be rolled back unless the transaction is rolled back.
7.7.14.1 SUSPEND
Examples
Using the SUSPEND statement in a selectable procedure
CREATE PROCEDURE GEN_100
RETURNS (I INTEGER)
AS
BEGIN
I = 1;
WHILE (1=1) DO
BEGIN
SUSPEND;
IF (I=100) THEN
EXIT;
I = I + 1;
END
END
See alsoSection 7.7.13, EXIT
7.7.15 EXECUTE STATEMENT
Used forExecuting dynamically created SQL statements
Available inPSQL
Syntax
<execute_statement> ::= EXECUTE STATEMENT <argument>
[<option> ...]
[INTO <variables>];
<argument> ::= <paramless_stmt>
| (<paramless_stmt>)
| (<stmt_with_params>) (<param_values>)
<param_values> ::= <named_values> | <positional_values>
<named_values> ::= <named_value> [, <named_value> ...]
<named_value> ::= [EXCESS] paramname := <value_expr>
<positional_values> ::= <value_expr> [, <value_expr> ...]
<option> ::=
WITH {AUTONOMOUS | COMMON} TRANSACTION
| WITH CALLER PRIVILEGES
| AS USER user
| PASSWORD password
| ROLE role
| ON EXTERNAL [DATA SOURCE] <connection_string>
<connection_string> ::=
!! See <filespec> in the CREATE DATABASE syntax !!
<variables> ::= [:]varname [, [:]varname ...]
Table 7.7.15.1 EXECUTE STATEMENT
Statement Parameters
Argument | Description |
---|---|
paramless_stmt | Literal string or variable containing a non-parameterized SQL query |
stmt_with_params | Literal string or variable containing a parameterized SQL query |
paramname | SQL query parameter name |
value_expr | SQL expression resolving to a value |
user | Username. It can be a string, |
password | Password. It can be a string or a string variable |
role | Role. It can be a string, |
connection_string | Connection string. It can be a string literal or a string variable |
varname | Variable |
The statement EXECUTE STATEMENT
takes a string parameter and executes it as if it were a DSQL statement. If the statement returns data, it can be passed to local variables by way of an INTO
clause.
Note
EXECUTE STATEMENT
can only produce a single row of data. Statements producing multiple rows of data must be executed with Section 7.7.17, FOR EXECUTE STATEMENT.
7.7.15.1 Parameterized Statements
You can use parameters — either named or positional — in the DSQL statement string. Each parameter must be assigned a value.
7.7.15.1.1 Special Rules for Parameterized Statements
Named and positional parameters cannot be mixed in one query
Each parameter must be used in the statement text.
To relax this rule, named parameters can be prefixed with the keyword
EXCESS
to indicate that the parameter may be absent from the statement text. This option is useful for dynamically generated statements that conditionally include or exclude certain parameters.If the statement has parameters, they must be enclosed in parentheses when
EXECUTE STATEMENT
is called, regardless of whether they come directly as strings, as variable names or as expressionsEach named parameter must be prefixed by a colon (
:
) in the statement string itself, but not when the parameter is assigned a valuePositional parameters must be assigned their values in the same order as they appear in the query text
The assignment operator for parameters is the special operator
:=
, similar to the assignment operator in PascalEach named parameter can be used in the statement more than once, but its value must be assigned only once
With positional parameters, the number of assigned values must match the number of parameter placeholders (question marks) in the statement exactly
A named parameter in the statement text can only be a regular identifier (it cannot be a quoted identifier)
7.7.15.1.2 Examples of EXECUTE STATEMENT
with parameters
With named parameters:
...
DECLARE license_num VARCHAR(15);
DECLARE connect_string VARCHAR (100);
DECLARE stmt VARCHAR (100) =
'SELECT license
FROM cars
WHERE driver = :driver AND location = :loc';
BEGIN
...
SELECT connstr
FROM databases
WHERE cust_id = :id
INTO connect_string;
...
FOR
SELECT id
FROM drivers
INTO current_driver
DO
BEGIN
FOR
SELECT location
FROM driver_locations
WHERE driver_id = :current_driver
INTO current_location
DO
BEGIN
...
EXECUTE STATEMENT (stmt)
(driver := current_driver,
loc := current_location)
ON EXTERNAL connect_string
INTO license_num;
...
The same code with positional parameters:
DECLARE license_num VARCHAR (15);
DECLARE connect_string VARCHAR (100);
DECLARE stmt VARCHAR (100) =
'SELECT license
FROM cars
WHERE driver = ? AND location = ?';
BEGIN
...
SELECT connstr
FROM databases
WHERE cust_id = :id
into connect_string;
...
FOR
SELECT id
FROM drivers
INTO current_driver
DO
BEGIN
FOR
SELECT location
FROM driver_locations
WHERE driver_id = :current_driver
INTO current_location
DO
BEGIN
...
EXECUTE STATEMENT (stmt)
(current_driver, current_location)
ON EXTERNAL connect_string
INTO license_num;
...
Use of
EXCESS
to allow named parameters to be unused (note: this is aFOR EXECUTE STATEMENT
):
CREATE PROCEDURE P_EXCESS (A_ID INT, A_TRAN INT = NULL, A_CONN INT = NULL)
RETURNS (ID INT, TRAN INT, CONN INT)
AS
DECLARE S VARCHAR(255);
DECLARE W VARCHAR(255) = '';
BEGIN
S = 'SELECT * FROM TTT WHERE ID = :ID';
IF (A_TRAN IS NOT NULL)
THEN W = W || ' AND TRAN = :a';
IF (A_CONN IS NOT NULL)
THEN W = W || ' AND CONN = :b';
IF (W <> '')
THEN S = S || W;
-- could raise error if TRAN or CONN is null
-- FOR EXECUTE STATEMENT (:S) (a := :A_TRAN, b := A_CONN, id := A_ID)
-- OK in all cases
FOR EXECUTE STATEMENT (:S) (EXCESS a := :A_TRAN, EXCESS b := A_CONN, id := A_ID)
INTO :ID, :TRAN, :CONN
DO SUSPEND;
END
7.7.15.2 WITH {AUTONOMOUS | COMMON} TRANSACTION
By default, the executed SQL statement runs within the current transaction. Using WITH AUTONOMOUS TRANSACTION
causes a separate transaction to be started, with the same parameters as the current transaction. This separate transaction will be committed when the statement was executed without errors and rolled back otherwise.
The clause WITH COMMON TRANSACTION
uses the current transaction whenever possible; this is the default behaviour. If the statement must run in a separate connection, an already started transaction within that connection is used, if available. Otherwise, a new transaction is started with the same parameters as the current transaction. Any new transactions started under the COMMON
regime are committed or rolled back with the current transaction.
7.7.15.3 WITH CALLER PRIVILEGES
By default, the SQL statement is executed with the privileges of the current user. Specifying WITH CALLER PRIVILEGES
combines the privileges of the calling procedure or trigger with those of the user, just as if the statement were executed directly by the routine. WITH CALLER PRIVILEGES
has no effect if the ON EXTERNAL
clause is also present.
7.7.15.4 ON EXTERNAL [DATA SOURCE]
With ON EXTERNAL [DATA SOURCE]
, the SQL statement is executed in a separate connection to the same or another database, possibly even on another server. If connection_string is NULL or ''
(empty string), the entire ON EXTERNAL [DATA SOURCE]
clause is considered absent, and the statement is executed against the current database.
7.7.15.4.1 Connection Pooling
External connections made by statements
WITH COMMON TRANSACTION
(the default) will remain open until the current transaction ends. They can be reused by subsequent calls toEXECUTE STATEMENT
, but only if connection_string is exactly the same, including caseExternal connections made by statements
WITH AUTONOMOUS TRANSACTION
are closed as soon as the statement has been executedStatements using
WITH AUTONOMOUS TRANSACTION
can and will re-use connections that were opened earlier by statementsWITH COMMON TRANSACTION
. If this happens, the reused connection will be left open after the statement has been executed. (It must be, because it has at least one active transaction!)
7.7.15.4.2 Transaction Pooling
If
WITH COMMON TRANSACTION
is in effect, transactions will be reused as much as possible. They will be committed or rolled back together with the current transactionIf
WITH AUTONOMOUS TRANSACTION
is specified, a fresh transaction will always be started for the statement. This transaction will be committed or rolled back immediately after the statement’s execution
7.7.15.4.3 Exception Handling
When ON EXTERNAL
is used, the extra connection is always made via a so-called external provider, even if the connection is to the current database. One of the consequences is that exceptions cannot be caught in the usual way. Every exception caused by the statement is wrapped in either an eds_connection
or an eds_statement
error. In order to catch them in your PSQL code, you have to use WHEN GDSCODE eds_connection
, WHEN GDSCODE eds_statement
or WHEN ANY
.
Note
Without ON EXTERNAL
, exceptions are caught in the usual way, even if an extra connection is made to the current database.
7.7.15.4.4 Miscellaneous Notes
The character set used for the external connection is the same as that for the current connection
Two-phase commits are not supported
7.7.15.5 AS USER
, PASSWORD
and ROLE
The optional AS USER
, PASSWORD
and ROLE
clauses allow specification of which user will execute the SQL statement and with which role. The method of user login, and whether a separate connection is opened, depends on the presence and values of the ON EXTERNAL [DATA SOURCE]
, AS USER
, PASSWORD
and ROLE
clauses:
If
ON EXTERNAL
is present, a new connection is always opened, and:If at least one of
AS USER
,PASSWORD
andROLE
is present, native authentication is attempted with the given parameter values (locally or remotely, depending on connection_string). No defaults are used for missing parametersIf all three are absent, and connection_string contains no hostname, then the new connection is established on the local server with the same user and role as the current connection. The term ‘local’ means on the same machine as the server here. This is not necessarily the location of the client
If all three are absent, and connection_string contains a hostname, then trusted authentication is attempted on the remote host (again, ‘remote’ from the perspective of the server). If this succeeds, the remote operating system will provide the username (usually the operating system account under which the Firebird process runs)
If
ON EXTERNAL
is absent:If at least one of
AS USER
,PASSWORD
andROLE
is present, a new connection to the current database is opened with the supplied parameter values. No defaults are used for missing parametersIf all three are absent, the statement is executed within the current connection
Note
If a parameter value is NULL or ''
(empty string), the entire parameter is considered absent. Additionally, AS USER
is considered absent if its value is equal to CURRENT_USER
, and ROLE
if it is the same as CURRENT_ROLE
.
7.7.15.6 Caveats with EXECUTE STATEMENT
There is no way to validate the syntax of the enclosed statement
There are no dependency checks to discover whether tables or columns have been dropped
Even though the performance in loops has been significantly improved in Firebird 2.5, execution is still considerably slower than when the same statements are executed directly
Return values are strictly checked for data type in order to avoid unpredictable type-casting exceptions. For example, the string
'1234'
would convert to an integer, 1234, but'abc'
would give a conversion error
All in all, this feature is meant to be used very cautiously, and you should always take the caveats into account. If you can achieve the same result with PSQL and/or DSQL, it will almost always be preferable.
See alsoSection 7.7.17, FOR EXECUTE STATEMENT
7.7.16 FOR SELECT
Used forLooping row-by-row through a selected result set
Available inPSQL
Syntax
[label:]
FOR <select_stmt> [AS CURSOR cursor_name]
DO <compound_statement>
Table 7.7.16.1 FOR SELECT
Statement Parameters
Argument | Description |
---|---|
label | Optional label for |
select_stmt |
|
cursor_name | Cursor name. It must be unique among cursor names in the PSQL module (stored procedure, stored function, trigger or PSQL block) |
compound_statement | A single statement, or a block of statements wrapped in |
The FOR SELECT
statement
retrieves each row sequentially from the result set, and executes the statement or block of statements for each row. In each iteration of the loop, the field values of the current row are copied into pre-declared variables.
Including the
AS CURSOR
clause enables positioned deletes and updates to be performed — see notes belowcan embed other
FOR SELECT
statementscan contain named parameters that must be previously declared in the
DECLARE VARIABLE
statement or exist as input or output parameters of the procedurerequires an
INTO
clause at the end of theSELECT … FROM …
specification. In each iteration of the loop, the field values of the current row are copied to the list of variables specified in theINTO
clause. The loop repeats until all rows are retrieved, after which it terminatescan be terminated before all rows are retrieved by using a
BREAK
,LEAVE
orEXIT
statement
7.7.16.1 The Undeclared Cursor
The optional AS CURSOR
clause surfaces the set in the FOR SELECT
structure as an undeclared, named cursor that can be operated on using the WHERE CURRENT OF
clause inside the statement or block following the DO
command, in order to delete or update the current row before execution moves to the next row. In addition, it is possible to use the cursor name as a record variable (similar to OLD
and NEW
in triggers), allowing access to the columns of the result set (i.e. cursor_name.columnname).
Rules for Cursor Variables
When accessing a cursor variable in a DML statement, the colon prefix can be added before the cursor name (i.e.
:*cursor_name*.*columnname*
) for disambiguation, similar to variables.The cursor variable can be referenced without colon prefix, but in that case, depending on the scope of the contexts in the statement, the name may resolve in the statement context instead of to the cursor (e.g. you select from a table with the same name as the cursor).
Cursor variables are read-only
In a
FOR SELECT
statement without anAS CURSOR
clause, you must use theINTO
clause. If anAS CURSOR
clause is specified, theINTO
clause is allowed, but optional; you can access the fields through the cursor instead.Reading from a cursor variable returns the current field values. This means that an
UPDATE
statement (with aWHERE CURRENT OF
clause) will update not only the table, but also the fields in the cursor variable for subsequent reads. Executing aDELETE
statement (with aWHERE CURRENT OF
clause) will set all fields in the cursor variable toNULL
for subsequent reads
Other points to take into account regarding undeclared cursors:
The
OPEN
,FETCH
andCLOSE
statements cannot be applied to a cursor surfaced by theAS CURSOR
clauseThe cursor_name argument associated with an
AS CURSOR
clause must not clash with any names created byDECLARE VARIABLE
orDECLARE CURSOR
statements at the top of the module body, nor with any other cursors surfaced by anAS CURSOR
clauseThe optional
FOR UPDATE
clause in theSELECT
statement is not required for a positioned update
7.7.16.2 Examples using FOR SELECT
A simple loop through query results:
CREATE PROCEDURE SHOWNUMS
RETURNS (
AA INTEGER,
BB INTEGER,
SM INTEGER,
DF INTEGER)
AS
BEGIN
FOR SELECT DISTINCT A, B
FROM NUMBERS
ORDER BY A, B
INTO AA, BB
DO
BEGIN
SM = AA + BB;
DF = AA - BB;
SUSPEND;
END
END
Nested
FOR SELECT
loop:CREATE PROCEDURE RELFIELDS
RETURNS (
RELATION CHAR(32),
POS INTEGER,
FIELD CHAR(32))
AS
BEGIN
FOR SELECT RDB$RELATION_NAME
FROM RDB$RELATIONS
ORDER BY 1
INTO :RELATION
DO
BEGIN
FOR SELECT
RDB$FIELD_POSITION + 1,
RDB$FIELD_NAME
FROM RDB$RELATION_FIELDS
WHERE
RDB$RELATION_NAME = :RELATION
ORDER BY RDB$FIELD_POSITION
INTO :POS, :FIELD
DO
BEGIN
IF (POS = 2) THEN
RELATION = ' "';
SUSPEND;
END
END
END
Using the
AS CURSOR
clause to surface a cursor for the positioned delete of a record:CREATE PROCEDURE DELTOWN (
TOWNTODELETE VARCHAR(24))
RETURNS (
TOWN VARCHAR(24),
POP INTEGER)
AS
BEGIN
FOR SELECT TOWN, POP
FROM TOWNS
INTO :TOWN, :POP AS CURSOR TCUR
DO
BEGIN
IF (:TOWN = :TOWNTODELETE) THEN
-- Positional delete
DELETE FROM TOWNS
WHERE CURRENT OF TCUR;
ELSE
SUSPEND;
END
END
Using an implicitly declared cursor as a cursor variable
EXECUTE BLOCK
RETURNS (o CHAR(63))
AS
BEGIN
FOR SELECT rdb$relation_name AS name
FROM rdb$relations AS CURSOR c
DO
BEGIN
o = c.name;
SUSPEND;
END
END
Disambiguating cursor variables within queries
EXECUTE BLOCK
RETURNS (o1 CHAR(63), o2 CHAR(63))
AS
BEGIN
FOR SELECT rdb$relation_name
FROM rdb$relations
WHERE
rdb$relation_name = 'RDB$RELATIONS' AS CURSOR c
DO
BEGIN
FOR SELECT
-- with a prefix resolves as a cursor
:c.rdb$relation_name x1,
-- no prefix as an alias for the rdb$relations table
c.rdb$relation_name x2
FROM rdb$relations c
WHERE
rdb$relation_name = 'RDB$DATABASE' AS CURSOR d
DO
BEGIN
o1 = d.x1;
o2 = d.x2;
SUSPEND;
END
END
END
See alsoSection 7.7.4, DECLARE .. CURSOR, Section 7.7.10, BREAK, Section 7.7.11, LEAVE, Section 7.7.12, CONTINUE, Section 7.7.13, EXIT, SELECT, UPDATE, DELETE
7.7.17 FOR EXECUTE STATEMENT
Used forExecuting dynamically created SQL statements that return a row set
Available inPSQL
Syntax
[label:]
FOR <execute_statement> DO <compound_statement>
Table 7.7.17.1 FOR EXECUTE STATEMENT
Statement Parameters
Argument | Description |
---|---|
label | Optional label for |
execute_stmt | An |
compound_statement | A single statement, or a block of statements wrapped in |
The statement FOR EXECUTE STATEMENT
is used, in a manner analogous to FOR SELECT
, to loop through the result set of a dynamically executed query that returns multiple rows.
7.7.17.1 FOR EXECUTE STATEMENT
Examples
Executing a dynamically constructed SELECT query that returns a data set
CREATE PROCEDURE DynamicSampleThree (
Q_FIELD_NAME VARCHAR(100),
Q_TABLE_NAME VARCHAR(100)
) RETURNS(
LINE VARCHAR(32000)
)
AS
DECLARE VARIABLE P_ONE_LINE VARCHAR(100);
BEGIN
LINE = '';
FOR
EXECUTE STATEMENT
'SELECT T1.' || :Q_FIELD_NAME ||
' FROM ' || :Q_TABLE_NAME || ' T1 '
INTO :P_ONE_LINE
DO
IF (:P_ONE_LINE IS NOT NULL) THEN
LINE = :LINE || :P_ONE_LINE || ' ';
SUSPEND;
END
See alsoSection 7.7.15, EXECUTE STATEMENT, Section 7.7.10, BREAK, Section 7.7.11, LEAVE, Section 7.7.12, CONTINUE
7.7.18 OPEN
Used forOpening a declared cursor
Available inPSQL
Syntax
OPEN cursor_name;
Table 7.7.18.1 OPEN
Statement Parameter
Argument | Description |
---|---|
cursor_name | Cursor name. A cursor with this name must be previously declared with a |
An OPEN
statement opens a previously declared cursor, executes its declared SELECT
statement, and makes the first record of the result data set ready to fetch. OPEN
can be applied only to cursors previously declared in a Section 7.7.4, DECLARE .. CURSOR statement.
Note
If the SELECT
statement of the cursor has parameters, they must be declared as local variables or exist as input or output parameters before the cursor is declared. When the cursor is opened, the parameter is assigned the current value of the variable.
7.7.18.1 OPEN
Examples
Using the
OPEN
statement:SET TERM ^;
CREATE OR ALTER PROCEDURE GET_RELATIONS_NAMES
RETURNS (
RNAME CHAR(63)
)
AS
DECLARE C CURSOR FOR (
SELECT RDB$RELATION_NAME
FROM RDB$RELATIONS);
BEGIN
OPEN C;
WHILE (1 = 1) DO
BEGIN
FETCH C INTO :RNAME;
IF (ROW_COUNT = 0) THEN
LEAVE;
SUSPEND;
END
CLOSE C;
END^
SET TERM ;^
A collection of scripts for creating views using a PSQL block with named cursors:
EXECUTE BLOCK
RETURNS (
SCRIPT BLOB SUB_TYPE TEXT)
AS
DECLARE VARIABLE FIELDS VARCHAR(8191);
DECLARE VARIABLE FIELD_NAME TYPE OF RDB$FIELD_NAME;
DECLARE VARIABLE RELATION RDB$RELATION_NAME;
DECLARE VARIABLE SOURCE TYPE OF COLUMN RDB$RELATIONS.RDB$VIEW_SOURCE;
-- named cursor
DECLARE VARIABLE CUR_R CURSOR FOR (
SELECT
RDB$RELATION_NAME,
RDB$VIEW_SOURCE
FROM
RDB$RELATIONS
WHERE
RDB$VIEW_SOURCE IS NOT NULL);
-- named cursor with local variable
DECLARE CUR_F CURSOR FOR (
SELECT
RDB$FIELD_NAME
FROM
RDB$RELATION_FIELDS
WHERE
-- Important! The variable has to be declared earlier
RDB$RELATION_NAME = :RELATION);
BEGIN
OPEN CUR_R;
WHILE (1 = 1) DO
BEGIN
FETCH CUR_R
INTO :RELATION, :SOURCE;
IF (ROW_COUNT = 0) THEN
LEAVE;
FIELDS = NULL;
-- The CUR_F cursor will use
-- variable value of RELATION initialized above
OPEN CUR_F;
WHILE (1 = 1) DO
BEGIN
FETCH CUR_F
INTO :FIELD_NAME;
IF (ROW_COUNT = 0) THEN
LEAVE;
IF (FIELDS IS NULL) THEN
FIELDS = TRIM(FIELD_NAME);
ELSE
FIELDS = FIELDS || ', ' || TRIM(FIELD_NAME);
END
CLOSE CUR_F;
SCRIPT = 'CREATE VIEW ' || RELATION;
IF (FIELDS IS NOT NULL) THEN
SCRIPT = SCRIPT || ' (' || FIELDS || ')';
SCRIPT = SCRIPT || ' AS ' || ASCII_CHAR(13);
SCRIPT = SCRIPT || SOURCE;
SUSPEND;
END
CLOSE CUR_R;
END
See alsoSection 7.7.4, DECLARE .. CURSOR, Section 7.7.19, FETCH, Section 7.7.20, CLOSE
7.7.19 FETCH
Used forFetching successive records from a data set retrieved by a cursor
Available inPSQL
Syntax
FETCH [<fetch_scroll> FROM] cursor_name
[INTO [:]varname [, [:]varname ...]];
<fetch_scroll> ::=
NEXT | PRIOR | FIRST | LAST
| RELATIVE n
| ABSOLUTE n
Table 7.7.19.1 FETCH
Statement Parameters
Argument | Description |
---|---|
cursor_name | Cursor name. A cursor with this name must be previously declared with a |
varname | Variable name |
n | Integer expression for the number of rows |
The FETCH
statement fetches the first and successive rows from the result set of the cursor and assigns the column values to PSQL variables. The FETCH
statement can be used only with a cursor declared with the Section 7.7.4, DECLARE .. CURSOR statement.
Using the optional fetch_scroll part of the FETCH
statement, you can specify in which direction and how many rows to advance the cursor position. The NEXT
clause can be used for scrollable and forward-only cursors. Other clauses are only supported for scrollable cursors.
The Scroll Options
NEXT
moves the cursor one row forward; this is the default
PRIOR
moves the cursor one record back
FIRST
moves the cursor to the first record.
LAST
moves the cursor to the last record
RELATIVE *n*
moves the cursor n rows from the current position; positive numbers move forward, negative numbers move backwards; using zero (0
) will not move the cursor, and ROW_COUNT
will be set to zero as no new row was fetched.
ABSOLUTE *n*
moves the cursor to the specified row; n is an integer expression, where 1
indicates the first row. For negative values, the absolute position is taken from the end of the result set, so -1
indicates the last row, -2
the second to last row, etc. A value of zero (0
) will position before the first row.
The optional INTO
clause gets data from the current row of the cursor and loads them into PSQL variables. If fetch moved beyond the bounds of the result set, the variables will be set to NULL
.
It is also possible to use the cursor name as a variable of a row type (similar to OLD
and NEW
in triggers), allowing access to the columns of the result set (i.e. cursor_name.columnname).
Rules for Cursor Variables
When accessing a cursor variable in a DML statement, the colon prefix can be added before the cursor name (i.e.
:*cursor_name*.*columnname*
) for disambiguation, similar to variables.The cursor variable can be referenced without colon prefix, but in that case, depending on the scope of the contexts in the statement, the name may resolve in the statement context instead of to the cursor (e.g. you select from a table with the same name as the cursor).
Cursor variables are read-only
In a
FOR SELECT
statement without anAS CURSOR
clause, you must use theINTO
clause. If anAS CURSOR
clause is specified, theINTO
clause is allowed, but optional; you can access the fields through the cursor instead.Reading from a cursor variable returns the current field values. This means that an
UPDATE
statement (with aWHERE CURRENT OF
clause) will update not only the table, but also the fields in the cursor variable for subsequent reads. Executing aDELETE
statement (with aWHERE CURRENT OF
clause) will set all fields in the cursor variable toNULL
for subsequent readsWhen the cursor is not positioned on a row — it is positioned before the first row, or after the last row — attempts to read from the cursor variable will result in error Cursor cursor_name is not positioned in a valid record
For checking whether all the rows of the result set have been fetched, the context variable ROW_COUNT
returns the number of rows fetched by the statement. If a record was fetched, then ROW_COUNT
is one (1
), otherwise zero (0
).
7.7.19.1 FETCH
Examples
Using the
FETCH
statement:CREATE OR ALTER PROCEDURE GET_RELATIONS_NAMES
RETURNS (RNAME CHAR(63))
AS
DECLARE C CURSOR FOR (
SELECT RDB$RELATION_NAME
FROM RDB$RELATIONS);
BEGIN
OPEN C;
WHILE (1 = 1) DO
BEGIN
FETCH C INTO RNAME;
IF (ROW_COUNT = 0) THEN
LEAVE;
SUSPEND;
END
CLOSE C;
END
Using the
FETCH
statement with nested cursors:EXECUTE BLOCK
RETURNS (SCRIPT BLOB SUB_TYPE TEXT)
AS
DECLARE VARIABLE FIELDS VARCHAR (8191);
DECLARE VARIABLE FIELD_NAME TYPE OF RDB$FIELD_NAME;
DECLARE VARIABLE RELATION RDB$RELATION_NAME;
DECLARE VARIABLE SRC TYPE OF COLUMN RDB$RELATIONS.RDB$VIEW_SOURCE;
-- Named cursor declaration
DECLARE VARIABLE CUR_R CURSOR FOR (
SELECT
RDB$RELATION_NAME,
RDB$VIEW_SOURCE
FROM RDB$RELATIONS
WHERE RDB$VIEW_SOURCE IS NOT NULL);
-- Declaring a named cursor in which
-- a local variable is used
DECLARE CUR_F CURSOR FOR (
SELECT RDB$FIELD_NAME
FROM RDB$RELATION_FIELDS
WHERE
-- It is important that the variable must be declared earlier
RDB$RELATION_NAME =: RELATION);
BEGIN
OPEN CUR_R;
WHILE (1 = 1) DO
BEGIN
FETCH CUR_R INTO RELATION, SRC;
IF (ROW_COUNT = 0) THEN
LEAVE;
FIELDS = NULL;
-- Cursor CUR_F will use the value
-- the RELATION variable initialized above
OPEN CUR_F;
WHILE (1 = 1) DO
BEGIN
FETCH CUR_F INTO FIELD_NAME;
IF (ROW_COUNT = 0) THEN
LEAVE;
IF (FIELDS IS NULL) THEN
FIELDS = TRIM (FIELD_NAME);
ELSE
FIELDS = FIELDS || ',' || TRIM(FIELD_NAME);
END
CLOSE CUR_F;
SCRIPT = 'CREATE VIEW' || RELATION;
IF (FIELDS IS NOT NULL) THEN
SCRIPT = SCRIPT || '(' || FIELDS || ')' ;
SCRIPT = SCRIPT || 'AS' || ASCII_CHAR (13);
SCRIPT = SCRIPT || SRC;
SUSPEND;
END
CLOSE CUR_R;
EN
An example of using the
FETCH
statement with a scrollable cursor
EXECUTE BLOCK
RETURNS (N INT, RNAME CHAR (63))
AS
DECLARE C SCROLL CURSOR FOR (
SELECT
ROW_NUMBER() OVER (ORDER BY RDB$RELATION_NAME) AS N,
RDB$RELATION_NAME
FROM RDB$RELATIONS
ORDER BY RDB$RELATION_NAME);
BEGIN
OPEN C;
-- move to the first record (N = 1)
FETCH FIRST FROM C;
RNAME = C.RDB$RELATION_NAME;
N = C.N;
SUSPEND;
-- move 1 record forward (N = 2)
FETCH NEXT FROM C;
RNAME = C.RDB$RELATION_NAME;
N = C.N;
SUSPEND;
-- move to the fifth record (N = 5)
FETCH ABSOLUTE 5 FROM C;
RNAME = C.RDB$RELATION_NAME;
N = C.N;
SUSPEND;
-- move 1 record backward (N = 4)
FETCH PRIOR FROM C;
RNAME = C.RDB$RELATION_NAME;
N = C.N;
SUSPEND;
-- move 3 records forward (N = 7)
FETCH RELATIVE 3 FROM C;
RNAME = C.RDB$RELATION_NAME;
N = C.N;
SUSPEND;
-- move back 5 records (N = 2)
FETCH RELATIVE -5 FROM C;
RNAME = C.RDB$RELATION_NAME;
N = C.N;
SUSPEND;
-- move to the first record (N = 1)
FETCH FIRST FROM C;
RNAME = C.RDB$RELATION_NAME;
N = C.N;
SUSPEND;
-- move to the last entry
FETCH LAST FROM C;
RNAME = C.RDB$RELATION_NAME;
N = C.N;
SUSPEND;
CLOSE C;
END
See alsoSection 7.7.4, DECLARE .. CURSOR, Section 7.7.18, OPEN, Section 7.7.20, CLOSE
7.7.20 CLOSE
Used forClosing a declared cursor
Available inPSQL
Syntax
CLOSE cursor_name;
Table 7.7.20.1 CLOSE
Statement Parameter
Argument | Description |
---|---|
cursor_name | Cursor name. A cursor with this name must be previously declared with a |
A CLOSE
statement closes an open cursor. Any cursors that are still open will be automatically closed after the module code completes execution. Only a cursor that was declared with Section 7.7.4, DECLARE .. CURSOR can be closed with a CLOSE
statement.
7.7.20.1 CLOSE
Examples
See Section 7.7.19.1, FETCH Examples
See alsoSection 7.7.4, DECLARE .. CURSOR, Section 7.7.18, OPEN, Section 7.7.19, FETCH
7.7.21 IN AUTONOMOUS TRANSACTION
Used forExecuting a statement or a block of statements in an autonomous transaction
Available inPSQL
Syntax
IN AUTONOMOUS TRANSACTION DO <compound_statement>
Table 7.7.21.1 IN AUTONOMOUS TRANSACTION
Statement Parameter
Argument | Description |
---|---|
compound_statement | A single statement, or a block of statements |
The IN AUTONOMOUS TRANSACTION
statement enables execution of a statement or a block of statements in an autonomous transaction. Code running in an autonomous transaction will be committed right after its successful execution, regardless of the status of its parent transaction. This can be used when certain operations must not be rolled back, even if an error occurs in the parent transaction.
An autonomous transaction has the same isolation level as its parent transaction. Any exception that is thrown in the block of the autonomous transaction code will result in the autonomous transaction being rolled back and all changes made will be undone. If the code executes successfully, the autonomous transaction will be committed.
7.7.21.1 IN AUTONOMOUS TRANSACTION
Examples
Using an autonomous transaction in a trigger for the database ON CONNECT
event, in order to log all connection attempts, including those that failed:
CREATE TRIGGER TR_CONNECT ON CONNECT
AS
BEGIN
-- Logging all attempts to connect to the database
IN AUTONOMOUS TRANSACTION DO
INSERT INTO LOG(MSG)
VALUES ('USER ' || CURRENT_USER || ' CONNECTS.');
IF (EXISTS(SELECT *
FROM BLOCKED_USERS
WHERE USERNAME = CURRENT_USER)) THEN
BEGIN
-- Logging that the attempt to connect
-- to the database failed and sending
-- a message about the event
IN AUTONOMOUS TRANSACTION DO
BEGIN
INSERT INTO LOG(MSG)
VALUES ('USER ' || CURRENT_USER || ' REFUSED.');
POST_EVENT 'CONNECTION ATTEMPT BY BLOCKED USER!';
END
-- now calling an exception
EXCEPTION EX_BADUSER;
END
END
See alsoTransaction Control
7.7.22 POST_EVENT
Used forNotifying listening clients about database events in a module
Available inPSQL
Syntax
POST_EVENT event_name;
Table 7.7.22.1 POST_EVENT
Statement Parameter
Argument | Description |
---|---|
event_name | Event name (message) limited to 127 bytes |
The POST_EVENT
statement notifies the event manager about the event, which saves it to an event table. When the transaction is committed, the event manager notifies applications that are signalling their interest in the event.
The event name can be some sort of code, or a short message: the choice is open as it is just a string up to 127 bytes.
The content of the string can be a string literal, a variable or any valid SQL expression that resolves to a string.
7.7.22.1 POST_EVENT
Examples
Notifying the listening applications about inserting a record into the SALES
table:
CREATE TRIGGER POST_NEW_ORDER FOR SALES
ACTIVE AFTER INSERT POSITION 0
AS
BEGIN
POST_EVENT 'new_order';
END
7.7.23 RETURN
Used forReturn a value from a stored function
Available inPSQL
Syntax
RETURN value;
Table 7.7.23.1 RETURN
Statement Parameter
Argument | Description |
---|---|
value | Expression with the value to return; Can be any expression type-compatible with the return type of the function |
The RETURN
statement ends the execution of a function and returns the value of the expression value.
RETURN
can only be used in PSQL functions (stored and local functions).