Query to delete nth row in a table (SQL Server 2008 Express)

  • I found a query to select nth row....

    SELECT column/s FROM

    (

    SELECT column/s, row_number() over(ORDER BY getdate()) as r

    FROM tablename

    ) as t

    WHERE r = 4

    But couldn't find any query for deletion...

    Any idea ??

  • smarty3010 (3/3/2011)


    I found a query to select nth row....

    SELECT column/s FROM

    (

    SELECT column/s, row_number() over(ORDER BY getdate()) as r

    FROM tablename

    ) as t

    WHERE r = 4

    But couldn't find any query for deletion...

    Any idea ??

    DELETE t.Column

    FROM

    (

    SELECT column/s, row_number() over(ORDER BY getdate()) as r

    FROM tablename

    ) as t

    WHERE r = 4

  • try this

    BEGIN TRAN test

    DELETE tablename

    FROM (SELECT Column

    FROM

    (

    SELECT column/s, row_number() over(ORDER BY getdate()) as r

    FROM tablename

    ) as t

    WHERE r = 4)tmp

    INNER JOIN tablename

    ON tablename.column = tmp.column

    COMMIT TRAN test

  • Using CTE, you can select, update and delete specific record(s). Pls refer the below code

    create table #temp (id int)

    --delete #temp

    insert into #temp values(1)

    insert into #temp values(2)

    insert into #temp values(3)

    insert into #temp values(4)

    insert into #temp values(5)

    select * from #temp

    ;with cte (id,r_num)

    as(

    select *,ROW_NUMBER() over(Order by getdate()) from #temp

    )

    delete cte where r_num = 3;

    select * from #temp

    ;with cte (id,r_num)

    as(

    select *,ROW_NUMBER() over(Order by getdate()) from #temp

    )

    update cte set id = 1000 where r_num = 2;

    select * from #temp

    drop table #temp

    Thanks

    Gopi

  • It's important to note that none of these solutions will guarantee to delete the same rows as are being returned by the select statement (nor indeed is the select statement guaranteed to return the same rows each time).

    Because your row number order is entirely arbitrary, a different plan could well result in different results.

    My question is, why would you want to arbitrarily delete rows with no apparent logic?

  • HowardW (3/4/2011)


    It's important to note that none of these solutions will guarantee to delete the same rows as are being returned by the select statement...

    Hi Howard,

    I agree with your comments about the reason for deleting the 'nth' row in no particular order, but I can't for the life of me understand what the extract above is getting at. A query like the following is guaranteed to delete the row identified as #4 (peculiar though the logic is):

    DELETE E

    FROM (

    SELECT rn = ROW_NUMBER() OVER (ORDER BY (SELECT 0))

    FROM dbo.Example

    ) AS E

    WHERE E.rn = 4

    ;

    Naturally, we would normally use a deterministic order by with the row number window function to identify the row or rows to delete.

    Paul

  • Thanks a million guys !!

    Tried the code by SQLkiwi and ColdCoffee (used t instead of t.column)

    Worked perfectly

    I am building a visual tool for managing a database.....

    So a deleting a row (which a user can view and wants to delete) would be much simpler !!

  • SQLkiwi (3/4/2011)


    HowardW (3/4/2011)


    It's important to note that none of these solutions will guarantee to delete the same rows as are being returned by the select statement...

    Hi Howard,

    I agree with your comments about the reason for deleting the 'nth' row in no particular order, but I can't for the life of me understand what the extract above is getting at. A query like the following is guaranteed to delete the row identified as #4 (peculiar though the logic is):

    DELETE E

    FROM (

    SELECT rn = ROW_NUMBER() OVER (ORDER BY (SELECT 0))

    FROM dbo.Example

    ) AS E

    WHERE E.rn = 4

    ;

    Naturally, we would normally use a deterministic order by with the row number window function to identify the row or rows to delete.

    Paul

    It's guaranteed to delete the nth row within that delete statement, but as far as I'm aware, you could run the select (which will generate one plan) and assume that the delete statement will delete the same rows. However, the delete statement could reasonably generate a different plan and delete different arbitrary rows than your original select statement did. Unless I'm misunderstanding how the optimiser works in this case and it doesn't generate a plan based on the overall query and will always generate the plan based on the sub query alone.

    Hopefully the above makes sense (even if it's wrong!) 🙂

  • HowardW (3/4/2011)


    It's guaranteed to delete the nth row within that delete statement, but as far as I'm aware, you could run the select (which will generate one plan) and assume that the delete statement will delete the same rows. However, the delete statement could reasonably generate a different plan and delete different arbitrary rows than your original select statement did. Unless I'm misunderstanding how the optimiser works in this case and it doesn't generate a plan based on the overall query and will always generate the plan based on the sub query alone. Hopefully the above makes sense (even if it's wrong!) 🙂

    I see, so you were saying that running the SELECT first (and noting the row it selected) and then expecting the DELETE (with the same SELECT statement as a subquery) to delete the same row would be unsound. I agree with that of course.

    I thought you were saying that the DELETE might not delete the row identified by the SELECT (when run as part of the DELETE statement). My apologies - I think I did misread what you were getting at.

  • SQLkiwi (3/4/2011)


    I see, so you were saying that running the SELECT first (and noting the row it selected) and then expecting the DELETE (with the same SELECT statement as a subquery) to delete the same row would be unsound. I agree with that of course.

    I thought you were saying that the DELETE might not delete the row identified by the SELECT (when run as part of the DELETE statement). My apologies - I think I did misread what you were getting at.

    Exactly. No problem, I probably wasn't being very clear! 😛

Viewing 10 posts - 1 through 9 (of 9 total)

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