From 7cd63601dbe70218af3a345047b871b72ab143a2 Mon Sep 17 00:00:00 2001 From: Simon Anastasiadis Date: Thu, 27 Jun 2024 09:29:31 +1200 Subject: [PATCH] ensure consistency with consultant definitions --- health/GP_contacts.sql | 112 ++++++++++++++++-- health/funded_moh_disability.sql | 169 +++++++++++++++++++++++---- housing/emergency_housing_spells.sql | 8 +- housing/residential_care.sql | Bin 52928 -> 53874 bytes 4 files changed, 250 insertions(+), 39 deletions(-) diff --git a/health/GP_contacts.sql b/health/GP_contacts.sql index 6ac05fb..691b41c 100644 --- a/health/GP_contacts.sql +++ b/health/GP_contacts.sql @@ -22,6 +22,11 @@ of GP contact at the individual level by date of visit. Intended purpose: Estimate primary care consults for each snz_uid by date. +This code returns an estimated number of times a patient has contacted a GP in the specified time period. +This could be used to compare characteristics of populations that have regular contact with a GP against those that do not. + +This code does not accurately identify the maximum number of times a patient has contact with a GP. +This should not be used for exact or maximum patient contact with a GP. Inputs & Dependencies: - [IDI_Clean].[acc_clean].[payments] @@ -33,9 +38,36 @@ Inputs & Dependencies: - [IDI_Clean].[moh_clean].[pop_cohort_demographics] - [IDI_Clean].[moh_clean].[pho_enrolment] - [IDI_Clean].[moh_clean].[gms_claims] + Outputs: - [IDI_Sandpit].[DL-MAA20XX-YY].[defn_GP_contacts] +Key concepts: + A GP (General Practitioner) is a family doctor that is usually the first point of contact for the patients’ new injury or illness. + Visits to GPs are partially funded by the central government and the funding history is recorded in 3 datasets – + General Medical Service (GMS), Primary Health Organization (PHO) and National Enrolment Service (NES). + + Originally, almost all healthcare user visits to general practitioners resulted in a fee-for-service GMS claim. + However since 2003, capitation payments made via Primary Health Organisations (PHOs) have progressively replaced fee-for-service claiming. + Now GMS claims are made for only a limited number of healthcare user visits of specific types. + From 2003 to 2006, GPs progressively moved to the PHO funding model. + By 2006 almost all GPs were part of a PHO so the majority of non-enrolled healthcare users were those without a regular GP. + By 2012, 96.1% of the estimated resident New Zealand population were enrolled in a PHO. + NES enrolments replaced PHO funding in the data in 2019. + These datasets are all used to provide information about when a patient visited a GP. + + PHO and NES data is stored in quarterly snapshots, so it is also not possible to see the exact date a person visited a GP, + it is only possible to tell if they had contact in the quarter. + It is possible to construct a frequency of primary care contact history at the individual level using several data sources in the IDI: + - Primary Healthcare Organisation (PHO) – last contact date + - Laboratory Testing Claims – provider visit date + - General Medical Subsidy Claims – GP visit date + - ACC claims – first payment date + - NES – last contact date + + Results are consistent with expectations that ~81% of the population have 1 or more contacts with their GP each year. + The approx. number of GP visits a year has been verified against www.rnzcpg.org.nz/gpdocs/new-website/publications/2021-GP-future-workforce-report-FINAL.pdf + They state that “GPs deliver 14 million consultations per year”. Notes: 1) The indicator relies primarily on this: @@ -55,21 +87,20 @@ Notes: compare favourably to the indicator, within a few percent. Total volume comparisons by age, gender, and ethnic group are also similar but differ by about 5-10%. 4) We exclude multiple events on the same day, but for some people these are likely to exist. -5) Final table: Dec 2014-Jan 2021. -6) In the 20210720 refresh the data is complete from 2014-2018, partial for 2019-2020 (80-90%) - and has very little for 2021 except for January. -7) Using Lab visits presents a challenge. ~20% of labs data is from hospitals and not GP visits. +5) In the 20210720 refresh the data is complete from 2014-2018, partial for 2019-2020 (80-90%) + and has very little for 2021 except for January. Data is incomplete before 2003. +6) Using Lab visits presents a challenge. ~20% of labs data is from hospitals and not GP visits. There is no indicator to identify this. Our approach is to drop lab visits on days where the snz_uid is in hospital or a non-admitted patient (NAP). This reduced lab tests by ~3.5% Investigation suggested that lab tests reported the day after a hospital visit behave similarly to lab tests during a hospital visit, hence these were also excluded. This increased the reduction in lab tests from ~3.5% to ~5.5% -8) Results are consistent with expectations that ~81% of the population have 1 or more contacts +7) Results are consistent with expectations that ~81% of the population have 1 or more contacts with their GP each year. -9) A small proportion of people will have multiple visits to a GP on the same day. For some datasets +8) A small proportion of people will have multiple visits to a GP on the same day. For some datasets this can be observed via duplicate records. But this can not be reliably detected across datasets. We have not attempted to capture multiple visits on the same day. -10) The lab tests data includes provider codes. This should include the ID of the referring entity. +9) The lab tests data includes provider codes. This should include the ID of the referring entity. This definition might be further refined by investigation & use of these codes. For example, if we observe providers whose lab tests never coincide with ACC, GMS, or GP enrolments, then this would suggest these providers are operating in a different function from GPs. @@ -99,6 +130,13 @@ GO /******************************************************** ACC GP visits + +- The first ACC claim payment date is used as an indicator of a GP visit. +A last payment date also exists, however the distribution of the length of claims +has weekly spikes suggesting an influence by a billing cycle. This suggests that we cannot use the last +day as an indication of a GP visit. We do not account for multiple claims in a single day. + +- This produces ~30,000,000 distinct claims. ********************************************************/ INSERT INTO [IDI_Sandpit].[DL-MAA20XX-YY].[tmp_GP_contacts_list] (snz_uid, visit_date) @@ -114,6 +152,24 @@ GO /******************************************************** Labs + +- The GP visit date is determined based on the [moh_lab_visit_date] +which is the date the healthcare user visited the referring practitioner. + +- Lab claims that match or fall between the date on which a healthcare event began at a publically funded hospital +for a unique user and one day past the discharge date are excluded as these lab tests are assumed to be from the +hospital admission. + +- Lab claims that match the date that the triaged patient's treatment starts by a suitable ED medical professional +or one day past this date are excluded as these lab tests are assumed to be from an ED interaction. + +- Approximately 20% of lab tests are requested in the secondary care setting and this is likely +to drive a slight over count in estimates. + +- Investigation suggested that lab tests reported the day after a hospital visit behave similarly +to lab tests during a hospital visit, hence these were also excluded. + +- This produces ~110,000,000 distinct claims. ********************************************************/ WITH adding_hospital_indicators_to_lab_tests AS ( @@ -140,10 +196,29 @@ INSERT INTO [IDI_Sandpit].[DL-MAA20XX-YY].[tmp_GP_contacts_list] (snz_uid, visit SELECT snz_uid ,visit_date FROM adding_hospital_indicators_to_lab_tests +WHERE public_hospital_discharge = 0 +AND non_admitted_patient = 0 +AND hospital = 0 +AND (public_hospital_discharge_extra = 0 OR public_hospital_discharge_extra IS NULL) +AND (non_admitted_patient_extra = 0 OR non_admitted_patient_extra IS NULL) GO /******************************************************** NES - contact events for the National enrolment service data + +- The NES quarterly reporting of last date of GP contact (up to four visits a year). + +- The data is stored in quarterly snapshots, so it is not possible to see the exact date a person +visited a GP, it is only possible to tell if they had contact in the quarter. + +- Enrolment registers are submitted on a quarterly basis before the quarter of interest begins. +The GP stops recording variables (eg last consultation date) before the quarter of interest. +Any dates submitted after the quarter of interest start date are likely to be data quality errors. + +- NES data replaces PHO in 2019/2020 with a new series that is split into two tables [moh_clean].[pop_cohort_nes_address] +and [moh_clean].[nes_enrolment]. + +- This produces ~42,000,000 distinct claims. ********************************************************/ INSERT INTO [IDI_Sandpit].[DL-MAA20XX-YY].[tmp_GP_contacts_list] (snz_uid, visit_date) @@ -157,6 +232,17 @@ GO /******************************************************** PHO - contact events for the PHO enrolment service data + +- The PHO quarterly reporting of last date of GP contact (up to four visits a year). + +- The data is stored in quarterly snapshots, so it is not possible to see the exact date a person +visited a GP, it is only possible to tell if they had contact in the quarter. + +- Enrolment registers are submitted on a quarterly basis before the quarter of interest begins. +The GP stops recording variables (eg last consultation date) before the quarter of interest. +Any dates submitted after the quarter of interest start date are likely to be data quality errors. + +- This produces ~140,000,000 distinct claims. ********************************************************/ INSERT INTO [IDI_Sandpit].[DL-MAA20XX-YY].[tmp_GP_contacts_list] (snz_uid, visit_date) @@ -168,6 +254,13 @@ GO /******************************************************** GMS - contact events for GP visits outside of PHO enrolment + +- GMS claims provide the date of GP visits ([moh_gms_visit_date]). + +- Up until 2003 most GP visits were in a GMS claim; a limited number of specific health care user +visits are still made through GMS. + +- This produces ~30,000,000 distinct claims. ********************************************************/ INSERT INTO [IDI_Sandpit].[DL-MAA20XX-YY].[tmp_GP_contacts_list] (snz_uid, visit_date) @@ -179,6 +272,11 @@ GO /******************************************************** Combine + +- Filter snz_uid and visit dates that are NULL and select distinct snz_uid/visit_date pairs. + +- Since the GP visit dates are compiled from several sources, it is possible that duplicates on the same day will exist and so these need to be filtered out. +This code does not accurately identify the maximum number of times a patient has contact with a GP, but instead the distinct number of events. ********************************************************/ DROP TABLE IF EXISTS [IDI_Sandpit].[DL-MAA20XX-YY].[defn_GP_contacts] diff --git a/health/funded_moh_disability.sql b/health/funded_moh_disability.sql index f3b672d..309ccee 100644 --- a/health/funded_moh_disability.sql +++ b/health/funded_moh_disability.sql @@ -21,51 +21,170 @@ Recent funded MOH disability client in SOCRATES Intended purpose: Identifying people receiving funding via SOCRATES (MOH) for a disability. +## Purpose of the MOH Funded Disability indicator: +This code defines spells where clients are eligible to receive MoH disability funding. It is based on having a needs assessment done by a Needs Assessment and Service Coordination (NASC) provider where the outcome was “Requires Service Coordination” (see www.health.govt.nz/your-health/services-and-support/disability-services/getting-support-disability/needs-assessment-and-service-coordination-services). +Note that this does not mean that the client actually received any services, it simply means that they were assessed as being eligible. + +## Key concepts +Access to MoH Disability funding is managed via service needs assessments that are facilitated by NASC organizations that are contracted by Disability Support Services, Ministry of Health. +Full details can be found here: +www.health.govt.nz/your-health/services-and-support/disability-services/getting-support-disability/needs-assessment-and-service-coordination-services +The Ministry funds services for people with a physical, intellectual and/or sensory impairment or disability that is: +• Likely to continue for a minimum of 6 months +• Reduces your ability to function independently, to the extent that ongoing support is required. +In addition, a person with Autism Spectrum Disorder may also be eligible for a needs assessment. These are usually for people under the age of 65. Disability support services for people with mental health needs are generally funded by DHBs. +Before a needs assessment can take place the clients need a written referral (e.g. by GPs, Family, DHBs, service providers or self-referrals). +A service needs assessment has a DateAssessmentCompleted and ReassessmentRequestedDate which count as the start and end date of a spell. A spell will often last for 3 years, however, shorter spells are possible. + +## Practical notes +There are some issues with the data: +• This indicator is only reliable from 01/01/2008 to 31/03/2021. It is likely that the end date of the reliable period will extend as the data is updated. +• The AssessmentOutcome is only reliable after 2008, before that the outcome is usually “Migrated by Socrates Project”. The assessments themselves go back to the early 2000’s. Currently the data only includes up to assessments up to 31/03/2021. +• There are some payments that happen outside the spell period defined by the DateAssessmentCompleted and ReassessmentRequestedDate. Including people who are getting support outside a spell changes the total count of clients eligible at any given time by 1 to 2 percentage. +• The data includes a flag for CurrentNA, which indicates the most recent needs assessment. However, the CurrentNA maybe up to 20 years old. +• There may be a bias towards clients who live in poorer regions because anecdotally those who have sufficient income to manage their disability without requiring MOH support are less likely to engage with the system. +Note that this DOES NOT mean: +• The client actually received funding for the whole spell +• The client actually received funding at all during the spell +• These clients (or other clients) didn't receive funding from other sources. This could be indirectly from MoH too (e.g. via DHBs) +• The list includes all the clients who were eligible since it only includes those who went through a needs assessment + +## References and contacts +The Ministry of Health publishes statistics on disability support funding approximately every 3 years (e.g. www.health.govt.nz/system/files/documents/publications/demographic-report-for-client-allocated-ministry-of-health-disability-support-services-2018-update14nov2019.pdf). This includes a total number of Disability Support Services for 2018 of 38,342 (1 Oct 2017 to 30 Sept 2018) and is a publicly available number from outside of the IDI. The equivalent count from the indicator is of the order of 38,000 and within 100 of the published count (based on those that have a spell that includes either 1 Oct 2017 or 30 Sept 2018). + +## Module business rules +### Key rules applied +A service needs assessment has a DateAssessmentCompleted and ReassessmentRequestedDate which count as the start and end date of a spell. A spell will often last for 3 years, however, shorter spells are possible. +Only assessments with an outcome of “Requires Service Coordination” are included. Other options include “No Action Required - Exit Services” and “Eligible for Service but No Action Required”. +The start date of the spell is the DateAssessmentCompleted from the service needs assessment. +The end date of the spell is the ReassessmentRequestedDate from the service needs assessment. +Spells that have less than 60 days between the end of one spell and the start of the next are merged (i.e. they count as a continuous spell in the final dataset). + +## Parameters +The following parameters should be supplied to this module to run it in the database: +1. {idicleanversion}: The IDI Clean version that the spell datasets need to be based on. +2. {targetschema}: The project schema under the target database into which the spell datasets are to be created. +3. {projprefix}: A (short) prefix that enables you to identify the spell dataset easily in the schema, and prevent overwriting any existing datasets that have the same name. +4. IDI_UserCode: The SQL database on which the spell datasets are to be created. + Inputs & Dependencies: - [IDI_Adhoc].[clean_read_MOH_SOCRATES].[moh_needs_assessment_202110] - [IDI_Clean].[security].[concordance] Outputs: -- [IDI_Sandpit].[DL-MAA20XX-YY].[moh_disability_funded] +- [IDI_Sandpit].[DL-MAA20XX-YY].[defn_moh_dis_assess_elig] + + +Linking between the two is done on snz_moh_uid. No rows are lost via this linking. + + +## Variable Descriptions + +Column name Description +------------------------------ -------------------------------------------------------------------------------------------- +snz_uid The unique STATSNZ person identifier for the student +snz_moh_uid The unique STATSNZ MOH person identifier for the disabled +start_date The start date of the spell (the DateAssessmentCompleted from the needs assessment) +end_date The end date of the spell (the ReassessmentRequestedDate from the needs assessment) -Notes: Parameters & Present values: Current refresh = YYYYMM - Prefix = vacc_ + Prefix = defn_ Project schema = DL-MAA20XX-YY -Issues: History (reverse order): +2022-06-01 Consultant version 2021-10-31 CW v1 + **************************************************************************************************/ -DROP TABLE IF EXISTS [IDI_Sandpit].[DL-MAA20XX-YY].[moh_disability_funded] +/* Assign the target database to which all the components need to be created in. */ +USE IDI_Sandpit; GO +/* Delete the database object if it already exists */ +DROP TABLE IF EXISTS [DL-MAA20XX-YY].tmp_moh_dis_assess_elig; +GO + +/* Create the database object */ SELECT b.snz_uid - ,1 as moh_disability_funded - --,a.[snz_moh_uid] - --,[snz_moh_soc_client_uid] - --,[ReferralID] - --,[NeedsAssessmentID] - --,[NASCCode] - --,[AssessmentType] - --,[AssessmentLocation] - --,[ReassessmentRequestDate] - --,[FirstContactDate] - --,[DateAssessmentCompleted] - --,[AssessmentOutcome] - --,[CurrentNA] -INTO [IDI_Sandpit].[DL-MAA20XX-YY].[moh_disability_funded] -FROM [IDI_Adhoc].[clean_read_MOH_SOCRATES].[moh_needs_assessment_202110] as a -INNER JOIN [IDI_Clean_YYYYMM].[security].[concordance] as b + ,a.snz_moh_uid + ,CASE + WHEN SUBSTRING(a.DateAssessmentCompleted,6,1) = '9' THEN CONVERT(date,CONCAT(SUBSTRING(a.DateAssessmentCompleted,1,2),' ',SUBSTRING(a.DateAssessmentCompleted,3,3),' 19',SUBSTRING(a.DateAssessmentCompleted,6,2)),106) + ELSE CONVERT(date,CONCAT(SUBSTRING(a.DateAssessmentCompleted,1,2),' ',SUBSTRING(a.DateAssessmentCompleted,3,3),' 20',SUBSTRING(a.DateAssessmentCompleted,6,2)),106) + END AS [start_date] + ,CASE + WHEN SUBSTRING(a.ReassessmentRequestDate,6,1) = '9' THEN CONVERT(date,CONCAT(SUBSTRING(a.ReassessmentRequestDate,1,2),' ',SUBSTRING(a.ReassessmentRequestDate,3,3),' 19',SUBSTRING(a.ReassessmentRequestDate,6,2)),106) + ELSE CONVERT(date,CONCAT(SUBSTRING(a.ReassessmentRequestDate,1,2),' ',SUBSTRING(a.ReassessmentRequestDate,3,3),SUBSTRING(a.ReassessmentRequestDate,6,2)),106) + END AS [end_date] +INTO [DL-MAA20XX-YY].tmp_moh_dis_assess_elig +FROM [IDI_Adhoc].[clean_read_MOH_SOCRATES].[moh_needs_assessment] AS a +INNER JOIN [IDI_Clean_202203].[security].[concordance] AS b ON a.snz_moh_uid = b.snz_moh_uid -WHERE [CurrentNA] = 1 -AND assessmentoutcome = 'Requires Service Coordination' +WHERE a.assessmentoutcome in ('Requires Service Coordination') + GO -CREATE NONCLUSTERED INDEX my_index_name ON [IDI_Sandpit].[DL-MAA20XX-YY].[moh_disability_funded] (snz_uid); +-- Consolidate spells that are near each other into a smaller number of spells +DROP TABLE IF EXISTS [DL-MAA20XX-YY].defn_moh_dis_assess_elig; GO -ALTER TABLE [IDI_Sandpit].[DL-MAA20XX-YY].[moh_disability_funded] REBUILD PARTITION = ALL WITH (DATA_COMPRESSION = PAGE) + +WITH +/* start dates that are not within another spell */ +input_data AS ( + SELECT [snz_uid] + ,[start_date] + /* Adds a 60 day threshold between each assessment so that any consecutive assessment made within 60 day thresholds can be joined up together into a single spell. */ + ,DATEADD(day, 60, [end_date]) AS [end_date] + FROM [DL-MAA20XX-YY].tmp_moh_dis_assess_elig + GROUP BY snz_uid, [start_date], [end_date] +), + +spell_starts AS ( + SELECT [snz_uid] + ,[start_date] + ,[end_date] + FROM input_data AS s1 + WHERE NOT EXISTS ( + SELECT 1 + FROM input_data AS s2 + WHERE s1.snz_uid = s2.snz_uid + AND s2.[start_date] < s1.[start_date] + AND s1.[start_date] <= s2.[end_date] + ) +), + +/* end dates that are not within another spell */ +spell_ends AS ( + SELECT [snz_uid] + ,[start_date] + ,[end_date] + FROM input_data AS t1 + WHERE NOT EXISTS ( + SELECT 1 + FROM input_data AS t2 + WHERE t2.snz_uid = t1.snz_uid + AND t2.[start_date] <= t1.[end_date] + AND t1.[end_date] < t2.[end_date] + ) +) + +SELECT s.snz_uid + ,s.[start_date] + ,DATEADD(day, -60, min(e.[end_date])) AS [end_date] +INTO [DL-MAA20XX-YY].defn_moh_dis_assess_elig +FROM spell_starts s +INNER JOIN spell_ends e +ON s.snz_uid = e.snz_uid +AND s.[start_date] <= e.[end_date] +GROUP BY s.snz_uid, s.[start_date] + +CREATE NONCLUSTERED INDEX my_index_name ON [IDI_Sandpit].[DL-MAA20XX-YY].[defn_moh_dis_assess_elig] (snz_uid); +GO +ALTER TABLE [IDI_Sandpit].[DL-MAA20XX-YY].[defn_moh_dis_assess_elig] REBUILD PARTITION = ALL WITH (DATA_COMPRESSION = PAGE) +GO + +/* Clean up any temporary tables or views */ +DROP TABLE IF EXISTS [IDI_Sandpit].[DL-MAA20XX-YY].tmp_moh_dis_assess_elig; GO diff --git a/housing/emergency_housing_spells.sql b/housing/emergency_housing_spells.sql index cdfac7e..823ea05 100644 --- a/housing/emergency_housing_spells.sql +++ b/housing/emergency_housing_spells.sql @@ -74,21 +74,15 @@ Parameters & Present values: Project schema = [DL-MAA20XX-YY] --------------------------------------------------------------------------------------------------------------------------- -Column Description -name +Column name Description ------------------------------ -------------------------------------------------------------------------------------------- snz_uid The unique STATSNZ person identifier for the individual in an emergency housing - data_source A tag signifying a source dataset description (hard-coded to "MSD") - snz_msd_uid The unique MSD person identifier for the individual in an emergency housing - start_date The start date for the emergency housing, i.e., the first day that the person applied for a third tier benefit from MSD to stay at an emergency housing - end_date The latest date for when the person last consecutively applied for emergency housing benefit from MSD for the current spell. - ---------------------------------------------------------------------------------------------------------------------------- History (reverse order): diff --git a/housing/residential_care.sql b/housing/residential_care.sql index 1f5e45e036f0270024e0f68aeeb94fd7d2c93880..54ac5bf079a2415b237ce6d5e8101bcd419c7866 100644 GIT binary patch delta 799 zcmX>wm-*8Y<_&h5%)AU-lbtp78Lc)KYD%-pIx&0$;2h9ICw4wz@P zxmoYKaD5mt%M<5Pn@MDOYd~mt2 zc?wWG51c^Kfa+3#2}Xe-4H)7ex&&%QF_2Zt08^;|N6(CpYFQPd;bKqYCl?$et9S4^n_JSOVn1^l}1KgJ8(yhtnjn>E2xA$ delta 34 qcmeygg!#Z+<_&h5tjY|^3<{GSHT5?aX-ctf-lX?Vc(ab1TMq!tAPb-X