Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


T-SQL Pvot Data and Hide duplicates


T-SQL Pvot Data and Hide duplicates

Author
Message
az1862
az1862
Forum Newbie
Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)

Group: General Forum Members
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
hunchback
hunchback
SSC-Enthusiastic
SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)SSC-Enthusiastic (117 reputation)

Group: General Forum Members
Points: 117 Visits: 639
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!



az1862
az1862
Forum Newbie
Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)

Group: General Forum Members
Points: 4 Visits: 10
You are great with my poor explaination you still got it perfect Smile
Actual query has 4 sub-queries corolla, camry, rava4, prius

Your solution is good for n queries though.
I was missing rn join Smile; without which it was multiplying.
Thanks a lot I will make sure to post in format you requested next time.
Jeff Moden
Jeff Moden
SSC-Forever
SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)

Group: General Forum Members
Points: 45447 Visits: 39944
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.
Although they tell us that they want it real bad, our primary goal is to ensure that we dont actually give it to them that way.
Although change is inevitable, change for the better is not.
Just because you can do something in PowerShell, doesnt mean you should. Wink

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
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