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 2005 Forums
 Transact-SQL (2005)
 Hard time with pivoting

Author  Topic 

ranalk
Starting Member

49 Posts

Posted - 2012-12-02 : 03:28:21
Hi all,

Can you please assist with the script for converting the table on the left to the one on the right?



Thanks in advance!

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2012-12-02 : 03:40:31
[code]
SELECT *
FROM Table t
UNPIVOT (Code FOR Name IN ([Phil],[Bill],[Larry]))u
[/code]

for making names dynamic you can use dynamic sql



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

Go to Top of Page

sodeep
Master Smack Fu Yak Hacker

7174 Posts

Posted - 2012-12-02 : 10:38:26
[code]Select distinct Date,
MAX(Case When Name = 'Phil' then Code End) OVER(PARTITION BY Date)as Phil,
MAX(Case When Name = 'Bill' then Code End) OVER(PARTITION BY Date)as Bill,
MAX(Case When Name = 'Larry' then Code End) OVER(PARTITION BY Date)as Larry
from Table[/code]
Go to Top of Page

ranalk
Starting Member

49 Posts

Posted - 2012-12-05 : 04:00:02
quote:
Originally posted by visakh16


SELECT *
FROM Table t
UNPIVOT (Code FOR Name IN ([Phil],[Bill],[Larry]))u


for making names dynamic you can use dynamic sql



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





Unfortunately, I was unable to unpivot due to SQL errors
can you assist?
DECLARE @table TABLE ([Date] Date,[Name] nvarchar(15),[Code] nvarchar(15))
INSERT INTO @table ([date],[name],[code]) VALUES ('11/11/2012','phil','xxxx')
INSERT INTO @table ([date],[name],[code]) VALUES ('11/12/2012','phil','1111')
INSERT INTO @table ([date],[name],[code]) VALUES ('11/11/2012','Larry','yyyy')
INSERT INTO @table ([date],[name],[code]) VALUES ('11/12/2012','Larry','2222')
INSERT INTO @table ([date],[name],[code]) VALUES ('11/11/2012','Bill','zzzz')
INSERT INTO @table ([date],[name],[code]) VALUES ('11/12/2012','Bill','3333')

SELECT * FROM @table


SELECT *
FROM @table t
UNPIVOT (Code FOR Name IN ([Phil],[Bill],[Larry]))u
Go to Top of Page

bandi
Master Smack Fu Yak Hacker

2242 Posts

Posted - 2012-12-05 : 05:48:49
[code]
DECLARE @table TABLE ([Date] Date,[Name] nvarchar(15),[Code] varchar(15))
INSERT INTO @table ([date],[name],[Code]) VALUES ('11/11/2012','phil','xxxx')
INSERT INTO @table ([date],[name],[Code]) VALUES ('11/12/2012','phil','1111')
INSERT INTO @table ([date],[name],[Code]) VALUES ('11/11/2012','Larry','yyyy')
INSERT INTO @table ([date],[name],[Code]) VALUES ('11/12/2012','Larry','2222')
INSERT INTO @table ([date],[name],[Code]) VALUES ('11/11/2012','Bill','zzzz')
INSERT INTO @table ([date],[name],[Code]) VALUES ('11/12/2012','Bill','3333')

SELECT *
FROM @table t
PIVOT
( MAX(code) FOR [Name] IN ([phil], [larry], [bill]) )u
[/code]

--
Chandu
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2012-12-06 : 01:37:57
And if you want to make names dynamic use

http://beyondrelational.com/modules/2/blogs/70/posts/10840/dynamic-pivot-in-sql-server-2005.aspx

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

Go to Top of Page

ranalk
Starting Member

49 Posts

Posted - 2012-12-06 : 01:57:54
Thanks for the help, I have managed to Pivot.

Now I will need to put some thinking regarding dynamic pivoting for the same table...
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2012-12-06 : 02:14:55
quote:
Originally posted by ranalk

Thanks for the help, I have managed to Pivot.

Now I will need to put some thinking regarding dynamic pivoting for the same table...


see the article. it does excatly that

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

Go to Top of Page

ranalk
Starting Member

49 Posts

Posted - 2012-12-06 : 02:17:43
quote:
Originally posted by visakh16

quote:
Originally posted by ranalk

Thanks for the help, I have managed to Pivot.

Now I will need to put some thinking regarding dynamic pivoting for the same table...


see the article. it does excatly that

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




Cool, will check it out.
Go to Top of Page

bandi
Master Smack Fu Yak Hacker

2242 Posts

Posted - 2012-12-06 : 02:42:37
[code]
CREATE TABLE #table ([Date] Date,[Name] nvarchar(15),[Code] varchar(15))
INSERT INTO #table ([date],[name],[Code]) VALUES ('11/11/2012','phil','xxxx')
INSERT INTO #table ([date],[name],[Code]) VALUES ('11/12/2012','phil','1111')
INSERT INTO #table ([date],[name],[Code]) VALUES ('11/11/2012','Larry','yyyy')
INSERT INTO #table ([date],[name],[Code]) VALUES ('11/12/2012','Larry','2222')
INSERT INTO #table ([date],[name],[Code]) VALUES ('11/11/2012','Bill','zzzz')
INSERT INTO #table ([date],[name],[Code]) VALUES ('11/12/2012','Bill','3333')

DECLARE @cols varchar(1000) ='', @str varchar(max) =''
SET @cols = STUFF((SELECT distinct ',' + QUOTENAME([NAME]) FROM #table FOR XML PATH(''), TYPE).value('.', 'NVARCHAR(MAX)'),1,1,'')
SET @str = 'SELECT [DATE], ' + @cols + ' FROM #table t
PIVOT
( MAX(code) FOR [Name] IN ( ' + @cols + ' ))u '
EXEC(@str)

DROP TABLE #table
[/code]

--
Chandu
Go to Top of Page

ranalk
Starting Member

49 Posts

Posted - 2012-12-06 : 02:48:43
quote:
Originally posted by bandi


CREATE TABLE #table ([Date] Date,[Name] nvarchar(15),[Code] varchar(15))
INSERT INTO #table ([date],[name],[Code]) VALUES ('11/11/2012','phil','xxxx')
INSERT INTO #table ([date],[name],[Code]) VALUES ('11/12/2012','phil','1111')
INSERT INTO #table ([date],[name],[Code]) VALUES ('11/11/2012','Larry','yyyy')
INSERT INTO #table ([date],[name],[Code]) VALUES ('11/12/2012','Larry','2222')
INSERT INTO #table ([date],[name],[Code]) VALUES ('11/11/2012','Bill','zzzz')
INSERT INTO #table ([date],[name],[Code]) VALUES ('11/12/2012','Bill','3333')

DECLARE @cols varchar(1000) ='', @str varchar(max) =''
SET @cols = STUFF((SELECT distinct ',' + QUOTENAME([NAME]) FROM #table FOR XML PATH(''), TYPE).value('.', 'NVARCHAR(MAX)'),1,1,'')
SET @str = 'SELECT [DATE], ' + @cols + ' FROM #table t
PIVOT
( MAX(code) FOR [Name] IN ( ' + @cols + ' ))u '
EXEC(@str)

DROP TABLE #table


Nicely done!
Thanks a lot.

--
Chandu

Go to Top of Page

bandi
Master Smack Fu Yak Hacker

2242 Posts

Posted - 2012-12-06 : 02:51:25
Welcome

--
Chandu
Go to Top of Page

Lampas
Starting Member

1 Post

Posted - 2012-12-07 : 00:31:04
--This is another way of pivoting that gives more freedom to add other value to your results, like do a calculation on the results, while you pivot.


-- Create your table
DECLARE @table TABLE ([Date] Datetime,[Name] nvarchar(15),[Code] varchar(15))
INSERT INTO @table ([date],[name],[Code]) VALUES ('11/11/2012','phil','xxxx')
INSERT INTO @table ([date],[name],[Code]) VALUES ('11/12/2012','phil','1111')
INSERT INTO @table ([date],[name],[Code]) VALUES ('11/11/2012','Larry','yyyy')
INSERT INTO @table ([date],[name],[Code]) VALUES ('11/12/2012','Larry','2222')
INSERT INTO @table ([date],[name],[Code]) VALUES ('11/11/2012','Bill','zzzz')
INSERT INTO @table ([date],[name],[Code]) VALUES ('11/12/2012','Bill','3333')

-- Create your pivot table -- note that an empty string is added against each name
-- This extra table might seem to be a lot of work, but it is a clean and fast way of coding
DECLARE @Pivotable TABLE ([Name] nvarchar(15),Phil varchar(1),Larry varchar(1),Bill varchar(1))
INSERT INTO @Pivotable ([Name],Phil,Larry,Bill) VALUES ('Phil','',NULL,NULL)
INSERT INTO @Pivotable ([Name],Phil,Larry,Bill) VALUES ('Larry',NULL,'',NULL)
INSERT INTO @Pivotable ([Name],Phil,Larry,Bill) VALUES ('Bill',NULL,NULL,'')

-- Pivot statement -- this gives more ablility to manipulate and use isnull and other functions in your statement
-- I did this in SQL2000, so it is fully backwards compatible as well.
-- The pivot statement in SQL is very effective if you need a simple pivoting only
SELECT [Date]
, Phil = Max(Code+P.Phil)
, Larry = Max(Code+P.Larry)
, Bill = Max(Code+P.Bill)
FROM @table t
join @Pivotable P on T.[Name] = P.[Name]
group by [Date]
Go to Top of Page

ranalk
Starting Member

49 Posts

Posted - 2012-12-07 : 02:02:58
quote:
Originally posted by Lampas

--This is another way of pivoting that gives more freedom to add other value to your results, like do a calculation on the results, while you pivot.


-- Create your table
DECLARE @table TABLE ([Date] Datetime,[Name] nvarchar(15),[Code] varchar(15))
INSERT INTO @table ([date],[name],[Code]) VALUES ('11/11/2012','phil','xxxx')
INSERT INTO @table ([date],[name],[Code]) VALUES ('11/12/2012','phil','1111')
INSERT INTO @table ([date],[name],[Code]) VALUES ('11/11/2012','Larry','yyyy')
INSERT INTO @table ([date],[name],[Code]) VALUES ('11/12/2012','Larry','2222')
INSERT INTO @table ([date],[name],[Code]) VALUES ('11/11/2012','Bill','zzzz')
INSERT INTO @table ([date],[name],[Code]) VALUES ('11/12/2012','Bill','3333')

-- Create your pivot table -- note that an empty string is added against each name
-- This extra table might seem to be a lot of work, but it is a clean and fast way of coding
DECLARE @Pivotable TABLE ([Name] nvarchar(15),Phil varchar(1),Larry varchar(1),Bill varchar(1))
INSERT INTO @Pivotable ([Name],Phil,Larry,Bill) VALUES ('Phil','',NULL,NULL)
INSERT INTO @Pivotable ([Name],Phil,Larry,Bill) VALUES ('Larry',NULL,'',NULL)
INSERT INTO @Pivotable ([Name],Phil,Larry,Bill) VALUES ('Bill',NULL,NULL,'')

-- Pivot statement -- this gives more ablility to manipulate and use isnull and other functions in your statement
-- I did this in SQL2000, so it is fully backwards compatible as well.
-- The pivot statement in SQL is very effective if you need a simple pivoting only
SELECT [Date]
, Phil = Max(Code+P.Phil)
, Larry = Max(Code+P.Larry)
, Bill = Max(Code+P.Bill)
FROM @table t
join @Pivotable P on T.[Name] = P.[Name]
group by [Date]




But it is not dynamic and forcing you to add each records manually.
But thanks!
Go to Top of Page
   

- Advertisement -