October 4, 2013 at 9:20 am
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
SELECTDISTINCT a.Id, a.Name, b.Code
FROMTable1 a
INNER JOIN Table2 b ON a.Name = b.Name
Here is the current output
IdNameCode
1Penp1
1Penp2
2Penp1
2Penp2
But here is what i want
IdNameCode
1Penp1
2Penp2
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.
October 4, 2013 at 9:34 am
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)
October 4, 2013 at 9:38 am
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.
October 4, 2013 at 9:51 am
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.
October 4, 2013 at 10:11 am
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.
October 4, 2013 at 10:54 am
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
October 4, 2013 at 10:54 am
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 Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
October 4, 2013 at 12:44 pm
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.
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply