Try whether the following SELECT statement will return what you expected
(assumed the table has 2 columns called OldCust and NewCust)
Create Table qtemp/MyTable
(OldCust Integer Not NULL default 0,
NewCust Integer Not NULL Default 0);
Select Min(Connect_By_Root(OldCust)) StartOldCust, NewCust
from Mytable
Where connect_by_isleaf = 1
start with OldCust > 0 connect by Prior NewCust = OldCust
Group By NewCust
Order By StartOldCust;
Mit freundlichen Grüßen / Best regards
Birgitta Hauser
"Shoot for the moon, even if you miss, you'll land among the stars." (Les
Brown)
"If you think education is expensive, try ignorance." (Derek Bok)
"What is worse than training your staff and losing them? Not training them
and keeping them!"
?Train people well enough so they can leave, treat them well enough so they
don't want to.? (Richard Branson)
-----Original Message-----
From: MIDRANGE-L <midrange-l-bounces@xxxxxxxxxxxx> On Behalf Of Alan Shore
Sent: Mittwoch, 2. Mai 2018 15:32
To: midrange-l@xxxxxxxxxxxx
Subject: Recursive SQL queries
Hi everyone
Before I forget - we are on V7r1
Here is my situation
When an order is placed, a customer record is created from the name and
address of the person placing that order.
This creates a unique customer number - unless its recognized that this
particular customer has already placed an order (How that recognition works
is not part of this situation)
However - the person placing the order COULD have already placed an order in
the past - but the name and/or address slightly different Todays order was
placed by John Smith of a certain address He could have placed a past order
as J Smith Or even Johnathan Smith
In these instances, these 3 customer records (and their statistics) need to
be merged into one
That is happening, and we keep an audit trail of what old customer number
was merged into what "NEW" customer number This data is in a file with 2
fields Old customer number New customer number
With the customer record with the OLD customer number being deleted and the
customer record with the New customer number being updated from the OLD
customer number
Here is my situation
There are records where the NEW customer number has been merged into another
customer number and then THAT new custome number is then merged into yet
another one
Here is an example
Old Cust # New Cust #
1 2
2 3
3 6
7 10
6 24
27 30
94 110
110 225
My aim is to pare this down to the following
Old Cust # New Cust #
1 24
7 10
27 30
94 225
I created queries to take the new customer number as the old customer number
and see if that had been merged into another different new customer number I
then took the results of that and repeated the process I then took the
results of that and repeated the process I then took the results of that and
repeated the process Etc.
It took 5 iterations, but the problem is - what happens when and if I need a
6th, and then a 7th
That's when I remembered reading about recursive sql
I found the following web sites
https://www.ibm.com/developerworks/ibmi/library/i-db2connectby/index.html
http://downloads.teradata.com/forum/database/help-with-recursive-query
From the last web site I created the following SQL - the problem was
that it was running for OVER 8 hours (281,000 records on the file
cstmerge)
I don't know if there is anything wrong with the below SQl I am hoping
someone can see something that is wrong or can explain whats missing or
needs changing
WITH RECURSIVE cte
(CMOLDCST#, CMNEWCST#, CMLSTCST#)
AS
(
SELECT CMOLDCST#, CMNEWCST#, CMNEWCST# as CMLSTCST#
FROM prodfa.cstmerge
WHERE CMOLDCST# <> CMNEWCST#
UNION ALL
SELECT t.CMOLDCST#, t.CMNEWCST#, cte.CMLSTCST#
FROM cte
INNER JOIN prodfa.cstmerge AS t
ON cte.CMOLDCST# = t.CMNEWCST#
WHERE t.CMOLDCST# <> t.CMNEWCST#
)
SELECT * FROM cte
ORDER BY 3,1
Alan Shore
E-mail : ASHORE@xxxxxxxx
Phone [O] : (631) 200-5019
Phone [C] : (631) 880-8640
'If you're going through hell, keep going.'
Winston Churchill
--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list
To post a message email: MIDRANGE-L@xxxxxxxxxxxx To subscribe, unsubscribe,
or change list options,
visit:
https://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx Before posting, please take a
moment to review the archives at
https://archive.midrange.com/midrange-l.
Please contact support@xxxxxxxxxxxx for any subscription related questions.
Help support midrange.com by shopping at amazon.com with our affiliate link:
http://amzn.to/2dEadiD
As an Amazon Associate we earn from qualifying purchases.