Developmental Delay - Code Module

adelaide.wilson
25 May

Output path

SQL:[IDI_Community].[cm_read_developmental_delay].[developmental_delay_YYYYMM]
SAS: libname cmid dsn=idi_community_srvprd schema=cm_read_developmental_delay; 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 developmental delay.

The dataset will list individuals, the earliest event when an individual has a recorded diagnosis of developmental delay 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 developmental delay due to limitations of the datasets included in the IDI. The code module allows researchers to have a consistent way of identifying people with developmental delay and will allow for comparisons of outcomes for people with developmental delay and people without developmental delay. Developmental delay can be transient, longer-term or life-long.

Key Concepts

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).

Due to the nature of how clinical coding and classifications using ICD codes work, there are some instances where ICD-10-AM 1st Edition codes back map to ICD-9-CM-A codes that may include more than just the intended diagnosis for this code module due to changes and decisions made with ICD code mapping overtime (see Table 2).

Notes for specific datasets

References

  1. 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
  2. Saraf R and Marks R (2019) Neurodevelopmental screening and surveillance. In: Cutfield WS, Derraik JGB, Waetford C, Gillon GT, Taylor BJ (editors). Brief Evidence Reviews for the Well Child Tamariki Ora Programme. A Better Start National Science Challenge. Auckland, New Zealand; p 7-51.

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 -
‘E2F0.’ (Specific reading disorder),
‘E2F01’ (Alexia, finding),
‘E2F02’ (Developmental dyslexia),
‘Eu81.’ (Developmental academic disorder),
‘Eu82.’ (Motor skill disorder),
‘E2Fz.’ (Developmental disorder),
‘E2F3’ (Disorder of speech and language development),
‘E2E1’ (Hyperkinesis with developmental delay, or
‘E2F30’ (Developmental aphasia).
Publicly funded hospital discharges (NMDS) A publicly funded hospital discharge with a primary or secondary ICD-9-CM-A diagnosis code of: 1988 -
31500 (Reading disorder, unspecified),
31501 (Alexia),
31502 (Developmental dyspraxia),
31509 (Other developmental reading disorder),
3151 (Specific developmental arithmetical disorder),
3152 (Other specific developmental learning difficulties),
31531 (Developmental language disorder),
31539 (Other developmental speech or language disorder),
3154 (Developmental coordination disorder),
3155 (Mixed development disorder),
3158 (Other specified delays in development),
3159 (Unspecified delay in development), or
7834 (Lack of expected normal physiological development).
Privately funded hospital discharges (NMDS) A privately funded hospital discharge with a primary or secondary ICD-9-CM-A diagnosis code of: 2001 -
31500 (Reading disorder, unspecified),
31501 (Alexia),
31502 (Developmental dyspraxia),
31509 (Other developmental reading disorder),
3151 (Specific developmental arithmetical disorder),
3152 (Other specific developmental learning difficulties),
31531 (Developmental language disorder),
31539 (Other developmental speech or language disorder),
3154 (Developmental coordination disorder),
3155 (Mixed development disorder),
3158 (Other specified delays in development),
3159 (Unspecified delay in development), or
7834 (Lack of expected normal physiological development).
Mortality Collection (MORT) Identified as an underlying or contributing cause of death with an ICD-9-CM-A diagnosis code of: 1988 -
31500 (Reading disorder, unspecified),
31501 (Alexia),
31502 (Developmental dyspraxia),
31509 (Other developmental reading disorder),
3151 (Specific developmental arithmetical disorder),
3152 (Other specific developmental learning difficulties),
31531 (Developmental language disorder),
31539 (Other developmental speech or language disorder),
3154 (Developmental coordination disorder),
3155 (Mixed development disorder),
3158 (Other specified delays in development),
3159 (Unspecified delay in development),
7834 (Lack of expected normal physiological development),
or an ICD-10-AM diagnosis code of:
F801 (Expressive language disorder),
F809 (Developmental disorder of speech and language, unspecified),
F810 (Specific reading disorder),
F811 (Specific spelling disorder),
F818 (Other developmental disorders of scholastic skills),
F819 (Developmental disorder of scholastic skills, unspecified),
F82 (Specific developmental disorder of motor function),
F83 (Mixed specific developmental disorders),
F89 (Unspecified disorder of psychological development),
R620 (Delayed milestone),
R628 (Other lack of expected normal physiological development), or
R629 (Lack of expected normal physiological development, unspecified).
Disability Support Services database (SOCRATES) Recorded as having a developmental delay in the Referral Diagnosis/Health Condition field with a code of: 1998 -
1204 (Developmental delay, type not specified),
1210 (Developmental delay, type not specified), or
1299 (Other intellectual, learning or developmental disorder (specify)).
Programme for the Integration of Mental Health Data (PRIMHD) A diagnosis in the DSM-IV classification system in secondary mental health and addiction services with a code of: 2009 -
31500 (Reading disorder),
31501 (Alexia),
31502 (Developmental dyspraxia),
31509 (Other developmental reading disorder)
3151 (Mathematics disorder),
3152 (Disorder of written expression),
31531 (Developmental language disorder),
31539 (Phonological disorder),
3154 (Developmental coordination disorder),
3155 (Mixed development disorder),
3158 (Other specified delays in development),
3159 (Unspecified delay in development),
7834 (Lack of expected normal physiological development),
or an ICD-10-AM diagnosis code of:
F801 (Expressive language disorder),
F809 (Developmental disorder of speech and language, unspecified),
F810 (Specific reading disorder),
F811 (Specific spelling disorder),
F818 (Other developmental disorders of scholastic skills),
F819 (Developmental disorder of scholastic skills, unspecified),
F82 (Specific developmental disorder of motor function),
F83 (Mixed specific developmental disorders),
F89 (Unspecified disorder of psychological development),
R620 (Delayed milestone),
R628 (Other lack of expected normal physiological development), or
R629 (Lack of expected normal physiological development, unspecified).
Mental Health Information National Collection (MHINC) A diagnosis in the DSM-IV classification system in secondary mental health and addiction services with a code of: July 2001 - 2008
31500 (Reading disorder),
31501 (Alexia),
31502 (Developmental dyspraxia),
31509 (Other developmental reading disorder),
3151 (Mathematics disorder),
3152 (Disorder of written expression),
31531 (Developmental language disorder),
31539 (Phonological disorder),
3154 (Developmental coordination disorder),
3155 (Mixed development disorder),
3158 (Other specified delays in development),
3159 (Unspecified delay in development),
7834 (Lack of expected normal physiological development),
or an ICD-9-CM-A diagnosis code of:
31500 (Reading disorder, unspecified),
31501 (Alexia),
31502 (Developmental dyspraxia),
31509 (Other developmental reading disorder),
3151 (Specific developmental arithmetical disorder),
3152 (Other specific developmental learning difficulties),
31531 (Developmental language disorder),
31539 (Other developmental speech or language disorder),
3154 (Developmental coordination disorder),
3155 (Mixed development disorder),
3158 (Other specified delays in development),
3159 (Unspecified delay in development),
7834 (Lack of expected normal physiological development).
Oranga Tamariki Gateway Assessments Data A need type of Global Developmental Delay or Developmental Delay in a Gateway Assessment. 2013 -

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
31501 Alexia F810 Specific reading disorder
31502 Developmental dyslexia F810 Specific reading disorder
3151 Specific developmental arithmetical disorder F812 Specific disorder of arithmetical skills
31539 Other developmental speech or language disorder F800 Specific speech articulation disorder, F808 Other developmental disorders of speech and language
3158 Other specified delays in development F88 Other disorders of psychological development

Table 2: ICD-10-AM 1st Edition codes that back map to ICD-9-CM-A codes included in the code module

ICD-9-CM-A code and definition ICD-10-AM 1st Edition code and definition
31531 Developmental language disorder F802 Receptive language disorder, F803 Acquired aphasia with epilepsy (Landau-Kleffner)
3152 Other specific developmental learning difficulties F813 Mixed disorder of scholastic skills

Data quality and other known issues

  1. Not all individuals in New Zealand diagnosed with developmental delay will be identified in this module. The module requires that the individual has had an ACC claim form, hospital discharge events, received mental health or Disability Support Services, an Oranga Tamariki gateway assessment, or had their death recorded, where the diagnosis of developmental delay has been specified.

  2. 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.

  3. 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.

  4. While more severe developmental delay can be diagnosed before the child is two years old, less severe developmental delay may not be recognised until a child is older or starts school. Thus there will be delay in data entering the IDI for individuals as well as datasets.

  5. Registerable stillbirths are included in the mortality dataset.

Comparison against other sources

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:

  1. {targetdb}: The SQL database on which the datasets are to be created.
  2. {idicleanversion}: The IDI Clean version that the datasets need to be based on.
  3. {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}.[security].[concordance]
{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]
[IDI_Adhoc].[clean_read_CYF].[cyf_gateway_cli_needs]

Outputs

{targetdb}.{targetschema}.developmental_delay
Column name Description
snz_uid The unique Stats NZ person identifier for the the individual
type A string indicating which condition or disability this table has identified (hard-coded to “DD”)
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_code and 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 refers to developmental delay)*/

DROP TABLE IF EXISTS #acc_dd;
SELECT
c.snz_uid
,'ACC' AS source_table
,c.code
,c.date AS event_date
,CAST(NULL AS VARCHAR(10)) AS entity
INTO #acc_dd
FROM 
(
SELECT 
[snz_uid]
,[acc_cla_accident_date] AS date
,[acc_cla_read_code] AS code
FROM  [$(idicleanversion)].[acc_clean].[claims]
      WHERE [acc_cla_read_code] IN ('E2F0','E2F01', 'E2F02', 'Eu81.','Eu82.','E2Fz.','E2F3.','E2E1.','E2F30')
UNION ALL  
SELECT 
b.snz_uid
,b.acc_cla_accident_date AS date
,a.[acc_med_read_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  a.[acc_med_read_code] IN ('E2F0','E2F01', 'E2F02', 'Eu81.','Eu82.','E2Fz.','E2F3.','E2E1.','E2F30')
      ) AS c;

/*Publicly-funded hospital discharges where clinical code matches a diagnosis of developmental delay*/

DROP TABLE IF EXISTS #moh_pub_dd;
SELECT 
b.snz_uid
,'MOH_PUB' AS source_table
,a.[moh_dia_submitted_system_code]
,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_dd
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 ('3151', '3152', '3154', '3155', '3158', '3159', '7834') OR SUBSTRING(a.[moh_dia_clinical_code],1,5) IN ('31500', '31501', '31502', '31509', '31531', '31539'))  
     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 developmental delay*/

DROP TABLE IF EXISTS #moh_pri_dd;
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_dd
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 ('3151', '3152', '3154', '3155', '3158', '3159', '7834') OR SUBSTRING(a.[moh_pri_diag_clinic_code],1,5) IN ('31500', '31501', '31502', '31509', '31531', '31539')) 
     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 developmental delay*/

DROP TABLE IF EXISTS #mos_dd;
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_dd
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 ('3151', '3152', '3154', '3155', '3158', '3159', '7834') OR SUBSTRING(a.[moh_mort_diag_clinical_code],1,5) IN ('31500', '31501', '31502', '31509', '31531', '31539'))  
     AND a.[moh_mort_diag_clinic_sys_code] = '06')
	 OR ((SUBSTRING(a.[moh_mort_diag_clinical_code],1,4) IN ('F801', 'F809', 'F810','F811', 'F818','F819', 'R620','R628','R629')  OR SUBSTRING(a.[moh_mort_diag_clinical_code],1,3) IN ('F82','F83', 'F89'))
     AND a.[moh_mort_diag_clinic_sys_code] >= '10');

/* Individuals in the Ministry of Health SOCRATES database with codes 1204, 1210 and 1299. 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_dd;
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_dd
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 ('1210','1204','1299');

  /*Developmental delay diagnosis in PRIMHD diagnosis data*/

DROP TABLE IF EXISTS #moh_PRIMHD_dd; 
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_dd
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 ('3151', '3152', '3154','3159', '7834')  OR SUBSTRING(a.[clinical_code],1,5) IN ('31500','31531', '31539'))
     AND a.[clinical_coding_system_id] = '07' AND diagnosis_type IN ('A','B','P')) 
	 OR ((SUBSTRING(a.[clinical_code],1,4) IN ('F801', 'F809', 'F810','F811', 'F818','F819', 'R620','R628','R629')  OR SUBSTRING(a.[clinical_code],1,3) IN ('F82','F83', 'F89'))
     AND a.[clinical_coding_system_id] >= '10');

/* Develomental delay diagnosis in PRIMHD MHINC data*/

DROP TABLE IF EXISTS #moh_mhinc_dd;
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_dd
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 ('3151', '3152', '3154', '3155', '3158', '3159', '7834')  OR SUBSTRING(a.[clinical_code],1,5) IN ('31500', '31501', '31502', '31509', '31531', '31539')
     AND a.[clinical_coding_system_id] = '06'AND diagnosis_type IN ('A','B','P'))
	 OR (SUBSTRING(a.[clinical_code],1,4) IN ('3151', '3152', '3154','3159', '7834')  OR SUBSTRING(a.[clinical_code],1,5) IN ('31500','31531', '31539')
     AND a.[clinical_coding_system_id] = '07' AND diagnosis_type IN ('A','B','P')));
	

/* develomental delay as a client need in gateway assesssments*/

DROP TABLE IF EXISTS #cyf_gateway_dd;
SELECT       
b.snz_uid
,a.snz_msd_uid
,a.[need_type_code]
,a.[needs_desc]
,a.[need_category_code] AS code
,a.[needs_cat_desc]
,needs_created_date AS event_date
,'CYF' AS source_table
, CAST (NULL AS VARCHAR (10)) AS entity
INTO #cyf_gateway_dd
FROM [IDI_Adhoc].[clean_read_CYF].[cyf_gateway_cli_needs] AS a
     LEFT JOIN [$(idicleanversion)].security.concordance AS b  ON a.snz_msd_uid = b.snz_msd_uid
     WHERE need_type_code IN ('GLO277','DED');

 
/* collate data from all sources into one table*/

DROP TABLE IF EXISTS #dd;
SELECT
a.snz_uid 
,MIN(event_date) AS min_date
,source_table
,entity
INTO #dd
FROM (
SELECT snz_uid, event_date, source_table, entity FROM #acc_dd
UNION ALL
SELECT snz_uid, event_date, source_table, entity FROM #moh_pub_dd
UNION ALL
SELECT snz_uid, event_date, source_table, entity FROM #mos_dd
UNION ALL
SELECT snz_uid, event_date, source_table, entity FROM #moh_pri_dd
UNION ALL
SELECT snz_uid, event_date, source_table, entity FROM #moh_soc_dd
UNION ALL
SELECT snz_uid, event_date, source_table, entity FROM #moh_primhd_dd
UNION ALL
SELECT snz_uid, event_date, source_table, entity FROM #moh_mhinc_dd
UNION ALL
SELECT snz_uid, event_date, source_table, entity FROM #cyf_gateway_dd
)  AS a
GROUP BY snz_uid
,source_table
,entity;

 /* subset of individuals who are deceased and are in death data*/

DROP TABLE IF EXISTS #dd_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
,'DD' AS [type]
INTO #dd_dd
FROM #dd 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 #dd_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
,'DD' AS [type]
INTO #dd_od
FROM #dd 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 #dd_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 
,'DD' AS [type]
 INTO #dd_ad
 FROM #dd 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 #dd_dd)
     AND a.snz_uid NOT IN (SELECT DISTINCT snz_uid FROM #dd_od);
  

 /* join all tables together*/

DROP TABLE IF EXISTS #dd_final;
WITH dd_union AS (
SELECT
* 
FROM #dd_dd
UNION ALL
SELECT * FROM #dd_od
UNION ALL
SELECT * FROM #dd_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 #dd_final
FROM dd_union;

/* select all required variables */

DROP TABLE IF EXISTS #dd_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 #dd_min
FROM #dd_final;

/*take earliest recorded date for each snz_uid and create table */
DROP TABLE IF EXISTS #dd_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 #dd_dbl
FROM #dd_min a
WHERE min_date = (
SELECT MIN(min_date)
FROM #dd_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)].[developmental_delay];

WITH cte AS 
(SELECT ROW_NUMBER() OVER(PARTITION BY snz_uid
ORDER BY snz_uid DESC) AS rn
FROM #dd_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)].[developmental_delay]

FROM #dd_dbl