Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 SQL Server 2008 Forums
 SSIS and Import/Export (2008)
 Multiple query resultset in Execute SQL Task

Author  Topic 

varalakshmi
Yak Posting Veteran

98 Posts

Posted - 2011-12-05 : 05:43:22
Hi,

I have to retrieve the count of records in multiple tables and assign it to multiple variables.

For example,

select count(*) from table1
select count(*) from table1,...

and assign it to variables tab1count, tab2count,...

Is it possible to use a single Execute SQL task or should I need to use multiple tasks to assign the values to variable.

Please help me in implementing this with minimum tasks.

Thanks in Advance.

- Varalakshmi

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-12-05 : 06:09:29
you need multiple sql tasks with above queries.
However,if you need to wrap them in same tasks, you need rewrite query merged using UNION ALL like

SELECT SUM(case when cat='t1' then cnt else 0 end) as tab1count,
SUM(case when cat='t2' then cnt else 0 end) as tab2count
FROM
(
select count(*) as cnt,'t1' as cat from table1
union all
select count(*),'t2' from table2
)t


then you can map them to your variables inside same sql task after selecting single row as resultset type.

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

varalakshmi
Yak Posting Veteran

98 Posts

Posted - 2011-12-05 : 06:39:28
Thanks a lot

- Varalakshmi
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-12-05 : 06:44:54
wc

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

nigelrivett
Master Smack Fu Yak Hacker

3385 Posts

Posted - 2011-12-05 : 06:46:16
Variables would be @tab1count, @tab2count

select @tab1count = (select count(*) from table1) ,
@tab1count = (select count(*) from table2)
..

but faster is

select @tab1count = (select rows from sysindexes where id = object_name('Table1') and indid in (0,1)) ,
@tab2count = (select rows from sysindexes where id = object_name('Table2') and indid in (0,1)) ,

or you could
select @tab1count = max(case when object_name(id) = 'Table1' then rows else 0 end)
select @tab2count = max(case when object_name(id) = 'Table2' then rows else 0 end)
from sysindexes
where id in (object_id('Table1'),object_id('Table2'))
and indid in (0,1)


If you want a resultset just remove the @ from the names.

==========================================
Cursors are useful if you don't know sql.
SSIS can be used in a similar way.
Beer is not cold and it isn't fizzy.
Go to Top of Page
   

- Advertisement -