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


Just For Fun: An Impossible Delete


Just For Fun: An Impossible Delete

Author
Message
RBarryYoung
RBarryYoung
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10324 Visits: 9517
Comments posted to this topic are about the item Just For Fun: An Impossible Delete

-- RBarryYoung, (302)375-0451 blog: MovingSQL.com, Twitter: @RBarryYoung
Proactive Performance Solutions, Inc.
"Performance is our middle name."
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)SSC Guru (54K reputation)

Group: General Forum Members
Points: 54401 Visits: 40390
What an amazing article! Covers most everything from womb-to-tomb for such an "impossible" delete. I remember being amazed when Barry first posted his solution on the original thread. I'm even more amazed that he wove in some of the techniques used in the old days and took the time to explain how each byte of memory was cherished which made these types of methods absolutely necessary.

Well done, Barry!

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Emre Erkan
Emre Erkan
Forum Newbie
Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)

Group: General Forum Members
Points: 1 Visits: 10
Nice Article. I learned a lot. But for this problem there may be a shorter/ simpler solution :

--======1 Insert Records We want to have
Insert into SOURCE(Name, Age, Sex)
Select Name
, Age
, Case Sex When 'M' Then 'N' Else 'G' End
From SOURCE
Group By Name, Age, Sex
Having Count (*) > 1

--======2: Remove the old rows
Delete from SOURCE
Where Sex In ('M','F')

--======3: Update the inserted records accordingly
Update SOURCE
Set Sex = CASE Sex When 'N' Then 'M' Else 'F' End

Both of us depend on the case that Sex column has one of two values. If that is not the case then solution would be appending a character / string that does not exist in the original data (ex '~~~~~') in first step. Delete the ones that does not have appended string in the second step. Remove appended string in the third step.
Jacob Luebbers
Jacob Luebbers
Old Hand
Old Hand (378 reputation)Old Hand (378 reputation)Old Hand (378 reputation)Old Hand (378 reputation)Old Hand (378 reputation)Old Hand (378 reputation)Old Hand (378 reputation)Old Hand (378 reputation)

Group: General Forum Members
Points: 378 Visits: 1215
eerkan - I don't think your solution will give what the OP wanted. It'll collapse all duplicated rows into a single row, whereas the OP wanted to retain all dupes as seperate rows.

Great article btw - RBarryYoung bringing back the old skool Tongue

Regards,

Jacob
ChiragNS
ChiragNS
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2637 Visits: 1865
great article!!

"Keep Trying"
Atif-ullah Sheikh
Atif-ullah Sheikh
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: 3399 Visits: 5175
GREAT ARTICLE...

Alot of learning points in it...

My First thought, I would have gone for cursors to solve the issue. Secondly, I would certainly NOT go for the conversions as used in the article (who cares about bit and bytes nowdays...). But one MUST know the way to accomplish the task using the limited and KNOWN resources whic makes the solution in the article THE BEST in all aspects...

BRAVO...


Atif Sheikh

----------------------------------------------------------------------------------------------------------------------------------------------------------------------

Sometimes, winning is not an issue but trying.

You can check my BLOG here


Atif-ullah Sheikh
Atif-ullah Sheikh
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: 3399 Visits: 5175
eerkan... your solution misses one record

Try again...BigGrin


Atif Sheikh

----------------------------------------------------------------------------------------------------------------------------------------------------------------------

Sometimes, winning is not an issue but trying.

You can check my BLOG here


Tao Klerks
Tao Klerks
UDP Broadcaster
UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)UDP Broadcaster (1.4K reputation)

Group: General Forum Members
Points: 1435 Visits: 1249
Hmm, my curiousity is piqued... The solution presented is quite interesting, but I believe the purported interest in bits and bytes is a little exaggerated, as the solution is still quite expensive (rewrites an entire column in a single update statement, and rewrites/deletes the bulk of the data if there are many duplicates - needing up to almost double the original storage space to complete). So I'm quite curious:

What would the most efficient way of addressing this problem be? (using least memory and / or using least I/O, especially on a very large data set; also consider whether the data can still be accessed during the update process)

This should be quite easy to test, given a few hours to create a large (GB-sized?) data set and try out a few different approaches...

It seems a problem that many more people are likely to face nowadays - powerful hardware, very robust systems that can remain online as you do things like add columns, but extremely large amounts of data (many gigabytes) and no maintenance time / downtime available!

http://poorsql.com for T-SQL formatting: free as in speech, free as in beer, free to run in SSMS or on your version control server - free however you want it.
Samuel Vella
Samuel Vella
SSC-Addicted
SSC-Addicted (485 reputation)SSC-Addicted (485 reputation)SSC-Addicted (485 reputation)SSC-Addicted (485 reputation)SSC-Addicted (485 reputation)SSC-Addicted (485 reputation)SSC-Addicted (485 reputation)SSC-Addicted (485 reputation)

Group: General Forum Members
Points: 485 Visits: 2141
I think this calls for Monty Pythons The Four Yorkshiremen skit:
http://www.phespirit.info/montypython/four_yorkshiremen.htm
Phil Factor
Phil Factor
Ten Centuries
Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)Ten Centuries (1K reputation)

Group: General Forum Members
Points: 1037 Visits: 2953
Surely this is the simplest solution? (be warned of a nasty catch when creating these 'quirky updates'. the order of execution of the update is -variable assignments first then column assignments-both left to right!)



--create the sample table
DECLARE @Sample TABLE (TheName VARCHAR(4),Identifier INT, sex VARCHAR(1))
INSERT INTO @Sample (TheName,Identifier,Sex)
  
SELECT 'ABC', 24, 'M' UNION ALL
  
SELECT 'ABC',  24,'M' UNION ALL
  
SELECT 'LMN',  27, 'M' UNION ALL
  
SELECT 'LMN',  27, 'M' UNION ALL
  
SELECT 'LMN',  27, 'M' UNION ALL
  
SELECT 'PQRS',  25, 'F' UNION ALL
  
SELECT 'XYZ',  24, 'M' UNION ALL
  
SELECT 'XYZ',  25, 'M'
--@Sex variable only used to force the order of execution of the update
DECLARE @hash VARCHAR(80), @sex VARCHAR(1)
UPDATE @sample
  
SET
  
@sex=Sex = CASE WHEN COALESCE(@hash,'')
                           <>
TheName+CONVERT(VARCHAR(5),Identifier)+sex
          
THEN 'd' ELSE SEX END,
  
@hash= TheName+CONVERT(VARCHAR(5),Identifier)+sex

DELETE FROM @sample WHERE sex='d'
SELECT * FROM @sample



Best wishes,

Phil Factor
Simple Talk
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