SQL SERVER – Storing Variable Values in Temporary Array or Temporary List

SQL Server does not support arrays or a dynamic length storage mechanism like list. Absolutely there are some clever workarounds and few extra-ordinary solutions but everybody can;t come up with such solution. Additionally, sometime the requirements are very simple that doing extraordinary coding is not required. Here is the simple case.

Let us say here are the values: a, 10, 20, c, 30, d. Now the requirement is to store them in a array or list. It is very easy to do the same in C# or C. However, there is no quick way to do the same in SQL Server. Every single time when I get such requirement, I create a table variable and store the values in the table variables. Here is the example:

For SQL Server 2012:
DECLARE @ListofIDs TABLE(IDs VARCHAR(100));
INSERT INTO @ListofIDs
VALUES('a'),('10'),('20'),('c'),('30'),('d');
SELECT IDs FROM @ListofIDs;
GO

When executed above script it will give following resultset.

Above script will work in SQL Server 2012 only for SQL Server 2008 and earlier version run following code.

DECLARE @ListofIDs TABLE(IDs VARCHAR(100), ID INT IDENTITY(1,1));
INSERT INTO @ListofIDs
SELECT 'a'
UNION ALL
SELECT '10'
UNION ALL
SELECT '20'
UNION ALL
SELECT 'c'
UNION ALL
SELECT '30'
UNION ALL
SELECT 'd';
SELECT IDs FROM @ListofIDs;
GO

Now in this case, I have to convert numbers to varchars because I have to store mix datatypes in a single column. Additionally, this quick solution does not give any features of arrays (like inserting values in between as well accessing values using array index).

Well, do you ever have to store temporary multiple values in SQL Server – if the count of values are dynamic and datatype is not specified early how will you about storing values which can be used later in the programming.

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

About these ads

17 thoughts on “SQL SERVER – Storing Variable Values in Temporary Array or Temporary List

  1. Hi PInal,

    Given query I tried on “Sql Server 2008 R2″ as well as “Sql Server 2012″ it’s working in both of them.
    ——————————————————————–
    DECLARE @ListofIDs TABLE(IDs VARCHAR(100));
    INSERT INTO @ListofIDs
    VALUES(‘a’),(’10’),(’20’),(‘c’),(’30’),(‘d’);
    SELECT IDs FROM @ListofIDs;
    ——————————————————————–

    In “Sql Server 2005″ it’ll not work.

  2. If for multidatatype varchar is use then to manipulate those data ,one has to use isnumeric,isdate etc. and do manipulation,which is little lengthy process.Beside this one cannot find the exact other datatype beside these two isdate and isnumeric.So process is lengthy and complicated.

    In case of Sql_variant,same thing is very easy.We can use sql_variant_property to do so.

    declare @t table(col1 sql_variant )
    insert into @t values(1),(‘2′)
    Select sql_variant_property(col1, ‘BaseType’) from @t

    vs

    declare @t table(col1 varchar(100) )
    insert into @t values(1),(‘2′)
    Select sql_variant_property(col1, ‘BaseType’) from @t

  3. Hi Pinal ,
    If values are stored in variable then how above script.works.
    e.g:
    Declare @var NVARCHAR(max)
    @var = ‘a,b,c,d’

  4. We can also get a similar result using CTE

    Declare @stringvar VARCHAR(max)
    set @stringvar = ‘a,10,20,c,30,d';
    with cte(IDs,stringvalue,id)
    as
    (
    select cast(” as VARCHAR(MAX)), @stringvar, 0
    union all
    select left(stringvalue,charindex(‘,’,stringvalue,0)-1), right(stringvalue,len(stringvalue)-charindex(‘,’,stringvalue,0)), id+1 from cte where charindex(‘,’,stringvalue,0)>0
    union all
    select stringvalue,”, id+1 from cte where charindex(‘,’,stringvalue,0)=0 and stringvalue”
    )
    select IDs from cte where IDs”

  5. DECLARE @ListofIDs TABLE(IDs VARCHAR(100));
    INSERT INTO @ListofIDs
    VALUES(‘a’),(’10’),(’20’),(‘c’),(’30’),(‘d’);
    SELECT IDs FROM @ListofIDs;
    script is also works in Sql Server 2008 R2.
    Check this out..

  6. A table-typed variable is useful. But you can also use the XML data type.

    My preference is to use a table-typed variable (it’s just easier to work with), but when you have data where each row does not conform to the same shape and data types, xml is very flexible. It does require learning some XQuery though:

    This will load up an XML-typed variable:

    DECLARE @MyListXML [xml]
    
    SET @MyListXML = CAST	(	'<root>
    								<item type="varchar(20)"	>a</item>
    								<item type="int"			>10</item>
    								<item type="int"			>20</item>
    								<item type="varchar(20)"	>c</item>
    								<item type="int"			>30</item>
    								<item type="varchar(20)"	>d</item>
    							</root>'	
    						as [xml]
    						);
    

    This will allow you to see it represented as a table:

    SELECT	T.c.query('.')											as [raw_element], 
    		T.c.query('.').value('(/item/@type)[1]', 'varchar(20)') as [data_type], 
    		T.c.query('.').value('(/item)[1]', 'varchar(20)')		as [value]
    FROM	@MyListXML.nodes('/root/item') T(c)
    

    This will allow you to work with only the [int] typed data stored within the XML variable:

    SELECT	T.c.query('.')											as [raw_element], 
    		T.c.query('.').value('(/item/@type)[1]', 'varchar(20)') as [data_type], 
    		T.c.query('.').value('(/item)[1]', 'varchar(20)')		as [value]
    FROM	@MyListXML.nodes('/root/item[@type="int"]') T(c)
    
  7. How do i do this dynamically.
    For instance:
    Select ID from MyTable Where Fact = 0
    Now, I need to store the list of IDs in a list or in an array so that I can use that list/array in another SQL Statement.
    For instance, Select * from MyAnotherTable Where ID in

    Thank you

  8. @Prachyut,There can be so many ways.It depend upon exact scenario/requirement.
    Select * from MyAnotherTable Where ID in(Select ID from MyTable Where Fact = 0).
    using CTE is one of them.

    • Thank you for response Kumar. I did the same way, the script created seems like it should work, but I haven’t tested it yet, will update after I test it. thank you again

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