Output path
SQL:[IDI_Community].[dsbl_cerebral_palsy].[cerebral_palsy_YYYYMM]
SAS: libname cmid dsn=idi_community_srvprd schema=dsbl_cerebral_palsy; run ;
How to access a code module in the Data Lab:Read here
Description
The purpose of this code module is to identify individuals in New Zealand in the IDI who have a recorded diagnosis of Cerebral Palsy.
The dataset will list individuals, the earliest event when an individual has a recorded diagnosis of Cerebral Palsy in the IDI, date of the earliest event, the individual’s age and whether they are alive at the time of the IDI refresh. For those individuals who have died, the dataset lists a date of death and age at death.
This module is not intended to be used to give a true prevalence rate of people in New Zealand with Cerebral Palsy due to limitations of the datasets included in the IDI. The code module allows researchers to have a consistent way of identifying people with Cerebral Palsy and will allow for comparisons of outcomes for people with Cerebral Palsy and people without Cerebral Palsy.
Key Concepts
- Individuals are identified from a diagnosis recorded using a recognised ICD-9-CM-A diagnosis code for Cerebral Palsy or a diagnosis recorded through other means by a professional.
- An individual may have multiple entries in a source dataset or across a number of source datasets.
- This module collates the earliest reference to the individual with an appropriate diagnosis code in a dataset and then identifies the earliest reference amongst all datasets.
- The module indicates whether the individual was alive at the time of the most recent IDI refresh.
- The module will record events within the time period that data is included in the IDI. However, as a lifelong condition resulting from brain injury before, during or while the brain is developing after birth, the individual will have been with Cerebral Palsy since birth or shortly after birth.
- The earliest date recorded in the IDI is not a date of diagnosis or onset of a condition.
Business history
Code history and ICD code notes
ICD codes used are based on the ICD clinical code system for the earliest date of data as per Health New Zealand (HNZ) | Te Whatu Ora best practice. This means ICD-9-CM-A codes have been used in line with the start of the health-related datasets in the IDI.
On advice from HNZ clinical coding/classification staff, codes have first been looked up directly in ICD-10-AM 12th Edition (current Edition used), then back mapped to ICD-10-AM 1st Edition and then back mapped to ICD-9-CM-A codes.
ICD-9-CM-A codes have also been added to ensure coverage if the diagnosis was coded in ICD-9-CM-A using the latest ICD classification definitions (see Table 1).
Notes for specific datasets
-
For the MORT dataset, ICD codes have only been provided in their submitted system codes (i.e. not backmapped). This means the source dataset includes both ICD-9-CM-A and editions of ICD-10-AM and the code underlying this module has been written to reflect this.
-
For the PRIMHD dataset, codes have been provided DSM-IV and ICD-10-AM edition codes. This means the source dataset includes both DSM-IV and ICD-10-AM editions and the code underlying this module has been written to reflect this.
-
For the MHINC dataset, codes have been provided in various ICD code editions as well as backmapping to DSM-IV where possible. This means the source dataset includes both DSM-IV and ICD-9-CM-A/ICD-10-AM editions and the code underlying this module has been written to reflect this.
References
- Beltran-Castillon L and McLeod K (2023) From Data to Dignity: Health and Wellbeing Indicators for New Zealanders with Intellectual Disability. Published: IHC, Kōtātā Insight
- Cerebral Palsy Society - About Cerebral Palsy. URL: https://cerebralpalsy.org.nz/cerebral_palsy
Community of Interest
Domain | Agency | Person |
---|---|---|
Initial code | Social Investment Agency (SIA) | Craig Wright |
Module coder | Whaikaha - Ministry of Disabled People | Adelaide Wilson |
Module coder | Nicholson Consulting | Sarah Underwood |
Lead SME/Policy | Whaikaha - Ministry of Disabled People | Michelle Gezentsvey, Claire Bretherton |
Key business rules
Dataset name | Diagnosis definition | Dataset time period |
---|---|---|
Accident Compensation Corporation (ACC) Injury Claims Data | Recorded as having an ACC read code on the ACC45 claim form of: | 1974 - |
‘G669.’ (Cerebral Palsy, not congenital or infantile, acute), | ||
‘FYU9.’ (Cerebral palsy and other paralytic syndromes), | ||
‘F23Y2’(Spastic cerebral palsy), | ||
‘F1370’ (Athetoid cerebral palsy), | ||
‘F23..’(Congenital cerebral palsy), | ||
‘F23Y3’ (Dyskinetic cerebral palsy), | ||
‘F23Z.’ (Congential cerebral palsy nos), | ||
‘FY23YZ’ (Other infantile cerebral palsy nos), | ||
‘F23Y.’ (Other congenital cerebral palsy), | ||
‘F23Y0’ (Ataxic infantile cerebral palsy), or | ||
‘FYU90’ (Other infantile cerebral palsy). | ||
Publicly funded hospital discharges (NMDS) | A publicly funded hospital discharge with a primary or secondary ICD-9-CM-A diagnosis code of: | 1988 - |
3430 (Congenital diplegia), | ||
3431 (Congential hemiplegia), | ||
3432 (Congential quadriplegia), | ||
3433 (Congenital monoplegia), | ||
3434 (Infantile hemiplegia), | ||
3438 (Other specified infantile cerebral palsy), or | ||
3439 (Infantile cerebral palsy, unspecified). | ||
Privately funded hospital discharges (NMDS) | A privately funded hospital discharge with a primary or secondary ICD-9-CM-A diagnosis code of: | 2001 - |
3430 (Congenital diplegia), | ||
3431 (Congential hemiplegia), | ||
3432 (Congential quadriplegia), | ||
3433 (Congenital monoplegia), | ||
3434 (Infantile hemiplegia), | ||
3438 (Other specified infantile cerebral palsy), or | ||
3439 (Infantile cerebral palsy, unspecified). | ||
Mortality Collection (MORT) | Identified as an underlying or contributing cause of death with an ICD-9-CM-A diagnosis code of: | 1988 - |
3430 (Congenital diplegia), | ||
3431 (Congential hemiplegia), | ||
3432 (Congential quadriplegia), | ||
3433 (Congenital monoplegia), | ||
3434 (Infantile hemiplegia), | ||
3438 (Other specified infantile cerebral palsy), or | ||
3439 (Infantile cerebral palsy, unspecified), | ||
or an ICD-10-AM code (12th edition) of: | ||
G800 (Spastic cerebral palsy), | ||
G803 (Dyskinetic cerebral palsy), | ||
G804 (Ataxic cerebral palsy), | ||
G808 (Other cerebral palsy), or | ||
G809 (Cerebral palsy, unspecified). | ||
Disability Support Services database (SOCRATES) | Recorded as having cerebral palsy in the Referral Diagnosis/Health Condition field with the code of: | 1998 - |
1804 (Cerebral palsy). | ||
Programme for the Integration of Mental Health Data (PRIMHD) | There is no cerebral palsy code in the DSM-IV classification system for secondary mental health and addiction services. Identified with an ICD-10-AM (12th edition) diagnosis code of: | 2009 - |
G800 (Spastic cerebral palsy), | ||
G803 (Dyskinetic cerebral palsy), | ||
G804 (Ataxic cerebral palsy), | ||
G808 (Other cerebral palsy), or | ||
G809 (Cerebral palsy, unspecified). | ||
Mental Health Information National Collection (MHINC) | There is no cerebral palsy code in the DSM-IV classification system for secondary mental health and addiction services. Identified with an ICD-9-CM-A diagnosis code of: | July 2001 - 2008 |
3430 (Congenital diplegia), | ||
3431 (Congential hemiplegia), | ||
3432 (Congential quadriplegia), | ||
3433 (Congenital monoplegia), | ||
3434 (Infantile hemiplegia), | ||
3438 (Other specified infantile cerebral palsy), or | ||
3439 (Infantile cerebral palsy, unspecified). | ||
Table 1: ICD-9-CM-A codes included to ensure coverage if coding in ICD-9-CM-A – includes forward/backward map to ICD-10-AM 1st Edition
To ensure coverage when using ICD-9-CM-A codes, the following codes are noted to forward/backward map to ICD-10-AM 1st Edition.
Note:
Forward mapping provides equivalent codes for deleted codes in the newer edition
Backward mapping provides equivalent codes for new codes in the newer edition.
ICD-9-CM-A code and definition | ICD-10-AM 1st Edition code and definition |
---|---|
3430 Congenital diplegia | G801 Spastic diplegia |
3431 Congenital hemiplegia | G802 Infantile hemiplegia |
3432 Congenital quadriplegia | G808 Other infantile cerebral palsy |
3433 Congenital monoplegia | G808 Other infantile cerebral palsy |
3434 Infantile hemiplegia | G802 Infantile hemiplegia |
Data quality and other known issues
-
Not all individuals in New Zealand diagnosed with Cerebral Palsy will be identified in this module. This module assumes that the individual has had an ACC claim form, hospital discharge events, received Disability Support Services, or has had their death recorded where the diagnosis of Cerebral Palsy has been specified.
-
Datasets included have different lag times for having updated data available in the IDI. This means the completeness of the data at the time of analysis will depend on the lag time of the different datasets.
-
Individuals identified in the SOCRATES disability dataset do not always appear in the referral or needs assessment datasets as well. Where an individual is only identified through the SOCRATES disability dataset there is no associated event date. In this case a proxy date of ‘3999-12-31’ will be seen in the final table.
-
It is likely that individuals who are less severely affected are less likely to be diagnosed and thus identified in the data. Time to diagnosis and recognition in the data leads to lower than anticipated individuals in younger age groups.
-
Registerable stillbirths are included in the mortality dataset.
Comparison against other sources
-
Counts of individuals published in the IHC publication ‘From Data to Dignity’ (2023) were for those individuals with Cerebral Palsy in the study population defined as the 2018 Administrative Population Census (APC). The counts from this code module for people with Cerebral Palsy are lower than those in the 2023 publication.
-
The Cerebral Palsy Society note that there are more than ten thousand people with Cerebral Palsy in New Zealand (URL: About Cerebral Palsy - Cerebral Palsy Society). This module undercounts people with Cerebral Palsy.
Note:
When using this code module it is important to make sure to consider biases and limitations of the IDI data as well as biases and limitations that exist within health/health-related datasets. Some biases may include under-diagnosis, miss-diagnosis, cultural preference, systemic racism, clinician bias, policy changes, and data recording changes. These biases and limitations will vary for different groups and therefore have different effects on the resulting data and any analysis.
Parameters
The following parameters should be supplied to this module to run it in the database:
- {targetdb}: The SQL database on which the spell datasets are to be created.
- {idicleanversion}: The IDI Clean version that the datasets need to be based on.
- {targetschema}: The project schema under the target database into which the datasets are to be created.
Dependencies
{idicleanrefresh}.[acc_clean].[claims]
{idicleanrefresh}.[acc_clean].[medical_codes]
{idicleanrefresh}.[moh_clean].[pub_fund_hosp_discharges_diag]
{idicleanrefresh}.[moh_clean].[pub_fund_hosp_discharges_event]
{idicleanrefresh}.[moh_clean].[priv_fund_hosp_discharges_diag]
{idicleanrefresh}.[moh_clean].[priv_fund_hosp_discharges_event]
{idicleanrefresh}.[moh_clean].[mortality_diagnosis]
{idicleanrefresh}.[moh_clean].[mortality_registrations]
{idicleanrefresh}.[moh_clean].[pop_cohort_demographics]
{idicleanrefresh}.[data].[personal_detail]
{idicleanrefresh}.[dia_clean].[deaths]
The following IDI_Adhoc are the most recent versions for this current refresh but changes to the code will need to be made as new datasets are uploaded into the IDI.
[IDI_Adhoc].[clean_read_MOH_SOCRATES].[moh_disability_2022]
[IDI_Adhoc].[clean_read_MOH_SOCRATES].[moh_needs_assessment_2022]
[IDI_Adhoc].[clean_read_MOH_SOCRATES].[moh_referral_2022]
[IDI_Adhoc].[clean_read_MOH_PRIMHD].[primhd_diagnoses_202502]
[IDI_Adhoc].[clean_read_MOH_PRIMHD].[moh_primhd_mhinc]
Outputs
{targetdb}.{targetschema}.cerebral_palsy
Column name | Description |
---|---|
snz_uid | The unique Stats NZ person identifier for the the individual |
type | A string indicating which condition of disability this table has identified (hard-coded to “CP”) |
entity | A string indicating the organisation or provider ID that has provided a service for mental health services, where relevant |
source_table | A string that states the data source for the earliest record of diagnosis for an individual in the IDI |
min_date | The earliest record of diagnosis for an individual in the IDI (Note: not a date of diagnosis or onset of a condition) |
snz_sex_gender_code | Code for an individual’s gender |
snz_birth_month_nbr | Month of an individual’s birth |
snz_birth_year_nbr | Year of an individual’s birth |
snz_birth_date_proxy | Proxy date of an individual’s birth |
age | Age of an individual at the time of the IDI refresh |
death_status | A binary indicator indicating whether an individual is recorded dead (value = 1) or alive (value = 0) at the time of refresh |
snz_deceased_year_nbr | Year of an individual’s death (if relevant) |
snz_deceased_month_nbr | Month of an individual’s death (if relevant) |
dod | Date of death (if relevant) |
age_at_death | Age of an individual at death (if relevant) |
Variable descriptions
Granularity:
One row represents an individual, the earliest identification of their diagnosis in the IDI, birthdate, gender and death (if applicable).
Module Version & Change History
Date | Version | Comments |
---|---|---|
26 May 2025 | Initial | Version based on specifications from Commissioning document |
09 June 2025 | 1.1 | Update to ACC variable with 202506 refresh. acc_med_read_code updated to acc_med_injury_codeand acc_cla_read_code to acc_cla_primary_inj_code with acc_cla_primary_inj_type_code added. |
Code
/*Set Parameters*/
/*Ref date should be the 15th of the month of the refresh used*/
:setvar targetdb
:setvar targetschema
:setvar idicleanversion
:setvar refdate
:setvar idimetadataversion
USE $(targetdb);
GO
/*ACC claims with a code that includes cerebral palsy*/
DROP TABLE IF EXISTS #acc_cp;
SELECT
c.snz_uid
,'ACC' AS source_table
,c.code
,c.date AS event_date
,CAST(NULL AS VARCHAR(10)) AS entity
INTO #acc_cp
FROM
(
SELECT
[snz_uid]
,[acc_cla_accident_date] AS date
,[acc_cla_primary_inj_code] AS code
FROM [$(idicleanversion)].[acc_clean].[claims]
WHERE ([acc_cla_primary_inj_code] IN ('G669.','FYU9.','F23Y2','F1370','F23..','F23Y3','F23Z.','F23YZ','F23Y.','F23Y0','FYU90') AND [acc_cla_primary_inj_type_code] = 'Read Code')
UNION ALL
SELECT
b.snz_uid
,b.acc_cla_accident_date AS date
,a.[acc_med_injury_code] AS code
FROM [$(idicleanversion)].[acc_clean].[medical_codes] AS a
LEFT JOIN [$(idicleanversion)].[acc_clean].[claims] AS b ON a.[snz_acc_claim_uid] = b.[snz_acc_claim_uid]
WHERE [acc_med_injury_code] IN ('G669.','FYU9.','F23Y2','F1370','F23..','F23Y3','F23Z.','F23YZ','F23Y.','F23Y0','FYU90')
) AS c;
/*Publicly-funded hospital discharges where clinical code matches a diagnosis of cerebral palsy*/
DROP TABLE IF EXISTS #moh_pub_cp;
SELECT
b.snz_uid
,'MOH_PUB' AS source_table
,a.[moh_dia_submitted_system_code] AS code_sys
,a.[moh_dia_diagnosis_type_code]
,a.[moh_dia_event_id_nbr]
,a.[moh_dia_clinical_code]
,b.moh_evt_birth_year_nbr
,b.[moh_evt_evst_date] AS event_date
,CAST(NULL AS VARCHAR(10)) AS entity
INTO #moh_pub_cp
FROM [$(idicleanversion)].[moh_clean].[pub_fund_hosp_discharges_diag] AS a
LEFT JOIN [$(idicleanversion)].[moh_clean].[pub_fund_hosp_discharges_event] AS b ON a.moh_dia_event_id_nbr = b.moh_evt_event_id_nbr
WHERE (SUBSTRING(a.[moh_dia_clinical_code],1,4) IN ('3430', '3431', '3432', '3433', '3434', '3438', '3439') AND a.[moh_dia_clinical_sys_code] = '06' AND a.[moh_dia_diagnosis_type_code] IN ('A','B'));
/*Privately-funded hospital discharges where clinical code matches a diagnosis of cerebral palsy*/
DROP TABLE IF EXISTS #moh_pri_cp;
SELECT
b.snz_uid
,'MOH_PRI' AS source_table
,a.[moh_pri_diag_event_id_nbr]
,a.[moh_pri_diag_clinic_sys_code]
,a.[moh_pri_diag_sub_sys_code]
,a.[moh_pri_diag_diag_type_code]
,a.[moh_pri_diag_clinic_code]
,b.[moh_pri_evt_start_date] AS event_date
,CAST(NULL AS VARCHAR(10)) AS entity
INTO #moh_pri_cp
FROM [$(idicleanversion)].[moh_clean].[priv_fund_hosp_discharges_diag] AS a
LEFT JOIN [$(idicleanversion)].[moh_clean].[priv_fund_hosp_discharges_event] AS b ON a.moh_pri_diag_event_id_nbr = b.moh_pri_evt_event_id_nbr
WHERE (SUBSTRING(a.[moh_pri_diag_clinic_code],1,4) IN ('3430', '3431', '3432', '3433', '3434', '3438', '3439') AND a.[moh_pri_diag_clinic_sys_code] = '06'AND a.[moh_pri_diag_diag_type_code] IN ('A','B'));
/*Registrations in the mortality dataset where clinical code matches a diagnosis of cerebral palsy*/
DROP TABLE IF EXISTS #mos_cp;
SELECT
b.[snz_uid]
,b.[snz_moh_uid]
,'MOH_MOS' AS source_table
,DATEFROMPARTS(b.moh_mor_birth_year_nbr,b.moh_mor_birth_month_nbr,15) AS event_date
,a.[moh_mort_diag_clinical_code] AS code
,a.[moh_mort_diag_clinic_type_code]
,a.[moh_mort_diag_clinic_sys_code]
,a.[moh_mort_diag_diag_type_code]
,CAST (NULL AS VARCHAR(10)) AS entity
INTO #mos_cp
FROM [$(idicleanversion)].[moh_clean].[mortality_diagnosis] AS a
LEFT JOIN [$(idicleanversion)].[moh_clean].[mortality_registrations] AS b ON a.snz_dia_death_reg_uid = b.snz_dia_death_reg_uid
WHERE (SUBSTRING(a.[moh_mort_diag_clinical_code],1,4) IN ('3430', '3431', '3432', '3433', '3434', '3438', '3439') AND a.[moh_mort_diag_clinic_sys_code] = '06')
OR (SUBSTRING(a.[moh_mort_diag_clinical_code],1,4) IN ('G800', 'G803', 'G804', 'G808', 'G809') AND a.[moh_mort_diag_clinic_sys_code] >= '10');
/* Individuals in the Ministry of Health SOCRATES database with code 1804. Date can either be first contact date or referral date.
Where an individual appears only in the disability table but not the needs assessment or referral table, an event date of 3999-12-31 is added.
This date will be removed in the collation process if the individual appears in other datasets with an earlier event_date or kept if the
diagnosis table is the only record for the individual*/
DROP TABLE IF EXISTS #moh_soc_cp;
SELECT
DISTINCT
b.snz_uid
,'SOC' AS source_table
,CASE WHEN CAST(SUBSTRING(c.[FirstContactDate],1,7) AS date) IS NOT NULL THEN CAST(SUBSTRING(c.[FirstContactDate],1,7) AS date)
WHEN CAST(SUBSTRING(e.[ReferralDate],1,7) AS date) IS NOT NULL THEN CAST(SUBSTRING(e.[ReferralDate],1,7) AS date)
WHEN CAST(SUBSTRING(e.[ReferralDate],1,7) AS date) IS NULL AND CAST(SUBSTRING(c.[FirstContactDate],1,7) AS date) IS NULL THEN '3999-12-31'
END AS event_date
,CAST(a.code AS VARCHAR(7)) AS code
,a.[Description]
,CAST (NULL AS VARCHAR(10)) AS entity
INTO #moh_soc_cp
FROM [IDI_Adhoc].[clean_read_MOH_SOCRATES].[moh_disability_2022] AS a
LEFT JOIN [$(idicleanversion)].[moh_clean].[pop_cohort_demographics] AS b ON a.snz_moh_uid = b.snz_moh_uid
LEFT JOIN (SELECT DISTINCT snz_moh_uid,[FirstContactDate] FROM [IDI_Adhoc].[clean_read_MOH_SOCRATES].[moh_needs_assessment_2022] ) AS c ON a.snz_moh_uid = c.snz_moh_uid
LEFT JOIN (SELECT DISTINCT snz_moh_uid,[ReferralDate] FROM [IDI_Adhoc].[clean_read_MOH_SOCRATES].[moh_referral_2022]) AS e ON a.snz_moh_uid = e.snz_moh_uid
WHERE code IN ('1804');
/*cerebral palsy diagnosis in PRIMHD diagnosis data*/
DROP TABLE IF EXISTS #moh_PRIMHD_cp;
SELECT
b.snz_uid
,a.[snz_moh_uid]
,'MOH_PRIMHD' AS source_table
,CAST (a.[organisation_id] AS VARCHAR(10)) AS entity
,a.[classification_code_id]
,a.[diagnosis_type]
,CONVERT(date,a.[classification_start_date],103) AS event_date
,a.[clinical_coding_system_id]
,a.[clinical_code] AS code
INTO #moh_PRIMHD_cp
FROM [IDI_Adhoc].[clean_read_MOH_PRIMHD].[primhd_diagnoses_202502] AS a
LEFT JOIN [$(idicleanversion)].[moh_clean].[pop_cohort_demographics] AS b ON a.snz_moh_uid = b.snz_moh_uid
WHERE (SUBSTRING(a.[clinical_code],1,4) IN ('G800', 'G803', 'G804', 'G808', 'G809') AND a.[clinical_coding_system_id] >= '10');
/* cerebral palsy diagnosis in PRIMHD MHINC data*/
DROP TABLE IF EXISTS #moh_mhinc_cp;
SELECT
b.snz_uid
,'MOH_MHINC' AS source_table
,CAST (a.[organisation_id] AS VARCHAR(10)) AS entity
,a.[classification_start] AS event_date
,a.[clinical_coding_system_id]
,a.[clinical_code] AS code
,a.[diagnosis_type]
INTO #moh_mhinc_cp
FROM [IDI_Adhoc].[clean_read_MOH_PRIMHD].[moh_primhd_mhinc] AS a
LEFT JOIN [$(idicleanversion)].[moh_clean].[pop_cohort_demographics] AS b ON a.snz_moh_uid = b.snz_moh_uid
WHERE (SUBSTRING(a.[clinical_code],1,4) IN ('3430', '3431', '3432', '3433', '3434', '3438', '3439') AND [clinical_coding_system_id] = '06');
/* collate data from all sources into one table*/
DROP TABLE IF EXISTS #cp;
SELECT
a.snz_uid
,MIN(event_date) AS min_date
,source_table
,entity
INTO #cp
FROM (
SELECT snz_uid, event_date, source_table, entity FROM #moh_pub_cp
UNION ALL
SELECT snz_uid, event_date, source_table, entity FROM #moh_pri_cp
UNION ALL
SELECT snz_uid, event_date, source_table, entity FROM #mos_cp
UNION ALL
SELECT snz_uid, event_date, source_table, entity FROM #moh_soc_cp
UNION ALL
SELECT snz_uid, event_date, source_table, entity FROM #moh_mhinc_cp
UNION ALL
SELECT snz_uid, event_date, source_table, entity FROM #moh_primhd_cp
UNION ALL
SELECT snz_uid, event_date, source_table, entity FROM #acc_cp
) AS a
GROUP BY snz_uid
, source_table
, entity;
/* subset of individuals who are deceased and are in death data*/
DROP TABLE IF EXISTS #cp_dd;
SELECT
a.*
,b.snz_birth_month_nbr
,b.snz_birth_year_nbr
,b.snz_sex_gender_code
,b.snz_deceased_year_nbr
,b.snz_deceased_month_nbr
,b.snz_birth_date_proxy
,NULL AS age
,DATEFROMPARTS(b.snz_deceased_year_nbr, b.snz_deceased_month_nbr, 15) AS dod
,'CP' AS [type]
INTO #cp_dd
FROM #cp as a
INNER JOIN [$(idicleanversion)].[data].[personal_detail] AS b ON a.snz_uid = b.snz_uid
WHERE a.snz_uid IN (SELECT DISTINCT snz_uid FROM [$(idicleanversion)].[dia_clean].[deaths])
AND b.snz_deceased_year_nbr IS NOT NULL;
/* subset of individuals who are deceased but not in death data*/
DROP TABLE IF EXISTS #cp_od;
SELECT
a.*
,b.snz_birth_month_nbr
,b.snz_birth_year_nbr
,b.snz_sex_gender_code
,b.snz_deceased_year_nbr
,b.snz_deceased_month_nbr
,b.snz_birth_date_proxy
,NULL AS age
,DATEFROMPARTS(b.snz_deceased_year_nbr, b.snz_deceased_month_nbr, 15) AS dod
,'CP' AS [type]
INTO #cp_od
FROM #cp AS a
INNER JOIN [$(idicleanversion)].[data].[personal_detail] AS b ON a.snz_uid = b.snz_uid
WHERE a.snz_uid NOT IN (SELECT DISTINCT snz_uid FROM [$(idicleanversion)].[dia_clean].[deaths])
AND b.snz_deceased_year_nbr IS NOT NULL;
/* subset of individuals who are alive*/
DROP TABLE IF EXISTS #cp_ad;
SELECT
a.*
,b.snz_birth_month_nbr
,b.snz_birth_year_nbr
,b.snz_sex_gender_code
,b.snz_deceased_year_nbr
,b.snz_deceased_month_nbr
,b.snz_birth_date_proxy
,DATEDIFF(YEAR, b.snz_birth_date_proxy, '$(refdate)') AS age
,'3999-12-31' AS dod
,'CP' AS [type]
INTO #cp_ad
FROM #cp AS a
INNER JOIN [$(idicleanversion)].[data].[personal_detail] AS b ON a.snz_uid = b.snz_uid
WHERE a.snz_uid NOT IN (SELECT DISTINCT snz_uid FROM [$(idicleanversion)].[dia_clean].[deaths])
AND a.snz_uid NOT IN (SELECT DISTINCT snz_uid FROM #cp_dd)
AND a.snz_uid NOT IN (SELECT DISTINCT snz_uid FROM #cp_od);
/* join all tables together*/
DROP TABLE IF EXISTS #cp_final;
WITH cp_union AS (
SELECT
*
FROM #cp_dd
UNION ALL
SELECT * FROM #cp_od
UNION ALL
SELECT * FROM #cp_ad
)
SELECT
*
,DATEDIFF(YEAR, snz_birth_date_proxy, dod) AS age_at_death
,CASE WHEN age IS NOT NULL THEN 0 ELSE 1 END AS death_status
INTO #cp_final
FROM cp_union;
/* select all required variables */
DROP TABLE IF EXISTS #cp_min;
SELECT
snz_uid
,[type]
,entity
,source_table
,min_date
,snz_sex_gender_code
,snz_birth_month_nbr
,snz_birth_year_nbr
,snz_birth_date_proxy
,age
,death_status
,snz_deceased_year_nbr
,snz_deceased_month_nbr
,CASE WHEN dod = '3999-12-31' THEN NULL ELSE dod END AS dod
,CASE WHEN age_at_death > 1000 THEN NULL ELSE age_at_death END AS age_at_death
INTO #cp_min
FROM #cp_final;
/*take earliest recorded date for each snz_uid and create table */
DROP TABLE IF EXISTS #cp_dbl;
SELECT
snz_uid
,[type]
,entity
,source_table
,min_date
,snz_sex_gender_code
,snz_birth_month_nbr
,snz_birth_year_nbr
,snz_birth_date_proxy
,age
,death_status
,snz_deceased_year_nbr
,snz_deceased_month_nbr
,dod
,age_at_death
INTO #cp_dbl
FROM #cp_min a
WHERE min_date = (
SELECT MIN(min_date)
FROM #cp_min b
WHERE b.snz_uid = a.snz_uid)
ORDER BY snz_uid;
/* remove duplicate snz_uid with the same minimum date but different entities or sources. Create table in IDI_Sandpit */
DROP TABLE IF EXISTS [$(targetdb)].[$(targetschema)].[cerebral_palsy];
WITH cte AS
(SELECT ROW_NUMBER() OVER(PARTITION BY snz_uid
ORDER BY snz_uid DESC) AS rn
FROM #cp_dbl)
DELETE FROM cte WHERE rn > 1;
SELECT
snz_uid
,[type]
,entity
,source_table
,min_date
,snz_sex_gender_code
,snz_birth_month_nbr
,snz_birth_year_nbr
,snz_birth_date_proxy
,age
,death_status
,snz_deceased_year_nbr
,snz_deceased_month_nbr
,dod
,age_at_death
INTO [$(targetdb)].[$(targetschema)].[cerebral_palsy]
FROM #cp_dbl