February 20, 2013 at 8:16 am
Hi,
I have a rather large number of tables made using a (fairly) standard template. Due to a compatibility issue with another program, I need to drop one of the columns from all tables. I'm working on the syntax for it, but my brain is not cooperating. Can anyone help me finish off the code, or point me to a better way to do it?
Thanks
use sample
declare @sql = nvarchar(max)
declare @tblnm = nvarchar(64)
set @sql = 'alter table ['+@tblnm+'drop column Active'
select @tblnm = from information_schema.columns
where column_name = 'active'
February 20, 2013 at 8:45 am
You may want to look at the procedure (in the Master DB) titled
[sys].[sp_MSforeachtable].
Review the T-SQL to determine if it will perform as you want it to, or if it does not prehaps a simple modification will suffice.
February 20, 2013 at 9:19 am
bitbucket-25253 (2/20/2013)
You may want to look at the procedure (in the Master DB) titled[sys].[sp_MSforeachtable].
Review the T-SQL to determine if it will perform as you want it to, or if it does not prehaps a simple modification will suffice.
Oh, that's awesome. Thanks. Based on your experience, if it runs into a table that doesn't have the column I'm trying to get rid of, will it stop and throw an error, or continue the loop?
exec sp_msforeachtable
'alter table ''?'' drop column Active'
I'm reading up on the @commandorder parameters now.
February 20, 2013 at 10:17 am
I use this to add the same column to a group of tables. You can modify it to remove a column. I choose "Results to text", then copy-paste the results to a new window to review it and run. It has a "GO" between each line, so it should keep running if some operations fail if the column is not found.
use MyDatabase
set nocount on
select 'use MyDatabase'
SELECT 'ALTER TABLE ' + o.name + ' ADD PROMO_ROLLOFF_DATE varchar(25) NULL
go '
FROM (select name from sys.objects where (name like 'DLRT%')
and name <> 'DLTest' and schema_id = 1) o
order by o.name
February 22, 2013 at 12:58 am
You can also EXEC the @sql returned by this:
DECLARE @sql nvarchar(max) = ''
SELECT @sql = @sql + CHAR(10) + '
BEGIN TRY
ALTER TABLE [' + TABLE_NAME + ']
DROP COLUMN Active
END TRY
BEGIN CATCH
PRINT ''' + TABLE_NAME + '''
END CATCH;'
FROM information_schema.columns
WHERE COLUMN_NAME= 'Active'
PRINT @sql
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 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply