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

Find the first appointment by patient and month Expand / Collapse
Author
Message
Posted Thursday, March 21, 2013 9:54 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, May 28, 2014 4:38 PM
Points: 5, Visits: 33
I am trying write an efficient t-sql query that will return, for a specific date range, the first appointment for each patient for each month. For example, a particular patient has the folowing appointments for 1/1/2012 - 3/31/2012:

Patient Name Appt Number Appt Timestamp
------------- ------------- ---------------
John Smith 18374832 2012-01-05 08:15:00
John Smith 19837289 2012-01-07 14:30:00
John Smith 19982776 2012-02-15 09:00:00
John Smith 20091092 2012-02-27 15:45:00
John Smith 20100939 2012-02-28 07:25:00
John Smith 20110938 2012-03-05 16:50:00

Given that data the query will only return:
John Smith 18374832 2012-01-05 08:15:00
John Smith 19982776 2012-02-15 09:00:00
John Smith 20110938 2012-03-05 16:50:00

Any ideas what an efficient code would be go create such a result set?

Thanks in advance!
Babak
Phoenix, AZ
Post #1434124
Posted Thursday, March 21, 2013 10:49 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 8:47 PM
Points: 23,293, Visits: 32,028
This should help you get started. Please note how I created a table and populated that table with sample data. This is what you need to provide in the future when posting questions like this. I do have to give you credit for also posting the expected results as that is needed as well.


create table #TestTable (
PatientName varchar(132),
ApptNumber int,
ApptDate datetime
);

insert into #TestTable
values
('John Smith',18374832,'2012-01-05 08:15:00'),
('John Smith',19837289,'2012-01-07 14:30:00'),
('John Smith',19982776,'2012-02-15 09:00:00'),
('John Smith',20091092,'2012-02-27 15:45:00'),
('John Smith',20100939,'2012-02-28 07:25:00'),
('John Smith',20110938,'2012-03-05 16:50:00');

with BaseData as (
select
PatientName,
ApptNumber,
ApptDate,
rn = row_number() over (partition by PatientName, dateadd(mm, datediff(mm, 0, ApptDate), 0) order by ApptDate asc)
from
#TestTable
)
select
PatientName,
ApptNumber,
ApptDate
from
BaseData
where
rn = 1;

drop table #TestTable;

/*
Given that data the query will only return:
John Smith 18374832 2012-01-05 08:15:00
John Smith 19982776 2012-02-15 09:00:00
John Smith 20110938 2012-03-05 16:50:00
*/





Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #1434130
Posted Friday, March 22, 2013 12:16 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, May 28, 2014 4:38 PM
Points: 5, Visits: 33
Lynn, thanks for the information and the feedback!
Post #1434142
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse