About Me

My photo
Mumbai, Maharastra, India
He has more than 7.6 years of experience in the software development. He has spent most of the times in web/desktop application development. He has sound knowledge in various database concepts. You can reach him at viki.keshari@gmail.com https://www.linkedin.com/in/vikrammahapatra/ https://twitter.com/VikramMahapatra http://www.facebook.com/viki.keshari

Search This Blog

Friday, May 3, 2013

Know potential reduction in the size of the table before implementing VARDECIMAL


Before we actually go for implementing Vardecimal, we should know whether the table required Vardecimal.  It is clear if a table has no decimal or numeric field, there will be no saving, but even if you have table with decimal and numeric field whether implementing Vardecimal make any sense on storage?  There is no guarantee that you will be able to reduce the size of the table by enabling Vardecimal storage format.

SQL Server provides a stored procedure, to estimate the ‘reduction in row size’ with Vardecimal storage format. We will use this to know whether the table requires Vardecimal implementation.

Let stimulate a situation to know whether to implement Vardecimal by taking two table testWhetherNeedVarDecimal and testWhetherNeedVarDecimal2 and check which among these two require Vardecimal.

Let’s create first table testWhetherNeedVarDecimal  with two field of numeric and varchar type.

create table testWhetherNeedVarDecimal
(col1 numeric(18,2),
col2 varchar(10) default 10)

Now we have table in place let’s populate some data in it.

declare @cnt int
set @cnt=1
while (@cnt < 3000)
begin
      if (@cnt < 2000)
            insert into testWhetherNeedVarDecimal(col1) values(0)
      else
            insert into testWhetherNeedVarDecimal(col2) values((@cnt + 10))
      set @cnt +=1
end

We are ready with table1, now lets create another table testWhetherNeedVarDecimal2.

create table testWhetherNeedVarDecimal2
(col1 numeric(10,2),
col2 varchar(10) default 'asd')

Let’s populate testWhetherNeedVarDecimal2 with some data

declare @cnt int
set @cnt=1
while (@cnt < 3000)
begin
      if (@cnt < 2000)
            insert into testWhetherNeedVarDecimal2(col1) values(12345678.12) 
      set @cnt +=1
end

Now since both the table are ready, let’s try analyze which table requires Vardecimal by firing system stored procedure sp_estimated_rowsize_reduction_for_vardecimal

exec sp_estimated_rowsize_reduction_for_vardecimal 'testWhetherNeedVarDecimal'

avg_rowlen_fixed_format  avg_rowlen_vardecimal_format  row_count
-----------------------  ----------------------------  ---------
22.67                                   15.67          2999

exec sp_estimated_rowsize_reduction_for_vardecimal 'testWhetherNeedVarDecimal2'

avg_rowlen_fixed_format  avg_rowlen_vardecimal_format  row_count
-----------------------  ----------------------------  ---------
22.00                                   21.00          1999

So it is clear from the output that table testWhetherNeedVarDecimal requires Vardecimal, and by doing so user will be able to save (22.67-15.67) 7 byte per record which is significant enough to save.

Focus on code what really matters & letting go of the rest.


Post Reference: Vikram Aristocratic Elfin Share

Just like Varchar for Char, why don’t we have Varnumeric for Numeric…


When tables grow to millions of rows reducing the amount of storage a few bytes per row can have significant effect. The decimal and numeric data types are typically stored on disk as fixed-length data. Mostly these values are defined with high precision, but precision is not required in most of these cases. In such cases the storage space consumed is unnecessary. The situation becomes even worse when NULL or zero values are also present in numeric or decimal type column. Such issues are required to be addressed for optimization of storage space, but what options are available?


SQL Server 2005 has introduced the VARDECIMAL storage format. This new storage format, stores decimal and numeric data as variable length columns and can be enabled or disabled at the table level.

When a table is not using the VARDECIMAL format every numeric or decimal value uses a fixed size (between 5 and 17 bytes) even when the data is 0. With VARDECIMAL, storage becomes dynamic and optimized for each value.

The VARDECIMAL is implemented at table level, so we can have table first with all column defined and inserted data, there after we can find how much space it takes without actually going for VARDECIMAL and how much we can save if we go for VARDECIMAL.

Let create the scenario to test the VARDECIMAL, we are creating table with decimal and numeric datatype fields

create table testVarDecimal
(col1 decimal(18,0),
col2 numeric(18,0))
Command(s) completed successfully.

Now lets try to insert around 4000 record in by the below script.

declare @cnt int
set @cnt=1
while (@cnt < 4000)
begin
      if (@cnt < 2000)
            insert into testVarDecimal values(@cnt,0)
      else
            insert into testVarDecimal values(@cnt,(@cnt + 100))
      set @cnt +=1
end

Now since we have records in place, lets analyze how much space we can reduce if we implement VARDECIMAL to this table.

exec sp_estimated_rowsize_reduction_for_vardecimal 'testVarDecimal'

avg_rowlen_fixed_format   avg_rowlen_vardecimal_format  row_count
-----------------------   ----------------------------  ----------
25.00                                   16.27           3999

We can see that there may be difference of about (25.00 – 16.27) i.e.9 bytes in each row. So it seems suitable to apply vardecimal storage for this table.

To implement VARDECIMAL, we first need to enable it for the database, which can done like the way below

execute sp_db_vardecimal_storage_format 'testDemo', 'on'
Command(s) completed successfully.

Here my database is testDemo, you can put your own database name, where your table object reside.
Now let’s implement it on table by following script

exec sys.sp_tableoption 'testVarDecimal', 'VarDecimal storage format',1

So it is all over. If you want to check which all database has VarDecimal Enabled just fire the below command

exec sp_db_vardecimal_storage_format

To check which table has VARDECIMAL enabled execute the following

select name, OBJECT_ID, type_desc from sys.objects 
WHERE OBJECTPROPERTY(OBJECT_ID, N'TableHasVarDecimalStorageFormat') = 1

Code not always straightforward, but rewards are worth it