The ORDER BY
Clause
The ORDER BY
can be used to influence the order in which rows are evaluated.The primary use case is when combined with RETURNING
, to influence the order rows are returned.
Examples of SELECT queries with different types of column lists
ORDER BY
ClauseThe ORDER BY
can be used to influence the order in which rows are evaluated.The primary use case is when combined with RETURNING
, to influence the order rows are returned.
RETURNING
ClauseA MERGE
statement can contain a RETURNING
clause to return rows added, modified or removed.The merge is executed to completion before rows are returned.The RETURNING
clause can contain any columns from the target table (or updatable view), as well as other columns (eg from the source) and expressions.
The user executing the statement needs to have SELECT
privileges on the columns specified in the RETURNING
clause.
In PSQL, If a RETURNING
clause is present and more than one matching record is found, an error “multiple rows in singleton select” is raised.This behaviour may change in a future Firebird version.
The optional INTO
sub-clause is only valid in PSQL.
Column names can be qualified by the OLD
or NEW
prefix to define exactly what value to return: before or after modification. The returned values include the changes made by BEFORE
triggers.
The syntax of the returning_list is similar to the column list of a SELECT
clause.It is possible to reference all columns using *
, or table_name.*
, NEW.*
and/or OLD.*
.
For the UPDATE
or INSERT
action, unqualified column names, or those qualified by the target table name or alias will behave as if qualified by NEW
, while for the DELETE
action as if qualified by OLD
.
The following example modifies the previous example to affect one line, and adds a RETURNING
clause to return the old and new quantity of goods, and the difference between those values.
MERGE
with a RETURNING
clauseMERGE INTO PRODUCT_INVENTORY AS TARGET
USING (
SELECT
SL.ID_PRODUCT,
SUM(SL.QUANTITY)
FROM SALES_ORDER_LINE SL
JOIN SALES_ORDER S ON S.ID = SL.ID_SALES_ORDER
WHERE S.BYDATE = CURRENT_DATE
AND SL.ID_PRODUCT =: ID_PRODUCT
GROUP BY 1
) AS SRC (ID_PRODUCT, QUANTITY)
ON TARGET.ID_PRODUCT = SRC.ID_PRODUCT
WHEN MATCHED AND TARGET.QUANTITY - SRC.QUANTITY <= 0 THEN
DELETE
WHEN MATCHED THEN
UPDATE SET
TARGET.QUANTITY = TARGET.QUANTITY - SRC.QUANTITY,
TARGET.BYDATE = CURRENT_DATE
RETURNING OLD.QUANTITY, NEW.QUANTITY, SRC.QUANTITY
INTO : OLD_QUANTITY, :NEW_QUANTITY, :DIFF_QUANTITY
MERGE
Update books when present, or add new record if absent
MERGE INTO books b
USING purchases p
ON p.title = b.title and p.type = 'bk'
WHEN MATCHED THEN
UPDATE SET b.desc = b.desc || '; ' || p.desc
WHEN NOT MATCHED THEN
INSERT (title, desc, bought) values (p.title, p.desc, p.bought);
Using a derived table
MERGE INTO customers c
USING (SELECT * from customers_delta WHERE id > 10) cd
ON (c.id = cd.id)
WHEN MATCHED THEN
UPDATE SET name = cd.name
WHEN NOT MATCHED THEN
INSERT (id, name) values (cd.id, cd.name);
Together with a recursive CTE
MERGE INTO numbers
USING (
WITH RECURSIVE r(n) AS (
SELECT 1 FROM rdb$database
UNION ALL
SELECT n+1 FROM r WHERE n < 200
)
SELECT n FROM r
) t
ON numbers.num = t.n
WHEN NOT MATCHED THEN
INSERT(num) VALUES(t.n);
Using DELETE
clause
MERGE INTO SALARY_HISTORY
USING (
SELECT EMP_NO
FROM EMPLOYEE
WHERE DEPT_NO = 120) EMP
ON SALARY_HISTORY.EMP_NO = EMP.EMP_NO
WHEN MATCHED THEN DELETE
The following example updates the PRODUCT_INVENTORY
table daily based on orders processed in the SALES_ORDER_LINE
table.If the stock level of the product would drop to zero or lower, then the row for that product is removed from the PRODUCT_INVENTORY
table.
MERGE INTO PRODUCT_INVENTORY AS TARGET
USING (
SELECT
SL.ID_PRODUCT,
SUM (SL.QUANTITY)
FROM SALES_ORDER_LINE SL
JOIN SALES_ORDER S ON S.ID = SL.ID_SALES_ORDER
WHERE S.BYDATE = CURRENT_DATE
GROUP BY 1
) AS SRC (ID_PRODUCT, QUANTITY)
ON TARGET.ID_PRODUCT = SRC.ID_PRODUCT
WHEN MATCHED AND TARGET.QUANTITY - SRC.QUANTITY <= 0 THEN
DELETE
WHEN MATCHED THEN
UPDATE SET
TARGET.QUANTITY = TARGET.QUANTITY - SRC.QUANTITY,
TARGET.BYDATE = CURRENT_DATE
EXECUTE PROCEDURE
Executes a stored procedure
EXECUTE PROCEDURE procname [{ <inparam-list | ( <inparam-list> ) }] [RETURNING_VALUES { <outvar-list> | ( <outvar-list ) }] <inparam-list> ::= <inparam> [, <inparam> ...] <outvar-list> ::= <outvar> [, <outvar> ...] <outvar> ::= [:]varname
Argument | Description |
---|---|
procname |
Name of the stored procedure |
inparam |
An expression evaluating to the declared data type of an input parameter |
varname |
A PSQL variable to receive the return value |
Executes an executable stored procedure, taking a list of one or more input parameters, if they are defined for the procedure, and returning a one-row set of output values, if they are defined for the procedure.
The EXECUTE PROCEDURE
statement is most commonly used to invoke “executable” stored procedures to perform some data-modifying task at the server side — those that do not contain any SUSPEND
statements in their code.They can be designed to return a result set, consisting of only one row, which is usually passed, via a set of RETURNING_VALUES()
variables, to another stored procedure that calls it.Client interfaces usually have an API wrapper that can retrieve the output values into a single-row buffer when calling EXECUTE PROCEDURE
in DSQL.
Invoking “selectable” stored procedures is also possible with EXECUTE PROCEDURE
, but it returns only the first row of an output set which is almost surely designed to be multi-row.Selectable stored procedures are designed to be invoked by a SELECT
statement, producing output that behaves like a virtual table.
Note
|
|
EXECUTE PROCEDURE
In PSQL, with optional colons and without optional parentheses:
EXECUTE PROCEDURE MakeFullName
:FirstName, :MiddleName, :LastName
RETURNING_VALUES :FullName;
In Firebird’s command-line utility isql, with literal parameters and optional parentheses:
EXECUTE PROCEDURE MakeFullName ('J', 'Edgar', 'Hoover');
Note
|
In DSQL (e.g. in isql), |
A PSQL example with expression parameters and optional parentheses:
EXECUTE PROCEDURE MakeFullName
('Mr./Mrs. ' || FirstName, MiddleName, upper(LastName))
RETURNING_VALUES (FullName);
EXECUTE BLOCK
Creates an “anonymous” block of PSQL code in DSQL for immediate execution
DSQL
EXECUTE BLOCK [(<inparams>)] [RETURNS (<outparams>)] <psql-module-body> <inparams> ::= <param_decl> = ? [, <inparams> ] <outparams> ::= <param_decl> [, <outparams>] <param_decl> ::= paramname <domain_or_non_array_type> [NOT NULL] [COLLATE collation] <domain_or_non_array_type> ::= !! See Scalar Data Types Syntax !! <psql-module-body> ::= !! See Syntax of a Module Body !!
Argument | Description |
---|---|
param_decl |
Name and description of an input or output parameter |
paramname |
The name of an input or output parameter of the procedural block, up to 63 characters long.The name must be unique among input and output parameters and local variables in the block |
collation |
Collation |
Executes a block of PSQL code as if it were a stored procedure, optionally with input and output parameters and variable declarations.This allows the user to perform “on-the-fly” PSQL within a DSQL context.
This example injects the numbers 0 through 127 and their corresponding ASCII characters into the table ASCIITABLE
:
EXECUTE BLOCK
AS
declare i INT = 0;
BEGIN
WHILE (i < 128) DO
BEGIN
INSERT INTO AsciiTable VALUES (:i, ascii_char(:i));
i = i + 1;
END
END
The next example calculates the geometric mean of two numbers and returns it to the user:
EXECUTE BLOCK (x DOUBLE PRECISION = ?, y DOUBLE PRECISION = ?)
RETURNS (gmean DOUBLE PRECISION)
AS
BEGIN
gmean = SQRT(x*y);
SUSPEND;
END
Because this block has input parameters, it has to be prepared first.Then the parameters can be set and the block executed.It depends on the client software how this must be done and even if it is possible at all — see the notes below.
Our last example takes two integer values, smallest
and largest
.For all the numbers in the range smallest
…largest
, the block outputs the number itself, its square, its cube and its fourth power.
EXECUTE BLOCK (smallest INT = ?, largest INT = ?)
RETURNS (number INT, square BIGINT, cube BIGINT, fourth BIGINT)
AS
BEGIN
number = smallest;
WHILE (number <= largest) DO
BEGIN
square = number * number;
cube = number * square;
fourth = number * cube;
SUSPEND;
number = number + 1;
END
END
Again, it depends on the client software if and how you can set the parameter values.
Executing a block without input parameters should be possible with every Firebird client that allows the user to enter their own DSQL statements.If there are input parameters, things get trickier: these parameters must get their values after the statement is prepared, but before it is executed.This requires special provisions, which not every client application offers.(Firebird’s own isql, for one, doesn’t.)
The server only accepts question marks (“?
”) as placeholders for the input values, not “:a
”, “:MyParam
” etc., or literal values.Client software may support the “:xxx
” form though, and will preprocess it before sending it to the server.
If the block has output parameters, you must use SUSPEND
or nothing will be returned.
Output is always returned in the form of a result set, just as with a SELECT
statement.You can’t use RETURNING_VALUES
or execute the block INTO
some variables, even if there is only one result row.
For more information about writing PSQL, consult Chapter Procedural SQL (PSQL) Statements.
Some SQL statement editors — specifically the isql utility that comes with Firebird, and possibly some third-party editors — employ an internal convention that requires all statements to be terminated with a semicolon.This creates a conflict with PSQL syntax when coding in these environments.If you are unacquainted with this problem and its solution, please study the details in the PSQL chapter in the section entitled Switching the Terminator in isql.