Pivot problem

  • Hi

    I have the following table

    CREATE TABLE #Test

    (

    ProductID int,

    MainMasterFeatureID int,

    --MasterFeatureValue Varchar(100),

    ChilFeatureName varchar(100),

    ParentFeatureName varchar(100)

    )

    INSERT INTO #Test

    SELECT 40,1,,'Pack','Type'

    UNION ALL

    SELECT 40,0,'Laminate','Technology'

    UNION ALL

    SELECT 40,11,'Yes','Coated'

    UNION ALL

    SELECT 52,1,'Roll','Type'

    UNION ALL

    SELECT 52,11,'NO','Coated'

    SELECT * FROM #Test

    Expected Output

    If MainMasterFeatureID = 0 then select value from MasterFeatureValue ..here In case of Technology value is Laminate(select value from MasterFeatureValue)

    ELSE

    SELECT Value from ChilFeatureName

    ProductID Type Technology Coated

    40 Pack Laminate YES

    52 Roll Null No

    Thank you

  • This is what I developed:

    CREATE TABLE #Test

    (

    ProductID int,

    MainMasterFeatureID int,

    MasterFeatureValue Varchar(100),

    ChilFeatureName varchar(100),

    ParentFeatureName varchar(100)

    );

    INSERT INTO #Test

    SELECT 40,1,'1','Pack','Type'

    UNION ALL

    SELECT 40,0,'Laminate','Technology','Technology'

    UNION ALL

    SELECT 40,11,'1','Yes','Coated'

    UNION ALL

    SELECT 52,1,'1','Roll','Type'

    UNION ALL

    SELECT 52,11,'1','NO','Coated';

    select * from #Test;

    go

    select

    ProductID,

    max(case when ParentFeatureName = 'Type'

    then case when MainMasterFeatureID = 0 then MasterFeatureValue else ChilFeatureName end

    end) as [Type],

    max(case when ParentFeatureName = 'Technology'

    then case when MainMasterFeatureID = 0 then MasterFeatureValue else ChilFeatureName end

    end) as [Technology],

    max(case when ParentFeatureName = 'Coated'

    then case when MainMasterFeatureID = 0 then MasterFeatureValue else ChilFeatureName end

    end) as [Coated]

    from

    #Test

    group by

    ProductID;

    go

    drop table #Test;

    go

    /*

    ProductID Type Technology Coated

    40 Pack Laminate YES

    52 Roll Null No

    */

  • Hi Lynn, thanks for the reply

    The value in ParentFeatureName can be dynamically change..it will not always give the same value

    I am trying this dynamic pivot..but still not getting the desire results

    there is error

    DECLARE @ParentFeatureName varchar(max)

    SELECT @ParentFeatureName = STUFF((select distinct ',['+'ParentFeatureName'+']' from #Test for xml path(' ')),1,1,'')

    --error is coming here to get the distict value

    SELECT @ParentFeatureName = (

    SELECT SUBSTRING(

    (SELECT DISTINCT ',' + CAST(ParentFeatureName as Varchar(MAX)) FROM #Test FOR XML PATH('')),2,2000000))

    SELECT

    ProductID,'+@ParentFeatureName+'

    FROM

    (SELECT * FROM #Test) AS D

    PIVOT

    (

    MIN(MasterFeatureValue)

    FOR ParentFeatureName IN ('+@ParentFeatureName+')

    ) AS DD

    Group By ProductID

    DECLARE @sql VARCHAR(max)

    SET @sql = '

    SELECT

    ProductID,'+@ParentFeatureName+'

    FROM

    (SELECT * FROM #Test) AS D

    PIVOT

    (

    MIN(MasterFeatureValue)

    FOR ParentFeatureName IN ('+@ParentFeatureName+')

    ) AS DD

    Group By ProductID'

    EXEC @sql

  • I think this is what you are looking for...it would dynamically flatten your data :

    --Creating Table

    CREATE TABLE #Test

    (

    ProductID int,

    MainMasterFeatureID int,

    --MasterFeatureValue Varchar(100),

    ChilFeatureName varchar(100),

    ParentFeatureName varchar(100)

    )

    --Inserting Sample Data

    INSERT INTO #Test

    SELECT 40,1,'Pack','Type'

    UNION ALL

    SELECT 40,0,'Laminate','Technology'

    UNION ALL

    SELECT 40,11,'Yes','Coated'

    UNION ALL

    SELECT 52,1,'Roll','Type'

    UNION ALL

    SELECT 52,11,'NO','Coated'

    --Dynamic Cross Tab Query

    Declare @sql Varchar(MAX)

    Select @sql = 'SELECT ProductID, '

    Select @sql = @sql + STUFF((Select DISTINCT ',MAX(Case When ParentFeatureName = ' + CHAR(39) + ParentFeatureName + CHAR(39) + ' Then ChilFeatureName Else ' + CHAR(39) + CHAR(39) + ' End) As ' + ParentFeatureName From #Test For XML PATH('')),1,1,'')

    Select @sql = @sql + ' FROM #Test Group By ProductID'

    Execute(@sql)

    Hope this helps.

    Vinu Vijayan

    For better and faster solutions please check..."How to post data/code on a forum to get the best help" - Jeff Moden[/url] 😉

  • thanks vinu

    Now i am trying to join this query with a table to get the desire results

    CREATE TABLE #tProduct

    (

    tProductID bigint PRIMARY KEY,

    tProductCode nvarchar(128),

    tProductName nvarchar(256),

    tManufacturerName nvarchar(256),

    tProductDescription nvarchar(4000)

    )

    EXECUTE ('SELECT *

    FROM #tProduct AS P

    JOIN(SELECT ProductID, +STUFF((Select DISTINCT '',MAX(Case When ParentFeatureName = '' + CHAR(39) + ParentFeatureName + CHAR(39) + '' Then ChilFeatureName Else '' + CHAR(39) + CHAR(39) + '' End) As '' + ParentFeatureName From #Test For XML PATH('')),1,1,'''')

    + FROM #Test Group By ProductID'' ) AS A ON P.tProductID = A.ProductID')

    I am getting this error

    Msg 156, Level 15, State 1, Line 4

    Incorrect syntax near the keyword 'AS'.

  • SQL006 (1/14/2013)


    thanks vinu

    Now i am trying to join this query with a table to get the desire results

    CREATE TABLE #tProduct

    (

    tProductID bigint PRIMARY KEY,

    tProductCode nvarchar(128),

    tProductName nvarchar(256),

    tManufacturerName nvarchar(256),

    tProductDescription nvarchar(4000)

    )

    EXECUTE ('SELECT *

    FROM #tProduct AS P

    JOIN(SELECT ProductID, +STUFF((Select DISTINCT '',MAX(Case When ParentFeatureName = '' + CHAR(39) + ParentFeatureName + CHAR(39) + '' Then ChilFeatureName Else '' + CHAR(39) + CHAR(39) + '' End) As '' + ParentFeatureName From #Test For XML PATH('')),1,1,'''')

    + FROM #Test Group By ProductID'' ) AS A ON P.tProductID = A.ProductID')

    I am getting this error

    Msg 156, Level 15, State 1, Line 4

    Incorrect syntax near the keyword 'AS'.

    First suggestion I have is build the dynamic query into a variable. Second, PRINT it out so you can see the query itself to be sure it is what you expect. If you print it, you can copy it to another query window to test that it actually runs. This is what I do when writing a dynamic query as it is sometimes hard to be sure you have the correct number of single quotes in the correct places otherwise.

  • CREATE TABLE #Test

    (

    ProductID int,

    MainMasterFeatureID int,

    --MasterFeatureValue Varchar(100),

    ChilFeatureName varchar(100),

    ParentFeatureName varchar(100)

    )

    --Inserting Sample Data

    INSERT INTO #Test

    SELECT 40,1,'Pack','Type'

    UNION ALL

    SELECT 40,0,'Laminate','Technology'

    UNION ALL

    SELECT 40,11,'Yes','Coated'

    UNION ALL

    SELECT 52,1,'Roll','Type'

    UNION ALL

    SELECT 52,11,'NO','Coated'

    CREATE TABLE #tProduct

    (

    tProductID int PRIMARY KEY,

    tProductCode nvarchar(128),

    tProductName nvarchar(256)

    )

    INSERT INTO #tProduct

    SELECT 40,'001','ABC'

    UNION ALL

    SELECT 52,'002','XYZ'

    UNION ALL

    SELECT 50,'006','IJK'

    Declare @sql Varchar(MAX)

    Select @sql = 'SELECT ProductID, ' +STUFF((Select DISTINCT ',MAX(Case When ParentFeatureName = ' + CHAR(39) + ParentFeatureName + CHAR(39) + ' Then ChilFeatureName Else ' + CHAR(39) + CHAR(39) + ' End) As ' + ParentFeatureName From #Test For XML PATH('')),1,1,'')

    + ' FROM #Test Group By ProductID'

    DECLARE @product varchar(max)

    SET @product = '(SELECT *

    FROM #tProduct) AS P JOIN'+@SQL+' AS T ON P.tProductID = T.ProductID'

    this error is coming..tried a lot

    Msg 156, Level 15, State 1, Line 2

    Incorrect syntax near the keyword 'AS'.

    Now I want to join this dynamic query to #tProduct to get the desired results:

    tProductID tProductName Type Technology Coated

    40 ABC Pack Laminate YES

    52 XYZ Roll Null No

  • When I run the SQL you posted, I don't get that error at all. Instead I get complaints that the objects in bold (fragment of your assignment to @sql) don't exist:

    ParentFeatureName + CHAR(39) + ' Then ChilFeatureName Else ' + CHAR(39) + CHAR(39) + ' End) As ' + ParentFeatureName

    From #Test

    Neither the column name nor the referenced table are provided in the DDL.

    Then of course there's the question of "what do you think you're assigning to @product?" It starts with an open paren. Is that supposed to be a subquery or something?


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    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

  • SQL006 (1/14/2013)


    CREATE TABLE #Test

    (

    ProductID int,

    MainMasterFeatureID int,

    --MasterFeatureValue Varchar(100),

    ChilFeatureName varchar(100),

    ParentFeatureName varchar(100)

    )

    --Inserting Sample Data

    INSERT INTO #Test

    SELECT 40,1,'Pack','Type'

    UNION ALL

    SELECT 40,0,'Laminate','Technology'

    UNION ALL

    SELECT 40,11,'Yes','Coated'

    UNION ALL

    SELECT 52,1,'Roll','Type'

    UNION ALL

    SELECT 52,11,'NO','Coated'

    CREATE TABLE #tProduct

    (

    tProductID int PRIMARY KEY,

    tProductCode nvarchar(128),

    tProductName nvarchar(256)

    )

    INSERT INTO #tProduct

    SELECT 40,'001','ABC'

    UNION ALL

    SELECT 52,'002','XYZ'

    UNION ALL

    SELECT 50,'006','IJK'

    Declare @sql Varchar(MAX)

    Select @sql = 'SELECT ProductID, ' +STUFF((Select DISTINCT ',MAX(Case When ParentFeatureName = ' + CHAR(39) + ParentFeatureName + CHAR(39) + ' Then ChilFeatureName Else ' + CHAR(39) + CHAR(39) + ' End) As ' + ParentFeatureName From #Test For XML PATH('')),1,1,'')

    + ' FROM #Test Group By ProductID'

    DECLARE @product varchar(max)

    SET @product = '(SELECT *

    FROM #tProduct) AS P JOIN'+@SQL+' AS T ON P.tProductID = T.ProductID'

    this error is coming..tried a lot

    Msg 156, Level 15, State 1, Line 2

    Incorrect syntax near the keyword 'AS'.

    Now I want to join this dynamic query to #tProduct to get the desired results:

    tProductID tProductName Type Technology Coated

    40 ABC Pack Laminate YES

    52 XYZ Roll Null No

    The following is the edited version of your above sql. I've marked the changes that I made in bold. It gets you the required results :

    Declare @sql Varchar(MAX)

    DECLARE @product varchar(max)

    Select @sql = 'SELECT ProductID, ' +STUFF((Select DISTINCT ',MAX(Case When ParentFeatureName = ' + CHAR(39) + ParentFeatureName + CHAR(39) + ' Then ChilFeatureName Else ' + CHAR(39) + CHAR(39) + ' End) As ' + ParentFeatureName From #Test For XML PATH('')),1,1,'')

    + ' FROM #Test Group By ProductID'

    SET @product = 'Select tProductId, tProductName, Type, Technology, Coated From (SELECT * FROM #tProduct) AS P JOIN ('+@SQL+') AS T ON P.tProductID = T.ProductID'

    Execute (@Product)

    If you still don't understand then print the variable @product for both the queries...yours and mine....you'll see the difference.

    Hope this worked out for you.

    Vinu Vijayan

    For better and faster solutions please check..."How to post data/code on a forum to get the best help" - Jeff Moden[/url] 😉

Viewing 10 posts - 1 through 9 (of 9 total)

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