A Brief Introduction To The SQL Procedures Language
September 27, 2016 Ted Holt
The SQL Procedures Language, or SQL PL, is a proprietary procedural language that IBM designed to work with the DB2 family of database management systems. I believe that it’s a good idea for anyone who works with DB2 to learn SQL PL. If you know RPG, CL, or COBOL, you’ll find it easy to learn. SQL PL is available for all the DB2s. Knowledge of SQL PL that you acquire by working with DB2 for i applies in large part to the mainframe and LUW (Linux-Unix-Windows) versions. You can use SQL PL to create stored procedures, functions, and triggers. You can also use it to build dynamic compound statements, which you can store in source physical file members and the IFS and run using the Run SQL Statements (RUNSQLSTM) command. So, what’s SQL PL like? It’s like RPG in some ways. For example: * It has data declarations. And it’s also not like RPG in some ways. For example: * It doesn’t have subroutines. The basic building block of SQL PL is the compound statement. Let me tell you a few things about compound statements. Then I’ll show you an example. A compound statement begins with the word BEGIN and ends with the word END. Between these two you can include declarations and procedural code. * If you wish, you may provide a label for a compound statement. The label is terminated by a colon and precedes BEGIN. That’s enough facts for now. Let’s see an example. create trigger ValidateOrder no cascade before insert on SalesOrderHeaders referencing new row as n for each row mode db2sql begin atomic declare v_Status dec(1); declare v_Parent dec(5); -- check the customer for credit hold select Status, parent into v_Status, v_Parent from Customers where AccountNumber = n.CustomerID; if v_Status <> 0 then signal sqlstate '85510' set Message_text = 'Customer is on credit hold'; end if; -- check the parent for credit hold select Status into v_Status from Customers where AccountNumber = v_Parent; if v_Status <> 0 then signal sqlstate '85511' set Message_text = 'Parent customer is on credit hold'; end if; end This purpose of this trigger is to prevent sales to customers who are on credit hold. The compound statement begins with BEGIN ATOMIC. This means that the entire compound statement is to be treated as a whole. If there were multiple database changes under commitment control, and one of them failed, all changes would be rolled back. In this case, a non-atomic statement would probably work just as well. This compound statement declares two variables to contain the STATUS and PARENT fields from the customer master table. I prefix variable names with V_ to distinguish them from database columns (fields). One feature of SQL PL that I like is that I can mix variables and column names as required. There’s no need to prefix variables with a colon, as RPG and COBOL require me to do. I didn’t come up with the idea of using the V_ prefix. That came from the book DB2 SQL Procedural Language for Linux, UNIX, and Windows, by Yip et al. The first SELECT checks the customer status. A non-zero status means that a customer is on credit hold. If the customer is not on credit hold, the second SELECT checks the parent company (if there is one) to see if the parent is on credit hold. The trigger indicates a credit hold status by sending an error to the caller. SQL state 85510 means that the customer is on credit hold. SQL state 85511 means that the parent company is on credit hold. The following shows the error I got when I tried to create an order for a customer using green-screen SQL. Diagnostic message SQL0723 SQL trigger VALIDATEORDER in MYLIB failed with SQLCODE -438 SQLSTATE 85510. An error has occurred in a triggered SQL statement in trigger VALIDATEORDER in schema MYLIB. The SQLCODE is -438, the SQLSTATE is 85510, and the message is Customer is on credit hold. That’s the brief introduction. The rest is details. I hope to say more about SQL PL in upcoming issues of Four Hundred Guru. By the way, if the word proprietary scares you, consider that Transact-SQL, also called T-SQL, (Microsoft and Sybase) and PL/SQL (Oracle) are also proprietary, and that doesn’t stop people from using them every day. Ted Holt welcomes your comments and questions. Email him through the IT Jungle Contacts page.
RELATED STORIES Dynamic Compound Statements In DB2 For i Book Excerpt: DB2 SQL Procedural Language for Linux, UNIX, and Windows
|
Gracias Ted. Un artículo muy interesante.