March 4, 2009 at 4:00 pm
Hi,
I have two tables and both of these table contains user phone information.
There is not a single column value is common in both of these table on which i can join tables. Both of these table contains 6 record each and i know the key value for both of these tables, i mean USER_KEY.
Now i want to generate a report where i can show phone nos from both of these table side by side. If i join these table like
select phone_no from tableA,tableB
where tableA.user_key=100 and tableB.user_key=1001
then i am getting 36 records which is correct. but i want to avoid this cartesian join and just want query to return me 6 records.
Your help is appreciated.
Thanks
March 4, 2009 at 10:52 pm
Heh... it's easy and I'll tell you... right after you tell me why you'd want to do such a thing... you know... what are the business requirements that require this to be done? I'd show you up front, but I've found that once people have their answer, they won't answer my question. This is a two way street and I like to know these things. Thanks for your time.
--Jeff Moden
Change is inevitable... Change for the better is not.
March 5, 2009 at 9:02 am
Allrite, here is the justification.
Business wants to compare the data between these two tables and business user are not SQL friendly thats why they asked me to generate a report or an excel sheet where it will show data side by side.
Hope this will clear you my requirement.
Thanks
March 5, 2009 at 2:00 pm
Perfect... thanks... here's how to do it...
;WITH
cteTableA AS
(
SELECT ROW_NUMBER() OVER (ORDER BY Phone_No) AS RowNumber,
Phone_No
FROM dbo.TableA
WHERE User_Key = 100
)
,
cteTableB AS
(
SELECT ROW_NUMBER() OVER (ORDER BY Phone_No) AS RowNumber,
Phone_No
FROM dbo.TableB
WHERE User_Key = 1001
)
SELECT a.Phone_No, b.Phone_No
FROM cteTableA
FULL OUTER JOIN cteTableB
ON a.RowNum = b.RowNum
Lemme know if you have any questions about how or why it works.
--Jeff Moden
Change is inevitable... Change for the better is not.
March 6, 2009 at 9:03 pm
Ya kinda left things hanging here... did that work for you or what?
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 5 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply
This website stores cookies on your computer.
These cookies are used to improve your website experience and provide more personalized services to you, both on this website and through other media.
To find out more about the cookies we use, see our Privacy Policy