January 8, 2013 at 8:47 am
Hi all,
I have a data like as shown below in my table.
ID Name Mode
-----------------------------
1 AAAAAAA Phone
2 AAAAAAA Phone
3 AAAAAAA Phone
4 BBBBB SMS
5 BBBBB SMS
6 CCCCC Email
7 AAAAAAA SMS
Need output as shown below.
O/P
----
Name Phone SMS email
----------------------------
AAAAAAA 3 1 0
BBBBB 0 2 0
CCCCC 0 0 1
Thank's in advance
January 8, 2013 at 8:56 am
DECLARE @t TABLE(ID INT, Name VARCHAR(10), Mode VARCHAR(10))
INSERT INTO @t(ID,Name,Mode)
VALUES(1, 'AAAAAAA','Phone'),
(2, 'AAAAAAA','Phone'),
(3, 'AAAAAAA','Phone'),
(4, 'BBBBB','SMS'),
(5, 'BBBBB','SMS'),
(6, 'CCCCC','Email'),
(7, 'AAAAAAA','SMS');
SELECT Name,
SUM(CASE WHEN Mode='Phone' THEN 1 ELSE 0 END) AS Phone,
SUM(CASE WHEN Mode='SMS' THEN 1 ELSE 0 END) AS SMS,
SUM(CASE WHEN Mode='Email' THEN 1 ELSE 0 END) AS Email
FROM @t
GROUP BY Name
ORDER BY Name;
____________________________________________________
Deja View - The strange feeling that somewhere, sometime you've optimised this query before
How to get the best help on a forum
http://www.sqlservercentral.com/articles/Best+Practices/61537January 8, 2013 at 9:09 am
Thankq for your response. I need Mode column values as column name.
January 8, 2013 at 9:15 am
Have a look here
____________________________________________________
Deja View - The strange feeling that somewhere, sometime you've optimised this query before
How to get the best help on a forum
http://www.sqlservercentral.com/articles/Best+Practices/61537January 8, 2013 at 5:58 pm
venkatesh.b 88975 (1/8/2013)
Thankq for your response. I need Mode column values as column name.
If you mean you have more than 3 modes and don't know how many you would need to convert Mark's solution to dynamic SQL that generates the dynamic column result.
My thought question: Have you ever been told that your query runs too fast?
My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.
Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
January 9, 2013 at 12:47 am
another query
select name,[Phone],[Sms],[Email]
from
(
select name , mode , sum(case
when name = 'AAAAA' then 1
when name = 'BBBBB' then 1
when name = 'CCCCC' then 1 else 0 end) as cnt from @t
group by mode, name
)t
pivot
( sum (cnt)
for mode in ([Email],[Phone],[Sms])
)pvt
ORDER BY Name; but i am unable to remove NULL.
-------Bhuvnesh----------
I work only to learn Sql Server...though my company pays me for getting their stuff done;-)
January 9, 2013 at 11:53 pm
If the values in the node column can be dynamic then you can do a Dynamic Cross tab as follows :
--Creating Table
Create table Ex1
(
ID Int,
Name Varchar(30),
Mode Varchar(30)
)
--Inserting Sample Data
Insert into Ex1
Select 1, 'AAAAAAA','Phone'
Union ALL
Select 2, 'AAAAAAA','Phone'
Union ALL
Select 3, 'AAAAAAA','Phone'
Union ALL
Select 4, 'BBBBB','SMS'
Union ALL
Select 5, 'BBBBB','SMS'
Union ALL
Select 6,'CCCCC','Email'
Union ALL
Select 7, 'AAAAAAA','SMS'
--Dynamic Pivot
Declare @sql Varchar(Max)
Set @sql = 'Select Name, '
Select @sql = @sql + STUFF((Select ',SUM(Case When mode = ' + CHAR(39) + Mode + CHAR(39) + ' Then 1 Else 0 End) As ' + Mode From (Select Distinct Mode From Ex1) As a FOR XML Path('')),1,1,'')
Select @sql = @sql + ' From Ex1 Group By Name'
Execute (@sql)
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply