• The Four Hundred
  • Subscribe
  • Media Kit
  • Contributors
  • About Us
  • Contact
Menu
  • The Four Hundred
  • Subscribe
  • Media Kit
  • Contributors
  • About Us
  • Contact
  • Case-Sensitive SQL Identifiers

    December 1, 2010 Hey, Ted

    Like most people who use SQL, I have never bothered worrying about which case a field name is written in. Case never seemed to matter. However, while performing a data fix, I discovered an instance where it does. (Fortunately, I was using test data!)

    I had a number of files from which records were to be deleted. The key values of the records to be deleted were held in a spreadsheet. There were three fields, one of them called VERSION, in the files I was deleting from.

    I tried to create a table to store the contents of the spreadsheet, and named the fields in the same way.

    create table getridof
    (key1 char(4), key2 char(12), version dec (3,0))
    

    I received a message saying that VERSION was a reserved word and needed to be delimited, so I put quotes around the name, without even thinking about the fact I had “version” in lower case.

    I performed my DELETEs inside an SQL RPG program.

    DELETE FROM FILE1
     WHERE KEY1 || KEY 2 || DIGITS("VERSION") IN 
           (SELECT KEY1 || KEY2 || DIGITS("VERSION")
              FROM GETRIDOF)
    

    That should work fine, shouldn’t it? No, it doesn’t, because the delimited field on my GETRIDOF file was not called “VERSION”, but “version”, so it actually used the value of VERSION in FILE1! So therefore, any matches between just the first two fields resulted in a delete, instead of matching all three keys. If, however, I had used “version” all would have worked fine!

    It now seems obvious, but I thought it was worth reporting to you as something to warn other readers about.

    –Mike

    You have run into the two types of SQL identifiers, Mike. In IBM literature, they are known as ordinary and delimited identifiers. In other literature, you may see them referred to as unquoted and quoted identifiers. You may read about identifiers in the IBM i Infocenter.

    An ordinary identifier consists of a letter followed by letters or digits. These are the identifiers most of us typically use. Delimited identifiers begin and end with double quotation marks and allow a more liberal character set. You may use both types of identifiers in column, table, index and view names.

    Here’s an example. The table name is delimited. Notice the apostrophe and space in the table name. The table has three ordinary columns and three delimited columns.

    create table qtemp/"Ted's Data"
      (alphafield   char(2),
       numericfield dec(3,0),
       account      char(1),
       "Account"    char(1),
       "account"    char(1),
       "/7$%"       char(1))
    
    insert into qtemp/"Ted's Data"
     values ('A', 1, 'B', 'C', 'D', 'E')
    
    select * from "Ted's Data"
    where "/7$%" = 'E'  
    

    The system creates a physical file name “Ted_0001” (with the quotation marks) in library QTEMP, with the following fields.

    • ALPHAFIELD
    • NUMER00001
    • ACCOUNT
    • ACCOU00001
    • ACCOU00002
    • Q7$__00001

    You may use quoted versions of unquoted columns, but they must be in uppercase. The following are identical, and retrieve the value of the INIT column from the QCUSTCDT physical file.

    select INIT   from qiws/qcustcdt
    select Init   from qiws/qcustcdt
    select init   from qiws/qcustcdt
    select "INIT" from qiws/qcustcdt
    

    You may also use quoted names in native interfaces, such as Create Physical File (CRTPF), but I don’t recommend it.

    One last point. I was not able to recreate Mike’s error.

    create table qtemp/mydata
    (key1 char(4), key2 char(12), version dec(3,0))
    
    select * from mydata
    where version = 77
    
    select * from mydata
    where "VERSION" = 77
    

    The V5R3 and V5R4 systems I tested with allowed the word version without quotation marks in the CREATE TABLE statement. Running Display File Field Descriptions (DSPFFD) showed the field named VERSION, without the quotations. However, the field list shown when I prompted a SELECT within embedded SQL showed a quoted “VERSION”.

    Thanks for bringing this to our attention, Mike.

    –Ted



                         Post this story to del.icio.us
                   Post this story to Digg
        Post this story to Slashdot

    Share this:

    • Reddit
    • Facebook
    • LinkedIn
    • Twitter
    • Email

    Tags:

    Sponsored by
    Raz-Lee Security

    Start your Road to Zero Trust!

    Firewall Network security, controlling Exit Points, Open DB’s and SSH. Rule Wizards and graphical BI.

    Request Demo

    Share this:

    • Reddit
    • Facebook
    • LinkedIn
    • Twitter
    • Email

    Sponsored Links

    VAULT400:  Which is right for you? Online back-up, DR, HA Webinar. Dec. 16, Jan. 20
    LANSA:  FREE Webinar. "Think Beyond Modernization." Dec 1, Dec 16
    PowerTech:  FREE Webinar! Configuring Real-Time Security Event Notification. Dec. 8

    IT Jungle Store Top Book Picks

    BACK IN STOCK: Easy Steps to Internet Programming for System i: List Price, $49.95

    The iSeries Express Web Implementer's Guide: List Price, $49.95
    The iSeries Pocket Database Guide: List Price, $59
    The iSeries Pocket SQL Guide: List Price, $59
    The iSeries Pocket WebFacing Primer: List Price, $39
    Migrating to WebSphere Express for iSeries: List Price, $49
    Getting Started with WebSphere Express for iSeries: List Price, $49
    The All-Everything Operating System: List Price, $35
    The Best Joomla! Tutorial Ever!: List Price, $19.95

    Companies Take a Step Back in DR Readiness, Symantec Report Finds Candescent Buys Quadrant Software as IntelliChief Spins Out

    Leave a Reply Cancel reply

Volume 10, Number 36 -- December 1, 2010
THIS ISSUE SPONSORED BY:

SEQUEL Software
ProData Computer Services
WorksRight Software

Table of Contents

  • The Top 10 IBM i Security Exposures, Part 1
  • Case-Sensitive SQL Identifiers
  • Admin Alert: Prototype Instructions for Running TCP/IP in i5/OS Restricted State
  • Large Subprocedure Return Values: V7 Brings Relief
  • Find Hidden IFS Files
  • Why Did Passphrase Activation Take Out My ODBC Connection?

Content archive

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

Recent Posts

  • Liam Allan Shares What’s Coming Next With Code For IBM i
  • From Stable To Scalable: Visual LANSA 16 Powers IBM i Growth – Launching July 8
  • VS Code Will Be The Heart Of The Modern IBM i Platform
  • The AS/400: A 37-Year-Old Dog That Loves To Learn New Tricks
  • IBM i PTF Guide, Volume 27, Number 25
  • Meet The Next Gen Of IBMers Helping To Build IBM i
  • Looks Like IBM Is Building A Linux-Like PASE For IBM i After All
  • Will Independent IBM i Clouds Survive PowerVS?
  • Now, IBM Is Jacking Up Hardware Maintenance Prices
  • IBM i PTF Guide, Volume 27, Number 24

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