SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Self Join Question


Self Join Question

Author
Message
Terry Gamble
Terry Gamble
SSC Eights!
SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)

Group: General Forum Members
Points: 808 Visits: 81
I've got a table with the following fields in it:

UniqueID
Sequence
BeforeStatus
AfterStatus
HistoryStatusDate

Sample data looks like :

08-40089445, 1, '','BNT',10/17/17
08-40089445, 2, 'BNT','VFD',1/18/18
08-40089445, 3, 'VFD','NST',1/23/18
08-40089445, 4, 'NST','SLD',1/23/18

What I need to do is basically make a "beginning history" and "ending history" date for each record:
08-40089445, 1, '','BNT',10/17/17, '1/17/18'
08-40089445, 2, 'BNT','VFD',1/18/18, '1/22/18'
08-40089445, 3, 'VFD','NST',1/23/18,'1/23/18'
08-40089445, 4, 'NST','SLD',1/23/18,''
When I write a self join such as


SELECT * FRom
(SELECT s.*,h.HistoryStatusDate statusEnddate
FROM [StatusHistory] S
JOIN [StatusHistory] h
ON s.UniqueID=h.UniqueID
WHERE s.Sequence=h.Sequence-1
) s
--Still trying to find the 7th record for this example
WHERE s.[unique#]='08-40089445'

I end up getting the first 3 back but always miss the 4th (in my example).

Anyone have an idea of a better way to write this/solve this problem? (it's tracking when a record changes a status but it's done in an iSeries so getting the programmers to put the "ending" date on isn't very likely, and the query is ignoring due to the sequence-1 portion for the 4th (max) record.
Phil Parkin
Phil Parkin
SSC Guru
SSC Guru (208K reputation)SSC Guru (208K reputation)SSC Guru (208K reputation)SSC Guru (208K reputation)SSC Guru (208K reputation)SSC Guru (208K reputation)SSC Guru (208K reputation)SSC Guru (208K reputation)

Group: General Forum Members
Points: 208010 Visits: 24242
Terry Gamble - Wednesday, January 31, 2018 1:22 PM
I've got a table with the following fields in it:

UniqueID
Sequence
BeforeStatus
AfterStatus
HistoryStatusDate

Sample data looks like :

08-40089445, 1, '','BNT',10/17/17
08-40089445, 2, 'BNT','VFD',1/18/18
08-40089445, 3, 'VFD','NST',1/23/18
08-40089445, 4, 'NST','SLD',1/23/18

What I need to do is basically make a "beginning history" and "ending history" date for each record:
08-40089445, 1, '','BNT',10/17/17, '1/17/18'
08-40089445, 2, 'BNT','VFD',1/18/18, '1/22/18'
08-40089445, 3, 'VFD','NST',1/23/18,'1/23/18'
08-40089445, 4, 'NST','SLD',1/23/18,''
When I write a self join such as


SELECT * FRom
(SELECT s.*,h.HistoryStatusDate statusEnddate
FROM [StatusHistory] S
JOIN [StatusHistory] h
ON s.UniqueID=h.UniqueID
WHERE s.Sequence=h.Sequence-1
) s
--Still trying to find the 7th record for this example
WHERE s.[unique#]='08-40089445'

I end up getting the first 3 back but always miss the 4th (in my example).

Anyone have an idea of a better way to write this/solve this problem? (it's tracking when a record changes a status but it's done in an iSeries so getting the programmers to put the "ending" date on isn't very likely, and the query is ignoring due to the sequence-1 portion for the 4th (max) record.

You should be able to get those end dates using LEAD. No need for any joins.



Help us to help you. For better, quicker and more-focused answers to your questions, consider following the advice in this link.

If the answer to your question can be found with a brief Google search, please perform the search yourself, rather than expecting one of the SSC members to do it for you.

Please surround any code or links you post with the appropriate IFCode formatting tags. It helps readability a lot.
Terry Gamble
Terry Gamble
SSC Eights!
SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)

Group: General Forum Members
Points: 808 Visits: 81
This is maybe not the right forum/version as I don't have the "lead" function that I can use/find. Is there a true "SQL" based solution using something like the self join? Versus the newer functions like LEAD (which btw I sincerely wish I could use).
Phil Parkin
Phil Parkin
SSC Guru
SSC Guru (208K reputation)SSC Guru (208K reputation)SSC Guru (208K reputation)SSC Guru (208K reputation)SSC Guru (208K reputation)SSC Guru (208K reputation)SSC Guru (208K reputation)SSC Guru (208K reputation)

Group: General Forum Members
Points: 208010 Visits: 24242
You posted in the SQL Server 2017 forum. In 2017, Lead is a true SQL function ☺


Help us to help you. For better, quicker and more-focused answers to your questions, consider following the advice in this link.

If the answer to your question can be found with a brief Google search, please perform the search yourself, rather than expecting one of the SSC members to do it for you.

Please surround any code or links you post with the appropriate IFCode formatting tags. It helps readability a lot.
Phil Parkin
Phil Parkin
SSC Guru
SSC Guru (208K reputation)SSC Guru (208K reputation)SSC Guru (208K reputation)SSC Guru (208K reputation)SSC Guru (208K reputation)SSC Guru (208K reputation)SSC Guru (208K reputation)SSC Guru (208K reputation)

Group: General Forum Members
Points: 208010 Visits: 24242
Which version are you using?


Help us to help you. For better, quicker and more-focused answers to your questions, consider following the advice in this link.

If the answer to your question can be found with a brief Google search, please perform the search yourself, rather than expecting one of the SSC members to do it for you.

Please surround any code or links you post with the appropriate IFCode formatting tags. It helps readability a lot.
Terry Gamble
Terry Gamble
SSC Eights!
SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)

Group: General Forum Members
Points: 808 Visits: 81
I'm not sure what version of SQL that my BI tool rides on (Sisense). I was looking through it for any solution and the only thing I found was self-joins to solve my issue and it drew me back to this site to ask the question.
DesNorton
DesNorton
SSCoach
SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)

Group: General Forum Members
Points: 17635 Visits: 7242
Try changing your JOIN to a LEFT JOIN


How to post data/code on a forum to get the best help.
Make sure that you include code in the appropriate IFCode tags.
Terry Gamble
Terry Gamble
SSC Eights!
SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)SSC Eights! (808 reputation)

Group: General Forum Members
Points: 808 Visits: 81
I had tried that. The table is 8 million rows right now and even trying to limit it to a specific unique ID the server basically locks up on the query (the cube goes to using 110+ GB memory and doesn't return the result so I end up having to kill the cube). It's an annoying issue.
Subramaniam Chandrasekar
Subramaniam Chandrasekar
Hall of Fame
Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)Hall of Fame (3.4K reputation)

Group: General Forum Members
Points: 3350 Visits: 531
Terry Gamble - Wednesday, January 31, 2018 1:22 PM
I've got a table with the following fields in it:

UniqueID
Sequence
BeforeStatus
AfterStatus
HistoryStatusDate

Sample data looks like :

08-40089445, 1, '','BNT',10/17/17
08-40089445, 2, 'BNT','VFD',1/18/18
08-40089445, 3, 'VFD','NST',1/23/18
08-40089445, 4, 'NST','SLD',1/23/18

What I need to do is basically make a "beginning history" and "ending history" date for each record:
08-40089445, 1, '','BNT',10/17/17, '1/17/18'
08-40089445, 2, 'BNT','VFD',1/18/18, '1/22/18'
08-40089445, 3, 'VFD','NST',1/23/18,'1/23/18'
08-40089445, 4, 'NST','SLD',1/23/18,''
When I write a self join such as


SELECT * FRom
(SELECT s.*,h.HistoryStatusDate statusEnddate
FROM [StatusHistory] S
JOIN [StatusHistory] h
ON s.UniqueID=h.UniqueID
WHERE s.Sequence=h.Sequence-1
) s
--Still trying to find the 7th record for this example
WHERE s.[unique#]='08-40089445'

I end up getting the first 3 back but always miss the 4th (in my example).

Anyone have an idea of a better way to write this/solve this problem? (it's tracking when a record changes a status but it's done in an iSeries so getting the programmers to put the "ending" date on isn't very likely, and the query is ignoring due to the sequence-1 portion for the 4th (max) record.

Could you please try to use OFFSET and FETCH for finding nth record as you wish. But still the performance is a concern.

kaj
kaj
SSC Eights!
SSC Eights! (929 reputation)SSC Eights! (929 reputation)SSC Eights! (929 reputation)SSC Eights! (929 reputation)SSC Eights! (929 reputation)SSC Eights! (929 reputation)SSC Eights! (929 reputation)SSC Eights! (929 reputation)

Group: General Forum Members
Points: 929 Visits: 420
DesNorton - Wednesday, January 31, 2018 10:31 PM
Try changing your JOIN to a LEFT JOIN


LEFT JOIN alone will not cut it. You'll also have to move the WHERE condition to ON:

CREATE TABLE #StatusHistory (
UniqueID varchar(30) ,
Sequence int,
BeforeStatus varchar(10),
AfterStatus varchar(10),
HistoryStatusDate date,
PRIMARY KEY(UniqueID, Sequence)
)

INSERT INTO #StatusHistory VALUES('08-40089445',1,'','BNT','20171017')
INSERT INTO #StatusHistory VALUES('08-40089445',2,'BNT','VFD','20180118')
INSERT INTO #StatusHistory VALUES('08-40089445',3,'VFD','NST','20180123')
INSERT INTO #StatusHistory VALUES('08-40089445',4,'NST','SLD','20180123')


SELECT * FRom
(SELECT s.*,h.HistoryStatusDate statusEnddate
FROM [#StatusHistory] S
LEFT JOIN [#StatusHistory] h
ON s.UniqueID=h.UniqueID
AND s.Sequence=h.Sequence-1
) s
--Still trying to find the 7th record for this example
WHERE s.[UniqueID]='08-40089445'
ORDER BY s.UniqueID, s.Sequence


Result:
UniqueID Sequence BeforeStatus AfterStatus HistoryStatusDate statusEnddate
------------------------------ ----------- ------------ ----------- ----------------- -------------
08-40089445 1 BNT 2017-10-17 2018-01-18
08-40089445 2 BNT VFD 2018-01-18 2018-01-23
08-40089445 3 VFD NST 2018-01-23 2018-01-23
08-40089445 4 NST SLD 2018-01-23 NULL

(4 rows affected)

However, I'd be reluctant to rely on the Sequence column being an unbroken sequence (the -1 condition). So I'd likely utilize an OUTER APPLY in stead of the LEFT JOIN:

SELECT * FRom
(SELECT s.*,h.HistoryStatusDate statusEnddate
FROM [#StatusHistory] S
OUTER APPLY (
SELECT TOP(1) HistoryStatusDate
FROM [#StatusHistory] h
WHERE s.UniqueID=h.UniqueID
AND h.Sequence > s.Sequence
ORDER BY h.Sequence ASC
) h
) s
--Still trying to find the 7th record for this example
WHERE s.[UniqueID]='08-40089445'
ORDER BY s.UniqueID, s.Sequence

If we put in a 5 instead of 4 in the last row (thereby creating a gap in the Sequence column sequence), we can see the difference:
UniqueID Sequence BeforeStatus AfterStatus HistoryStatusDate statusEnddate
------------------------------ ----------- ------------ ----------- ----------------- -------------
08-40089445 1 BNT 2017-10-17 2018-01-18
08-40089445 2 BNT VFD 2018-01-18 2018-01-23
08-40089445 3 VFD NST 2018-01-23 NULL
08-40089445 5 NST SLD 2018-01-23 NULL

(4 rows affected)

UniqueID Sequence BeforeStatus AfterStatus HistoryStatusDate statusEnddate
------------------------------ ----------- ------------ ----------- ----------------- -------------
08-40089445 1 BNT 2017-10-17 2018-01-18
08-40089445 2 BNT VFD 2018-01-18 2018-01-23
08-40089445 3 VFD NST 2018-01-23 2018-01-23
08-40089445 5 NST SLD 2018-01-23 NULL

(4 rows affected)

Only the last one can cope.

Anyway, both methods will need an index on UniqueID, Sequence in order to perform adequately if more than a few rows are to be processed.


Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum








































































































































































SQLServerCentral


Search