SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Delete Table records with Bakup


Delete Table records with Bakup

Author
Message
Minnu
Minnu
Ten Centuries
Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)

Group: General Forum Members
Points: 1359 Visits: 950
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.
free_mascot
free_mascot
SSCertifiable
SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)

Group: General Forum Members
Points: 7443 Visits: 2250
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."
Eirikur Eiriksson
Eirikur Eiriksson
SSC-Forever
SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)

Group: General Forum Members
Points: 40342 Visits: 19452
You can use the output clause with the delete
Cool

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

free_mascot
free_mascot
SSCertifiable
SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)

Group: General Forum Members
Points: 7443 Visits: 2250
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."
Eirikur Eiriksson
Eirikur Eiriksson
SSC-Forever
SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)

Group: General Forum Members
Points: 40342 Visits: 19452
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
Cool

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;


ScottPletcher
ScottPletcher
SSCoach
SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)

Group: General Forum Members
Points: 19513 Visits: 7410
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) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
Eirikur Eiriksson
Eirikur Eiriksson
SSC-Forever
SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)

Group: General Forum Members
Points: 40342 Visits: 19452
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!
Cool
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)SSC Guru (213K reputation)

Group: General Forum Members
Points: 213737 Visits: 41977
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.
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
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