SQL SERVER – Difference TempTable and Table Variable – TempTable in Memory a Myth

Recently, I have been conducting many training sessions at a leading technology company in India. During the discussion of temp table and table variable, I quite commonly hear that Table Variables are stored in memory and Temp Tables are stored in TempDB. I would like to bust this misconception by suggesting following:

Temp Table and Table Variable — both are created in TempDB and not in memory.

Let us prove this concept by running the following T-SQL script.

/* Check the difference between Temp Table and Memory Tables */
-- Get Current Session ID
SELECT @@SPID AS Current_SessionID
-- Check the space usage in page files
SELECT user_objects_alloc_page_count
FROM sys.dm_db_session_space_usage
WHERE session_id = (SELECT @@SPID )
GO
-- Create Temp Table and insert three thousand rows
CREATE TABLE #TempTable (Col1 INT)
INSERT INTO #TempTable (Col1)
SELECT TOP 3000 ROW_NUMBER() OVER(ORDER BY a.name)
FROM sys.all_objects a
CROSS JOIN sys.all_objects b
GO
-- Check the space usage in page files
SELECT user_objects_alloc_page_count
FROM sys.dm_db_session_space_usage
WHERE session_id = (SELECT @@SPID )
GO
-- Create Table Variable and insert three thousand rows
DECLARE @temp TABLE(Col1 INT)
INSERT INTO @temp (Col1)
SELECT TOP 3000 ROW_NUMBER() OVER(ORDER BY a.name)
FROM sys.all_objects a
CROSS JOIN sys.all_objects b
GO
-- Check the space usage in page files
SELECT user_objects_alloc_page_count
FROM sys.dm_db_session_space_usage
WHERE session_id = (SELECT @@SPID )
GO
-- Clean up
DROP TABLE #TempTable
GO

Let us see the resultset. It is very clear that the size of the table variable and temp table is the same and created in TempDb.

Have you ever heard of this misconception? Do you know any other method to prove that both Temp Table and TableVariable are created in TempDB.

Update : Ken Simmons have written excellent another article proving without inserting data that temp table and table variable both are created in TempDB please read here.

Reference: Pinal Dave (http://blog.SQLAuthority.com)

About these ads

65 thoughts on “SQL SERVER – Difference TempTable and Table Variable – TempTable in Memory a Myth

  1. Hi Pianl,

    I want to know the temp table name max length in temp db.

    What is the naming convention will be used to store the temp table name?

    Please explain the procees which is happening inside the SQL Server while creating temp table?

    Thanks in Advance.

    Regards
    Prasad

    • temporary table gives better performance than temporary variable.why means when we want to fire any query the temp table with bulk data gives result with max speed . table variable only for small amount of data.

  2. Hi,

    That is true, but when we used Temp table in place of table variable, performance much faster.

    We didn’t try to prove it. But there should be some difference in storage, that’s why we got better performance.

    is it when releasing memory after used?

    as usual Great Explanation..

    Thanks,

    Tejas

    • Hi Tejas,
      1. Yes as far as performance goes table variable does not outperform temp tables necessarily. Here is a quote from sqlmag (SQL Server Magazine)

      Table Variables vs. Temporary Tables
      By: Brian Moran
      Quote:
      A senior member of the SQL Server development team told me that table variables use internal metadata in a way that prevents the engine from using a table variable within a parallel query. He also said that SQL Server maintains statistics for queries that use temporary tables but not for queries that use table variables. Without statistics, SQL Server might choose a poor processing plan for a query that contains a table variable. The development team member added that you should limit your use of SQL Server 2000 table variables to reasonably small queries and data sets and use temporary tables for larger data sets.

      2. There is a situation using a table variable is preferred.
      In a user defined function if you want to access a temp table it is not possible, where you can access a table variable. For example: the following will work: the second example will not work, there will be compilation erors:

      CREATE FUNCTION dbo.example1
      (
      )
      RETURNS INT
      AS
      BEGIN
      DECLARE @t1 TABLE (i INT)
      INSERT @t1 VALUES(1)
      INSERT @t1 VALUES(2)
      UPDATE @t1 SET i = i + 5
      DELETE @t1 WHERE i < 7

      DECLARE @max INT
      SELECT @max = MAX(i) FROM @t1
      RETURN @max
      END
      GO

      Example 2:
      CREATE FUNCTION dbo.example2
      (
      )
      RETURNS INT
      AS
      BEGIN
      CREATE TABLE #t1 (i INT)
      INSERT #t1 VALUES(1)
      INSERT #t1 VALUES(2)
      UPDATE #t1 SET i = i + 5
      DELETE #t1 WHERE i < 7

      DECLARE @max INT
      SELECT @max = MAX(i) FROM #t1
      RETURN @max
      END
      GO

  3. This Q/A on stackoverflow: http://stackoverflow.com/questions/27894/whats-the-difference-between-a-temp-table-and-table-variable-in-mssql leads to a few other articles (note the accepted answer), the MS KB article seems to be down right now, but the MSDN blog article above that says that “First, the table variable is NOT necessarily memory resident. Under memory pressure, the pages belonging to a table variable can be pushed out to tempdb.”, which sounds to me like a much smaller test would need to be performed to determine if a table variable, when it is afforded plenty of RAM, will stay in memory…

  4. Hi Pinal,
    Good clarification,(there are still articles out there which claim table variables are created in memory).
    Thanks for the sql…

    Ramdas

  5. Thank you very much Ramdas for your very excellent note.

    Hello All,

    If you attempt this experiment with very simple and small number of rows, it will still give you same result – which means both of them are created in TempDB and no in memory.

    Kind Regards,
    Pinal

    • Hi pinal I run the query of 3000 records ,it gives the same result ,, I want to ask that ,,, is it proved that the great number o f rows can n’t be created in memory?

  6. I did not understand how the page count 6 and 12 for temp table and table variable resp shows that both uses tempdb. Can anyone explain this? Thanks.

  7. Hi Pinal,

    Thanks for the explanation. Have couple of questions haunting me now:

    1. If both reside in tempDB, how are table variables different from temp tables? What is the advantage of using table variables in place of temp tables?
    2. Why is it adviced to go for temporary tables when there is huge amount of data being stored in table variables?

    Request you to throw some light on this to make things more clear which would help us in better understanding on each of these at concept and usability level.

    Thanks for all your knowledge sharing.

    Regards,
    Phani.

    • Hi Phani,
      In the comments section i have attempted to throw some light on the questions you have, look at the reply for tejas shah in the comments section.

      Thank you

  8. Hello Phani,

    In case of large amount of data temp table is advised because sql server creates, maintains and uses the statistics of temp table while generating the execution plan. Besides this we can create index in tenp tables if that is needed.

    Regards,
    Pinal Dave

  9. I have tried the sequences and it worked ,but when i drop temp #TempTable the user_objects_alloc_page_count did not clear to 0 ,WHY?

  10. Hello sir,
    Great Topic to Discuss on blog.
    good explanation with example and very useful too.

    Ramdas has also give very good comment and very good explanation.

  11. Used temp (#) in this procedure. Check it out…

    alter procedure sp_Insert
    (
    @vStr varchar(max)
    )
    as

    Begin

    Declare @GetLine varchar(max), @GetCol varchar(max)
    Declare @p int, @col1 varchar(30), @col2 varchar(30)

    — Select @maxid = max(InvID) from tblMaster1
    — Delete from tblDetail1 where lid = @maxid

    create table #temp1 (col1 varchar(20), col2 varchar(20))

    While (len(@vstr) !=0)
    Begin
    if (len(@vstr) !=0 and charindex(‘^^’,@vstr,0) = 0)
    Begin
    set @getline = @vstr
    set @vstr = ”
    End
    else
    Begin
    Select @getline = substring(@vstr,0,charindex(‘^^’,@vstr,0))
    End

    set @p = 0

    While (len(@getline)!=0)
    Begin
    if (len(@getline) !=0 and charindex(‘^’,@getline,0) = 0)
    Begin
    set @getcol=@getline
    set @getline=”

    End
    Else
    Begin
    print @getline
    Select @getCol = substring(@getline,0,charindex(‘^’,@getline,0))
    print @getcol

    End
    set @P=@P+1
    IF(@p=1)
    begin

    set @col1= @getcol

    end

    if (@p=2)
    begin
    set @col2= @getcol

    end
    Set @getline = substring(@getline , charindex(‘^’ ,@getline,0)+1, len(@getline))
    print @getline
    End

    — Select @maxid= isnull(max(lid) from tbldet
    insert into #temp1 values(@col1,@col2)

    Set @vstr = substring(@vstr,charindex(‘^^’,@vstr,0)+2 , len(@vstr))

    End

    Select * from #temp1

    End

  12. Pingback: SQL SERVER – Difference Temp Table and Table Variable – Effect of Transaction Journey to SQL Authority with Pinal Dave

  13. On our test/development database server (2 sql server instances) with 4GB memory had a proc using table variabes and was running over 5 minutes. Changed to temp tables and is now running under 30 seconds. In production (single instance with 4GB) ran fine with table variables – around 30 seconds. Assuming memory constraints contributed to poor performance on test/development server, rather than stats.

  14. Hello Jakey,

    Table variables performs good only for small resordset. Because there data statistics is not used while creating the execution plan and because of that sometimes fully optimized plan are not created.
    Table variable should be used where they are joined with small tables only.

    There are many more details which are associated with table variables but this is just one line answer here.

    Regards,
    Pinal Dave

    • Hello, In terms of performance, is it better to create the temp table and use it or is it better to create the temp table on the fly?

      Is this better to do as below:
      create table #tv_target (c11 int, c22 char(100))
      go

      INSERT INTO #tv_target (c11, c22)
      SELECT c1, c2 FROM tv_source

      or is it better to do as below:
      SELECT c1, c2 into #tv_target
      FROM tv_source

  15. Please see this query :-

    SELECT TOP 3000 ROW_NUMBER() OVER(ORDER BY a.name)

    gives error like

    ‘ROW_NUMBER’ is not a recognized function name.
    when i run ito SQL 2005

    Please can u tell me function for gettin rowno in
    MS-SQL-2005 or 2008

  16. I want to do replication of two tables having two diff names and (same structure but diff records )
    in single table at subscriber side.

    Is it possible in SQL server 2008 or 2005.

    Please give me solution.

  17. The following stmt gives me the temp tables I created:
    SELECT TABLE_NAME
    FROM tempdb.INFORMATION_SCHEMA.TABLES
    WHERE TABLE_NAME LIKE ‘%#%';

    But it does not show me the table variables created in tempdb.

    How can I get the list of table variables created in tempdb?

  18. My ten pence.

    I have a rule of thumb that you should use what ever tool is best for the job.

    In this case temp tables or table variables.

    When having to run a ‘while’ loop or having to rerun the query many times, OR if I need to create a rank in a set of data the Table variable is best as you can program your SQL to run like you would run a data set in code, you have no need to have to keep dropping the table (which is always annoying), and you can use a quick ID identity field in the table variable create script that can give you a handy rank, rownumber or sequence number.

    Use Temp tables for all else and don’t forget the temp table has the global option which is very useful too when having two connections open and running multiple tests at the same time.

    When putting together the design in the first place you may find that creating a non temporary static table is always the best option, maybe developers get too hung up on leaving the workings out in the database, when in fact it makes debugging and picking up other peoples development far easier and you can index in the normal fashion improving performance.

    Regards

    Darren Harvey
    BI Dude MCTS, MCITP, MCDBA

  19. Hello,
    In my case when I use table variable my query time counts 7 sec and for temp table it is near about 30 sec.
    my main table rows are 3 million. After reading all these comments i am confuesd what should i use ?

    according to this blog table variable consumes double size then temp table.

    Plz make me happy with some usefull advice.

    Thanks & Regards
    Pramod sharma

  20. Pinal dave, I have used Global temp table and temp table.
    Temp table has dropped once the query get closed,
    Global temp table has dropped once the connection where it created get closed but in your definition you have mentioned that the global temp table definition will remain permanently, how ? kindly give me explaination..

  21. If memory serves me correctly, it’s not about in-memory or not; it’s all about scope of the connection. #TableName will get you in trouble with web services that use one connection. However, if you use table variables, the temp table is contained within the scope of the stored procedure.

  22. First, the table variable is NOT necessarily memory resident. Under memory pressure, the pages belonging to a table variable can be pushed out to tempdb. Here is one example shows space taken by table variable in tempdb

    use tempdb

    go

    drop table #tv_source

    go

    create table #tv_source(c1 int, c2 char(8000))

    go

    declare @i int

    select @i = 0

    while (@i 100 and name like ‘c%’

    This will return two rows containing columns c111 and c222. Now this means that if you were encountering DDL contention, you cannot address it by changing a #table to table variable.

    · Third, transactional and locking semantics. Table variables don’t participate in transactions or locking. Here is one example

    — create a source table

    create table tv_source(c1 int, c2 char(100))

    go

    declare @i int

    select @i = 0

    while (@i < 100)

    begin

    insert into tv_source values (@i, replicate ('a', 100))

    select @i = @i + 1

    end

    — using #table

    create table #tv_target (c11 int, c22 char(100))

    go

    BEGIN TRAN

    INSERT INTO #tv_target (c11, c22)

    SELECT c1, c2

    FROM tv_source

    — using table variable

    DECLARE @tv_target TABLE (c11 int, c22 char(100))

    BEGIN TRAN

    INSERT INTO @tv_target (c11, c22)

    SELECT c1, c2

    FROM tv_source

    — Now if I look at the locks, you will see that only

    — #table takes locks. Here is the query that used

    — to check the locks

    select

    t1.request_session_id as spid,

    t1.resource_type as type,

    t1.resource_database_id as dbid,

    (case resource_type

    WHEN 'OBJECT' then object_name(t1.resource_associated_entity_id)

    WHEN 'DATABASE' then ' '

    ELSE (select object_name(object_id)

    from sys.partitions

    where hobt_id=resource_associated_entity_id)

    END) as objname,

    t1.resource_description as description,

    t1.request_mode as mode,

    t1.request_status as status,

    t2.blocking_session_id

    from sys.dm_tran_locks as t1 left outer join sys.dm_os_waiting_tasks as t2

    ON t1.lock_owner_address = t2.resource_address

    Another interesting aspect is that if I rollback the transaction involving the table variable earlier, the data in the table variable is not rolled back.

    Rollback

    — this query will return 100 for table variable but 0 for #table.

    SELECT COUNT(*) FROM @tv_target

    · Fourth, the operations done on table variable are not logged. Here is the example I tried

    — create a table variable, insert bunch of rows and update

    DECLARE @tv_target TABLE (c11 int, c22 char(100))

    INSERT INTO @tv_target (c11, c22)

    SELECT c1, c2

    FROM tv_source

    — update all the rows

    update @tv_target set c22 = replicate ('b', 100)

    — look at the top 10 log records. I get no records for this case

    select top 10 operation,context, [log record fixed length], [log record length], AllocUnitId, AllocUnitName

    from fn_dblog(null, null)

    where AllocUnitName like '%tv_target%'

    order by [Log Record Length] Desc

    — create a local temptable

    drop table #tv_target

    go

    create table #tv_target (c11 int, c22 char(100))

    go

    INSERT INTO #tv_target (c11, c22)

    SELECT c1, c2

    FROM tv_source

    — update all the rows

    update #tv_target set c22 = replicate ('b', 100)

    — look at the log records. Here I get 100 log records for update

    select operation,context, [log record fixed length], [log record length], AllocUnitName

    from fn_dblog(null, null)

    where AllocUnitName like '%tv_target%'

    order by [Log Record Length] Desc

    · Fifth, no DDL is allowed on table variables. So if you have a large rowset which needs to be queried often, you may want to use #table when possible so that you can create appropriate indexes. You can get around this by creating unique constraints when declaring table variable.

    · Finally, no statistics is maintained on table variable which means that any changes in data impacting table variable will not cause recompilation of queries accessing table variable.

  23. Hello,

    please,How can I programaticaly get the structure of Table variable ?.

    i can get the name from sys.type but not the metada.

    need help.

    • @said,

      Table Variable has to be defined and declared, unlike a temporary table.

      You cannot get a structure into a Table variable unlike temporary table.

      Simple example to declare a table variable.

      Declare @Example Table (Eid int NOT NULL, EmpName varchar(40) NOT NULL)

      There is always an option to go dynamic and build a table variable by reading the source table structure, but I dont recommend it unless it is absolutely neccessary. If the table structure does not change, then declare the table variable as shown above.

      Hope this helps.

      ~ IM.

  24. Pingback: SQL SERVER – Debate – Table Variables vs Temporary Tables – Quiz – Puzzle – 13 of 31 « SQL Server Journey with SQL Authority

  25. you can create table variable even if you dont have an acces on tempdb
    but u cant create temp table.

    so that proves temp tables are created in tempdb but table variables are not

  26. ALTER PROC usp_InsertCustomer
    (@CustName VARCHAR(50),
    @dob DATETIME,
    @Gender CHAR(1),
    @Contact VARCHAR(10),
    @Pan VARCHAR(10),
    @Add VARCHAR(100)
    )
    AS
    BEGIN
    BEGIN TRY
    BEGIN
    IF EXISTS(SELECT * FROM tbl_Customer1)
    BEGIN

    DECLARE @custid VARCHAR(4)
    DECLARE @count INT

    –Auto generating customer id
    SET @count = (SELECT COUNT(CustId) FROM tbl_Customer1)
    SET @custid = ‘C’ + CONVERT(VARCHAR(4),100+@count)
    SELECT @custid

    –Auto generating Customer table name
    DECLARE @TranTable VARCHAR(20)
    SET @TranTable=’Tran_Table’+@custid
    SELECT @TranTable

    DECLARE @abc VARCHAR(100)
    SET @abc=’CREATE TABLE @TranTable(TID VARCHAR(10) PRIMARY KEY,
    TranType VARCHAR(20) NOT NULL,
    TranDesc VARCHAR(100) NOT NULL,
    Amount MONEY NOT NULL,
    Tag VARCHAR(20) NOT NULL,
    TranDate DATETIME NOT NULL
    )’
    SET @abc=REPLACE(@abc,’@TranTable’,@TranTable)

    EXEC(@abc)

    –Inserting values into customer table

    –Inserting values into Customer login Table
    DECLARE @uid VARCHAR(50)
    DECLARE @pwd VARCHAR(50)
    SET @uid=@CustName+@count
    SET @pwd=@CustName+@count
    INSERT INTO tbl_CustLogin VALUES(@custid,@uid,@pwd,GETDATE())

    –On successful Insertion returning 0
    RETURN 0
    END
    ELSE
    –If their is no customer insert bydefault 1 customer id
    INSERT INTO tbl_Customer1(CustId) VALUES(‘C100′)
    RETURN -1
    END
    END TRY
    BEGIN CATCH
    PRINT ERROR_MESSAGE()
    RETURN -2
    END CATCH
    END

  27. Sir in above code i want to create permanant table is it possible because every time their will be new name as per my table columns

  28. Hi,
    I have one query over here, when i created Temp Table and insert records, the user_objects_alloc_page_count comes out to be 10, when i drop the table, again it shows 10 against user_objects_alloc_page_count. It should come back to 4 as it was initially …please throw light on this..

  29. Temp tables cannot be used in table valued functions where table variables can be used

    Temp tables may have indexes added and table variables only can have Primary and unique key constraints as indexes.

    Table variables are dropped at the end of a batch but temp tables are dropped at the end of a session / stored procedure

    Table variables are not transactional and do not roll back. temp tables are transactional and do roll back.

    Temp tables are visible to called procedures but table variables

    Query optimizer always assumes that one row is returned from a table variable. Temp tables with indexes have statistics that generate better plans.

  30. Try the following code which shows a new temp table is created every time when the code block is executed

    BEGIN
    — Create Table Variable and insert three thousand rows
    DECLARE @temp TABLE(Col1 INT)
    INSERT INTO @temp (Col1)
    SELECT TOP 3000 ROW_NUMBER() OVER(ORDER BY a.name)
    FROM sys.all_objects a
    CROSS JOIN sys.all_objects b

    SELECT * FROM tempdb.sys.objects order by create_date desc
    END

  31. Hi Pinal,

    Can you correct the heading of your article which says “Temp table in memory a myth”….It should be “Table Variable in memory a myth”

  32. Hi Pinal,
    If I have created one temporary table #table1 in one stored procedure in sql having some input variables.
    If multiple user executes this then is #table1 created twice time in TempDB or created only once.
    If created only once, then can user1 get data of #table1 in which data is inserted by other user.
    Please have some reply.

  33. Hi Pinal,

    On which basis we will distinguish Large Table and Small Table.

    Can I say transaction table as Large table and master table is small table.Please Clarify . Thanks.

  34. Hi Pinal,
    Let I am creating a Payroll module which is supposed to generate pay slip for 50 Thousands employees at a time and In my Proc I am dealing with temp table ,which is not good by some experts view ,so please help me how should I deal ?

    I think , I should adopt table partitioning concept on main transaction table and based on that i will go forward in my GUI.Is it Fine or what step should I adopt.

    Please Clarify ASAP . Thanks.

  35. @Pinal.

    The only reason I can think of when I use temporary variables against temporary tables is when I have to perform ROLLBACK operation.

    Like some one mentioned above in their comments. Rollback operation also rollesback data from temporary tables. I usually do logging in temporary variables and even if the transactiosn rollsback, I still want to see why the transaction failed and until what point it executed with no errors. I capture all this information in table variables, on error I rollback the transaction but I still have all my information logged in table variables which is not rolledback which I then write to my permemnant tables as part of error handling.

    There is a difference in scope of Table Variable and Temporary table. I usually prefer Temporary tables over table variables when working with Dynamix SQL, they are easy to work with.

    ~ IM.

  36. Hi Pinal,

    Thanks for the article. I noticed the below with your example. When I execute the below query

    SELECT *
    FROM sys.dm_db_session_space_usage
    where session_id =

    I see after creating temp table the user_objects_dealloc_page_count value is 0. But After creating table variable the value is equal to the pages created. It seems, the pages are deallocated and the data is kept in memory incase of table variable. I also read an article which says, table variable will flush the data to tempdb when it come across memory pressure.

  37. declare @var1 numeric(10,2),
    @var2 numeric(10,2),
    @var3 numeric(10,2),
    @var4 numeric(10,2)

    set @var1=12500
    set @var2=NULL
    set @var3=500

    select @var4=(@var1+@var2+@var3)

    print @var4

    Why its not print the value sir…

  38. Pingback: SQL SERVER – SSMS does NOT Print NULL Values | SQL Server Journey with SQL Authority

  39. I have written the following code in my stored Procedure which cause error while compiling. Please help.

    if @l_Class_Code ’55’
    begin
    SELECT row_number() over(order by t.Class_Code) as srl,t.*
    into #TmpPolicyDetails
    FROM uplPolicyDetails t
    Where convert(nvarchar(10),DateReceiptatTpa,103) = @DateReceivedAtTpa
    and Office_Code = @BranchCode
    and LocationID = @LocationID
    and UploadedByID = cast(@UserCode as nvarchar(20))
    and Class_Code = @l_Class_Code
    and Updated = ‘N';
    end;
    else
    begin
    SELECT row_number() over(order by t.Class_Code) as srl,t.*
    into #TmpPolicyDetails
    FROM uplPolicyDetails t
    Where convert(nvarchar(10),DateReceiptatTpa,103) = @DateReceivedAtTpa
    and Office_Code = @BranchCode
    and LocationID = @LocationID
    and UploadedByID = cast(@UserCode as nvarchar(20))
    and Class_Code = @l_Class_Code
    and cast(rtrim(ltrim(DevOfficerID)) as int) = @l_DevOfficerID
    and Updated = ‘N';
    end;

  40. hi,
    I have created procedure like .

    USE [master]
    GO
    /****** Object: StoredProcedure [dbo].[b] Script Date: 04/28/2013 01:09:39 ******/
    SET ANSI_NULLS ON
    GO
    SET QUOTED_IDENTIFIER ON
    GO
    ALTER proc [dbo].[b]
    as
    begin
    declare @i table (id int)
    select * From tempdb.sys.tables
    end

    and after i ran the executed my proce

    exec b

    The result is :
    name objectid
    #023D5A04 37575172 and so on…

    i closed the above connection and after i opened new connection and ran the query like

    select * from tempdb.sys.tables

    it is showing the below result and table exists in tempdb with the name:

    The result is :
    name objectid
    #023D5A04 37575172 and so on…

    Question is:
    Why did not it automatically dropped when i ran procedure and even i closed the connection please help on this..

    Thanks,
    Dastagiri

  41. It might be old post but just happened to get through it and thought of updating one major performance difference ..
    @table variable never uses parallel operators where as Temp table does, which actually changes Performance impact in a great way.
    Thanks,
    Aditya

  42. This article might be old but topic is ever refreshing..thought of adding one more input which is major performance difference between Table variable and Temp table

    @table variable doesnt use Parallel operator where as temp table does, No matter how much is ur data in @table variable this would be a major hit in DWH

    Thanks,
    Aditya

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s