Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

T-SQL Pvot Data and Hide duplicates Expand / Collapse
Author
Message
Posted Friday, August 30, 2013 10:41 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, October 29, 2013 6:25 PM
Points: 4, Visits: 10
I need help in pivoting comments columns to show data in parallel below
Table 1
Camry_Id,Month,Year,Dealer,Camry_Comments,
1,7,2013,Hendrick,Camry Comment 1,
2,7,2013,Hendrick,Camry Comment 2,
3,7,2013,Hendrick,Camry Comment 3,
4,7,2013,AutoCity,Camry Comment 4,
5,7,2013,AutoCity,Camry Comment 5,
6,7,2013,Leith,Camry Comment 6,
7,8,2013,Leith,Camry Comment 8,
8,8,2013,Leith,Camry Comment 9,

Table 2
Corolla_Id,Month,Year,Dealer,Corolla_Comments,
1,7,2013,AutoCity,Corolla Comment 1,
2,7,2013,AutoCity,Corolla Comment 2,
3,7,2013,AutoCity,Corolla Comment 6,
4,7,2013,Leith,Corolla Comment 3,
4,7,2013,Leith,Corolla Comment 8,
6,8,2013,Leith,Corolla Comment 4,
8,7,2013,Hendrick,Corolla Comment 7,

Result
,Month,Year,Dealer,Camry_Comments,Corolla_Comments
,7,2013,AutoCity,Camry Comment 4,Corolla Comment 1
,7,2013,AutoCity,Camry Comment 5,Corolla Comment 2
,7,2013,AutoCity,,Corolla Comment 7
,7,2013,Hendrick,Camry Comment 1,Corolla Comment 7
,7,2013,Hendrick,Camry Comment 2,
,7,2013,Hendrick,Camry Comment 3,
,7,2013,Leith,Camry Comment 6,
,7,2013,Leith,,Corolla Comment 8
,8,2013,Leith,Camry Comment 8,Corolla Comment 4
,8,2013,Leith,Camry Comment 9,


Essentially I want to join on month, year and Dealer and display comments in each column aligned. So

if there are comments from both then show both on same like

If one has 2 and other has 1 show first ones on same line; second on next line.Hide duplicates.

It has to show all records(full outer join) from both tables with not multiply or duplicates on either corolla or camry comments column

Post #1490228
Posted Friday, August 30, 2013 1:04 PM
SSC Journeyman

SSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC JourneymanSSC Journeyman

Group: General Forum Members
Last Login: Monday, April 14, 2014 12:25 PM
Points: 99, Visits: 496
If you have maximum one comment per (Dealer, Year, Month, Car_Id) then you can enumerate the rows and then use a FULL OUTER JOIN.

SET NOCOUNT ON;
USE tempdb;
GO
DECLARE @T1 TABLE (
Camry_Id int,
[Month] tinyint,
[Year] smallint,
Dealer varchar(25),
Camry_Comments varchar(50)
);

DECLARE @T2 TABLE (
Corolla_Id int,
[Month] tinyint,
[Year] smallint,
Dealer varchar(25),
Corolla_Comments varchar(50)
);

INSERT INTO @T1 (
Camry_Id,
[Month],
[Year],
Dealer,
Camry_Comments
)
VALUES
(1,7,2013,'Hendrick','Camry Comment 1'),
(2,7,2013,'Hendrick','Camry Comment 2'),
(3,7,2013,'Hendrick','Camry Comment 3'),
(4,7,2013,'AutoCity','Camry Comment 4'),
(5,7,2013,'AutoCity','Camry Comment 5'),
(6,7,2013,'Leith','Camry Comment 6'),
(7,8,2013,'Leith','Camry Comment 8'),
(8,8,2013,'Leith','Camry Comment 9');

INSERT INTO @T2 (
Corolla_Id,
[Month],
[Year],
Dealer,
Corolla_Comments
)
VALUES
(1,7,2013,'AutoCity','Corolla Comment 1'),
(2,7,2013,'AutoCity','Corolla Comment 2'),
(3,7,2013,'AutoCity','Corolla Comment 6'),
(4,7,2013,'Leith','Corolla Comment 3'),
(4,7,2013,'Leith','Corolla Comment 8'),
(6,8,2013,'Leith','Corolla Comment 4'),
(8,7,2013,'Hendrick','Corolla Comment 7');

WITH P AS (
SELECT
*, ROW_NUMBER() OVER(PARTITION BY Dealer, [Year], [Month] ORDER BY Camry_Id) AS rn
FROM
@T1
),
Q AS (
SELECT
*, ROW_NUMBER() OVER(PARTITION BY Dealer, [Year], [Month] ORDER BY Corolla_Id) AS rn
FROM
@T2
)
SELECT
COALESCE(P.Dealer, Q.Dealer) AS D,
COALESCE(P.[Year], Q.[Year]) AS Y,
COALESCE(P.[Month], Q.[Month]) AS M,
P.Camry_Comments,
Q.Corolla_Comments
FROM
P
FULL OUTER JOIN
Q
ON P.Dealer = Q.Dealer
AND P.Year = Q.Year
AND P.Month = Q.Month
AND P.rn = Q.rn
ORDER BY
D, Y, M;
GO

BTW, next time post table schema and sample data in the form of "insert" statements. This way we do not need to guess column names, data types, constraints, etc.

Help us to be able to help you!



Post #1490268
Posted Friday, August 30, 2013 5:03 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, October 29, 2013 6:25 PM
Points: 4, Visits: 10
You are great with my poor explaination you still got it perfect :)
Actual query has 4 sub-queries corolla, camry, rava4, prius

Your solution is good for n queries though.
I was missing rn join :); without which it was multiplying.
Thanks a lot I will make sure to post in format you requested next time.

Post #1490335
Posted Friday, August 30, 2013 11:44 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 5:03 PM
Points: 35,954, Visits: 30,243
az1862 (8/30/2013)
Thanks a lot I will make sure to post in format you requested next time.



I can help there. Please see the first link in my signature line below...


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

"Change is inevitable. Change for the better is not." -- 04 August 2013
(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1490355
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse