Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


find pairs of NULL records without resorting to CURSORS


find pairs of NULL records without resorting to CURSORS

Author
Message
aaron.reese
aaron.reese
Mr or Mrs. 500
Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)

Group: General Forum Members
Points: 589 Visits: 898


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?
ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)

Group: General Forum Members
Points: 8975 Visits: 19028
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
Lowell
Lowell
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14959 Visits: 38977
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

--
help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

aaron.reese
aaron.reese
Mr or Mrs. 500
Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)

Group: General Forum Members
Points: 589 Visits: 898
@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
ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)

Group: General Forum Members
Points: 8975 Visits: 19028
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
J Livingston SQL
J Livingston SQL
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: 3448 Visits: 33040


;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

aaron.reese
aaron.reese
Mr or Mrs. 500
Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)

Group: General Forum Members
Points: 589 Visits: 898
@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
aaron.reese
aaron.reese
Mr or Mrs. 500
Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)Mr or Mrs. 500 (589 reputation)

Group: General Forum Members
Points: 589 Visits: 898
@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
ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)

Group: General Forum Members
Points: 8975 Visits: 19028
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 :-D

“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
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