SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Find the first appointment by patient and month


Find the first appointment by patient and month

Author
Message
bbk0919
bbk0919
SSC Rookie
SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)

Group: General Forum Members
Points: 39 Visits: 124
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
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)

Group: General Forum Members
Points: 89682 Visits: 38933
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
*/




Cool
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)
bbk0919
bbk0919
SSC Rookie
SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)SSC Rookie (39 reputation)

Group: General Forum Members
Points: 39 Visits: 124
Lynn, thanks for the information and the feedback! :-)
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