FirebirdSQL logo

Examples of MERGE

  1. 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);
  2. 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);
  3. 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);
  4. 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
  5. 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

Syntax
EXECUTE PROCEDURE procname
   [{ <inparam-list | ( <inparam-list> ) }]
   [RETURNING_VALUES { <outvar-list> | ( <outvar-list ) }]

<inparam-list> ::=
  <inparam> [, <inparam> ...]

<outvar-list> ::=
  <outvar> [, <outvar> ...]

<outvar> ::= [:]varname
Table 1. Arguments for the EXECUTE PROCEDURE Statement Parameters
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.

docnext count = 5

“Executable” Stored 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
  • In PSQL and DSQL, input parameters may be any expression that resolves to the expected type.

  • Although parentheses are not required after the name of the stored procedure to enclose the input parameters, their use is recommended for the sake of readability.

  • Where output parameters have been defined in a procedure, the RETURNING_VALUES clause can be used in PSQL to retrieve them into a list of previously declared variables that conforms in sequence, data type and number with the defined output parameters.

  • The list of RETURNING_VALUES may be optionally enclosed in parentheses and their use is recommended.

  • When DSQL applications call EXECUTE PROCEDURE using the Firebird API or some form of wrapper for it, a buffer is prepared to receive the output row and the RETURNING_VALUES clause is not used.

Examples of EXECUTE PROCEDURE

  1. In PSQL, with optional colons and without optional parentheses:

    EXECUTE PROCEDURE MakeFullName
      :FirstName, :MiddleName, :LastName
      RETURNING_VALUES :FullName;
  2. 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), RETURNING_VALUES is not used.Any output values are captured by the application and displayed automatically.

  3. 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

Available in

DSQL

Syntax
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 !!
Table 1. Arguments for the EXECUTE BLOCK Statement Parameters
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.

Examples

  1. 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
  2. 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.

  3. 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.

Input and output parameters

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.

PSQL Links

For more information about writing PSQL, consult Chapter Procedural SQL (PSQL) Statements.

Statement Terminators

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.