... |
{code} |
The criteria may be any valid boolean expression or an IS DISTINCT FROM predicate. IS DISTINCT FROM uses the syntax: {code:SQL} rowVal IS [NOT] DISTINCT FROM rowValOther {code} Where rowVal and rowValOther are references to row value group. This would typically be used in instead of update triggers on views to quickly determine if the row values are changing: {code:title=Example IS DISTINCT FROM If Statement} IF ( "new" IS DISTINCT FROM "old") BEGIN ...statement... END {code} IS DISTINCT FROM considers null values equivalent and never produces an UNKNOWN value. |
{tip:title=Tip}NULL values should be considered in the criteria of an IF statement. IS NULL criteria can be used to detect the presence of a NULL value. {tip} |
... |
Teiid supports a procedural language for defining Virtual Procedures. These are similar to stored procedures in relational database management systems. You can use this language to define the transformation logic for decomposing INSERT, UPDATE, and DELETE commands against views; these are known as Update Procedures.
A command statement executes a DML Command, such as SELECT, INSERT, UPDATE, DELETE, EXECUTE, or a DDL statement, dynamic SQL, etc.
Usage:
command [(WITH|WITHOUT) RETURN];
SELECT * FROM MySchema.MyTable WHERE ColA > 100 WITHOUT RETURN; INSERT INTO MySchema.MyTable (ColA,ColB) VALUES (50, 'hi');
Syntax Rules:
Dynamic SQL allows for the execution of an arbitrary SQL command in a virtual procedure. Dynamic SQL is useful in situations where the exact command form is not known prior to execution.
Usage:
EXECUTE IMMEDIATE <expression> AS <variable> <type> [, <variable> <type>]* [INTO <variable>] [USING <variable>=<expression> [,<variable>=<expression>]*] [UPDATE <literal>]
Syntax Rules:
... /* Typically complex criteria would be formed based upon inputs to the procedure. In this simple example the criteria is references the using clause to isolate the SQL string from referencing a value from the procedure directly */ DECLARE string criteria = 'Customer.Accounts.Last = DVARS.LastName'; /* Now we create the desired SQL string */ DECLARE string sql_string = 'SELECT ID, First || '' '' || Last AS Name, Birthdate FROM Customer.Accounts WHERE ' || criteria; /* The execution of the SQL string will create the #temp table with the columns (ID, Name, Birthdate). Note that we also have the USING clause to bind a value to LastName, which is referenced in the criteria. */ EXECUTE IMMEDIATE sql_string AS ID integer, Name string, Birthdate date INTO #temp USING LastName='some name'; /* The temp table can now be used with the values from the Dynamic SQL */ loop on (SELCT ID from #temp) as myCursor ...
Here is an example showing a more complex approach to building criteria for the dynamic SQL string. In short, the virtual procedure AccountAccess.GetAccounts has inputs ID, LastName, and bday. If a value is specified for ID it will be the only value used in the dynamic SQL criteria. Otherwise if a value is specified for LastName the procedure will detect if the value is a search string. If bday is specified in addition to LastName, it will be used to form compound criteria with LastName.
... DECLARE string crit = null; IF (AccountAccess.GetAccounts.ID IS NOT NULL) crit = '(Customer.Accounts.ID = DVARS.ID)'; ELSE IF (AccountAccess.GetAccounts.LastName IS NOT NULL) BEGIN IF (AccountAccess.GetAccounts.LastName == '%') ERROR "Last name cannot be %"; ELSE IF (LOCATE('%', AccountAccess.GetAccounts.LastName) < 0) crit = '(Customer.Accounts.Last = DVARS.LastName)'; ELSE crit = '(Customer.Accounts.Last LIKE DVARS.LastName)'; IF (AccountAccess.GetAccounts.bday IS NOT NULL) crit = '(' || crit || ' and (Customer.Accounts.Birthdate = DVARS.BirthDay))'; END ELSE ERROR "ID or LastName must be specified."; EXECUTE IMMEDIATE 'SELECT ID, First || '' '' || Last AS Name, Birthdate FROM Customer.Accounts WHERE ' || crit USING ID=AccountAccess.GetAccounts.ID, LastName=AccountAccess.GetAccounts.LastName, BirthDay=AccountAccess.GetAccounts.Bday; ...
Known Limitations and Work-Arounds
The use of dynamic SQL command results in an assignment statement requires the use of a temp table.
EXECUTE IMMEDIATE <expression> AS x string INTO #temp; DECLARE string VARIABLES.RESULT = (SELECT x FROM #temp);
The construction of appropriate criteria will be cumbersome if parts of the criteria are not present. For example if "criteria" were already NULL, then the following example results in "criteria" remaining NULL.
... criteria = '(' || criteria || ' and (Customer.Accounts.Birthdate = DVARS.BirthDay))';
The preferred approach is for the user to ensure the criteria is not NULL prior its usage. If this is not possible, a good approach is to specify a default as shown in the following example.
... criteria = '(' || nvl(criteria, '(1 = 1)') || ' and (Customer.Accounts.Birthdate = DVARS.BirthDay))';
If the dynamic SQL is an UPDATE, DELETE, or INSERT command, the rowcount of the statement can be obtained from the rowcount variable.
/* Execute an update */ EXECUTE IMMEDIATE <expression>;
A declaration statement declares a variable and its type. After you declare a variable, you can use it in that block within the procedure and any sub-blocks. A variable is initialized to null by default, but can also be assigned the value of an expression as part of the declaration statement.
Usage:
DECLARE <type> [VARIABLES.]<name> [= <expression>];
declare integer x; declare string VARIABLES.myvar = 'value';
Syntax Rules:
An assignment statement assigns a value to a variable by either evaluating an expression.
Usage:
<variable reference> = <expression>;
Example Syntax
myString = 'Thank you'; VARIABLES.x = (SELECT Column1 FROM MySchema.MyTable);
VARIABLES.ROWCOUNT integer variable will contain the numbers of rows affected by the last insert/update/delete command statement executed. Inserts that are processed by dynamic sql with an into clause will also update the ROWCOUNT.
Usage:
... UPDATE FOO SET X = 1 WHERE Y = 2; DECLARE INTEGER UPDATED = VARIABLES.ROWCOUNT; ...
Non-update command statements (WITH or WITHOUT RETURN) will reset the ROWCOUNT to 0.
![]() | To ensure you are getting the appropriate ROWCOUNT value, save the ROWCOUNT to a variable immediately after the command statement. |
A compound statement or block logically groups a series of statements. Temporary tables and variables created in a compound statement are local only to that block are destroyed when exiting the block.
Usage:
[label :] BEGIN [[NOT] ATOMIC] statement* [EXCEPTION ex statement* ] END
![]() | When a block is expected by a IF, LOOP, WHILE, etc. a single statement is also accepted by the parser. Even though the block BEGIN/END are not expected, the statement will execute as if wrapped in a BEGIN/END pair. |
Syntax Rules
If the EXCEPTION clause is used with in a compound statement, any processing exception emitted from statements will be caught with the flow of execution transferring to EXCEPTION statements. Any block level transaction started by this block will commit if the exception handler successfully completes. If another exception or the original exception is emitted from the exception handler the transaction will rollback. Any temporary tables or variables specific to the BLOCK will not be available to the exception handler statements.
![]() | Only processing exceptions, which are typically caused by errors originating at the sources or with function execution, are caught. A low-level internal Teiid error or Java RuntimeException will not be caught. |
To aid in the processing of a caught exception the EXCEPTION clause specifies a group name that exposes the significant fields of the exception. The exception group will contain:
Variable | Type | Description |
---|---|---|
STATE | string | The SQL State |
ERRORCODE | integer | The error or vendor code. In the case of Teiid internal exceptions this will be the integer suffix of the TEIIDxxxx code |
TEIIDCODE | string | The full Teiid event code. Typically TEIIDxxxx. |
EXCEPTION | object | The exception being caught, will be an instance of TeiidSQLException |
CHAIN | object | The chained exception or cause of the current exception |
![]() | Teiid does not yet fully comply with the ANSI SQL specification on SQL State usage. For Teiid errors without an underlying SQLException cause, it is best to use the Teiid code. |
The exception group name may not be the same as any higher level exception group or loop cursor name.
BEGIN DECLARE EXCEPTION e = SQLEXCEPTION 'this is bad' SQLSTATE 'xxxxx'; RAISE variables.e; EXCEPTION e IF (e.state = 'xxxxx') //in this trivial example, we'll always hit this branch and just log the exception RAISE SQLWARNING e.exception; ELSE RAISE e.exception; END
An IF statement evaluates a condition and executes either one of two statements depending on the result. You can nest IF statements to create complex branching logic. A dependent ELSE statement will execute its statement only if the IF statement evaluates to false.
Usage:
IF (criteria) block [ELSE block] END
IF ( var1 = 'North America') BEGIN ...statement... END ELSE BEGIN ...statement... END
The criteria may be any valid boolean expression or an IS DISTINCT FROM predicate. IS DISTINCT FROM uses the syntax:
rowVal IS [NOT] DISTINCT FROM rowValOther
Where rowVal and rowValOther are references to row value group. This would typically be used in instead of update triggers on views to quickly determine if the row values are changing:
IF ( "new" IS DISTINCT FROM "old") BEGIN ...statement... END
IS DISTINCT FROM considers null values equivalent and never produces an UNKNOWN value.
![]() | Tip NULL values should be considered in the criteria of an IF statement. IS NULL criteria can be used to detect the presence of a NULL value. |
A LOOP statement is an iterative control construct that is used to cursor through a result set.
Usage:
[label :] LOOP ON <select statement> AS <cursorname> statement
Syntax Rules
A WHILE statement is an iterative control construct that is used to execute a statement repeatedly whenever a specified condition is met.
Usage:
[label :] WHILE <criteria> statement
Syntax Rules
A CONTINUE statement is used inside a LOOP or WHILE construct to continue with the next loop by skipping over the rest of the statements in the loop. It must be used inside a LOOP or WHILE statement.
Usage:
CONTINUE [label];
Syntax Rules
A BREAK statement is used inside a LOOP or WHILE construct to break from the loop. It must be used inside a LOOP or WHILE statement.
Usage:
BREAK [label];
Syntax Rules
A LEAVE statement is used inside a compound, LOOP, or WHILE construct to leave to the specified level.
Usage:
LEAVE label;
Syntax Rules
A Return statement gracefully exits the procedure and optionally returns a value.
Usage:
RETURN [expression];
Syntax Rules
An ERROR statement declares that the procedure has entered an error state and should abort. This statement will also roll back the current transaction, if one exists. Any valid expression can be specified after the ERROR keyword.
Usage:
ERROR message;
ERROR 'Invalid input value: ' || nvl(Acct.GetBalance.AcctID, 'null');
An ERROR statement is equivalent to:
RAISE SQLEXCEPTION message;
A RAISE statement is used to raise an exception or warning. When raising an exception, this statement will also roll back the current transaction, if one exists.
Usage:
RAISE [SQLWARNING] exception;
Syntax Rules
RAISE SQLWARNING SQLEXCEPTION 'invalid' SQLSTATE '05000';
An exception expression creates an exception that can be raised or used as a warning.
Usage:
SQLEXCEPTION message [SQLSTATE state [, code]] CHAIN exception
Syntax Rules