Tek-Tips is the largest IT community on the Internet today!

Members share and learn making Tek-Tips Forums the best source of peer-reviewed technical information on the Internet!

  • Congratulations Mike Lewis on being selected by the Tek-Tips community for having the most helpful posts in the forums last week. Way to Go!

SQL Creation of Instream Sequence Numbers 1

Status
Not open for further replies.

ks01

MIS
Aug 11, 2002
110
0
0
US
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.
 
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

FAQ219-2884
FAQ181-2886
 
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!
 
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
 
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)[COLOR=#CC0000] - 1[/color]
FROM Nbrs ) D ( n )
WHERE n <= 9999;

Regards

Frederico Fonseca
SysSoft Integrated Ltd

FAQ219-2884
FAQ181-2886
 
Status
Not open for further replies.

Part and Inventory Search

Sponsor

Back
Top