Dynamic Pivot Table

  • 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:

  • 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

  • BOOM! Thanks, Dave!

  • 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

  • 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?

  • 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.

Viewing 6 posts - 1 through 5 (of 5 total)

You must be logged in to reply to this topic. Login to reply