August 14, 2012 at 1:15 pm
I need help to code days. As the sample data below, days between [ADMDATE] and [DSCHDATE] need to be count as this way (at different rows):
MEMBIDADMDATEDSCHDATE
0600024808/02/201008/04/2010
0600024808/10/201008/12/2010 (08/10/2010 - 08/04/2010=6)
0600024808/20/201008/22/2010 (08/20/2010 - 08/12/2012=8)
The final result is 6 and 8.
August 14, 2012 at 1:29 pm
EDITED: Yeah, what Lynn said below. That's why I'm the Grasshopper and he's the coach 🙂
August 14, 2012 at 1:33 pm
Not difficult. One thing you need to do is to look carefully at my code below. You notice I am creating the table, populating it with sample data, and after my query I delete the table used for development. The first 2 items and the last you should provide instead of relying on us to do it for you. So happens, it is a slow day today but don't always count on that.
/*
MEMBID ADMDATE DSCHDATE
06000248 08/02/2010 08/04/2010
06000248 08/10/2010 08/12/2010 (08/10/2010 - 08/04/2010=6)
06000248 08/20/2010 08/22/2010 (08/20/2010 - 08/12/2012=8)
*/
CREATE TABLE dbo.PatientInfo (
MEMBID CHAR(8),
ADMDATE DATE,
DSCHDATE DATE
);
go
INSERT INTO dbo.PatientInfo
VALUES ('06000248','08/02/2010','08/04/2010'),
('06000248','08/10/2010','08/12/2010'),
('06000248','08/20/2010','08/22/2010');
GO
WITH BaseData AS (
SELECT
ROW_NUMBER() OVER (PARTITION BY MEMBID ORDER BY DSCHDATE) rn,
MEMBID,
ADMDATE,
DSCHDATE
FROM
dbo.PatientInfo
)
SELECT
bd1.MEMBID,
bd1.ADMDATE,
bd1.DSCHDATE,
ISNULL(DATEDIFF(dd, bd2.DSCHDATE, bd1.ADMDATE),0) DaysOut
FROM
BaseData bd1
LEFT OUTER JOIN BaseData bd2
ON (bd1.rn = bd2.rn + 1)
;
GO
DROP TABLE dbo.PatientInfo;
GO
August 14, 2012 at 2:36 pm
Thank you. I almost get there.
But, if I inserted more values, the duplicate result will displays.
How to fix it?
INSERT INTO dbo.PatientInfo
VALUES ('06000248','08/02/2010','08/04/2010'),
('06000248','08/10/2010','08/12/2010'),
('06000248','08/20/2010','08/22/2010'),
('06000348','08/02/2011','08/04/2011'),
('06000348','08/10/2011','08/12/2011'),
('06000348','08/20/2011','08/22/2011');
GO
MEMBID ADMDATE DSCHDATEDaysOut
060002482010-08-022010-08-040
060002482010-08-102010-08-126
060002482010-08-102010-08-12-359
060002482010-08-202010-08-228
060002482010-08-202010-08-22-357
060003482011-08-022011-08-040
060003482011-08-102011-08-12371
060003482011-08-102011-08-126
060003482011-08-202011-08-22373
060003482011-08-202011-08-228
August 14, 2012 at 3:33 pm
adonetok (8/14/2012)
Thank you. I almost get there.But, if I inserted more values, the duplicate result will displays.
How to fix it?
INSERT INTO dbo.PatientInfo
VALUES ('06000248','08/02/2010','08/04/2010'),
('06000248','08/10/2010','08/12/2010'),
('06000248','08/20/2010','08/22/2010'),
('06000348','08/02/2011','08/04/2011'),
('06000348','08/10/2011','08/12/2011'),
('06000348','08/20/2011','08/22/2011');
GO
MEMBID ADMDATE DSCHDATEDaysOut
060002482010-08-022010-08-040
060002482010-08-102010-08-126
060002482010-08-102010-08-12-359
060002482010-08-202010-08-228
060002482010-08-202010-08-22-357
060003482011-08-022011-08-040
060003482011-08-102011-08-12371
060003482011-08-102011-08-126
060003482011-08-202011-08-22373
060003482011-08-202011-08-228
You tell me, are duplicate records allowed? Your original sample data set did not have duplicates. If duplicates can exist, what are your business rules regarding them, can you eliminate them prior to processing or do you have work them and if so what are the rules for dealing with duplicates.
Nevermind the above, small font on a small screen (laptop) didn't realize the account numbers were different. Yes, to the below, we need to add a bit more to the join criteria.
August 14, 2012 at 3:36 pm
I think just doing the self join (the left join) on MEMBID and the row number to row number + 1 will solve the problem in the second set of sample data posted.
August 14, 2012 at 3:40 pm
Here is the updated code:
CREATE TABLE dbo.PatientInfo (
MEMBID CHAR(8),
ADMDATE DATE,
DSCHDATE DATE
);
go
INSERT INTO dbo.PatientInfo
VALUES ('06000248','08/02/2010','08/04/2010'),
('06000248','08/10/2010','08/12/2010'),
('06000248','08/20/2010','08/22/2010'),
('06000348','08/02/2011','08/04/2011'),
('06000348','08/10/2011','08/12/2011'),
('06000348','08/20/2011','08/22/2011');
GO
WITH BaseData AS (
SELECT
ROW_NUMBER() OVER (PARTITION BY MEMBID ORDER BY DSCHDATE) rn,
MEMBID,
ADMDATE,
DSCHDATE
FROM
dbo.PatientInfo
)
SELECT
bd1.MEMBID,
bd1.ADMDATE,
bd1.DSCHDATE,
ISNULL(DATEDIFF(dd, bd2.DSCHDATE, bd1.ADMDATE),0) DaysOut
FROM
BaseData bd1
LEFT OUTER JOIN BaseData bd2
ON (bd1.rn = bd2.rn + 1
AND bd1.MEMBID = bd2.MEMBID)
;
GO
DROP TABLE dbo.PatientInfo;
GO
August 15, 2012 at 9:26 am
It works great.
Thank you again
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply