SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Dynamic Pivot Table


Dynamic Pivot Table

Author
Message
IniJoy
IniJoy
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 44


I'm trying to pivot the data so that all of the PostClickConversions are aggregated for each ActivityTagID (by Date & AdID) as a column so the result set will look like this:



My attempt:

DECLARE @PivotColumnHeaders VARCHAR(MAX)
SELECT @PivotColumnHeaders =
COALESCE(
@PivotColumnHeaders + ',[' + cast([ActivityTagID] as varchar) + ']',
'[' + cast([ActivityTagID] as varchar)+ ']'
)
FROM dbo.ConversionsTest

DECLARE @PivotTableSQL NVARCHAR(MAX)
SET @PivotTableSQL = N'
SELECT *
FROM (
select [date],[AdId],[ActivityTagID],[PostClickConversions]
from dbo.ConversionsTest


) AS PivotData
PIVOT (
sum([PostClickConversions])
FOR [ActivityTagID] IN (
' + @PivotColumnHeaders + '
)
) AS PivotTable
'

EXECUTE(@PivotTableSQL)


The error message yields:

Msg 8156, Level 16, State 1, Line 14
The column '280378' was specified multiple times for 'PivotTable'.


HELP!!w00t
Dave.Valentine
Dave.Valentine
SSC Rookie
SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)SSC Rookie (40 reputation)

Group: General Forum Members
Points: 40 Visits: 240
You will need to have a distinct set of ActivityTagID in your PivotColumnHeaders. Try adding the group by ActivityTagID in your query as such:

DECLARE @PivotColumnHeaders VARCHAR(MAX)
SELECT @PivotColumnHeaders =
COALESCE(
@PivotColumnHeaders + ',[' + cast([ActivityTagID] as varchar) + ']',
'[' + cast([ActivityTagID] as varchar)+ ']'
)
FROM dbo.ConversionsTest
GROUP BY ActivityTagID

http://www.ingenioussql.com/2013/02/06/dynamic-t-sql-pivot/

Thanks,
Dave
IniJoy
IniJoy
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 44
BOOM! Thanks, Dave!
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)

Group: General Forum Members
Points: 94749 Visits: 38956
Something more like this maybe:



use SandBox; -- Move to a SandBox database for testing
go

create table dbo.ConversionsTest (
ActDate date,
AdId int,
ActivityTagID int,
PostImpConversions int,
PostClickConversions int
);

insert into dbo.ConversionsTest
values
('2013-04-1', 12807324, 280378, 0, 1),
('2013-04-1', 13573240, 280378, 0, 1),
('2013-04-1', 13575149, 280378, 0, 3),
('2013-04-1', 13575471, 280378, 0, 2),
('2013-04-1', 13521989, 280377, 0, 1),
('2013-04-1', 13521989, 280378, 0, 3),
('2013-04-1', 13521989, 289201, 0, 1),
('2013-04-1', 13566439, 280378, 0, 1),
('2013-04-1', 13566442, 280378, 0, 1),
('2013-04-1', 13597657, 280378, 0, 1);

go

DECLARE @PivotColumnHeaders VARCHAR(MAX);
DECLARE @PivotColumnHeaders1 VARCHAR(MAX);
with DistinctActivityTagIDs as (
select distinct ActivityTagID from dbo.ConversionsTest)
SELECT
@PivotColumnHeaders =
COALESCE(
@PivotColumnHeaders + ',[' + cast([ActivityTagID] as varchar) + ']',
'[' + cast([ActivityTagID] as varchar)+ ']'
),
@PivotColumnHeaders1 =
COALESCE(
@PivotColumnHeaders1 + ',isnull([' + cast([ActivityTagID] as varchar) + '],0) as [' + cast([ActivityTagID] as varchar) + ']',
'isnull([' + cast([ActivityTagID] as varchar) + '],0) as [' + cast([ActivityTagID] as varchar) + ']'
)
FROM
DistinctActivityTagIDs

DECLARE @PivotTableSQL NVARCHAR(MAX)
SET @PivotTableSQL = N'
SELECT [ActDate],[AdId],' + @PivotColumnHeaders1 + N'
FROM (
select [ActDate],[AdId],[ActivityTagID],[PostClickConversions]
from dbo.ConversionsTest
) AS PivotData
PIVOT (
sum([PostClickConversions])
FOR [ActivityTagID] IN (' + @PivotColumnHeaders + '
)
) AS PivotTable
'

EXECUTE(@PivotTableSQL)

go

drop table dbo.ConversionsTest;
go




Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
IniJoy
IniJoy
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 44
A second layer to this scenario:

Is there a way to add a "top 10" factor to only select the ActivityID's whose aggregates are in the top 10 #'s for each group?
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)

Group: General Forum Members
Points: 94749 Visits: 38956
IniJoy (4/26/2013)
A second layer to this scenario:

Is there a way to add a "top 10" factor to only select the ActivityID's whose aggregates are in the top 10 #'s for each group?


Look at how I setup my code for you; DDL for the table, sample data to load the table. That is what you will need to do for us AND include the expected results based on the sample data.

Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search