• The Four Hundred
  • Subscribe
  • Media Kit
  • Contributors
  • About Us
  • Contact
Menu
  • The Four Hundred
  • Subscribe
  • Media Kit
  • Contributors
  • About Us
  • Contact
  • 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.
    * It isn’t case-sensitive.
    * It has decision structures.
    * It has looping structures.
    * It has semicolons.

    And it’s also not like RPG in some ways. For example:

    * It doesn’t have subroutines.
    * It has strong messaging features. (Yes!)
    * It isn’t limited to one database platform.

    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.
    * You may also place the label, without the terminating colon, after the corresponding END. The label may be used to qualify within a block.
    * You may nest compound statements within the procedural section of a compound statement.
    * A compound statement may be ATOMIC (treated as a whole unit) or NOT ATOMIC (a series of independent statements).

    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

    DB2 SQL PL Guide

    Book Excerpt: DB2 SQL Procedural Language for Linux, UNIX, and Windows

     

    Share this:

    • Reddit
    • Facebook
    • LinkedIn
    • Twitter
    • Email

    Tags:

    Sponsored by
    Maxava

    Migrate IBM i with Confidence

    Tired of costly and risky migrations? Maxava Migrate Live minimizes disruption with seamless transitions. Upgrading to Power10 or cloud hosted system, Maxava has you covered!

    Learn More

    Share this:

    • Reddit
    • Facebook
    • LinkedIn
    • Twitter
    • Email

    Sponsored Links

    System i Developer:  RPG & DB2 Summit - October 4-6 2016 in Chicago. Register now! BCD:  Webinar: What's Possible with PHP on IBM i. Tues., Sept. 27 at 1pm ET. Sign up now! Manta Technologies Inc.:  The Leader in IBM i Education! Download catalog and take sample sessions!

    IBM Preaches Cognitive, Cloud, And IT Consumption PowerHA Implementations No Picnic; Help On The Way

    One thought on “A Brief Introduction To The SQL Procedures Language”

    • Nelson Carta says:
      January 4, 2023 at 11:16 am

      Gracias Ted. Un artículo muy interesante.

      Reply

    Leave a Reply Cancel reply

Volume 16, Number 21 -- September 27, 2016
THIS ISSUE SPONSORED BY:

WorksRight Software
T.L. Ashford
COMMON

Table of Contents

  • RPG Talks To Watson
  • A Brief Introduction To The SQL Procedures Language
  • How To Replace MOVE And MOVEL With Subprocedures

Content archive

  • The Four Hundred
  • Four Hundred Stuff
  • Four Hundred Guru

Recent Posts

  • Public Preview For Watson Code Assistant for i Available Soon
  • COMMON Youth Movement Continues at POWERUp 2025
  • IBM Preserves Memory Investments Across Power10 And Power11
  • Eradani Uses AI For New EDI And API Service
  • Picking Apart IBM’s $150 Billion In US Manufacturing And R&D
  • FAX/400 And CICS For i Are Dead. What Will IBM Kill Next?
  • Fresche Overhauls X-Analysis With Web UI, AI Smarts
  • Is It Time To Add The Rust Programming Language To IBM i?
  • Is IBM Going To Raise Prices On Power10 Expert Care?
  • IBM i PTF Guide, Volume 27, Number 20

Subscribe

To get news from IT Jungle sent to your inbox every week, subscribe to our newsletter.

Pages

  • About Us
  • Contact
  • Contributors
  • Four Hundred Monitor
  • IBM i PTF Guide
  • Media Kit
  • Subscribe

Search

Copyright © 2025 IT Jungle