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


Help me with the SELECT statement please ?


Help me with the SELECT statement please ?

Author
Message
mw112009
mw112009
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10380 Visits: 1182
drew.allen - Monday, February 5, 2018 1:39 PM
So you're okay with someone who has a gap that crosses years?


INSERT INTO #t(BeneficiaryID, EligYear, EligMonth )
Select '12345678',2016,6 UNION
Select '12345678',2016,7 UNION
Select '12345678',2016,8 UNION
Select '12345678',2016,9 UNION
Select '12345678',2016,10 UNION
Select '12345678',2017,3 UNION
Select '12345678',2017,4 UNION
Select '12345678',2017,5


Drew

Yep! The code will check for each member per year. So if a member has 3 months in 2 different years, her gets listed 2 times ( my requirement is to capture a member who has had 3 or more months in a given year )

mw112009
mw112009
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10380 Visits: 1182
I did insert your sample records and ran the code, See attached. It works well.



If object_id('tempdb..#t') IS NOT NULL DROP TABLE #t;
CREATE TABLE #t( BeneficiaryID VARCHAR(10), EligYear INT, EligMonth INT );

INSERT INTO #t(BeneficiaryID, EligYear, EligMonth )
Select '0068576102',2016,3 UNION
Select '0068576102',2016,6 UNION
Select '0068576102',2016,7 UNION
Select '0068576102',2016,8 UNION
Select '0068576102',2016,9 UNION
Select '0068576102',2016,10 UNION
Select '0068576102',2016,11 UNION
Select '0068576102',2016,12 UNION
Select '0068576102',2017,10 UNION
Select '0068576102',2017,11 UNION
Select '0068576102',2017,12 UNION
Select '0078576103',2016,8 UNION
Select '0078576103',2016,9 UNION
Select '78576103',2016,8 UNION
Select '78576103',2016,9 UNION
Select '78576103',2016,10 UNION
Select '78576109',2016,8 UNION
Select '78576109',2016,9 UNION
Select '78576109',2016,11 UNION
Select '78576109',2016,12;

INSERT INTO #t(BeneficiaryID, EligYear, EligMonth )
Select '12345678',2016,6 UNION
Select '12345678',2016,7 UNION
Select '12345678',2016,8 UNION
Select '12345678',2016,9 UNION
Select '12345678',2016,10 UNION
Select '12345678',2017,3 UNION
Select '12345678',2017,4 UNION
Select '12345678',2017,5



;
WITH T AS
(
SELECT *
,DENSE_RANK() OVER (PARTITION BY BeneficiaryID, EligYear ORDER BY EligMonth) - EligMonth AS Grp2
FROM #t
)
--Select * FROM T ORDER BY 1
,
CONSECUTIVE_MONTHS_TOGETHER as
(
SELECT
BeneficiaryID,
EligYear,
MIN(EligMonth) AS RangeStart,
MAX(EligMonth) AS RangeEnd,
MAX(EligMonth) - MIN(EligMonth) as DIFF
FROM T
GROUP BY BeneficiaryID,EligYear, Grp2
)
Select * FROM CONSECUTIVE_MONTHS_TOGETHER WHERE DIFF >= 2 --( See Explanation )

/*
This solution works when the numbers are in a sequence ( that is the case with my example )
So if you had any 3 months of consecutive coverage the difference between the largest and smallest must be > 1 -- OR ( >= (2) )
*/





mw112009
mw112009
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10380 Visits: 1182
mw112009 - Monday, February 5, 2018 2:25 PM
drew.allen - Monday, February 5, 2018 1:39 PM
So you're okay with someone who has a gap that crosses years?


INSERT INTO #t(BeneficiaryID, EligYear, EligMonth )
Select '12345678',2016,6 UNION
Select '12345678',2016,7 UNION
Select '12345678',2016,8 UNION
Select '12345678',2016,9 UNION
Select '12345678',2016,10 UNION
Select '12345678',2017,3 UNION
Select '12345678',2017,4 UNION
Select '12345678',2017,5


Drew

Yep! The code will check for each member per year. So if a member has 3 months in 2 different years, her gets listed 2 times ( my requirement is to capture a member who has had 3 or more months in a given year )

Mr Drew:
I thought about this...
I think what your asking is if a members enrollment spans across years can you find out whether he/she has enrollment for more than 3 or more months ? ( example: 2016/12,207/1,2017/2 will qualify for a 3 month span )

Yes, the code below takes care of it.....


If object_id('tempdb..#t') IS NOT NULL DROP TABLE #t;
CREATE TABLE #t( BeneficiaryID VARCHAR(10), EligYear INT, EligMonth INT );

INSERT INTO #t(BeneficiaryID, EligYear, EligMonth )
Select '12345678',2016,6 UNION
Select '12345678',2016,7 UNION
Select '12345678',2016,8 UNION
Select '12345678',2016,9 UNION
Select '12345678',2016,10 UNION
Select '12345678',2017,2 UNION
Select '12345678',2017,3 UNION
Select '12345678',2017,4 UNION

Select '82345678',2016,6 UNION
Select '82345678',2016,7 UNION
Select '82345678',2016,8 UNION
Select '82345678',2016,9 UNION
Select '82345678',2016,10 UNION
Select '82345678',2016,11 UNION
Select '82345678',2016,12 UNION
Select '82345678',2017,1 UNION
Select '82345678',2017,2 UNION
Select '82345678',2017,3 UNION
Select '82345678',2017,4 UNION
Select '82345678',2017,5 UNION
Select '92345678',2016,12 UNION
Select '92345678',2017,1


;
With START_POINT as
(
Select
BeneficiaryID, MIN(EligYear) MIN_YEAR, MIN(EligMonth) MIN_MONTH
FROM #t
GROUP BY BeneficiaryID
)
,
MONTH_POSITION as
(
Select T.*, B.MIN_YEAR, B.MIN_MONTH,
((T.ELIGYear - B.MIN_YEAR )*(12) + (EligMonth)) as MONTH_SEQ
FROM
#t T
INNER JOIN START_POINT B ON ( B.BeneficiaryID = T.BeneficiaryID )

)
,
T AS
(
SELECT *
,DENSE_RANK() OVER (PARTITION BY BeneficiaryID ORDER BY MONTH_SEQ) - MONTH_SEQ AS Grp2
FROM MONTH_POSITION
)
,
CONSECUTIVE_MONTHS_TOGETHER as
(
SELECT
BeneficiaryID,
MIN(MONTH_SEQ) AS RangeStart,
MAX(MONTH_SEQ) AS RangeEnd,
MAX(MONTH_SEQ) - MIN(MONTH_SEQ) as DIFF
FROM T
GROUP BY BeneficiaryID, Grp2
)
Select *
FROM
CONSECUTIVE_MONTHS_TOGETHER
WHERE DIFF >= 2 -- Continuous Months for 3 or more
ORDER BY 1,2







Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (540K reputation)SSC Guru (540K reputation)SSC Guru (540K reputation)SSC Guru (540K reputation)SSC Guru (540K reputation)SSC Guru (540K reputation)SSC Guru (540K reputation)SSC Guru (540K reputation)

Group: General Forum Members
Points: 540257 Visits: 44587
The biggest problem with this whole thing is the notion of storing the year and month in separate columns instead of as whole dates that represent the first of the month. Any chance of you changing that or adding a persisted computed column?

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
ScottPletcher
ScottPletcher
SSC-Forever
SSC-Forever (49K reputation)SSC-Forever (49K reputation)SSC-Forever (49K reputation)SSC-Forever (49K reputation)SSC-Forever (49K reputation)SSC-Forever (49K reputation)SSC-Forever (49K reputation)SSC-Forever (49K reputation)

Group: General Forum Members
Points: 49839 Visits: 8227
Jeff Moden - Wednesday, February 14, 2018 6:31 AM
The biggest problem with this whole thing is the notion of storing the year and month in separate columns instead of as whole dates that represent the first of the month. Any chance of you changing that or adding a persisted computed column?

Couldn't you just multiply the year by 12 and add the months, then check for sequential numbers?


SQL DBA,SQL Server MVP(07, 08, 09) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
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