Down Syndrome - Code Module

adelaide.wilson
25 May

Output path

SQL:[IDI_Community].[cm_read_down_syndrome].[down_syndrome_YYYYMM]
SAS: libname cmid dsn=idi_community_srvprd schema=cm_read_down_syndrome; 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 Down syndrome.

The dataset will list individuals, the earliest event when an individual has a recorded diagnosis of Down syndrome 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 Down syndrome due to limitations of the datasets included in the IDI. The code module allows researchers to have a consistent way of identifying people with Down syndrome and will allow for comparisons of outcomes for people with Down syndrome and people without Down syndrome.

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.

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. National Screening Unit (2023) Antenatal Screening for Down Syndrome and Other Conditions: 2020 Monitoring Report. Published: Wellington, National Screening Unit
  3. de Graaf G et al (2022) Estimation of the number of people with Down syndrome in Australia and New Zealand. Genetics in Medicine. 24(12) 2568-2577
  4. NZ Congenital Anomalies Registry (NZCAR) (2020) Birth defects ascertained among livebirths, 2012-2019. URL: EHINZ

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
Publicly funded hospital discharges (NMDS) A publicly funded hospital discharge with a primary or secondary ICD-9-CM-A diagnosis code of: 1988 -
7580 (Down syndrome),
or the supplementary ICD-10-AM diagnosis code of:
U882 (Down’s syndrome).
Privately funded hospital discharges (NMDS) A privately funded hopsital discharge with a primary or secondary ICD-9-CM-A diagnosis code of: 2001 -
7580 (Down syndrome),
or the supplementary ICD-10-AM diagnosis code of:
U882 (Down’s syndrome).
Mortality Collection (MORT) Identified as an underlying or contributing cause of death with an ICD-9-CM-A diagnosis code of: 1988 -
7580 (Down syndrome),
or an ICD-10-AM diagnosis code of:
Q900 (Trisomy 21, meiotic nondisjunction),
Q901(Trisomy 21, mosaicism),
Q902 (Trisomy 21, translocation), or
Q909 (Down’s syndrome, unspecified).
Disability Support Services database (SOCRATES) Recorded as having Down syndrome in the Referral Diagnosis/Health Condition field with the code of: 1998 -
1101 (Down syndrome (Trisomy 21)).
Programme for the Integration of Mental Health Data (PRIMHD) There is no code for Down syndrome 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 -
Q900 (Trisomy 21, meiotic nondisjunction),
Q901 (Trisomy 21, mosaicism),
Q902 (Trisomy 21, translocation),
Q909 (Down’s syndrome, unspecified),
or the supplementary ICD-10-AM diagnosis code of:
U882 (Down’s syndrome).
Mental Health Information National Collection (MHINC) There is no code for Down syndrome 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
7580 (Down syndrome).

Data quality and other known issues

  1. Not all individuals in New Zealand born with Down syndrome will be identified in this module. The module requires that the individual has had hospital discharge events, received Disability Support Services, or has had their death recorded with the diagnosis of Down syndrome 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. The total population of individuals with Down syndrome has decreased in New Zealand since 2011. This decrease in population has been attributed in part to the availability of antenatal screening and an increase in selective termination of pregnancies with a high likelihood of a Down syndrome baby (de Graaf et al, 2022).

  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 spell datasets are to be created.
  2. {idicleanversion}: The IDI Clean version that the spell datasets need to be based on.
  3. {targetschema}: The project schema under the target database into which the spell datasets are to be created.

Dependencies

{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}.down_syndrome
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 “DS”)
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

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

/*Publicly-funded hospital discharges where clinical code matches a diagnosis of Down syndrome*/

DROP TABLE IF EXISTS #moh_pub_ds;
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_ds
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([moh_dia_clinical_code],1,4) IN ('7580') AND [moh_dia_clinical_sys_code] = '06' AND [moh_dia_diagnosis_type_code] IN ('A','B'))
	 OR (SUBSTRING(a.[moh_dia_clinical_code],1,4) IN ('U882') AND a.[moh_dia_clinical_sys_code] >= '10' AND [moh_dia_diagnosis_type_code] IN ('A','B'));

/*Privately-funded hospital discharges where clinical code matches a diagnosis of Down syndrome*/

DROP TABLE IF EXISTS  #moh_pri_ds;
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_ds
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) = '7580' AND a.[moh_pri_diag_clinic_sys_code] ='06' AND a.[moh_pri_diag_diag_type_code] IN ('A','B'))
      OR (SUBSTRING(a.[moh_pri_diag_clinic_code],1,4) IN ('U882') AND a.[moh_pri_diag_clinic_sys_code] >= '10' AND a.[moh_pri_diag_diag_type_code] IN ('A','B'));

/*Registrations in the mortality dataset where clinical code matches a diagnosis of Down syndrome*/

DROP TABLE IF EXISTS #mos_ds;
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_ds
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([moh_mort_diag_clinical_code],1,4)='7580' AND [moh_mort_diag_clinic_sys_code] ='06')
	  OR (SUBSTRING(a.[moh_mort_diag_clinical_code],1,4) IN ('Q900','Q901','Q902','Q909') AND a.[moh_mort_diag_clinic_sys_code] >= '10');

  
/* Individuals in the Ministry of Health SOCRATES database with code 1101. 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_ds;
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_ds
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 ('1101');
	 

/*Down Syndrome diagnosis in PRIMHD diagnosis data*/

DROP TABLE IF EXISTS #moh_PRIMHD_ds;
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_ds
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 ('Q900','Q901','Q902','Q909','U882') AND a.[clinical_coding_system_id] >= '10');

/* Down Syndrome diagnosis in PRIMHD MHINC data*/

DROP TABLE IF EXISTS #moh_mhinc_ds;
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_ds
 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) = '7580' AND a.[clinical_coding_system_id] = '06');

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

DROP TABLE IF EXISTS #ds;

SELECT
a.snz_uid 
,MIN(event_date) AS min_date
,source_table
,entity
INTO #ds
FROM (
SELECT snz_uid, event_date, source_table, entity  FROM #moh_pub_ds
UNION ALL
SELECT snz_uid, event_date, source_table, entity  FROM #moh_pri_ds
UNION ALL
SELECT snz_uid, event_date, source_table, entity  FROM #mos_ds
UNION ALL
SELECT snz_uid, event_date, source_table, entity  FROM #moh_soc_ds
UNION ALL
SELECT snz_uid, event_date, source_table, entity  FROM #moh_primhd_ds
UNION ALL
SELECT snz_uid, event_date, source_table, entity  FROM #moh_mhinc_ds
)  AS a
GROUP BY snz_uid
, source_table
, entity;

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

DROP TABLE IF EXISTS #ds_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
,'DS' AS [type]
INTO #ds_dd
FROM #ds 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 #ds_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
,'DS' AS [type]
INTO #ds_od
FROM #ds 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 #ds_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 
,'DS' AS [type]
 INTO #ds_ad
 FROM #ds 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 #ds_dd)
 AND a.snz_uid NOT IN (SELECT DISTINCT snz_uid FROM #ds_od);

 /* join all tables together*/

DROP TABLE IF EXISTS #ds_final;
WITH ds_union AS (
SELECT
* 
FROM #ds_dd
UNION ALL
SELECT * FROM #ds_od
UNION ALL
SELECT * FROM #ds_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 #ds_final
FROM ds_union;

/* select all required variables */

DROP TABLE IF EXISTS #ds_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 #ds_min
FROM #ds_final;

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

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

FROM #ds_dbl