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


Swiss Cheese!


Swiss Cheese!

Author
Message
John Esraelo-498130
John Esraelo-498130
SSChasing Mays
SSChasing Mays (601 reputation)SSChasing Mays (601 reputation)SSChasing Mays (601 reputation)SSChasing Mays (601 reputation)SSChasing Mays (601 reputation)SSChasing Mays (601 reputation)SSChasing Mays (601 reputation)SSChasing Mays (601 reputation)

Group: General Forum Members
Points: 601 Visits: 1030
Comments posted to this topic are about the item Swiss Cheese!

Cheers,
John Esraelo
nikswann
nikswann
Forum Newbie
Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)

Group: General Forum Members
Points: 4 Visits: 319
The Cursor has massive overhead.

Have you considered CTE and Ranking functions in a set based operation:

Ideally have an Index:
CREATE CLUSTERED INDEX idx_ID ON MyDB.dbo.Employees(ID);



Create a CTE that assigns row numbers to rows based on seqval ordering. The
outer query then joins two instances, matching current and next values based on an offset of
1 between their row numbers.

WITH CTE AS
(
SELECT ID, ROW_NUMBER() OVER(ORDER BY ID) AS rownum
FROM MyDB.dbo.Employees
)
SELECT Cur.ID + 1 AS start_range, Nxt.ID- 1 AS end_range
FROM CTE AS Cur
JOIN CTE AS Nxt
ON Nxt.rownum = Cur.rownum + 1
WHERE Nxt.ID - Cur.ID > 1;



or if your ID List has duplicates :

WITH CTE AS
(
SELECT ID, ROW_NUMBER() OVER(ORDER BY ID) AS rownum
FROM (SELECT DISTINCT ID FROM MyDB.dbo.Employees) AS D
)
SELECT Cur.ID + 1 AS start_range, Nxt.ID - 1 AS end_range
FROM CTE AS Cur
JOIN CTE AS Nxt
ON Nxt.rownum = Cur.rownum + 1
WHERE Nxt.ID - Cur.ID > 1;



This will run about 10 times faster than a Cursor, Tested on 10000000 Rows with 9,999 Gaps (Ran on my system in around 23 seconds).

If you need to return the list of individual missing values as opposed to missing ranges, using a Nums table (Every database NEEDS a Nums table) makes the task is very simple:

SELECT n FROM dbo.Nums
WHERE n BETWEEN (SELECT MIN(ID) FROM MyDB.dbo.Employees)
AND (SELECT MAX(ID) FROM MyDB.dbo.Employees)
AND n NOT IN(SELECT ID FROM MyDB.dbo.Employees);


Iwas Bornready
Iwas Bornready
SSCrazy Eights
SSCrazy Eights (9.9K reputation)SSCrazy Eights (9.9K reputation)SSCrazy Eights (9.9K reputation)SSCrazy Eights (9.9K reputation)SSCrazy Eights (9.9K reputation)SSCrazy Eights (9.9K reputation)SSCrazy Eights (9.9K reputation)SSCrazy Eights (9.9K reputation)

Group: General Forum Members
Points: 9944 Visits: 885
Thanks for the script.
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