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


JOIN issue


JOIN issue

Author
Message
DBABC
DBABC
SSC Veteran
SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)

Group: General Forum Members
Points: 249 Visits: 482
I am having a join issue because of duplicate value in my join keys. I cannot change the data source or the structure of tables. So how can I get my required output as described below.



CREATE TABLE Table1
(
   Id INT,
   Name VARCHAR(50)
);


CREATE TABLE Table2
(
   Name VARCHAR(50),
   Code VARCHAR(10)
);

INSERT INTO Table1 VALUES (1, 'Pen');
INSERT INTO Table1 VALUES (2, 'Pen');

INSERT INTO Table2 VALUES ('Pen', 'p1');
INSERT INTO Table2 VALUES ('Pen', 'p2');





Here is my current query



SELECT   DISTINCT a.Id, a.Name, b.Code
FROM   Table1 a
      INNER JOIN Table2 b ON a.Name = b.Name





Here is the current output

Id   Name   Code
1   Pen   p1
1   Pen   p2
2   Pen   p1
2   Pen   p2


But here is what i want

Id   Name   Code
1   Pen   p1
2   Pen   p2



So basically i want to join the first record from table1 to first matching record in table2, and second record (with same name) from table1 should match to the second record (with same name) from table2 and so on.
Luis Cazares
Luis Cazares
SSCrazy Eights
SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)

Group: General Forum Members
Points: 8487 Visits: 18089
This could cause you some serious problems. Until you become able to change anything, here are two possible solutions, but try to convince someone to authorize the change.

SELECT *
FROM Table1 t1
JOIN Table2 t2 ON LEFT( t1.Name, 1) + CAST( t1.Id AS varchar(10)) = t2.Code

SELECT *
FROM Table1 t1
JOIN Table2 t2 ON t1.Id = CAST( REPLACE( t2.Code, 'p', '') AS Int)




Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
SrcName
SrcName
SSC-Enthusiastic
SSC-Enthusiastic (122 reputation)SSC-Enthusiastic (122 reputation)SSC-Enthusiastic (122 reputation)SSC-Enthusiastic (122 reputation)SSC-Enthusiastic (122 reputation)SSC-Enthusiastic (122 reputation)SSC-Enthusiastic (122 reputation)SSC-Enthusiastic (122 reputation)

Group: General Forum Members
Points: 122 Visits: 394
if the logic is like this then you may use RIGHT (not in where becouse there is performance problem)

you can try on this way:

select * from TABLE1 t join
( select *, right(code,1)code form TABLE2 )q on t.id = q.code and t.name = q.name

or
select *, right(code,1)code into #temp form TABLE2

and after that you can join two tables.
Luis Cazares
Luis Cazares
SSCrazy Eights
SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)

Group: General Forum Members
Points: 8487 Visits: 18089
SrcName (10/4/2013)
if the logic is like this then you may use RIGHT (not in where becouse there is performance problem)

you can try on this way:

select * from TABLE1 t join
( select *, right(code,1)code form TABLE2 )q on t.id = q.code and t.name = q.name

or
select *, right(code,1)code into #temp form TABLE2

and after that you can join two tables.

You might be just following ideas to improve performance without knowing the complete part. Functions on the WHERE clause and on the ON clause for a JOIN. The reason is because SQL Server won't be able to use indexes but there's no way that an index might be helpful for this join.

Your second suggestion implies that you have to copy table2 into a temp table. That will have an overhead for the extra read and write for the whole table and again, no index gain.


Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
DBABC
DBABC
SSC Veteran
SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)

Group: General Forum Members
Points: 249 Visits: 482
Thanks for the suggestions guys. I am sorry i should not have used "P1" & "p2" as codes, these are just my examples codes actual values won't have any correlation with Id (e.g. actual code value could be "2956" or "4684" etc) so i cannot use what you guys suggested.


I want a solution that doesn't depend on values. I was thinking something like, get minimum code for the first matching record, then get the minimum code (greater than the code applied on first record) for the second record and so on.
Luis Cazares
Luis Cazares
SSCrazy Eights
SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)SSCrazy Eights (8.5K reputation)

Group: General Forum Members
Points: 8487 Visits: 18089
You might want to add a column to your queries, using ROW_NUMBER().
Here's an example, but without some data more similar to the real data, it's hard to give a good option.

WITH t1 AS(
SELECT *,
ROW_NUMBER() OVER( Order BY Id) AS rn
FROM Table1
),
t2 AS(
SELECT *,
ROW_NUMBER() OVER( Order BY Code) AS rn
FROM Table2
)
SELECT *
FROM t1
JOIN t2 ON t1.rn = t2.rn




Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
Sean Lange
Sean Lange
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16540 Visits: 16993
UDBA (10/4/2013)
Thanks for the suggestions guys. I am sorry i should not have used "P1" & "p2" as codes, these are just my examples codes actual values won't have any correlation with Id (e.g. actual code value could be "2956" or "4684" etc) so i cannot use what you guys suggested.


I want a solution that doesn't depend on values. I was thinking something like, get minimum code for the first matching record, then get the minimum code (greater than the code applied on first record) for the second record and so on.


I suppose you could rownumber but this is really sloppy to say the least. How do you define what is the first row? You are basically just picking an arbitrary value as your join condition which is bizarre.

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
DBABC
DBABC
SSC Veteran
SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)SSC Veteran (249 reputation)

Group: General Forum Members
Points: 249 Visits: 482
Luis Cazares (10/4/2013)
You might want to add a column to your queries, using ROW_NUMBER().
Here's an example, but without some data more similar to the real data, it's hard to give a good option.

WITH t1 AS(
SELECT *,
ROW_NUMBER() OVER( Order BY Id) AS rn
FROM Table1
),
t2 AS(
SELECT *,
ROW_NUMBER() OVER( Order BY Code) AS rn
FROM Table2
)
SELECT *
FROM t1
JOIN t2 ON t1.rn = t2.rn




Luis you beauty....THANK YOU.....it worked perfect on my real data and gives exactly what i was looking for.
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