SQL Server Management Studio is pretty good tool to manage and develop against SQL Server instances. You have to be aware of some things that can be dangerous. Just the other day I had to help someone on a development environment who had a problem when he made a column bigger
The table looked like this
CREATE TABLE [TestTable] ( [id] [int] IDENTITY (1, 1) NOT NULL , [itemdate] [datetime] NOT NULL , [title] [varchar] (30) NOT NULL , ) ON [PRIMARY]
So what the person wanted to do was make the title column 50 characters instead of 30. He right clicked on the table, clicked on Design, made the change and hit the save button. He then tried to run a query against the table and it was stuck, nothing was being returned. After a couple of minutes all seemed fine.
So what happened? Behind the scenes SSMS actually created a new table, dumped all that data into that table, dropped the original table and then renamed this new table to match the name of the original table
Here is what the script looks like that SSMS generates
BEGIN TRANSACTION SET QUOTED_IDENTIFIER ON SET ARITHABORT ON SET NUMERIC_ROUNDABORT OFF SET CONCAT_NULL_YIELDS_NULL ON SET ANSI_NULLS ON SET ANSI_PADDING ON SET ANSI_WARNINGS ON COMMIT BEGIN TRANSACTION GO CREATE TABLE dbo.Tmp_TestTable ( id int NOT NULL IDENTITY (1, 1), itemdate datetime NOT NULL, title varchar(50) NOT NULL ) ON [PRIMARY] GO ALTER TABLE dbo.Tmp_TestTable SET (LOCK_ESCALATION = TABLE) GO SET IDENTITY_INSERT dbo.Tmp_TestTable ON GO IF EXISTS(SELECT * FROM dbo.TestTable) EXEC('INSERT INTO dbo.Tmp_TestTable (id, itemdate, title) SELECT id, itemdate, title FROM dbo.TestTable WITH (HOLDLOCK TABLOCKX)') GO SET IDENTITY_INSERT dbo.Tmp_TestTable OFF GO DROP TABLE dbo.TestTable GO EXECUTE sp_rename N'dbo.Tmp_TestTable', N'TestTable', 'OBJECT' GO COMMIT
All that can be replaced with this simple one line command, it runs much faster and it doesn't recreate anything, no data is being moved around either.
ALTER TABLE [TestTable] ALTER COLUMN [title] [varchar] (50)
The only time you should be using the designer is if the table is empty or if you want to see what kind of T-SQL the designer generates. You can see the T-SQL that SSMS generates by clicking on the Generate Change Script icon, you can then copy the T-SQL into a SSMS query window to look at it. You can see the Generate Change Script icon in the image below
By the way, SSMS will by default disable the recreation of tables when clicking on the save button, this can be disabled or enabled by unchecking or checking the highlighted option in the image below. You can get to this by clicking Tools-->Options-->Table and Database Designers
No comments:
Post a Comment