March 18, 2015 at 12:00 pm
MS SQL 2008
I want to execute a delete query on certain tables in my database to delete some rows in the tables.
The tables selected has a certain name pattern (the name ends with "Temp").
So I can do this to get a list of the table names
SELECT name
FROM sys.Tables where
name like '%Temp'
Now I want to check each table to see if it has a column with the name "DateStamp" and then execute a delete query as follows:
delete form TableName where
DateStamp is < '2010-01-01'
In other words I need to iterate through the tables names
How to do this?
March 18, 2015 at 12:19 pm
you can find every column namedDateStamp, and it's tablename (but it might be VIEWNAME !!) you can join to sys.tables and then sys.columns as instead
select
'delete from '
+ quotename(object_name(object_id))
+ ' WHERE '
+ quotename(name)
+' < 2010-01-01'';'
from sys.columns
where name = 'DateStamp'
then you can copy and paste the code to execute, after you reviewed it of course
Lowell
March 18, 2015 at 12:53 pm
How to add one more condition that the table name ends with "Temp"
I am trying to do an inner join, so far no success yet.
March 18, 2015 at 12:58 pm
techzone12 (3/18/2015)
How to add one more condition that the table name ends with "Temp"I am trying to do an inner join, so far no success yet.
here's a full example:
select
'delete from '
+ quotename(tabz.name)
+ ' WHERE '
+ quotename(colz.name)
+' < 2010-01-01'';'
from sys.tables tabz
inner join sys.columns colz
on tabz.object_id = colz.object_id
where colz.name = 'DateStamp'
and tabz.name like '%temp'
Lowell
March 18, 2015 at 1:30 pm
I am amazed with the quality of answers on this site. Fast and accurate, but yet efficient code.
Thanks for the help
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply
This website stores cookies on your computer.
These cookies are used to improve your website experience and provide more personalized services to you, both on this website and through other media.
To find out more about the cookies we use, see our Privacy Policy