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 12»»

SQL Query to select one row and fill missing columns from another matching row. Expand / Collapse
Author
Message
Posted Tuesday, October 02, 2012 2:52 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, January 09, 2013 7:09 AM
Points: 4, Visits: 18
I have a table with the following structure and need to retrieve only record from the table:

Table: Person
Records:

Id, Name, MartialStatus, EmploymentStatus, Email, JobId
1, John,8,6,John@xxx.com,99
2, John,10,7,John@xxx.com,100
3, John,NULL,NULL,John@xxx.com,101
4, Max,6,5,max@emailreaction.org, 102


JobId, GroupId, Desc
99, 50, "blah blah"
100, 50, "blah blah"
101, 50, "blah blah"
102, 51, "blah blah"


I want to retrieve a record from the person table based on the group id...
for eg. for Group Id 50 I want the following record which is mix of record 3 and 2 as:
------------------------------------
3, John,10,7,John@xxx.com,101
-------------------------------------

Record num 3 should be retrieved with the marital status and employment status from record two as they were null.

any help will be highly appreciated.
Post #1366907
Posted Tuesday, October 02, 2012 3:23 AM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Wednesday, March 19, 2014 9:43 AM
Points: 316, Visits: 1,022
This works for the test data. It picks up values from the 3rd row if the 2nd has nulls too.


--===== TEST DATA =========
declare @Person table
(Id int, Name varchar(20), MartialStatus int, EmploymentStatus int, Email varchar(50), JobId int );

INSERT INTO @Person
( Id, Name, MartialStatus, EmploymentStatus, Email, JobId )
VALUES
(1, 'John', 8, 6, 'John@xxx.com', 99),
(2, 'John', 10, 7, 'John@xxx.com', 100),
(3, 'John', NULL, NULL, 'John@xxx.com', 101),
(4, 'Max', 6, 5, 'max@emailreaction.org', 102);

--select * from @Person

declare @Job table
(JobId int, GroupId int, [Desc] varchar(30) );

INSERT INTO @Job
( JobId, GroupId, [Desc] )
VALUES
(99, 50, 'blah blah'),
(100, 50, 'blah blah'),
(101, 50, 'blah blah'),
(102, 51, 'blah blah');

--select * from @Job

--I want to retrieve a record from the person table based on the group id...
--for eg. for Group Id 50 I want the following record which is mix of record 3 and 2 as:
--------------------------------------
--3, John,10,7,John@xxx.com,101
---------------------------------------

--Record num 3 should be retrieved with the marital status and employment status from record two as they were null.

--====== SUGGESTED SOLUTION =========
declare @GroupId int = 50;

with CTE as
(
select
RowId = ROW_NUMBER() over (partition by p.Name order by p.JobId desc),
p.Id,
p.Name,
p.MartialStatus,
p.EmploymentStatus,
p.Email,
p.JobId
from @job j
inner join @Person p on j.jobId = p.JobId
where j.GroupId = @GroupId
)
select a.Id,
a.Name,
MartialStatus = coalesce(a.MartialStatus,b.MartialStatus,c.MartialStatus),
EmploymentStatus = coalesce(a.EmploymentStatus,b.EmploymentStatus,c.EmploymentStatus),
a.Email,
a.JobId
from CTE a
left outer join CTE b on a.RowId +1 = b.RowId
left outer join CTE c on a.RowId +2 = c.RowId
where a.RowId = 1;


Post #1366922
Posted Tuesday, October 02, 2012 4:19 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Yesterday @ 6:03 PM
Points: 3,590, Visits: 5,098
Record 1 is also part of the group defined for 2 and 3 (groupid 50) and you didn't say how you wanted that to be handled (unless ignoring as you did is what you want).

This approach may be a little simpler (uses Laurie's set up data):

SELECT Id=MAX(Id), Name=MAX(Name)
,MartialStatus=MAX(MartialStatus)
,EmploymentStatus=MAX(EmploymentStatus)
,Email=MAX(Email)
,JobId=MAX(a.JobId)
FROM @Person a
INNER JOIN @Job b ON a.JobId = b.JobId
GROUP BY b.GroupId





My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1366939
Posted Tuesday, October 02, 2012 4:45 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, January 09, 2013 7:09 AM
Points: 4, Visits: 18
Thanks laurie and dwain.c.

dwain.c i like your approach as it's bit simple but please can you give some explanation so that it makes more sense to me... i always thought that max() function is used for numbers...

did a quick test and both of them seem to work but unfortunately I can't use SQL 2008, sorry didn't mention this earlier.

Regards,
kk
Post #1366945
Posted Tuesday, October 02, 2012 4:46 AM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Wednesday, March 19, 2014 9:43 AM
Points: 316, Visits: 1,022
[b]

Record num 3 should be retrieved with the marital status and employment status from record two as they were null.



I read this as 3 being a later record than 2.

The marital status & employment status do ascend in the sample data, but if they don't, selecting MAX() may get a value from any record, not necessarily the latest. Same goes for the other columns e.g. email address may change to something which sorts lower e.g. "john@aaa.com". So selecting MAX() may not get the latest results.
Post #1366947
Posted Tuesday, October 02, 2012 4:47 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, January 09, 2013 7:09 AM
Points: 4, Visits: 18
also is it possible to auto return all columns in the table or we need to explicitly specity all the columns in a select query?
Post #1366948
Posted Tuesday, October 02, 2012 4:48 AM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Wednesday, March 19, 2014 9:43 AM
Points: 316, Visits: 1,022

unfortunately I can't use SQL 2008, sorry didn't mention this earlier.


What version are you using?
Post #1366949
Posted Tuesday, October 02, 2012 4:50 AM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Wednesday, March 19, 2014 9:43 AM
Points: 316, Visits: 1,022
kk 93815 (10/2/2012)
also is it possible to auto return all columns in the table or we need to explicitly specity all the columns in a select query?


You should always specify the columns you want in case more columns are added to the table - this will change your query results.

Its also easier & clearer to read.
Post #1366951
Posted Tuesday, October 02, 2012 4:55 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, January 09, 2013 7:09 AM
Points: 4, Visits: 18
Thanks laurie. we are using 2005
Post #1366956
Posted Tuesday, October 02, 2012 4:56 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Yesterday @ 6:03 PM
Points: 3,590, Visits: 5,098
kk 93815 (10/2/2012)
Thanks laurie and dwain.c.

dwain.c i like your approach as it's bit simple but please can you give some explanation so that it makes more sense to me... i always thought that max() function is used for numbers...

did a quick test and both of them seem to work but unfortunately I can't use SQL 2008, sorry didn't mention this earlier.

Regards,
kk


Laurie's answer is correct on MAX. Remember that character strings also have an inherent collation sequence, which is used to resolve MAX/MIN.

Laurie's double LEFT JOIN and using COALESCE may be better at resolving multiple record ties, unfortunately I don't think it will work if there happens to be 4 records that are all tied.

I meant to say originally that you probably should try both approaches across a wider range of test data to see which works better for you. Often when you do that, you'll find there are issues and then you can repost those cases so someone can suggest how to best handle them.



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1366958
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse