Sunday, October 28, 2007

Happy Birthday Bill Gates ...


Bill Gates turns 52 today :) Happy Birthday BillG.


Tuesday, October 23, 2007

Wednesday, October 10, 2007

SQLCMD -- Part VIII (:r and about concatenating string with spaces)

Theory:

:r -- parses additional T-SQL statements and sqlcmd commands from the file specified by into the statement cache.

In this article we would see the usage of :r as well as handling spaces in SQLCMD.

In SQL Mgmt Studio:

Step 1: 01VariableInitialization.sql

:setvar filepath "C:\Vadivel\SQL Related\Scripts\sqlcmd"
:r $(filePath)\02TableCreation.sql


Step 2: 02TableCreation.sql

Create table tblTest
(
Sno int identity,
FName varchar(20)
)
Go

:r $(filePath)\03InsertScripts.sql


Step 3: 03InsertScripts.sql

Insert into tblTest (Fname) values ('alpha')

Explanation of each file:

01VariableInitialization.sql -- In this file we create a scripting variable 'filePath' which will hold the path of the .sql files which we use for this demo. Then it executes 02TableCreation.sql.

02TableCreation.sql -- In this, we create tables of our choice. Also we make use of the scripting variable created in the previous file here to call another .sql file to insert records into this table.

It's advisable to check whether that table exists before creating it.

03InsertScripts.sql -- Insert records into our dummy table.

In Command Prompt:

Now open command prompt (start >> Run >> cmd) and connect to a DB server to execute the first .sql file alone.

Step 4: SQLCMD -i "C:\Vadivel\SQL Related\Scripts\sqlcmd\01VariableInitialization.sql"

Till now everything would have worked properly.

Step 5: If at all you have your 01VariableInitialization.sql as shown below:

:setvar filepath "C:\Vadivel"
:r $(filePath)\SQL Related\Scripts\sqlcmd\02TableCreation.sql


If you try this it would fail. Why? Because there is a space within the string which we have concatenated with our scripting variable. So if we have space then we need to enclose the string within quotes.

Is this the way to add quotes?
:r $"(filePath)\SQL Related\Scripts\sqlcmd\02TableCreation.sql"

No this would throw an syntax error!!

The correct way to add quotes is shown below:

:r $(filePath)"\SQL Related\Scripts\sqlcmd\02TableCreation.sql"

So the lesson learned is add quotes only for the string which is being concatenated with a scripting variable (that too if it has spaces in it).

Hope this helps!

Saturday, October 06, 2007

SQLCMD -- Part VII (Concatenating string with a Scripting Variable)

This example demonstrates the way to create a variable and make use of it for multiple purpose.

Actually in this example we would see how to create a variable and append strings into it. Lets create two Database with slight difference in the name. For example, DB1 and DB2. Then create a table in each DB and populate few records into it.

---Code snippet which needs to be run in Mgmt Studio starts here---
Use master
go

Create Database DB1
go

Use DB1
go

Create table t1 (a int)
go

insert into t1 values (1)
insert into t1 values (2)
insert into t1 values (3)
go

Create database DB2
go

Use DB2
go

Create table t2 (Num int)
go

insert into t2 values (4)
insert into t2 values (5)
insert into t2 values (6)
go

--Code snippet to be run in Mgmt studio ends here---

Now open command prompt and connect into the DB.

Step 1: SQLCMD -U sa -P hot -S VADIVEL
Step 2: Press Enter

Now lets create a variable by name "dbname" and assign 'DB' as the string to it.

Step 3: :setvar dbname DB

Now lets make use of this variable and list out all records from table t1

Step 4: use $(dbname)1
Step 5: go
Step 6: select * from t1
Step 7: go

If you see along with the variable I have appended the value 1. So that it would take it as 'DB1'. Hope I have made the point!

Now lets make use of this variable and list out all records from table t2 which exists within DB2 database

Step 8: use $(dbname)2
Step 9: go
Step 10: Select * from t2
Step 11: go

Monday, October 01, 2007

Reclaiming the table space after dropping a column [without clustered index]

If we drop a column it gets dropped but the space which it was occupying stays as it is! In this article we would see the way to reclaim the space for a table which has a non-clustered Index.

Create a table with non-clustered index in it:

Create Table tblDemoTable_nonclustered (
[Sno] int primary key nonclustered,
[Remarks] varchar(5000) not null
)
Go


Pump-in some data into the newly created table:

Set nocount on
Declare @intRecNum int
Set @intRecNum = 1

While @intRecNum <= 15000

Begin
Insert tblDemoTable_nonclustered (Sno, Remarks ) Values (@intRecNum, convert(varchar,getdate(),109))
Set @intRecNum = @intRecNum + 1
End

Check the fragmentation info before dropping the column:

DBCC SHOWCONTIG ('dbo.tblDemoTable_nonclustered')
GO

Output:

DBCC SHOWCONTIG scanning 'tblDemoTable_nonclustered' table...
Table: 'tblDemoTable_nonclustered' (1781581385); index ID: 0, database ID: 9
TABLE level scan performed.
- Pages Scanned................................: 84
- Extents Scanned..............................: 12
- Extent Switches..............................: 11
- Avg. Pages per Extent........................: 7.0
- Scan Density [Best Count:Actual Count].......: 91.67% [11:12]
- Extent Scan Fragmentation ...................: 41.67%
- Avg. Bytes Free per Page.....................: 417.4
- Avg. Page Density (full).....................: 94.84%
DBCC execution completed. If DBCC printed error messages, contact your system administrator.

Drop the Remarks column and reindex the table:

Alter table tblDemoTable_nonclustered drop column Remarks
go

DBCC DBREINDEX ( 'dbo.tblDemoTable_nonclustered' )
Go

Now check the Fragmentation info:

DBCC SHOWCONTIG ('dbo.tblDemoTable_nonclustered')
GO

Output:

DBCC SHOWCONTIG scanning 'tblDemoTable_nonclustered' table...
Table: 'tblDemoTable_nonclustered' (1781581385); index ID: 0, database ID: 9
TABLE level scan performed.
- Pages Scanned................................: 84
- Extents Scanned..............................: 12
- Extent Switches..............................: 11
- Avg. Pages per Extent........................: 7.0
- Scan Density [Best Count:Actual Count].......: 91.67% [11:12]
- Extent Scan Fragmentation ...................: 41.67%
- Avg. Bytes Free per Page.....................: 417.4
- Avg. Page Density (full).....................: 94.84%
DBCC execution completed. If DBCC printed error messages, contact your system administrator.

If you see there won't be any difference or rather the space hasn't reclaimed yet. Here, DBCC DBREINDEX won't work as nonclustered index are stored in heap. i.e., Heaps are tables that have no clustered index.

Solution:

Select * into #temp from tblDemoTable_nonclustered
Go

Truncate table tblDemoTable_nonclustered
Go

Insert into tblDemoTable_nonclustered select * from #temp
Go

Now check the fragmentation info to see that we have actually reclaimed the space!

DBCC SHOWCONTIG scanning 'tblDemoTable_nonclustered' table...
Table: 'tblDemoTable_nonclustered' (1781581385); index ID: 0, database ID: 9
TABLE level scan performed.
- Pages Scanned................................: 25
- Extents Scanned..............................: 7
- Extent Switches..............................: 6
- Avg. Pages per Extent........................: 3.6
- Scan Density [Best Count:Actual Count].......: 57.14% [4:7]
- Extent Scan Fragmentation ...................: 57.14%
- Avg. Bytes Free per Page.....................: 296.0
- Avg. Page Density (full).....................: 96.34%
DBCC execution completed. If DBCC printed error messages, contact your system administrator.

Hope this helps!

Reclaiming the table space after dropping a column - [With Clustered Index]

If we drop a column it gets dropped but the space which it was occupying stays as it is! In this article we would see the way to reclaim the space for a table which has a clustered Index.

Create a table with clustered index in it:

Create Table tblDemoTable (
[Sno] int primary key clustered,
[Remarks] char(5000) not null
)
Go

Pump-in some data into the newly created table:

Set nocount on
Declare @intRecNum int
Set @intRecNum = 1

While @intRecNum <= 15000

Begin
Insert tblDemoTable (Sno, Remarks ) Values (@intRecNum, convert(varchar,getdate(),109))
Set @intRecNum = @intRecNum + 1
End

If it's SQL 2000 or earlier:

DBCC SHOWCONTIG ('dbo.tblDemoTable') -- Displays fragmentation information for the data and indexes of the specified table
Go

Output:

DBCC SHOWCONTIG scanning 'tblDemoTable' table...
Table: 'tblDemoTable' (1717581157); index ID: 1, database ID: 9
TABLE level scan performed.
- Pages Scanned................................: 80
- Extents Scanned..............................: 12
- Extent Switches..............................: 11
- Avg. Pages per Extent........................: 6.7
- Scan Density [Best Count:Actual Count].......: 83.33% [10:12]
- Logical Scan Fragmentation ..................: 3.75%
- Extent Scan Fragmentation ...................: 8.33%
- Avg. Bytes Free per Page.....................: 33.7
- Avg. Page Density (full).....................: 99.58%
DBCC execution completed. If DBCC printed error messages, contact your system administrator.

If you are using SQL 2005:

As that DBCC feature would be removed in the future version of SQL Server I would suggest the following code snippet instead of DBCC SHOWCONTIG.

Declare @object_id int;
Set @object_id = Object_ID(N'Testbed.dbo.tblDemoTable');

Begin
Select index_type_desc, index_depth, index_level,
avg_fragmentation_in_percent, avg_fragment_size_in_pages,
page_count, avg_page_space_used_in_percent, record_count
from sys.dm_db_index_physical_stats (Db_id(), @object_id, NULL, NULL , 'Detailed');
End
Go

Output:


Drop the column 'Remarks' from the table:

Alter table tblDemoTable drop column Remarks
Go


Now try out DBCC SHOWCONTIG or sys.dm_db_index_physical_stats as explained previously and verify that the details haven't changed a bit :)

Solution:

DBCC DBREINDEX ( 'dbo.tblDemoTable' )
Go

Now try out either the SHOWCONTIG or dm_db_index_physical_stats and see that you have reclaimed the space successfully.

DBCC SHOWCONTIG ('dbo.tblDemoTable')
Go

Output:

DBCC SHOWCONTIG scanning 'tblDemoTable' table...
Table: 'tblDemoTable' (1717581157); index ID: 1, database ID: 9
TABLE level scan performed.
- Pages Scanned................................: 25
- Extents Scanned..............................: 5
- Extent Switches..............................: 4
- Avg. Pages per Extent........................: 5.0
- Scan Density [Best Count:Actual Count].......: 80.00% [4:5]
- Logical Scan Fragmentation ..................: 8.00%
- Extent Scan Fragmentation ...................: 20.00%
- Avg. Bytes Free per Page.....................: 296.0
- Avg. Page Density (full).....................: 96.34%
DBCC execution completed. If DBCC printed error messages, contact your system administrator.

May be this is one another good example of why we need to have clustered index on a table :)

Similarly if you have run this DMV sys.dm_db_index_physical_stats then the output would be this:



BTW, in SQL 2005 though DBCC DBREINDEX would work, its better to start practicing ALTER INDEX syntax.

In the next post we would see how to reclaim the space in a table which doesn't have clustered index in it.

Related Article: Reclaim Unused Table space. This article was written couple of years back and was tested with SQL 2000 at that time.