Delete Table records with Bakup

  • Hi Team,

    using below query

    DELETE FROM Table_name

    WHERE Date_column < GETDATE() - 30

    am able to delete old records morethan 30 days, but i want to results to be saved in file.

    before deleting i want to a craete a file and save the to be deleted records.

    Please suggest.

  • There are two ways you can achieve this.

    1st Create a table(tblToBeDeleted) for records to be deleted. Insert the data into tblToBeDeleted and once insert is done you can delete the records which are in table tblToBeDeleted.

    2nd you can create export data to excel; refer following link:

    http://social.msdn.microsoft.com/Forums/en-US/453c9593-a689-4f7e-8364-fa998e266363/how-to-export-sql-data-to-excel-spreadsheet-using-sql-query?forum=transactsql

    HTH

    ---------------------------------------------------
    "Thare are only 10 types of people in the world:
    Those who understand binary, and those who don't."

  • You can use the output clause with the delete

    😎

    DECLARE @TTABLE TABLE

    (

    TT_ID INT IDENTITY(1,1) PRIMARY KEY CLUSTERED NOT NULL

    ,TT_VAL INT NOT NULL

    );

    INSERT INTO @TTABLE(TT_VAL)

    VALUES (123),(234),(345),(456),(567);

    SELECT * FROM @TTABLE;

    DELETE

    FROM @TTABLE

    OUTPUT deleted.*

    WHERE TT_VAL < 300;

    SELECT * FROM @TTABLE;

    Results

    TT_ID TT_VAL

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

    1 123

    2 234

    3 345

    4 456

    5 567

    TT_ID TT_VAL

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

    1 123

    2 234

    TT_ID TT_VAL

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

    3 345

    4 456

    5 567

  • Great Eirikur, is it possible to send this OUTPUT to excel using this T-sql?

    ---------------------------------------------------
    "Thare are only 10 types of people in the world:
    Those who understand binary, and those who don't."

  • free_mascot (5/2/2014)


    Great Eirikur, is it possible to send this OUTPUT to excel using this T-sql?

    Use the output to insert the records into a table and export to excel/csv from there. I added the insert bit to the following code

    😎

    DECLARE @TTABLE TABLE

    (

    TT_ID INT IDENTITY(1,1) PRIMARY KEY CLUSTERED NOT NULL

    ,TT_VAL INT NOT NULL

    );

    DECLARE @TTDELETED TABLE

    (

    TT_ID INT PRIMARY KEY CLUSTERED NOT NULL

    ,TT_VAL INT NOT NULL

    );

    INSERT INTO @TTABLE(TT_VAL)

    VALUES (123),(234),(345),(456),(567);

    SELECT * FROM @TTABLE;

    DELETE

    FROM @TTABLE

    OUTPUT deleted.* INTO @TTDELETED(TT_ID,TT_VAL)

    WHERE TT_VAL < 300;

    SELECT * FROM @TTABLE;

    SELECT * FROM @TTDELETED;

  • I would never use a table variable for this -- if something goes wrong after the DELETEs, but before the output has been processed, the data is gone, with no way to get it back.

    Do you have a separate db that you use for export / other utility purposes? If not, you may want to create one. Output the rows to be deleted to a table, then delete the rows.

    Process that other table within a transaction, so that the rows must be successfully exported before the export table has its rows deleted.

    SQL DBA,SQL Server MVP(07, 08, 09) A socialist is someone who will give you the shirt off *someone else's* back.

  • ScottPletcher (5/5/2014)


    I would never use a table variable for this -- if something goes wrong after the DELETEs, but before the output has been processed, the data is gone, with no way to get it back.

    Do you have a separate db that you use for export / other utility purposes? If not, you may want to create one. Output the rows to be deleted to a table, then delete the rows.

    Process that other table within a transaction, so that the rows must be successfully exported before the export table has its rows deleted.

    I agree, the table variables are for the sake of providing a sample schema for the demonstration of the functionality, should have been more clear on that!

    😎

  • free_mascot (5/2/2014)


    Great Eirikur, is it possible to send this OUTPUT to excel using this T-sql?

    Why do you need to send it to Excel?

    --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.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

Viewing 8 posts - 1 through 7 (of 7 total)

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