Need a Subquery to delete the previous dates

  • I have created one table like below

    create table Verification(id int,date datetime)

    inserted values like

    insert into Verification values(1,'2013-07-10 03:12:05.397')

    insert into Verification values(1,'2013-07-09 03:12:05.397')

    insert into Verification values(1,'2013-07-08 03:12:05.397')

    insert into Verification values(2,'2013-07-10 03:12:05.397')

    insert into Verification values(2,'2013-07-09 03:12:05.397')

    insert into Verification values(2,'2013-07-08 03:12:05.397')

    insert into Verification values(3,'2013-07-10 03:12:05.397')

    insert into Verification values(3,'2013-07-09 03:12:05.397')

    insert into Verification values(3,'2013-07-08 03:12:05.397')

    I want to delete all the records except for the id who's have the max date.

    output record should be like this.

    ID date

    1 2013-07-10 03:12:05.397'

    2 2013-07-10 03:12:05.397'

    3 2013-07-10 03:12:05.397'

  • Delete through a CTE thusly:

    WITH Rows2Delete AS (

    SELECT id, [date], rn=ROW_NUMBER() OVER (PARTITION BY id ORDER BY [date] DESC)

    FROM Verification)

    DELETE FROM Rows2Delete

    WHERE rn <> 1;

    SELECT * FROM Verification;


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

Viewing 2 posts - 1 through 1 (of 1 total)

You must be logged in to reply to this topic. Login to reply