INTELLIGENT WORK FORUMS
FOR COMPUTER PROFESSIONALS

Log In

Come Join Us!

Are you a
Computer / IT professional?
Join Tek-Tips Forums!
  • Talk With Other Members
  • Be Notified Of Responses
    To Your Posts
  • Keyword Search
  • One-Click Access To Your
    Favorite Forums
  • Automated Signatures
    On Your Posts
  • Best Of All, It's Free!

*Tek-Tips's functionality depends on members receiving e-mail. By joining you are opting in to receive e-mail.

Posting Guidelines

Promoting, selling, recruiting, coursework and thesis posting is forbidden.

Jobs

SQL Creation of Instream Sequence Numbers

SQL Creation of Instream Sequence Numbers

(OP)
I’m not sure how best to describe what I’m looking for so apologies in advance if I’m not clear. I’m trying to come up with a solution to create as instream sequence number set as a source for comparison.

We have a table where we store a four-digit number that has been assigned to a customer. The number four-digit numeric is in character format (e.g. 0001, 0002, 0003, ... 9998, 9999). Therefore, there should be 9,999 numbers to be assigned.

We only store the numbers that have been assigned. Therefore, if I want to see the numbers that have are not assigned, I have to create a temporary table with all 9,999 values and apply a NOT IN predicate.

I’m trying to build an automated process that doesn’t require any manual intervention. Our installation purges tables in the tablespace we use after 30 days, so keeping the temporary table around isn’t an option for me.

I was trying to come up with a way to do something like:

CODE

SELECT A."A NUMBER"
        FROM (
              SELECT "A NUMBER"
                FROM SYSIBM.SYSDUMMY1
             ) AS A
       WHERE NOT IN (
                     SELECT CLIENT_NUMBER
                        FROM CLIENT_TABLE
                    ); 


... but I don’t know how to get the instream table to increase sequencing by one, 9998 times.

Does anyone have any ideas of how to do this or a better approach? Thank you in advance.

My shop uses DB2 z/OS version 10 release 1 for and QMF version 10 release 1.

RE: SQL Creation of Instream Sequence Numbers

this may work - can't test it as I don't have at the moment a DB2 db available

WITH Nbrs_3( n ) AS ( SELECT 1 FROM SYSIBM.SYSDUMMY1 UNION SELECT 0 FROM SYSIBM.SYSDUMMY1 ),
Nbrs_2( n ) AS ( SELECT 1 FROM Nbrs_3 n1 CROSS JOIN Nbrs_3 n2 ),
Nbrs_1( n ) AS ( SELECT 1 FROM Nbrs_2 n1 CROSS JOIN Nbrs_2 n2 ),
Nbrs_0( n ) AS ( SELECT 1 FROM Nbrs_1 n1 CROSS JOIN Nbrs_1 n2 ),
Nbrs ( n ) AS ( SELECT 1 FROM Nbrs_0 n1 CROSS JOIN Nbrs_0 n2 )
SELECT n
FROM ( SELECT ROW_NUMBER() OVER (ORDER BY n)
FROM Nbrs ) D ( n )
WHERE n <= 9999;

Regards

Frederico Fonseca
SysSoft Integrated Ltd
www.syssoft-int.com

FAQ219-2884: How Do I Get Great Answers To my Tek-Tips Questions?
FAQ181-2886: How can I maximize my chances of getting an answer?

RE: SQL Creation of Instream Sequence Numbers

(OP)
Thanks Frederico, that worked perfectly! Now I'll have to try and figure out what how that works ... I've never used these functions before. Thanks a bunch!

RE: SQL Creation of Instream Sequence Numbers

(OP)
Hi Frederico ...

Can I ask you a follow up question.

I just learned that the business assigned a value of "0000". How would I change your query to include a value of 0000?

Thanks again ...

Kent

RE: SQL Creation of Instream Sequence Numbers

CODE

WITH Nbrs_3( n ) AS ( SELECT 1 FROM SYSIBM.SYSDUMMY1 UNION SELECT 0 FROM SYSIBM.SYSDUMMY1 ),
Nbrs_2( n ) AS ( SELECT 1 FROM Nbrs_3 n1 CROSS JOIN Nbrs_3 n2 ),
Nbrs_1( n ) AS ( SELECT 1 FROM Nbrs_2 n1 CROSS JOIN Nbrs_2 n2 ),
Nbrs_0( n ) AS ( SELECT 1 FROM Nbrs_1 n1 CROSS JOIN Nbrs_1 n2 ),
Nbrs ( n ) AS ( SELECT 1 FROM Nbrs_0 n1 CROSS JOIN Nbrs_0 n2 )
SELECT n
FROM ( SELECT ROW_NUMBER() OVER (ORDER BY n) - 1
FROM Nbrs ) D ( n )
WHERE n <= 9999; 

Regards

Frederico Fonseca
SysSoft Integrated Ltd
www.syssoft-int.com

FAQ219-2884: How Do I Get Great Answers To my Tek-Tips Questions?
FAQ181-2886: How can I maximize my chances of getting an answer?

RE: SQL Creation of Instream Sequence Numbers

(OP)
Thank you!

Red Flag This Post

Please let us know here why this post is inappropriate. Reasons such as off-topic, duplicates, flames, illegal, vulgar, or students posting their homework.

Red Flag Submitted

Thank you for helping keep Tek-Tips Forums free from inappropriate posts.
The Tek-Tips staff will check this out and take appropriate action.

Reply To This Thread

Posting in the Tek-Tips forums is a member-only feature.

Click Here to join Tek-Tips and talk with other members!

Resources

Close Box

Join Tek-Tips® Today!

Join your peers on the Internet's largest technical computer professional community.
It's easy to join and it's free.

Here's Why Members Love Tek-Tips Forums:

Register now while it's still free!

Already a member? Close this window and log in.

Join Us             Close