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 12345»»»

Just For Fun: An Impossible Delete Expand / Collapse
Author
Message
Posted Monday, August 4, 2008 9:58 PM


SSCrazy Eights

SSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy Eights

Group: General Forum Members
Last Login: Thursday, December 4, 2014 7:52 AM
Points: 9,294, Visits: 9,495
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."
Post #546486
Posted Monday, August 4, 2008 11:30 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 8:47 PM
Points: 35,770, Visits: 32,436
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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #546516
Posted Tuesday, August 5, 2008 12:10 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, August 14, 2012 12:51 AM
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.
Post #546525
Posted Tuesday, August 5, 2008 12:30 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Thursday, March 6, 2014 6:13 PM
Points: 318, Visits: 1,183
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 :P

Regards,

Jacob
Post #546530
Posted Tuesday, August 5, 2008 12:47 AM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Tuesday, September 23, 2014 8:08 AM
Points: 2,365, Visits: 1,846
great article!!

"Keep Trying"
Post #546532
Posted Tuesday, August 5, 2008 1:21 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Saturday, November 29, 2014 3:55 PM
Points: 3,244, Visits: 5,010
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

Post #546541
Posted Tuesday, August 5, 2008 1:24 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Saturday, November 29, 2014 3:55 PM
Points: 3,244, Visits: 5,010
eerkan... your solution misses one record

Try again...:D


Atif Sheikh



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

Sometimes, winning is not an issue but trying.

You can check my BLOG here

Post #546543
Posted Tuesday, August 5, 2008 1:39 AM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Thursday, September 25, 2014 12:38 PM
Points: 1,385, Visits: 1,249
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.
Post #546549
Posted Tuesday, August 5, 2008 3:05 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Tuesday, November 18, 2014 5:51 AM
Points: 328, Visits: 2,001
I think this calls for Monty Pythons The Four Yorkshiremen skit:
http://www.phespirit.info/montypython/four_yorkshiremen.htm
Post #546578
Posted Tuesday, August 5, 2008 3:06 AM


Mr or Mrs. 500

Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500

Group: General Forum Members
Last Login: Friday, December 12, 2014 11:01 AM
Points: 594, Visits: 2,580
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
Post #546582
« Prev Topic | Next Topic »

Add to briefcase 12345»»»

Permissions Expand / Collapse