Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

find pairs of NULL records without resorting to CURSORS Expand / Collapse
Author
Message
Posted Tuesday, May 7, 2013 5:43 AM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Thursday, December 18, 2014 12:16 AM
Points: 461, Visits: 693

create table #tmp
(
ref int,
Date datetime,
time int,
seqno int
)
insert into #tmp (ref,date,time,seqno) values(34227664,'20130227',0,399850)
insert into #tmp (ref,date,time,seqno) values(34227664,'20130304',0,399860)
insert into #tmp (ref,date,time,seqno) values(34227664,'20130313',0,399870)
insert into #tmp (ref,date,time,seqno) values(34227664,'20130326',40820,NULL)
insert into #tmp (ref,date,time,seqno) values(34227664,'20130326',41201,NULL)
insert into #tmp (ref,date,time,seqno) values(34227664,'20130326',41287,NULL)
insert into #tmp (ref,date,time,seqno) values(34227664,'20130326',44797,NULL)
insert into #tmp (ref,date,time,seqno) values(34227664,'20130326',44809,5158850)
insert into #tmp (ref,date,time,seqno) values(34227664,'20130326',44820,NULL)
insert into #tmp (ref,date,time,seqno) values(34227664,'20130326',46147,5158870)
insert into #tmp (ref,date,time,seqno) values(34227664,'20130328',53698,NULL)
insert into #tmp (ref,date,time,seqno) values(34227664,'20130328',60518,NULL)

SELECT * from #tmp order by date,time,seqno



I am trying to identify the 2nd record in pairs of NULL sequence nos. E.g.
'20130326',41201 is the 2nd in a pair,
'20130326',44797 is the 2nd in a pair (although they come as a block of 4)
'20130328',60518 is the 2nd in a pair.

'20130326',44820 is not part of a pair so I am not interested in it.

So far I have tried:
Rank partition by seqno order by ref,date,time and this gives me 1 for each record which has a seqno and an incrementing counter for each that has null.
mod (rnak % 2) to give me 0 or 1 and take the 0 as being the 2nd in the pair but it goes wrong for '20130326',44820 because this is in the NULL ranks but is not paired and it throws the last pair out.

Also tried referencing the data to itself using rank = rank -1 in the join but this doesnt help unless we also go for min() and max() to create islands of records which is hidden RBAR and very slow on 1M records.

anyone got any bright ideas?
Post #1450078
Posted Tuesday, May 7, 2013 5:47 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Thursday, December 18, 2014 1:43 AM
Points: 6,890, Visits: 14,254
Why isn't 41287 the second of a pair?

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1450084
Posted Tuesday, May 7, 2013 5:49 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 5:42 AM
Points: 12,962, Visits: 32,502
my first guess looks pretty good;
just using row number, and joining the data against itself:

WITH MySampleData
AS
(
SELECT row_number() OVER(partition by date order by date,time,seqno) AS RW,
*
from #tmp
)
SELECT
T1.*,
T2.*
FROM MySampleData T1
LEFT OUTER JOIN MySampleData T2 ON T1.RW + 1 = T2.RW
WHERE T1.seqno IS NULL AND T2.seqno IS NULL



Lowell

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #1450085
Posted Tuesday, May 7, 2013 5:58 AM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Thursday, December 18, 2014 12:16 AM
Points: 461, Visits: 693
@Lowell Good effort but not quite.
Your results set picks up the recod with a time stamp of 41287 which is the first in a pair.

@ChrisM
Same answer as above: a pair is defined as a discreet pair; i.e. if you are the second in a pair, you cannot be the first in the next pair even when the records are consecutive.

so
40820 and 41201 are a pair
41287 and 44797 are a pair
53698 and 60518 are a pair

Post #1450088
Posted Tuesday, May 7, 2013 6:04 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Thursday, December 18, 2014 1:43 AM
Points: 6,890, Visits: 14,254
aaron.reese (5/7/2013)
@Lowell Good effort but not quite.
Your results set picks up the recod with a time stamp of 41287 which is the first in a pair.

@ChrisM
Same answer as above: a pair is defined as a discreet pair; i.e. if you are the second in a pair, you cannot be the first in the next pair even when the records are consecutive.

so
40820 and 41201 are a pair
41287 and 44797 are a pair
53698 and 60518 are a pair



Thanks. Try this:
SELECT *,  
Filter = CASE WHEN seqno IS NULL
THEN ROW_NUMBER() OVER (PARTITION BY rnThingy ORDER BY date, time, seqno)
ELSE NULL END%2
FROM (
SELECT *,
rnThingy = CASE WHEN seqno IS NULL
THEN (ROW_NUMBER() OVER (ORDER BY date, time, seqno) - ROW_NUMBER() OVER (ORDER BY seqno, date, time))
ELSE NULL END
FROM #tmp
) d
ORDER BY date, time, seqno



“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1450091
Posted Tuesday, May 7, 2013 6:15 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Yesterday @ 3:42 AM
Points: 1,943, Visits: 20,180

;WITH jls
AS
(
SELECT ROW_NUMBER ( ) OVER ( PARTITION BY date ORDER BY date ) AS RN
, *
FROM #tmp
WHERE (seqno IS NULL)
)

select * from jls where RN %2 = 0



______________________________________________________________
you can lead a user to data....but you cannot make them think
and remember....every day is a school day
Post #1450093
Posted Tuesday, May 7, 2013 7:58 AM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Thursday, December 18, 2014 12:16 AM
Points: 461, Visits: 693
@JLS

Thanks but I needed to be more precise over the ordering than just using date.

@ChrisM

Genius!

Definately is giving me the right results for the #tmp sample data set. As you would expect the 'real' data is much more complicated. I will run against this later and see what the performance is like and whether any other anomolies crawl out of the dataset.

Obiron

Post #1450154
Posted Wednesday, May 8, 2013 10:08 AM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Thursday, December 18, 2014 12:16 AM
Points: 461, Visits: 693
@ChrisM

I managed to run that against my entire dataset (some 800K records) and it took less than 30 seconds so a big thanks for that code.

Obiron

Post #1450670
Posted Thursday, May 9, 2013 1:16 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Thursday, December 18, 2014 1:43 AM
Points: 6,890, Visits: 14,254
aaron.reese (5/8/2013)
@ChrisM

I managed to run that against my entire dataset (some 800K records) and it took less than 30 seconds so a big thanks for that code.

Obiron



That's a result! Thank you very much for the feedback


“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1450907
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse