From a31e021af8194029878300660fe1ea0c227d8ad7 Mon Sep 17 00:00:00 2001 From: EddieDavison92 <143042680+EddieDavison92@users.noreply.github.com> Date: Wed, 11 Feb 2026 20:46:08 +0000 Subject: [PATCH 01/15] feat: add OLIDS data quality test suite SQL-based test suite for OLIDS with Python runner, 5 tests (220+ checks), and investigation scripts for drilling into failures. Portable across London ICBs via USE DATABASE injection from .env config. Tests: column completeness, referential integrity, concept mapping, data freshness, and registration counts vs PDS. --- OLIDS/Testing/.env.example | 5 + OLIDS/Testing/.gitignore | 5 + OLIDS/Testing/README.md | 103 ++ .../data-quality/test_column_completeness.sql | 209 +++ .../data-quality/test_concept_mapping.sql | 437 ++++++ .../data-quality/test_data_freshness.sql | 138 ++ .../test_referential_integrity.sql | 782 ++++++++++ .../data-quality/test_registration_pds.sql | 242 +++ .../investigate_column_completeness.sql | 57 + .../investigate_concept_mapping.sql | 124 ++ .../investigate_data_freshness.sql | 79 + .../investigate_referential_integrity.sql | 102 ++ .../investigate_registration_pds.sql | 148 ++ OLIDS/Testing/pyproject.toml | 10 + OLIDS/Testing/run_tests.py | 312 ++++ OLIDS/Testing/setup.ps1 | 136 ++ OLIDS/Testing/uv.lock | 1328 +++++++++++++++++ 17 files changed, 4217 insertions(+) create mode 100644 OLIDS/Testing/.env.example create mode 100644 OLIDS/Testing/.gitignore create mode 100644 OLIDS/Testing/README.md create mode 100644 OLIDS/Testing/data-quality/test_column_completeness.sql create mode 100644 OLIDS/Testing/data-quality/test_concept_mapping.sql create mode 100644 OLIDS/Testing/data-quality/test_data_freshness.sql create mode 100644 OLIDS/Testing/data-quality/test_referential_integrity.sql create mode 100644 OLIDS/Testing/data-quality/test_registration_pds.sql create mode 100644 OLIDS/Testing/investigations/investigate_column_completeness.sql create mode 100644 OLIDS/Testing/investigations/investigate_concept_mapping.sql create mode 100644 OLIDS/Testing/investigations/investigate_data_freshness.sql create mode 100644 OLIDS/Testing/investigations/investigate_referential_integrity.sql create mode 100644 OLIDS/Testing/investigations/investigate_registration_pds.sql create mode 100644 OLIDS/Testing/pyproject.toml create mode 100644 OLIDS/Testing/run_tests.py create mode 100644 OLIDS/Testing/setup.ps1 create mode 100644 OLIDS/Testing/uv.lock diff --git a/OLIDS/Testing/.env.example b/OLIDS/Testing/.env.example new file mode 100644 index 0000000..df52123 --- /dev/null +++ b/OLIDS/Testing/.env.example @@ -0,0 +1,5 @@ +SNOWFLAKE_ACCOUNT=XXXXXXX-XXX +SNOWFLAKE_USER=your.name@nhs.net +SNOWFLAKE_WAREHOUSE=your_warehouse +SNOWFLAKE_ROLE=your_role +SNOWFLAKE_DATABASE=your_database_name diff --git a/OLIDS/Testing/.gitignore b/OLIDS/Testing/.gitignore new file mode 100644 index 0000000..acac426 --- /dev/null +++ b/OLIDS/Testing/.gitignore @@ -0,0 +1,5 @@ +.env +.venv/ +__pycache__/ +*.pyc +output.txt diff --git a/OLIDS/Testing/README.md b/OLIDS/Testing/README.md new file mode 100644 index 0000000..01bfd18 --- /dev/null +++ b/OLIDS/Testing/README.md @@ -0,0 +1,103 @@ +# OLIDS Data Quality Tests + +SQL-based data quality tests for OLIDS, run against Snowflake. Portable across London ICBs — each ICB sets their own database name via `.env` and the runner injects `USE DATABASE` before each test. + +## Setup + +```powershell +cd OLIDS/Testing +.\setup.ps1 +``` + +This installs [uv](https://docs.astral.sh/uv/), prompts for Snowflake credentials, writes `.env`, and runs `uv sync`. + +## Running Tests + +All commands assume you're in the `OLIDS/Testing` directory. + +```bash +# Run all tests +uv run run_tests.py + +# Run a single test +uv run run_tests.py --test test_column_completeness + +# Show passing results and extra columns +uv run run_tests.py --verbose +``` + +## Tests + +| File | What it checks | +|---|---| +| `test_column_completeness.sql` | NULL rates per column, with per-column thresholds | +| `test_referential_integrity.sql` | Foreign keys reference existing parent records | +| `test_concept_mapping.sql` | Concept IDs map through CONCEPT_MAP to CONCEPT | +| `test_data_freshness.sql` | GP practices sending data within N days | +| `test_registration_pds.sql` | OLIDS registration counts vs PDS at 1%, 2%, 5% thresholds | + +## Output Contract + +Every test SQL must return these columns: + +| Column | Description | +|---|---| +| `test_name` | Identifier for the test | +| `table_name` | Table or domain being tested | +| `test_subject` | What specifically is being checked | +| `status` | `PASS`, `FAIL`, or `WARN` | +| `metric_value` | Measured value (usually a %) | +| `threshold` | Target the metric is compared against | + +Additional columns are allowed and shown with `--verbose`. + +## Adding Checks + +Each test file has a `-- To add a check:` comment at the top explaining the pattern. In general: + +- **Column completeness**: add a `UNION ALL SELECT` row with table, column, threshold, `COUNT(*)`, and `SUM(CASE WHEN col IS NULL ...)`. +- **Referential integrity**: add a `UNION ALL` block with the child table `LEFT JOIN`ed to the parent. +- **Concept mapping**: add a `UNION ALL` block joining the concept field through `CONCEPT_MAP` and `CONCEPT`. +- **Data freshness**: add a `UNION ALL` block selecting `table_name`, `org_code`, `MAX(date_recorded)` from any table with those columns. + +## Creating New Test Files + +Drop a `test_*.sql` file in `data-quality/` and the runner picks it up automatically. The final `SELECT` must return these columns: + +```sql +SELECT + 'my_test_name' AS test_name, -- identifies the test + 'SOME_TABLE' AS table_name, -- table or domain being tested + 'what is checked' AS test_subject, -- human-readable description of the check + CASE WHEN ... THEN 'PASS' ELSE 'FAIL' END AS status, -- PASS, FAIL, or WARN + 42.5 AS metric_value, -- measured value (usually a %) + 100.0 AS threshold -- target the metric is compared against +FROM ... +``` + +Use `UNION ALL` to return multiple checks from one file. Any extra columns beyond these six are shown with `--verbose`. + +Other notes: +- Use `SET var = value;` and `$var` for Snowflake session variables (e.g. thresholds) +- Use schema-qualified names (`OLIDS_COMMON.TABLE`) without the database prefix — the runner injects `USE DATABASE` +- Avoid semicolons in comments (the runner splits statements on `;`) + +## Investigating Failures + +The `investigations/` folder has companion scripts for each test. These return row-level detail to help diagnose failures. Run them directly in Snowsight or the VS Code Snowflake extension — each file has a `USE DATABASE` line at the top to fill in. + +| File | What it shows | +|---|---| +| `investigate_column_completeness.sql` | All checked columns with NULL counts and rates | +| `investigate_concept_mapping.sql` | Unmapped concept IDs and their row counts per table | +| `investigate_data_freshness.sql` | Per-org, per-table last data date, ordered by stalest | +| `investigate_referential_integrity.sql` | Orphaned FK values with row counts | +| `investigate_registration_pds.sql` | Per-practice OLIDS vs PDS counts with diff and status | + +## ICB-Specific Tests + +For tests that reference datasets unique to your ICB (e.g. local reference tables or warehouse-specific schemas), create a subdirectory and run with `--dir`: + +```bash +uv run run_tests.py --dir my-icb-tests +``` diff --git a/OLIDS/Testing/data-quality/test_column_completeness.sql b/OLIDS/Testing/data-quality/test_column_completeness.sql new file mode 100644 index 0000000..bc46fd9 --- /dev/null +++ b/OLIDS/Testing/data-quality/test_column_completeness.sql @@ -0,0 +1,209 @@ +/* + Test: Column Completeness + Run: uv run run_tests.py --test test_column_completeness + + Checks NULL rates for columns across OLIDS tables. + + How it works: + 1. The 'checks' CTE has one row per column check. Each row counts + total rows and NULL rows for that column in a single table scan. + 2. The 'threshold' value is the max allowed NULL % for that column. + Primary keys use 0.0 (no NULLs allowed). Most columns use 1.0. + 3. The final SELECT computes the completeness % (100 - null%) and + compares against the threshold. Empty tables return WARN. + + Output: + - metric_value = completeness % (e.g. 99.5 means 0.5% NULLs) + - threshold = minimum acceptable completeness % + - total_rows, null_count = raw counts (shown with --verbose) + + To add a check: + Add a UNION ALL SELECT row with (table_name, column_name, threshold, COUNT(*), SUM(...)) + Example: + UNION ALL SELECT 'MY_TABLE', 'my_column', 1.0, COUNT(*), + SUM(CASE WHEN my_column IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MY_TABLE +*/ + +WITH checks AS ( + -- Each row: table, column, max allowed NULL %, total rows, NULL count + -- PATIENT (OLIDS_MASKED) + SELECT 'PATIENT' AS table_name, 'id' AS column_name, 0.0 AS threshold, COUNT(*) AS total_rows, SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) AS null_count FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'sk_patient_id', 1.0, COUNT(*), SUM(CASE WHEN sk_patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'birth_year', 1.0, COUNT(*), SUM(CASE WHEN birth_year IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'birth_month', 1.0, COUNT(*), SUM(CASE WHEN birth_month IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'gender_concept_id', 1.0, COUNT(*), SUM(CASE WHEN gender_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + + -- PATIENT_ADDRESS (OLIDS_MASKED) + UNION ALL SELECT 'PATIENT_ADDRESS', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS + UNION ALL SELECT 'PATIENT_ADDRESS', 'address_type_concept_id', 1.0, COUNT(*), SUM(CASE WHEN address_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS + UNION ALL SELECT 'PATIENT_ADDRESS', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS + + -- PATIENT_CONTACT (OLIDS_MASKED) + UNION ALL SELECT 'PATIENT_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT + UNION ALL SELECT 'PATIENT_CONTACT', 'contact_type_concept_id', 1.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT + UNION ALL SELECT 'PATIENT_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT + + -- PATIENT_UPRN (OLIDS_MASKED) + UNION ALL SELECT 'PATIENT_UPRN', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_UPRN + UNION ALL SELECT 'PATIENT_UPRN', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_UPRN + + -- EPISODE_OF_CARE (OLIDS_COMMON) + UNION ALL SELECT 'EPISODE_OF_CARE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'patient_id', 1.0, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'person_id', 1.0, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_of_care_start_date', 1.0, COUNT(*), SUM(CASE WHEN episode_of_care_start_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_type_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN episode_type_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_status_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN episode_status_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + + -- OBSERVATION (OLIDS_COMMON) + UNION ALL SELECT 'OBSERVATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'patient_id', 1.0, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'person_id', 1.0, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'observation_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN observation_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'result_value_units_concept_id', 1.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'date_precision_concept_id', 1.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'episodicity_concept_id', 1.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + + -- MEDICATION_STATEMENT (OLIDS_COMMON) + UNION ALL SELECT 'MEDICATION_STATEMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'patient_id', 1.0, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'person_id', 1.0, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'medication_statement_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN medication_statement_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'authorisation_type_concept_id', 1.0, COUNT(*), SUM(CASE WHEN authorisation_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'date_precision_concept_id', 1.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + + -- MEDICATION_ORDER (OLIDS_COMMON) + UNION ALL SELECT 'MEDICATION_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'patient_id', 1.0, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'person_id', 1.0, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'medication_order_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN medication_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'date_precision_concept_id', 1.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + + -- DIAGNOSTIC_ORDER (OLIDS_COMMON) + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'patient_id', 1.0, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'person_id', 1.0, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'diagnostic_order_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN diagnostic_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'result_value_units_concept_id', 1.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'date_precision_concept_id', 1.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'episodicity_concept_id', 1.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + + -- ENCOUNTER (OLIDS_COMMON) + UNION ALL SELECT 'ENCOUNTER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'patient_id', 1.0, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'person_id', 1.0, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'encounter_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN encounter_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'date_precision_concept_id', 1.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + + -- ALLERGY_INTOLERANCE (OLIDS_COMMON) + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'patient_id', 1.0, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'person_id', 1.0, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'allergy_intolerance_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN allergy_intolerance_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'date_precision_concept_id', 1.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + + -- PROCEDURE_REQUEST (OLIDS_COMMON) + UNION ALL SELECT 'PROCEDURE_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'procedure_request_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN procedure_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'date_precision_concept_id', 1.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'status_concept_id', 1.0, COUNT(*), SUM(CASE WHEN status_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + + -- REFERRAL_REQUEST (OLIDS_COMMON) + UNION ALL SELECT 'REFERRAL_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN referral_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'date_precision_concept_id', 1.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_priority_concept_id', 1.0, COUNT(*), SUM(CASE WHEN referral_request_priority_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_type_concept_id', 1.0, COUNT(*), SUM(CASE WHEN referral_request_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_specialty_concept_id', 1.0, COUNT(*), SUM(CASE WHEN referral_request_specialty_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + + -- LOCATION_CONTACT (OLIDS_COMMON) + UNION ALL SELECT 'LOCATION_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT + UNION ALL SELECT 'LOCATION_CONTACT', 'contact_type_concept_id', 1.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT + UNION ALL SELECT 'LOCATION_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT + + -- APPOINTMENT (OLIDS_COMMON) + UNION ALL SELECT 'APPOINTMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'appointment_status_concept_id', 1.0, COUNT(*), SUM(CASE WHEN appointment_status_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'booking_method_concept_id', 1.0, COUNT(*), SUM(CASE WHEN booking_method_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'contact_mode_concept_id', 1.0, COUNT(*), SUM(CASE WHEN contact_mode_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + + -- APPOINTMENT_PRACTITIONER (OLIDS_COMMON) + UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER + UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER + + -- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE (OLIDS_COMMON) + UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE + UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE + + -- LOCATION (OLIDS_COMMON) + UNION ALL SELECT 'LOCATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION + UNION ALL SELECT 'LOCATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION + + -- FLAG (OLIDS_COMMON) + UNION ALL SELECT 'FLAG', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.FLAG + UNION ALL SELECT 'FLAG', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.FLAG + + -- ORGANISATION (OLIDS_COMMON) + UNION ALL SELECT 'ORGANISATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ORGANISATION + UNION ALL SELECT 'ORGANISATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ORGANISATION + + -- PRACTITIONER (OLIDS_COMMON) + UNION ALL SELECT 'PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER + UNION ALL SELECT 'PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER + + -- PRACTITIONER_IN_ROLE (OLIDS_COMMON) + UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE + UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE + + -- SCHEDULE (OLIDS_COMMON) + UNION ALL SELECT 'SCHEDULE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE + UNION ALL SELECT 'SCHEDULE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE + + -- SCHEDULE_PRACTITIONER (OLIDS_COMMON) + UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER + UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER + + -- CONCEPT (OLIDS_TERMINOLOGY) + UNION ALL SELECT 'CONCEPT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT + UNION ALL SELECT 'CONCEPT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT + + -- CONCEPT_MAP (OLIDS_TERMINOLOGY) + UNION ALL SELECT 'CONCEPT_MAP', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT_MAP + UNION ALL SELECT 'CONCEPT_MAP', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT_MAP +) + +-- Compute completeness % and compare against threshold +SELECT + 'column_completeness' AS test_name, + table_name, + column_name AS test_subject, + CASE + WHEN total_rows = 0 THEN 'WARN' + WHEN ROUND(100.0 * null_count / total_rows, 4) <= threshold THEN 'PASS' + ELSE 'FAIL' + END AS status, + CASE WHEN total_rows = 0 THEN NULL ELSE ROUND(100.0 - (100.0 * null_count / total_rows), 2) END AS metric_value, + ROUND(100.0 - threshold, 2) AS threshold, + total_rows, + null_count +FROM checks +ORDER BY status DESC, null_count DESC, table_name, column_name; diff --git a/OLIDS/Testing/data-quality/test_concept_mapping.sql b/OLIDS/Testing/data-quality/test_concept_mapping.sql new file mode 100644 index 0000000..319d6d5 --- /dev/null +++ b/OLIDS/Testing/data-quality/test_concept_mapping.sql @@ -0,0 +1,437 @@ +/* + Test: Concept Mapping Integrity + Run: uv run run_tests.py --test test_concept_mapping + + OLIDS stores coded clinical data using concept IDs. These must map through + the terminology layer to be usable: + concept_id -> CONCEPT_MAP.source_code_id -> CONCEPT_MAP.target_code_id -> CONCEPT.id + + How it works: + 1. The 'checks' CTE tests each concept_id column in each table. + For each, it LEFT JOINs to CONCEPT_MAP (source lookup) and CONCEPT + (target lookup), then counts how many distinct concept IDs have no match. + 2. Only non-NULL concept values are checked (NULLs are a completeness + issue, not a mapping issue). + 3. FAIL if any concept IDs are unmapped. The test_subject shows the + count (e.g. "3/100 unmapped"). + + Output: + - metric_value = % of distinct concepts that ARE mapped + - unmapped_concepts, unmapped_rows = counts (shown with --verbose) + + To add a check: + Add a UNION ALL block joining your table's concept column through + CONCEPT_MAP and CONCEPT. Follow the pattern below: + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base. = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id +*/ + +WITH checks AS ( + -- Each block: LEFT JOIN concept column through CONCEPT_MAP -> CONCEPT, + -- count distinct values and how many fail to map. + + -- OBSERVATION + SELECT 'OBSERVATION' AS table_name, 'observation_source_concept_id' AS concept_field, + COUNT(DISTINCT base.observation_source_concept_id) AS total_distinct, + COUNT(*) AS total_rows, + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.observation_source_concept_id END) AS unmapped_concepts, + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) AS unmapped_rows + FROM OLIDS_COMMON.OBSERVATION base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.observation_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.observation_source_concept_id IS NOT NULL + + UNION ALL + + SELECT 'OBSERVATION', 'result_value_units_concept_id', + COUNT(DISTINCT base.result_value_units_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.result_value_units_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.OBSERVATION base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.result_value_units_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.result_value_units_concept_id IS NOT NULL + + UNION ALL + + SELECT 'OBSERVATION', 'date_precision_concept_id', + COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.date_precision_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.OBSERVATION base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.date_precision_concept_id IS NOT NULL + + UNION ALL + + SELECT 'OBSERVATION', 'episodicity_concept_id', + COUNT(DISTINCT base.episodicity_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.episodicity_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.OBSERVATION base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.episodicity_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.episodicity_concept_id IS NOT NULL + + UNION ALL + + -- MEDICATION_STATEMENT + SELECT 'MEDICATION_STATEMENT', 'medication_statement_source_concept_id', + COUNT(DISTINCT base.medication_statement_source_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.medication_statement_source_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_STATEMENT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.medication_statement_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.medication_statement_source_concept_id IS NOT NULL + + UNION ALL + + SELECT 'MEDICATION_STATEMENT', 'authorisation_type_concept_id', + COUNT(DISTINCT base.authorisation_type_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.authorisation_type_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_STATEMENT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.authorisation_type_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.authorisation_type_concept_id IS NOT NULL + + UNION ALL + + SELECT 'MEDICATION_STATEMENT', 'date_precision_concept_id', + COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.date_precision_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_STATEMENT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.date_precision_concept_id IS NOT NULL + + UNION ALL + + -- MEDICATION_ORDER + SELECT 'MEDICATION_ORDER', 'medication_order_source_concept_id', + COUNT(DISTINCT base.medication_order_source_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.medication_order_source_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_ORDER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.medication_order_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.medication_order_source_concept_id IS NOT NULL + + UNION ALL + + SELECT 'MEDICATION_ORDER', 'date_precision_concept_id', + COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.date_precision_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_ORDER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.date_precision_concept_id IS NOT NULL + + UNION ALL + + -- DIAGNOSTIC_ORDER + SELECT 'DIAGNOSTIC_ORDER', 'diagnostic_order_source_concept_id', + COUNT(DISTINCT base.diagnostic_order_source_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.diagnostic_order_source_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.diagnostic_order_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.diagnostic_order_source_concept_id IS NOT NULL + + UNION ALL + + SELECT 'DIAGNOSTIC_ORDER', 'result_value_units_concept_id', + COUNT(DISTINCT base.result_value_units_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.result_value_units_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.result_value_units_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.result_value_units_concept_id IS NOT NULL + + UNION ALL + + SELECT 'DIAGNOSTIC_ORDER', 'date_precision_concept_id', + COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.date_precision_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.date_precision_concept_id IS NOT NULL + + UNION ALL + + SELECT 'DIAGNOSTIC_ORDER', 'episodicity_concept_id', + COUNT(DISTINCT base.episodicity_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.episodicity_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.episodicity_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.episodicity_concept_id IS NOT NULL + + UNION ALL + + -- PROCEDURE_REQUEST + SELECT 'PROCEDURE_REQUEST', 'procedure_request_source_concept_id', + COUNT(DISTINCT base.procedure_request_source_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.procedure_request_source_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.PROCEDURE_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.procedure_request_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.procedure_request_source_concept_id IS NOT NULL + + UNION ALL + + SELECT 'PROCEDURE_REQUEST', 'date_precision_concept_id', + COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.date_precision_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.PROCEDURE_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.date_precision_concept_id IS NOT NULL + + UNION ALL + + SELECT 'PROCEDURE_REQUEST', 'status_concept_id', + COUNT(DISTINCT base.status_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.status_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.PROCEDURE_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.status_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.status_concept_id IS NOT NULL + + UNION ALL + + -- REFERRAL_REQUEST + SELECT 'REFERRAL_REQUEST', 'referral_request_source_concept_id', + COUNT(DISTINCT base.referral_request_source_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.referral_request_source_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.REFERRAL_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.referral_request_source_concept_id IS NOT NULL + + UNION ALL + + SELECT 'REFERRAL_REQUEST', 'date_precision_concept_id', + COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.date_precision_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.REFERRAL_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.date_precision_concept_id IS NOT NULL + + UNION ALL + + SELECT 'REFERRAL_REQUEST', 'referral_request_priority_concept_id', + COUNT(DISTINCT base.referral_request_priority_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.referral_request_priority_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.REFERRAL_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_priority_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.referral_request_priority_concept_id IS NOT NULL + + UNION ALL + + SELECT 'REFERRAL_REQUEST', 'referral_request_type_concept_id', + COUNT(DISTINCT base.referral_request_type_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.referral_request_type_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.REFERRAL_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_type_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.referral_request_type_concept_id IS NOT NULL + + UNION ALL + + SELECT 'REFERRAL_REQUEST', 'referral_request_specialty_concept_id', + COUNT(DISTINCT base.referral_request_specialty_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.referral_request_specialty_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.REFERRAL_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_specialty_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.referral_request_specialty_concept_id IS NOT NULL + + UNION ALL + + -- ALLERGY_INTOLERANCE + SELECT 'ALLERGY_INTOLERANCE', 'allergy_intolerance_source_concept_id', + COUNT(DISTINCT base.allergy_intolerance_source_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.allergy_intolerance_source_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.ALLERGY_INTOLERANCE base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.allergy_intolerance_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.allergy_intolerance_source_concept_id IS NOT NULL + + UNION ALL + + SELECT 'ALLERGY_INTOLERANCE', 'date_precision_concept_id', + COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.date_precision_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.ALLERGY_INTOLERANCE base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.date_precision_concept_id IS NOT NULL + + UNION ALL + + -- ENCOUNTER + SELECT 'ENCOUNTER', 'encounter_source_concept_id', + COUNT(DISTINCT base.encounter_source_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.encounter_source_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.ENCOUNTER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.encounter_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.encounter_source_concept_id IS NOT NULL + + UNION ALL + + SELECT 'ENCOUNTER', 'date_precision_concept_id', + COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.date_precision_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.ENCOUNTER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.date_precision_concept_id IS NOT NULL + + UNION ALL + + -- EPISODE_OF_CARE + SELECT 'EPISODE_OF_CARE', 'episode_type_source_concept_id', + COUNT(DISTINCT base.episode_type_source_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.episode_type_source_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.EPISODE_OF_CARE base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.episode_type_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.episode_type_source_concept_id IS NOT NULL + + UNION ALL + + SELECT 'EPISODE_OF_CARE', 'episode_status_source_concept_id', + COUNT(DISTINCT base.episode_status_source_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.episode_status_source_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.EPISODE_OF_CARE base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.episode_status_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.episode_status_source_concept_id IS NOT NULL + + UNION ALL + + -- LOCATION_CONTACT + SELECT 'LOCATION_CONTACT', 'contact_type_concept_id', + COUNT(DISTINCT base.contact_type_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.contact_type_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.LOCATION_CONTACT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.contact_type_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.contact_type_concept_id IS NOT NULL + + UNION ALL + + -- APPOINTMENT + SELECT 'APPOINTMENT', 'appointment_status_concept_id', + COUNT(DISTINCT base.appointment_status_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.appointment_status_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.APPOINTMENT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.appointment_status_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.appointment_status_concept_id IS NOT NULL + + UNION ALL + + SELECT 'APPOINTMENT', 'booking_method_concept_id', + COUNT(DISTINCT base.booking_method_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.booking_method_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.APPOINTMENT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.booking_method_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.booking_method_concept_id IS NOT NULL + + UNION ALL + + SELECT 'APPOINTMENT', 'contact_mode_concept_id', + COUNT(DISTINCT base.contact_mode_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.contact_mode_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.APPOINTMENT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.contact_mode_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.contact_mode_concept_id IS NOT NULL + + UNION ALL + + -- PATIENT (OLIDS_MASKED) + SELECT 'PATIENT', 'gender_concept_id', + COUNT(DISTINCT base.gender_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.gender_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_MASKED.PATIENT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.gender_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.gender_concept_id IS NOT NULL + + UNION ALL + + -- PATIENT_ADDRESS (OLIDS_MASKED) + SELECT 'PATIENT_ADDRESS', 'address_type_concept_id', + COUNT(DISTINCT base.address_type_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.address_type_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_MASKED.PATIENT_ADDRESS base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.address_type_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.address_type_concept_id IS NOT NULL + + UNION ALL + + -- PATIENT_CONTACT (OLIDS_MASKED) + SELECT 'PATIENT_CONTACT', 'contact_type_concept_id', + COUNT(DISTINCT base.contact_type_concept_id), COUNT(*), + COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.contact_type_concept_id END), + SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_MASKED.PATIENT_CONTACT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.contact_type_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.contact_type_concept_id IS NOT NULL +) + +-- Compute mapping % per concept field +SELECT + 'concept_mapping' AS test_name, + table_name, + concept_field || ' (' || unmapped_concepts || '/' || total_distinct || ' unmapped)' AS test_subject, + CASE + WHEN unmapped_concepts = 0 THEN 'PASS' + ELSE 'FAIL' + END AS status, + ROUND(100.0 * (total_distinct - unmapped_concepts) / NULLIF(total_distinct, 0), 4) AS metric_value, + 100.0 AS threshold, + total_distinct, + total_rows, + unmapped_concepts, + unmapped_rows +FROM checks +ORDER BY status DESC, metric_value ASC, table_name, concept_field; diff --git a/OLIDS/Testing/data-quality/test_data_freshness.sql b/OLIDS/Testing/data-quality/test_data_freshness.sql new file mode 100644 index 0000000..7129e87 --- /dev/null +++ b/OLIDS/Testing/data-quality/test_data_freshness.sql @@ -0,0 +1,138 @@ +/* + Test: Data Freshness + Run: uv run run_tests.py --test test_data_freshness + + OLIDS tables have a date_recorded column showing when data was last received + from each GP practice. This test checks that practices are sending data recently. + + How it works: + 1. The 'org_freshness' CTE finds MAX(date_recorded) per org per table, + ignoring future dates (data quality issue in some feeds). + 2. The 'table_summary' CTE counts how many orgs are "fresh" (within + freshness_days of today) vs "stale" per table. + 3. PASS if >= pass_threshold_pct of orgs are fresh for that table. + + Configuration (SET variables): + - freshness_days: max days since last record to count as fresh (default: 5) + - pass_threshold_pct: % of orgs that must be fresh to pass (default: 90) + + Output: + - metric_value = % of orgs with fresh data + - total_orgs, fresh_orgs, stale_orgs, min/max/avg days (shown with --verbose) + + To add a table: + Add a UNION ALL block selecting table_name, org_code, MAX(date_recorded), + and DATEDIFF from any table with record_owner_organisation_code and + date_recorded columns. +*/ + +SET freshness_days = 5; +SET pass_threshold_pct = 90.0; + +WITH org_freshness AS ( + -- Each block: find most recent date_recorded per org for one table + -- OBSERVATION + SELECT 'OBSERVATION' AS table_name, record_owner_organisation_code AS org_code, + MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END) AS max_date_recorded, + DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) AS days_since_last + FROM OLIDS_COMMON.OBSERVATION WHERE record_owner_organisation_code IS NOT NULL + GROUP BY record_owner_organisation_code + + UNION ALL + + -- ENCOUNTER + SELECT 'ENCOUNTER', record_owner_organisation_code, + MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), + DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) + FROM OLIDS_COMMON.ENCOUNTER WHERE record_owner_organisation_code IS NOT NULL + GROUP BY record_owner_organisation_code + + UNION ALL + + -- MEDICATION_ORDER + SELECT 'MEDICATION_ORDER', record_owner_organisation_code, + MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), + DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) + FROM OLIDS_COMMON.MEDICATION_ORDER WHERE record_owner_organisation_code IS NOT NULL + GROUP BY record_owner_organisation_code + + UNION ALL + + -- MEDICATION_STATEMENT + SELECT 'MEDICATION_STATEMENT', record_owner_organisation_code, + MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), + DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) + FROM OLIDS_COMMON.MEDICATION_STATEMENT WHERE record_owner_organisation_code IS NOT NULL + GROUP BY record_owner_organisation_code + + UNION ALL + + -- DIAGNOSTIC_ORDER + SELECT 'DIAGNOSTIC_ORDER', record_owner_organisation_code, + MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), + DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER WHERE record_owner_organisation_code IS NOT NULL + GROUP BY record_owner_organisation_code + + UNION ALL + + -- ALLERGY_INTOLERANCE + SELECT 'ALLERGY_INTOLERANCE', record_owner_organisation_code, + MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), + DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) + FROM OLIDS_COMMON.ALLERGY_INTOLERANCE WHERE record_owner_organisation_code IS NOT NULL + GROUP BY record_owner_organisation_code + + UNION ALL + + -- PROCEDURE_REQUEST + SELECT 'PROCEDURE_REQUEST', record_owner_organisation_code, + MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), + DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) + FROM OLIDS_COMMON.PROCEDURE_REQUEST WHERE record_owner_organisation_code IS NOT NULL + GROUP BY record_owner_organisation_code + + UNION ALL + + -- REFERRAL_REQUEST + SELECT 'REFERRAL_REQUEST', record_owner_organisation_code, + MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), + DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) + FROM OLIDS_COMMON.REFERRAL_REQUEST WHERE record_owner_organisation_code IS NOT NULL + GROUP BY record_owner_organisation_code +), + +-- Aggregate: count fresh vs stale orgs per table +table_summary AS ( + SELECT + table_name, + COUNT(DISTINCT org_code) AS total_orgs, + COUNT(DISTINCT CASE WHEN days_since_last <= $freshness_days THEN org_code END) AS fresh_orgs, + COUNT(DISTINCT CASE WHEN days_since_last > $freshness_days THEN org_code END) AS stale_orgs, + ROUND(100.0 * COUNT(DISTINCT CASE WHEN days_since_last <= $freshness_days THEN org_code END) / NULLIF(COUNT(DISTINCT org_code), 0), 2) AS fresh_pct, + MIN(days_since_last) AS min_days_since, + MAX(days_since_last) AS max_days_since, + ROUND(AVG(days_since_last), 1) AS avg_days_since + FROM org_freshness + WHERE max_date_recorded IS NOT NULL + GROUP BY table_name +) + +SELECT + 'data_freshness' AS test_name, + table_name, + 'orgs with data within ' || $freshness_days || ' days' AS test_subject, + CASE + WHEN fresh_pct >= $pass_threshold_pct THEN 'PASS' + ELSE 'FAIL' + END AS status, + fresh_pct AS metric_value, + $pass_threshold_pct AS threshold, + total_orgs, + fresh_orgs, + stale_orgs, + min_days_since, + max_days_since, + avg_days_since +FROM table_summary +ORDER BY status DESC, fresh_pct ASC, table_name; diff --git a/OLIDS/Testing/data-quality/test_referential_integrity.sql b/OLIDS/Testing/data-quality/test_referential_integrity.sql new file mode 100644 index 0000000..b723e72 --- /dev/null +++ b/OLIDS/Testing/data-quality/test_referential_integrity.sql @@ -0,0 +1,782 @@ +/* + Test: Referential Integrity + Run: uv run run_tests.py --test test_referential_integrity + + OLIDS tables use foreign key columns (patient_id, encounter_id, etc.) to + link records across tables. This test checks that every FK value points to + an existing record in the parent table. + + How it works: + 1. The 'fk_checks' CTE has one block per FK relationship. Each block + LEFT JOINs the child table (alias 'c') to the parent table (alias 'p') + on the FK column, then counts how many distinct FK values have no match + (orphaned_fk) and how many rows are affected (orphaned_rows). + 2. Only non-NULL FK values are checked (NULLs are a completeness issue). + 3. FAIL if any orphaned FK values exist (threshold = 100% integrity). + + Output: + - metric_value = % of distinct FK values that DO have a parent record + - total_distinct_fk, orphaned_fk, orphaned_rows (shown with --verbose) + + To add a check: + Add a UNION ALL block with the child table LEFT JOINed to the parent. + Use aliases 'c' (child) and 'p' (parent). Follow the pattern below. +*/ + +WITH fk_checks AS ( + -- Each block: LEFT JOIN child.fk_column to parent.id, count orphaned values. + -- Uses 'c' for child table and 'p' for parent table throughout. + + -- ALLERGY_INTOLERANCE -> PATIENT + SELECT 'ALLERGY_INTOLERANCE' AS child_table, 'patient_id' AS fk_column, 'PATIENT' AS parent_table, + COUNT(DISTINCT c.patient_id) AS total_distinct_fk, + SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END) AS total_rows_with_fk, + COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END) AS orphaned_fk, + SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) AS orphaned_rows + FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + + UNION ALL + + -- ALLERGY_INTOLERANCE -> ENCOUNTER + SELECT 'ALLERGY_INTOLERANCE', 'encounter_id', 'ENCOUNTER', + COUNT(DISTINCT c.encounter_id), + SUM(CASE WHEN c.encounter_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN c.encounter_id END), + SUM(CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c + LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id + + UNION ALL + + -- ALLERGY_INTOLERANCE -> PRACTITIONER + SELECT 'ALLERGY_INTOLERANCE', 'practitioner_id', 'PRACTITIONER', + COUNT(DISTINCT c.practitioner_id), + SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), + SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + + UNION ALL + + -- APPOINTMENT -> PATIENT + SELECT 'APPOINTMENT', 'patient_id', 'PATIENT', + COUNT(DISTINCT c.patient_id), + SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), + SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.APPOINTMENT c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + + UNION ALL + + -- APPOINTMENT -> PRACTITIONER_IN_ROLE + SELECT 'APPOINTMENT', 'practitioner_in_role_id', 'PRACTITIONER_IN_ROLE', + COUNT(DISTINCT c.practitioner_in_role_id), + SUM(CASE WHEN c.practitioner_in_role_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.practitioner_in_role_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_in_role_id END), + SUM(CASE WHEN c.practitioner_in_role_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.APPOINTMENT c + LEFT JOIN OLIDS_COMMON.PRACTITIONER_IN_ROLE p ON c.practitioner_in_role_id = p.id + + UNION ALL + + -- APPOINTMENT -> SCHEDULE + SELECT 'APPOINTMENT', 'schedule_id', 'SCHEDULE', + COUNT(DISTINCT c.schedule_id), + SUM(CASE WHEN c.schedule_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.schedule_id IS NOT NULL AND p.id IS NULL THEN c.schedule_id END), + SUM(CASE WHEN c.schedule_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.APPOINTMENT c + LEFT JOIN OLIDS_COMMON.SCHEDULE p ON c.schedule_id = p.id + + UNION ALL + + -- APPOINTMENT_PRACTITIONER -> APPOINTMENT + SELECT 'APPOINTMENT_PRACTITIONER', 'appointment_id', 'APPOINTMENT', + COUNT(DISTINCT c.appointment_id), + SUM(CASE WHEN c.appointment_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.appointment_id IS NOT NULL AND p.id IS NULL THEN c.appointment_id END), + SUM(CASE WHEN c.appointment_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER c + LEFT JOIN OLIDS_COMMON.APPOINTMENT p ON c.appointment_id = p.id + + UNION ALL + + -- APPOINTMENT_PRACTITIONER -> PRACTITIONER + SELECT 'APPOINTMENT_PRACTITIONER', 'practitioner_id', 'PRACTITIONER', + COUNT(DISTINCT c.practitioner_id), + SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), + SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + + UNION ALL + + -- DIAGNOSTIC_ORDER -> PATIENT + SELECT 'DIAGNOSTIC_ORDER', 'patient_id', 'PATIENT', + COUNT(DISTINCT c.patient_id), + SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), + SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + + UNION ALL + + -- DIAGNOSTIC_ORDER -> ENCOUNTER + SELECT 'DIAGNOSTIC_ORDER', 'encounter_id', 'ENCOUNTER', + COUNT(DISTINCT c.encounter_id), + SUM(CASE WHEN c.encounter_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN c.encounter_id END), + SUM(CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c + LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id + + UNION ALL + + -- DIAGNOSTIC_ORDER -> PRACTITIONER + SELECT 'DIAGNOSTIC_ORDER', 'practitioner_id', 'PRACTITIONER', + COUNT(DISTINCT c.practitioner_id), + SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), + SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + + UNION ALL + + -- DIAGNOSTIC_ORDER -> OBSERVATION (parent) + SELECT 'DIAGNOSTIC_ORDER', 'parent_observation_id', 'OBSERVATION', + COUNT(DISTINCT c.parent_observation_id), + SUM(CASE WHEN c.parent_observation_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.parent_observation_id IS NOT NULL AND p.id IS NULL THEN c.parent_observation_id END), + SUM(CASE WHEN c.parent_observation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c + LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.parent_observation_id = p.id + + UNION ALL + + -- ENCOUNTER -> PATIENT + SELECT 'ENCOUNTER', 'patient_id', 'PATIENT', + COUNT(DISTINCT c.patient_id), + SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), + SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.ENCOUNTER c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + + UNION ALL + + -- ENCOUNTER -> PRACTITIONER + SELECT 'ENCOUNTER', 'practitioner_id', 'PRACTITIONER', + COUNT(DISTINCT c.practitioner_id), + SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), + SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.ENCOUNTER c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + + UNION ALL + + -- ENCOUNTER -> EPISODE_OF_CARE + SELECT 'ENCOUNTER', 'episode_of_care_id', 'EPISODE_OF_CARE', + COUNT(DISTINCT c.episode_of_care_id), + SUM(CASE WHEN c.episode_of_care_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.episode_of_care_id IS NOT NULL AND p.id IS NULL THEN c.episode_of_care_id END), + SUM(CASE WHEN c.episode_of_care_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.ENCOUNTER c + LEFT JOIN OLIDS_COMMON.EPISODE_OF_CARE p ON c.episode_of_care_id = p.id + + UNION ALL + + -- ENCOUNTER -> APPOINTMENT + SELECT 'ENCOUNTER', 'appointment_id', 'APPOINTMENT', + COUNT(DISTINCT c.appointment_id), + SUM(CASE WHEN c.appointment_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.appointment_id IS NOT NULL AND p.id IS NULL THEN c.appointment_id END), + SUM(CASE WHEN c.appointment_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.ENCOUNTER c + LEFT JOIN OLIDS_COMMON.APPOINTMENT p ON c.appointment_id = p.id + + UNION ALL + + -- ENCOUNTER -> ORGANISATION (service provider) + SELECT 'ENCOUNTER', 'service_provider_organisation_id', 'ORGANISATION', + COUNT(DISTINCT c.service_provider_organisation_id), + SUM(CASE WHEN c.service_provider_organisation_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.service_provider_organisation_id IS NOT NULL AND p.id IS NULL THEN c.service_provider_organisation_id END), + SUM(CASE WHEN c.service_provider_organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.ENCOUNTER c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.service_provider_organisation_id = p.id + + UNION ALL + + -- EPISODE_OF_CARE -> PATIENT + SELECT 'EPISODE_OF_CARE', 'patient_id', 'PATIENT', + COUNT(DISTINCT c.patient_id), + SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), + SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.EPISODE_OF_CARE c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + + UNION ALL + + -- EPISODE_OF_CARE -> ORGANISATION + SELECT 'EPISODE_OF_CARE', 'organisation_id', 'ORGANISATION', + COUNT(DISTINCT c.organisation_id), + SUM(CASE WHEN c.organisation_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN c.organisation_id END), + SUM(CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.EPISODE_OF_CARE c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id + + UNION ALL + + -- EPISODE_OF_CARE -> PRACTITIONER (care manager) + SELECT 'EPISODE_OF_CARE', 'care_manager_practitioner_id', 'PRACTITIONER', + COUNT(DISTINCT c.care_manager_practitioner_id), + SUM(CASE WHEN c.care_manager_practitioner_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.care_manager_practitioner_id IS NOT NULL AND p.id IS NULL THEN c.care_manager_practitioner_id END), + SUM(CASE WHEN c.care_manager_practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.EPISODE_OF_CARE c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.care_manager_practitioner_id = p.id + + UNION ALL + + -- FLAG -> PATIENT + SELECT 'FLAG', 'patient_id', 'PATIENT', + COUNT(DISTINCT c.patient_id), + SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), + SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.FLAG c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + + UNION ALL + + -- LOCATION -> ORGANISATION (managing) + SELECT 'LOCATION', 'managing_organisation_id', 'ORGANISATION', + COUNT(DISTINCT c.managing_organisation_id), + SUM(CASE WHEN c.managing_organisation_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.managing_organisation_id IS NOT NULL AND p.id IS NULL THEN c.managing_organisation_id END), + SUM(CASE WHEN c.managing_organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.LOCATION c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.managing_organisation_id = p.id + + UNION ALL + + -- LOCATION_CONTACT -> LOCATION + SELECT 'LOCATION_CONTACT', 'location_id', 'LOCATION', + COUNT(DISTINCT c.location_id), + SUM(CASE WHEN c.location_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.location_id IS NOT NULL AND p.id IS NULL THEN c.location_id END), + SUM(CASE WHEN c.location_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.LOCATION_CONTACT c + LEFT JOIN OLIDS_COMMON.LOCATION p ON c.location_id = p.id + + UNION ALL + + -- MEDICATION_ORDER -> PATIENT + SELECT 'MEDICATION_ORDER', 'patient_id', 'PATIENT', + COUNT(DISTINCT c.patient_id), + SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), + SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_ORDER c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + + UNION ALL + + -- MEDICATION_ORDER -> MEDICATION_STATEMENT + SELECT 'MEDICATION_ORDER', 'medication_statement_id', 'MEDICATION_STATEMENT', + COUNT(DISTINCT c.medication_statement_id), + SUM(CASE WHEN c.medication_statement_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.medication_statement_id IS NOT NULL AND p.id IS NULL THEN c.medication_statement_id END), + SUM(CASE WHEN c.medication_statement_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_ORDER c + LEFT JOIN OLIDS_COMMON.MEDICATION_STATEMENT p ON c.medication_statement_id = p.id + + UNION ALL + + -- MEDICATION_ORDER -> ORGANISATION + SELECT 'MEDICATION_ORDER', 'organisation_id', 'ORGANISATION', + COUNT(DISTINCT c.organisation_id), + SUM(CASE WHEN c.organisation_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN c.organisation_id END), + SUM(CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_ORDER c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id + + UNION ALL + + -- MEDICATION_ORDER -> ENCOUNTER + SELECT 'MEDICATION_ORDER', 'encounter_id', 'ENCOUNTER', + COUNT(DISTINCT c.encounter_id), + SUM(CASE WHEN c.encounter_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN c.encounter_id END), + SUM(CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_ORDER c + LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id + + UNION ALL + + -- MEDICATION_ORDER -> PRACTITIONER + SELECT 'MEDICATION_ORDER', 'practitioner_id', 'PRACTITIONER', + COUNT(DISTINCT c.practitioner_id), + SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), + SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_ORDER c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + + UNION ALL + + -- MEDICATION_ORDER -> OBSERVATION + SELECT 'MEDICATION_ORDER', 'observation_id', 'OBSERVATION', + COUNT(DISTINCT c.observation_id), + SUM(CASE WHEN c.observation_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.observation_id IS NOT NULL AND p.id IS NULL THEN c.observation_id END), + SUM(CASE WHEN c.observation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_ORDER c + LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.observation_id = p.id + + UNION ALL + + -- MEDICATION_ORDER -> ALLERGY_INTOLERANCE + SELECT 'MEDICATION_ORDER', 'allergy_intolerance_id', 'ALLERGY_INTOLERANCE', + COUNT(DISTINCT c.allergy_intolerance_id), + SUM(CASE WHEN c.allergy_intolerance_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.allergy_intolerance_id IS NOT NULL AND p.id IS NULL THEN c.allergy_intolerance_id END), + SUM(CASE WHEN c.allergy_intolerance_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_ORDER c + LEFT JOIN OLIDS_COMMON.ALLERGY_INTOLERANCE p ON c.allergy_intolerance_id = p.id + + UNION ALL + + -- MEDICATION_ORDER -> DIAGNOSTIC_ORDER + SELECT 'MEDICATION_ORDER', 'diagnostic_order_id', 'DIAGNOSTIC_ORDER', + COUNT(DISTINCT c.diagnostic_order_id), + SUM(CASE WHEN c.diagnostic_order_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.diagnostic_order_id IS NOT NULL AND p.id IS NULL THEN c.diagnostic_order_id END), + SUM(CASE WHEN c.diagnostic_order_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_ORDER c + LEFT JOIN OLIDS_COMMON.DIAGNOSTIC_ORDER p ON c.diagnostic_order_id = p.id + + UNION ALL + + -- MEDICATION_ORDER -> REFERRAL_REQUEST + SELECT 'MEDICATION_ORDER', 'referral_request_id', 'REFERRAL_REQUEST', + COUNT(DISTINCT c.referral_request_id), + SUM(CASE WHEN c.referral_request_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.referral_request_id IS NOT NULL AND p.id IS NULL THEN c.referral_request_id END), + SUM(CASE WHEN c.referral_request_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_ORDER c + LEFT JOIN OLIDS_COMMON.REFERRAL_REQUEST p ON c.referral_request_id = p.id + + UNION ALL + + -- MEDICATION_STATEMENT -> PATIENT + SELECT 'MEDICATION_STATEMENT', 'patient_id', 'PATIENT', + COUNT(DISTINCT c.patient_id), + SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), + SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_STATEMENT c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + + UNION ALL + + -- MEDICATION_STATEMENT -> ORGANISATION + SELECT 'MEDICATION_STATEMENT', 'organisation_id', 'ORGANISATION', + COUNT(DISTINCT c.organisation_id), + SUM(CASE WHEN c.organisation_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN c.organisation_id END), + SUM(CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_STATEMENT c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id + + UNION ALL + + -- MEDICATION_STATEMENT -> ENCOUNTER + SELECT 'MEDICATION_STATEMENT', 'encounter_id', 'ENCOUNTER', + COUNT(DISTINCT c.encounter_id), + SUM(CASE WHEN c.encounter_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN c.encounter_id END), + SUM(CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_STATEMENT c + LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id + + UNION ALL + + -- MEDICATION_STATEMENT -> PRACTITIONER + SELECT 'MEDICATION_STATEMENT', 'practitioner_id', 'PRACTITIONER', + COUNT(DISTINCT c.practitioner_id), + SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), + SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_STATEMENT c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + + UNION ALL + + -- MEDICATION_STATEMENT -> OBSERVATION + SELECT 'MEDICATION_STATEMENT', 'observation_id', 'OBSERVATION', + COUNT(DISTINCT c.observation_id), + SUM(CASE WHEN c.observation_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.observation_id IS NOT NULL AND p.id IS NULL THEN c.observation_id END), + SUM(CASE WHEN c.observation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_STATEMENT c + LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.observation_id = p.id + + UNION ALL + + -- MEDICATION_STATEMENT -> ALLERGY_INTOLERANCE + SELECT 'MEDICATION_STATEMENT', 'allergy_intolerance_id', 'ALLERGY_INTOLERANCE', + COUNT(DISTINCT c.allergy_intolerance_id), + SUM(CASE WHEN c.allergy_intolerance_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.allergy_intolerance_id IS NOT NULL AND p.id IS NULL THEN c.allergy_intolerance_id END), + SUM(CASE WHEN c.allergy_intolerance_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_STATEMENT c + LEFT JOIN OLIDS_COMMON.ALLERGY_INTOLERANCE p ON c.allergy_intolerance_id = p.id + + UNION ALL + + -- MEDICATION_STATEMENT -> DIAGNOSTIC_ORDER + SELECT 'MEDICATION_STATEMENT', 'diagnostic_order_id', 'DIAGNOSTIC_ORDER', + COUNT(DISTINCT c.diagnostic_order_id), + SUM(CASE WHEN c.diagnostic_order_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.diagnostic_order_id IS NOT NULL AND p.id IS NULL THEN c.diagnostic_order_id END), + SUM(CASE WHEN c.diagnostic_order_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_STATEMENT c + LEFT JOIN OLIDS_COMMON.DIAGNOSTIC_ORDER p ON c.diagnostic_order_id = p.id + + UNION ALL + + -- MEDICATION_STATEMENT -> REFERRAL_REQUEST + SELECT 'MEDICATION_STATEMENT', 'referral_request_id', 'REFERRAL_REQUEST', + COUNT(DISTINCT c.referral_request_id), + SUM(CASE WHEN c.referral_request_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.referral_request_id IS NOT NULL AND p.id IS NULL THEN c.referral_request_id END), + SUM(CASE WHEN c.referral_request_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_STATEMENT c + LEFT JOIN OLIDS_COMMON.REFERRAL_REQUEST p ON c.referral_request_id = p.id + + UNION ALL + + -- OBSERVATION -> PATIENT + SELECT 'OBSERVATION', 'patient_id', 'PATIENT', + COUNT(DISTINCT c.patient_id), + SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), + SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.OBSERVATION c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + + UNION ALL + + -- OBSERVATION -> ENCOUNTER + SELECT 'OBSERVATION', 'encounter_id', 'ENCOUNTER', + COUNT(DISTINCT c.encounter_id), + SUM(CASE WHEN c.encounter_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN c.encounter_id END), + SUM(CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.OBSERVATION c + LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id + + UNION ALL + + -- OBSERVATION -> PRACTITIONER + SELECT 'OBSERVATION', 'practitioner_id', 'PRACTITIONER', + COUNT(DISTINCT c.practitioner_id), + SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), + SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.OBSERVATION c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + + UNION ALL + + -- OBSERVATION -> OBSERVATION (parent) + SELECT 'OBSERVATION', 'parent_observation_id', 'OBSERVATION', + COUNT(DISTINCT c.parent_observation_id), + SUM(CASE WHEN c.parent_observation_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.parent_observation_id IS NOT NULL AND p.id IS NULL THEN c.parent_observation_id END), + SUM(CASE WHEN c.parent_observation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.OBSERVATION c + LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.parent_observation_id = p.id + + UNION ALL + + -- ORGANISATION -> ORGANISATION (parent) + SELECT 'ORGANISATION', 'parent_organisation_id', 'ORGANISATION', + COUNT(DISTINCT c.parent_organisation_id), + SUM(CASE WHEN c.parent_organisation_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.parent_organisation_id IS NOT NULL AND p.id IS NULL THEN c.parent_organisation_id END), + SUM(CASE WHEN c.parent_organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.ORGANISATION c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.parent_organisation_id = p.id + + UNION ALL + + -- PATIENT -> ORGANISATION (registered practice) + SELECT 'PATIENT', 'registered_practice_id', 'ORGANISATION', + COUNT(DISTINCT c.registered_practice_id), + SUM(CASE WHEN c.registered_practice_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.registered_practice_id IS NOT NULL AND p.id IS NULL THEN c.registered_practice_id END), + SUM(CASE WHEN c.registered_practice_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_MASKED.PATIENT c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.registered_practice_id = p.id + + UNION ALL + + -- PATIENT_ADDRESS -> PATIENT + SELECT 'PATIENT_ADDRESS', 'patient_id', 'PATIENT', + COUNT(DISTINCT c.patient_id), + SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), + SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_MASKED.PATIENT_ADDRESS c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + + UNION ALL + + -- PATIENT_CONTACT -> PATIENT + SELECT 'PATIENT_CONTACT', 'patient_id', 'PATIENT', + COUNT(DISTINCT c.patient_id), + SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), + SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_MASKED.PATIENT_CONTACT c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + + UNION ALL + + -- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE -> PATIENT + SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'patient_id', 'PATIENT', + COUNT(DISTINCT c.patient_id), + SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), + SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + + UNION ALL + + -- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE -> ORGANISATION + SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'organisation_id', 'ORGANISATION', + COUNT(DISTINCT c.organisation_id), + SUM(CASE WHEN c.organisation_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN c.organisation_id END), + SUM(CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id + + UNION ALL + + -- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE -> PRACTITIONER + SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'practitioner_id', 'PRACTITIONER', + COUNT(DISTINCT c.practitioner_id), + SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), + SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + + UNION ALL + + -- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE -> EPISODE_OF_CARE + SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'episode_of_care_id', 'EPISODE_OF_CARE', + COUNT(DISTINCT c.episode_of_care_id), + SUM(CASE WHEN c.episode_of_care_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.episode_of_care_id IS NOT NULL AND p.id IS NULL THEN c.episode_of_care_id END), + SUM(CASE WHEN c.episode_of_care_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c + LEFT JOIN OLIDS_COMMON.EPISODE_OF_CARE p ON c.episode_of_care_id = p.id + + UNION ALL + + -- PRACTITIONER_IN_ROLE -> PRACTITIONER + SELECT 'PRACTITIONER_IN_ROLE', 'practitioner_id', 'PRACTITIONER', + COUNT(DISTINCT c.practitioner_id), + SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), + SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + + UNION ALL + + -- PRACTITIONER_IN_ROLE -> ORGANISATION + SELECT 'PRACTITIONER_IN_ROLE', 'organisation_id', 'ORGANISATION', + COUNT(DISTINCT c.organisation_id), + SUM(CASE WHEN c.organisation_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN c.organisation_id END), + SUM(CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id + + UNION ALL + + -- PROCEDURE_REQUEST -> PATIENT + SELECT 'PROCEDURE_REQUEST', 'patient_id', 'PATIENT', + COUNT(DISTINCT c.patient_id), + SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), + SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.PROCEDURE_REQUEST c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + + UNION ALL + + -- PROCEDURE_REQUEST -> ENCOUNTER + SELECT 'PROCEDURE_REQUEST', 'encounter_id', 'ENCOUNTER', + COUNT(DISTINCT c.encounter_id), + SUM(CASE WHEN c.encounter_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN c.encounter_id END), + SUM(CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.PROCEDURE_REQUEST c + LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id + + UNION ALL + + -- PROCEDURE_REQUEST -> PRACTITIONER + SELECT 'PROCEDURE_REQUEST', 'practitioner_id', 'PRACTITIONER', + COUNT(DISTINCT c.practitioner_id), + SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), + SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.PROCEDURE_REQUEST c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + + UNION ALL + + -- REFERRAL_REQUEST -> PATIENT + SELECT 'REFERRAL_REQUEST', 'patient_id', 'PATIENT', + COUNT(DISTINCT c.patient_id), + SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), + SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.REFERRAL_REQUEST c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + + UNION ALL + + -- REFERRAL_REQUEST -> ENCOUNTER + SELECT 'REFERRAL_REQUEST', 'encounter_id', 'ENCOUNTER', + COUNT(DISTINCT c.encounter_id), + SUM(CASE WHEN c.encounter_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN c.encounter_id END), + SUM(CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.REFERRAL_REQUEST c + LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id + + UNION ALL + + -- REFERRAL_REQUEST -> PRACTITIONER + SELECT 'REFERRAL_REQUEST', 'practitioner_id', 'PRACTITIONER', + COUNT(DISTINCT c.practitioner_id), + SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), + SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.REFERRAL_REQUEST c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + + UNION ALL + + -- REFERRAL_REQUEST -> ORGANISATION + SELECT 'REFERRAL_REQUEST', 'organisation_id', 'ORGANISATION', + COUNT(DISTINCT c.organisation_id), + SUM(CASE WHEN c.organisation_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN c.organisation_id END), + SUM(CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.REFERRAL_REQUEST c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id + + UNION ALL + + -- REFERRAL_REQUEST -> ORGANISATION (requester) + SELECT 'REFERRAL_REQUEST', 'requester_organisation_id', 'ORGANISATION', + COUNT(DISTINCT c.requester_organisation_id), + SUM(CASE WHEN c.requester_organisation_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.requester_organisation_id IS NOT NULL AND p.id IS NULL THEN c.requester_organisation_id END), + SUM(CASE WHEN c.requester_organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.REFERRAL_REQUEST c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.requester_organisation_id = p.id + + UNION ALL + + -- REFERRAL_REQUEST -> ORGANISATION (recipient) + SELECT 'REFERRAL_REQUEST', 'recipient_organisation_id', 'ORGANISATION', + COUNT(DISTINCT c.recipient_organisation_id), + SUM(CASE WHEN c.recipient_organisation_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.recipient_organisation_id IS NOT NULL AND p.id IS NULL THEN c.recipient_organisation_id END), + SUM(CASE WHEN c.recipient_organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.REFERRAL_REQUEST c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.recipient_organisation_id = p.id + + UNION ALL + + -- SCHEDULE -> LOCATION + SELECT 'SCHEDULE', 'location_id', 'LOCATION', + COUNT(DISTINCT c.location_id), + SUM(CASE WHEN c.location_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.location_id IS NOT NULL AND p.id IS NULL THEN c.location_id END), + SUM(CASE WHEN c.location_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.SCHEDULE c + LEFT JOIN OLIDS_COMMON.LOCATION p ON c.location_id = p.id + + UNION ALL + + -- SCHEDULE -> PRACTITIONER + SELECT 'SCHEDULE', 'practitioner_id', 'PRACTITIONER', + COUNT(DISTINCT c.practitioner_id), + SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), + SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.SCHEDULE c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + + UNION ALL + + -- SCHEDULE_PRACTITIONER -> SCHEDULE + SELECT 'SCHEDULE_PRACTITIONER', 'schedule_id', 'SCHEDULE', + COUNT(DISTINCT c.schedule_id), + SUM(CASE WHEN c.schedule_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.schedule_id IS NOT NULL AND p.id IS NULL THEN c.schedule_id END), + SUM(CASE WHEN c.schedule_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER c + LEFT JOIN OLIDS_COMMON.SCHEDULE p ON c.schedule_id = p.id + + UNION ALL + + -- SCHEDULE_PRACTITIONER -> PRACTITIONER + SELECT 'SCHEDULE_PRACTITIONER', 'practitioner_id', 'PRACTITIONER', + COUNT(DISTINCT c.practitioner_id), + SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), + SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +) + +SELECT + 'referential_integrity' AS test_name, + child_table AS table_name, + fk_column || ' -> ' || parent_table || '.id' AS test_subject, + CASE + WHEN orphaned_fk = 0 THEN 'PASS' + ELSE 'FAIL' + END AS status, + ROUND(100.0 * (total_distinct_fk - orphaned_fk) / NULLIF(total_distinct_fk, 0), 2) AS metric_value, + 100.0 AS threshold, + total_distinct_fk, + total_rows_with_fk, + orphaned_fk, + orphaned_rows +FROM fk_checks +WHERE total_rows_with_fk > 0 +ORDER BY status DESC, metric_value ASC, child_table, fk_column; diff --git a/OLIDS/Testing/data-quality/test_registration_pds.sql b/OLIDS/Testing/data-quality/test_registration_pds.sql new file mode 100644 index 0000000..9025cac --- /dev/null +++ b/OLIDS/Testing/data-quality/test_registration_pds.sql @@ -0,0 +1,242 @@ +/* + Test: Registration Count - PDS Comparison + Run: uv run run_tests.py --test test_registration_pds + + Compares OLIDS GP registration counts against PDS (Personal Demographics Service) + to validate that the OLIDS data reflects the national registration picture. + + How it works: + 1. 'icb_practices' - gets practice codes from EPISODE_OF_CARE, limiting to + practices that actually have data in this OLIDS database (~175 for NCL). + 2. OLIDS side (CTEs: eligible_patients -> patient_death_dates -> filtered_episodes + -> deduplicated_registrations -> olids_counts): + - Start with patients who are not sensitive, confidential, or dummy + - Approximate death dates from year/month (mid-month or mid-year) + - Filter episodes: Regular type only, active as of snapshot, not soft-deleted + - Exclude "Left" episodes with no end date (malformed data) + - Treat end_date < start_date as still active (known data quality issue) + - Deduplicate: one registration per person per practice (latest episode wins) + 3. PDS side (CTEs: pds_merged -> pds_counts): + - Active registrations as of snapshot date + - Handle NHS number mergers (superseded numbers via PDS_Person_Merger) + - Exclude deceased patients (PDS_Person.Death Status) + - Exclude patients with reason for removal (PDS_Reason_For_Removal) + 4. 'comparison' - joins OLIDS and PDS counts per practice, computes % diff + 5. 'summary' - counts how many practices pass at each threshold + + Three output rows at different thresholds: + - <1% or <5 persons (strictest) + - <2% or <5 persons (tight) + - <5% or <5 persons (loose) + The <5 persons clause prevents small practices (e.g. 50 patients) from + failing due to a handful of patients causing a high % diff. + + Configuration: + - snapshot_date: defaults to last day of previous month + - PDS tables: in "Data_Store_Registries"."pds" (change if your ICB differs) +*/ + +-- Last day of the previous complete calendar month +SET snapshot_date = LAST_DAY(DATEADD(MONTH, -1, CURRENT_DATE)); + +-- Practice codes derived from EPISODE_OF_CARE (only practices with actual data) +WITH icb_practices AS ( + SELECT DISTINCT record_owner_organisation_code AS practice_code + FROM OLIDS_COMMON.EPISODE_OF_CARE + WHERE record_owner_organisation_code IS NOT NULL +), + +-- Step 1: Patients eligible for counting (exclude test/sensitive/confidential) +eligible_patients AS ( + SELECT + id AS patient_id, + sk_patient_id, + death_year, + death_month + FROM OLIDS_MASKED.PATIENT + WHERE sk_patient_id IS NOT NULL + AND is_spine_sensitive = FALSE + AND is_confidential = FALSE + AND is_dummy_patient = FALSE +), + +-- Step 2: Approximate death dates from year/month (OLIDS only stores year+month, not exact date) +-- If year+month known: use mid-month. If only year: use July 1st. +patient_death_dates AS ( + SELECT + patient_id, + sk_patient_id, + death_year IS NOT NULL AS is_deceased, + CASE + WHEN death_year IS NOT NULL AND death_month IS NOT NULL + THEN DATEADD( + DAY, + FLOOR(DAY(LAST_DAY(TO_DATE(death_year || '-' || LPAD(death_month, 2, '0') || '-01'))) / 2), + TO_DATE(death_year || '-' || LPAD(death_month, 2, '0') || '-01') + ) + WHEN death_year IS NOT NULL + THEN TO_DATE(death_year || '-07-01') + ELSE NULL + END AS death_date_approx + FROM eligible_patients +), + +-- Step 3: Map patient_id to person_id (OLIDS deduplicates by person, not patient) +patient_to_person AS ( + SELECT patient_id, person_id + FROM OLIDS_COMMON.PATIENT_PERSON + WHERE patient_id IS NOT NULL AND person_id IS NOT NULL +), + +-- Step 4: Look up concept IDs for 'Regular' episode type and 'Left' status +episode_type_regular AS ( + SELECT source_code_id + FROM OLIDS_TERMINOLOGY.CONCEPT_MAP + WHERE source_code = 'Regular' +), + +episode_status_left AS ( + SELECT source_code_id + FROM OLIDS_TERMINOLOGY.CONCEPT_MAP + WHERE source_code = 'Left' +), + +-- Step 5: Filter to active, valid registration episodes as of the snapshot date +filtered_episodes AS ( + SELECT + eoc.id AS episode_id, + ptp.person_id, + eoc.record_owner_organisation_code AS practice_code, + eoc.organisation_id, + eoc.episode_of_care_start_date + FROM OLIDS_COMMON.EPISODE_OF_CARE eoc + INNER JOIN patient_death_dates pdd ON eoc.patient_id = pdd.patient_id + INNER JOIN patient_to_person ptp ON eoc.patient_id = ptp.patient_id + INNER JOIN episode_type_regular etr ON eoc.episode_type_source_concept_id = etr.source_code_id + LEFT JOIN episode_status_left esl ON eoc.episode_status_source_concept_id = esl.source_code_id + WHERE COALESCE(eoc.lds_is_deleted, FALSE) = FALSE + AND eoc.lds_start_date_time IS NOT NULL + AND eoc.episode_of_care_start_date IS NOT NULL + AND eoc.patient_id IS NOT NULL + AND eoc.organisation_id IS NOT NULL + -- Exclude Left episodes with no end date (data quality issue) + AND NOT (esl.source_code_id IS NOT NULL AND eoc.episode_of_care_end_date IS NULL) + -- Episode started on or before snapshot + AND eoc.episode_of_care_start_date <= $snapshot_date::DATE + -- Episode still active: not ended, or end_date after snapshot, or end_date < start_date (bad data, treat as active) + AND ( + eoc.episode_of_care_end_date IS NULL + OR eoc.episode_of_care_end_date > $snapshot_date::DATE + OR eoc.episode_of_care_end_date < eoc.episode_of_care_start_date + ) + -- Patient alive as of snapshot + AND (pdd.is_deceased = FALSE OR pdd.death_date_approx IS NULL OR pdd.death_date_approx > $snapshot_date::DATE) +), + +-- Step 6: One registration per person per practice (latest episode wins) +deduplicated_registrations AS ( + SELECT person_id, practice_code + FROM filtered_episodes + QUALIFY ROW_NUMBER() OVER ( + PARTITION BY person_id, organisation_id + ORDER BY episode_of_care_start_date DESC, episode_id DESC + ) = 1 +), + +-- Step 7: Count distinct persons per practice +olids_counts AS ( + SELECT practice_code, COUNT(DISTINCT person_id) AS olids_count + FROM deduplicated_registrations + GROUP BY practice_code +), + +-- Step 8: PDS registrations - count per practice using merged NHS numbers +-- PDS tables are in "Data_Store_Registries"."pds" - change if your ICB differs. +-- Uses temporal BETWEEN filters on business effective dates for point-in-time accuracy. +pds_merged AS ( + SELECT + COALESCE(merger."Pseudo Superseded NHS Number", reg."Pseudo NHS Number") AS merged_sk_patient_id, + reg."Primary Care Provider" AS practice_code + FROM "Data_Store_Registries"."pds"."PDS_Patient_Care_Practice" reg + INNER JOIN icb_practices ip ON reg."Primary Care Provider" = ip.practice_code + LEFT JOIN "Data_Store_Registries"."pds"."PDS_Person_Merger" merger + ON reg."Pseudo NHS Number" = merger."Pseudo NHS Number" + AND $snapshot_date::DATE BETWEEN merger."Person Merger Business Effective From Date" + AND COALESCE(merger."Person Merger Business Effective To Date", '9999-12-31') + LEFT JOIN "Data_Store_Registries"."pds"."PDS_Person" person + ON reg."Pseudo NHS Number" = person."Pseudo NHS Number" + AND $snapshot_date::DATE BETWEEN person."Person Business Effective From Date" + AND COALESCE(person."Person Business Effective To Date", '9999-12-31') + LEFT JOIN "Data_Store_Registries"."pds"."PDS_Reason_For_Removal" rfr + ON reg."Pseudo NHS Number" = rfr."Pseudo NHS Number" + AND $snapshot_date::DATE BETWEEN rfr."Reason for Removal Business Effective From Date" + AND COALESCE(rfr."Reason for Removal Business Effective To Date", '9999-12-31') + WHERE $snapshot_date::DATE BETWEEN reg."Primary Care Provider Business Effective From Date" + AND COALESCE(reg."Primary Care Provider Business Effective To Date", '9999-12-31') + AND person."Death Status" IS NULL + AND rfr."Pseudo NHS Number" IS NULL +), + +-- Step 9: Count distinct merged NHS numbers per practice +pds_counts AS ( + SELECT practice_code, COUNT(DISTINCT merged_sk_patient_id) AS pds_count + FROM pds_merged + WHERE practice_code IS NOT NULL + GROUP BY practice_code +), + +-- Step 10: Compare OLIDS vs PDS counts per practice +comparison AS ( + SELECT + p.practice_code, + COALESCE(o.olids_count, 0) AS olids_count, + p.pds_count, + ABS(COALESCE(o.olids_count, 0) - p.pds_count) AS abs_diff, + ABS(COALESCE(o.olids_count, 0) - p.pds_count) * 100.0 / p.pds_count AS abs_pct_diff + FROM pds_counts p + LEFT JOIN olids_counts o ON p.practice_code = o.practice_code + WHERE p.pds_count > 0 +), + +summary AS ( + SELECT + COUNT(*) AS total_practices, + SUM(CASE WHEN abs_pct_diff < 1 OR abs_diff < 5 THEN 1 ELSE 0 END) AS pass_strictest, + SUM(CASE WHEN abs_pct_diff < 2 OR abs_diff < 5 THEN 1 ELSE 0 END) AS pass_tight, + SUM(CASE WHEN abs_pct_diff < 5 OR abs_diff < 5 THEN 1 ELSE 0 END) AS pass_loose + FROM comparison +) + +SELECT + 'registration_pds_comparison' AS test_name, + 'Practice Registrations' AS table_name, + pass_strictest || '/' || total_practices || ' practices within 1% or <5 persons of PDS' AS test_subject, + CASE WHEN ROUND(100.0 * pass_strictest / NULLIF(total_practices, 0), 2) >= 100 THEN 'PASS' ELSE 'FAIL' END AS status, + ROUND(100.0 * pass_strictest / NULLIF(total_practices, 0), 2) AS metric_value, + 100.0 AS threshold, + $snapshot_date::DATE AS snapshot_date +FROM summary + +UNION ALL + +SELECT + 'registration_pds_comparison', + 'Practice Registrations', + pass_tight || '/' || total_practices || ' practices within 2% or <5 persons of PDS' AS test_subject, + CASE WHEN ROUND(100.0 * pass_tight / NULLIF(total_practices, 0), 2) >= 100 THEN 'PASS' ELSE 'FAIL' END AS status, + ROUND(100.0 * pass_tight / NULLIF(total_practices, 0), 2) AS metric_value, + 100.0 AS threshold, + $snapshot_date::DATE AS snapshot_date +FROM summary + +UNION ALL + +SELECT + 'registration_pds_comparison', + 'Practice Registrations', + pass_loose || '/' || total_practices || ' practices within 5% or <5 persons of PDS', + CASE WHEN ROUND(100.0 * pass_loose / NULLIF(total_practices, 0), 2) >= 100 THEN 'PASS' ELSE 'FAIL' END, + ROUND(100.0 * pass_loose / NULLIF(total_practices, 0), 2), + 100.0, + $snapshot_date::DATE +FROM summary; diff --git a/OLIDS/Testing/investigations/investigate_column_completeness.sql b/OLIDS/Testing/investigations/investigate_column_completeness.sql new file mode 100644 index 0000000..c3bb24b --- /dev/null +++ b/OLIDS/Testing/investigations/investigate_column_completeness.sql @@ -0,0 +1,57 @@ +/* + Investigation: Column Completeness + Run: Execute directly in Snowsight or VS Code Snowflake extension. + Set the USE DATABASE below to your ICB's OLIDS database. + + Shows NULL counts and rates for every checked column, + ordered by null rate descending to highlight problem areas. + Includes total_rows so you can gauge table size. +*/ + +USE DATABASE "Data_Store_OLIDS_Clinical_Validation"; -- Replace with your ICB's OLIDS database name + +WITH checks AS ( + -- PATIENT (OLIDS_MASKED) + SELECT 'PATIENT' AS table_name, 'id' AS column_name, 0.0 AS threshold, COUNT(*) AS total_rows, SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) AS null_count FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'sk_patient_id', 1.0, COUNT(*), SUM(CASE WHEN sk_patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'birth_year', 1.0, COUNT(*), SUM(CASE WHEN birth_year IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'birth_month', 1.0, COUNT(*), SUM(CASE WHEN birth_month IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'gender_concept_id', 1.0, COUNT(*), SUM(CASE WHEN gender_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + + -- PATIENT_ADDRESS (OLIDS_MASKED) + UNION ALL SELECT 'PATIENT_ADDRESS', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS + UNION ALL SELECT 'PATIENT_ADDRESS', 'address_type_concept_id', 1.0, COUNT(*), SUM(CASE WHEN address_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS + UNION ALL SELECT 'PATIENT_ADDRESS', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS + + -- PATIENT_CONTACT (OLIDS_MASKED) + UNION ALL SELECT 'PATIENT_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT + UNION ALL SELECT 'PATIENT_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT + + -- PATIENT_UPRN (OLIDS_MASKED) + UNION ALL SELECT 'PATIENT_UPRN', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_UPRN + UNION ALL SELECT 'PATIENT_UPRN', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_UPRN + + -- EPISODE_OF_CARE (OLIDS_COMMON) + UNION ALL SELECT 'EPISODE_OF_CARE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'patient_id', 1.0, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_of_care_start_date', 1.0, COUNT(*), SUM(CASE WHEN episode_of_care_start_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_type_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN episode_type_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_status_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN episode_status_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE +) + +SELECT + table_name, + column_name, + total_rows, + null_count, + CASE WHEN total_rows = 0 THEN NULL ELSE ROUND(100.0 * null_count / total_rows, 4) END AS null_pct, + threshold AS max_null_pct, + CASE + WHEN total_rows = 0 THEN 'EMPTY TABLE' + WHEN ROUND(100.0 * null_count / total_rows, 4) <= threshold THEN 'PASS' + ELSE 'FAIL' + END AS status +FROM checks +ORDER BY null_pct DESC NULLS LAST, table_name, column_name; diff --git a/OLIDS/Testing/investigations/investigate_concept_mapping.sql b/OLIDS/Testing/investigations/investigate_concept_mapping.sql new file mode 100644 index 0000000..2ec58f2 --- /dev/null +++ b/OLIDS/Testing/investigations/investigate_concept_mapping.sql @@ -0,0 +1,124 @@ +/* + Investigation: Concept Mapping + Run: Execute directly in Snowsight or VS Code Snowflake extension. + Set the USE DATABASE below to your ICB's OLIDS database. + + For each concept field that has unmapped values, lists the distinct + unmapped concept IDs with their row counts. +*/ + +USE DATABASE "Data_Store_OLIDS_Clinical_Validation"; -- Replace with your ICB's OLIDS database name + +-- Unmapped concepts per table/field with row counts +WITH unmapped AS ( + SELECT 'OBSERVATION' AS table_name, 'observation_source_concept_id' AS concept_field, + base.observation_source_concept_id AS concept_id, COUNT(*) AS row_count + FROM OLIDS_COMMON.OBSERVATION base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.observation_source_concept_id = cm.source_code_id + WHERE base.observation_source_concept_id IS NOT NULL AND cm.source_code_id IS NULL + GROUP BY base.observation_source_concept_id + + UNION ALL + SELECT 'OBSERVATION', 'result_value_units_concept_id', + base.result_value_units_concept_id, COUNT(*) + FROM OLIDS_COMMON.OBSERVATION base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.result_value_units_concept_id = cm.source_code_id + WHERE base.result_value_units_concept_id IS NOT NULL AND cm.source_code_id IS NULL + GROUP BY base.result_value_units_concept_id + + UNION ALL + SELECT 'MEDICATION_STATEMENT', 'medication_statement_source_concept_id', + base.medication_statement_source_concept_id, COUNT(*) + FROM OLIDS_COMMON.MEDICATION_STATEMENT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.medication_statement_source_concept_id = cm.source_code_id + WHERE base.medication_statement_source_concept_id IS NOT NULL AND cm.source_code_id IS NULL + GROUP BY base.medication_statement_source_concept_id + + UNION ALL + SELECT 'MEDICATION_STATEMENT', 'authorisation_type_concept_id', + base.authorisation_type_concept_id, COUNT(*) + FROM OLIDS_COMMON.MEDICATION_STATEMENT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.authorisation_type_concept_id = cm.source_code_id + WHERE base.authorisation_type_concept_id IS NOT NULL AND cm.source_code_id IS NULL + GROUP BY base.authorisation_type_concept_id + + UNION ALL + SELECT 'MEDICATION_ORDER', 'medication_order_source_concept_id', + base.medication_order_source_concept_id, COUNT(*) + FROM OLIDS_COMMON.MEDICATION_ORDER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.medication_order_source_concept_id = cm.source_code_id + WHERE base.medication_order_source_concept_id IS NOT NULL AND cm.source_code_id IS NULL + GROUP BY base.medication_order_source_concept_id + + UNION ALL + SELECT 'DIAGNOSTIC_ORDER', 'result_value_units_concept_id', + base.result_value_units_concept_id, COUNT(*) + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.result_value_units_concept_id = cm.source_code_id + WHERE base.result_value_units_concept_id IS NOT NULL AND cm.source_code_id IS NULL + GROUP BY base.result_value_units_concept_id + + UNION ALL + SELECT 'PROCEDURE_REQUEST', 'procedure_request_source_concept_id', + base.procedure_request_source_concept_id, COUNT(*) + FROM OLIDS_COMMON.PROCEDURE_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.procedure_request_source_concept_id = cm.source_code_id + WHERE base.procedure_request_source_concept_id IS NOT NULL AND cm.source_code_id IS NULL + GROUP BY base.procedure_request_source_concept_id + + UNION ALL + SELECT 'PROCEDURE_REQUEST', 'status_concept_id', + base.status_concept_id, COUNT(*) + FROM OLIDS_COMMON.PROCEDURE_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.status_concept_id = cm.source_code_id + WHERE base.status_concept_id IS NOT NULL AND cm.source_code_id IS NULL + GROUP BY base.status_concept_id + + UNION ALL + SELECT 'REFERRAL_REQUEST', 'referral_request_priority_concept_id', + base.referral_request_priority_concept_id, COUNT(*) + FROM OLIDS_COMMON.REFERRAL_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_priority_concept_id = cm.source_code_id + WHERE base.referral_request_priority_concept_id IS NOT NULL AND cm.source_code_id IS NULL + GROUP BY base.referral_request_priority_concept_id + + UNION ALL + SELECT 'REFERRAL_REQUEST', 'referral_request_type_concept_id', + base.referral_request_type_concept_id, COUNT(*) + FROM OLIDS_COMMON.REFERRAL_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_type_concept_id = cm.source_code_id + WHERE base.referral_request_type_concept_id IS NOT NULL AND cm.source_code_id IS NULL + GROUP BY base.referral_request_type_concept_id + + UNION ALL + SELECT 'ENCOUNTER', 'encounter_source_concept_id', + base.encounter_source_concept_id, COUNT(*) + FROM OLIDS_COMMON.ENCOUNTER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.encounter_source_concept_id = cm.source_code_id + WHERE base.encounter_source_concept_id IS NOT NULL AND cm.source_code_id IS NULL + GROUP BY base.encounter_source_concept_id + + UNION ALL + SELECT 'ALLERGY_INTOLERANCE', 'allergy_intolerance_source_concept_id', + base.allergy_intolerance_source_concept_id, COUNT(*) + FROM OLIDS_COMMON.ALLERGY_INTOLERANCE base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.allergy_intolerance_source_concept_id = cm.source_code_id + WHERE base.allergy_intolerance_source_concept_id IS NOT NULL AND cm.source_code_id IS NULL + GROUP BY base.allergy_intolerance_source_concept_id + + UNION ALL + SELECT 'APPOINTMENT', 'booking_method_concept_id', + base.booking_method_concept_id, COUNT(*) + FROM OLIDS_COMMON.APPOINTMENT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.booking_method_concept_id = cm.source_code_id + WHERE base.booking_method_concept_id IS NOT NULL AND cm.source_code_id IS NULL + GROUP BY base.booking_method_concept_id +) + +SELECT + table_name, + concept_field, + concept_id, + row_count +FROM unmapped +ORDER BY table_name, concept_field, row_count DESC; diff --git a/OLIDS/Testing/investigations/investigate_data_freshness.sql b/OLIDS/Testing/investigations/investigate_data_freshness.sql new file mode 100644 index 0000000..dd9896a --- /dev/null +++ b/OLIDS/Testing/investigations/investigate_data_freshness.sql @@ -0,0 +1,79 @@ +/* + Investigation: Data Freshness + Run: Execute directly in Snowsight or VS Code Snowflake extension. + Set the USE DATABASE below to your ICB's OLIDS database. + + Shows per-org, per-table freshness: last date_recorded and days since. + Ordered by stalest first to identify which orgs are behind. +*/ + +USE DATABASE "Data_Store_OLIDS_Clinical_Validation"; -- Replace with your ICB's OLIDS database name + +SET freshness_days = 5; + +WITH org_freshness AS ( + SELECT 'OBSERVATION' AS table_name, record_owner_organisation_code AS org_code, + MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END) AS last_date_recorded, + DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) AS days_since + FROM OLIDS_COMMON.OBSERVATION WHERE record_owner_organisation_code IS NOT NULL + GROUP BY record_owner_organisation_code + + UNION ALL + SELECT 'ENCOUNTER', record_owner_organisation_code, + MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), + DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) + FROM OLIDS_COMMON.ENCOUNTER WHERE record_owner_organisation_code IS NOT NULL + GROUP BY record_owner_organisation_code + + UNION ALL + SELECT 'MEDICATION_ORDER', record_owner_organisation_code, + MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), + DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) + FROM OLIDS_COMMON.MEDICATION_ORDER WHERE record_owner_organisation_code IS NOT NULL + GROUP BY record_owner_organisation_code + + UNION ALL + SELECT 'MEDICATION_STATEMENT', record_owner_organisation_code, + MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), + DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) + FROM OLIDS_COMMON.MEDICATION_STATEMENT WHERE record_owner_organisation_code IS NOT NULL + GROUP BY record_owner_organisation_code + + UNION ALL + SELECT 'DIAGNOSTIC_ORDER', record_owner_organisation_code, + MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), + DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER WHERE record_owner_organisation_code IS NOT NULL + GROUP BY record_owner_organisation_code + + UNION ALL + SELECT 'ALLERGY_INTOLERANCE', record_owner_organisation_code, + MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), + DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) + FROM OLIDS_COMMON.ALLERGY_INTOLERANCE WHERE record_owner_organisation_code IS NOT NULL + GROUP BY record_owner_organisation_code + + UNION ALL + SELECT 'PROCEDURE_REQUEST', record_owner_organisation_code, + MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), + DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) + FROM OLIDS_COMMON.PROCEDURE_REQUEST WHERE record_owner_organisation_code IS NOT NULL + GROUP BY record_owner_organisation_code + + UNION ALL + SELECT 'REFERRAL_REQUEST', record_owner_organisation_code, + MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), + DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) + FROM OLIDS_COMMON.REFERRAL_REQUEST WHERE record_owner_organisation_code IS NOT NULL + GROUP BY record_owner_organisation_code +) + +SELECT + table_name, + org_code, + last_date_recorded, + days_since, + CASE WHEN days_since <= $freshness_days THEN 'FRESH' ELSE 'STALE' END AS freshness_status +FROM org_freshness +WHERE last_date_recorded IS NOT NULL +ORDER BY days_since DESC, table_name, org_code; diff --git a/OLIDS/Testing/investigations/investigate_referential_integrity.sql b/OLIDS/Testing/investigations/investigate_referential_integrity.sql new file mode 100644 index 0000000..bc3f8c3 --- /dev/null +++ b/OLIDS/Testing/investigations/investigate_referential_integrity.sql @@ -0,0 +1,102 @@ +/* + Investigation: Referential Integrity + Run: Execute directly in Snowsight or VS Code Snowflake extension. + Set the USE DATABASE below to your ICB's OLIDS database. + + For the most common FK failures, shows orphaned FK values + with their row counts. Helps identify whether orphans are + systematic (few IDs, many rows) or scattered. + Add more FK checks as needed following the same pattern. +*/ + +USE DATABASE "Data_Store_OLIDS_Clinical_Validation"; -- Replace with your ICB's OLIDS database name + +-- ENCOUNTER -> PATIENT: orphaned patient_ids +SELECT 'ENCOUNTER' AS child_table, 'patient_id' AS fk_column, 'PATIENT' AS parent_table, + c.patient_id AS orphaned_value, COUNT(*) AS row_count +FROM OLIDS_COMMON.ENCOUNTER c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +WHERE c.patient_id IS NOT NULL AND p.id IS NULL +GROUP BY c.patient_id + +UNION ALL + +-- OBSERVATION -> PATIENT +SELECT 'OBSERVATION', 'patient_id', 'PATIENT', + c.patient_id, COUNT(*) +FROM OLIDS_COMMON.OBSERVATION c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +WHERE c.patient_id IS NOT NULL AND p.id IS NULL +GROUP BY c.patient_id + +UNION ALL + +-- OBSERVATION -> ENCOUNTER +SELECT 'OBSERVATION', 'encounter_id', 'ENCOUNTER', + c.encounter_id, COUNT(*) +FROM OLIDS_COMMON.OBSERVATION c +LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id +WHERE c.encounter_id IS NOT NULL AND p.id IS NULL +GROUP BY c.encounter_id + +UNION ALL + +-- MEDICATION_ORDER -> PATIENT +SELECT 'MEDICATION_ORDER', 'patient_id', 'PATIENT', + c.patient_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_ORDER c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +WHERE c.patient_id IS NOT NULL AND p.id IS NULL +GROUP BY c.patient_id + +UNION ALL + +-- MEDICATION_ORDER -> ENCOUNTER +SELECT 'MEDICATION_ORDER', 'encounter_id', 'ENCOUNTER', + c.encounter_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_ORDER c +LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id +WHERE c.encounter_id IS NOT NULL AND p.id IS NULL +GROUP BY c.encounter_id + +UNION ALL + +-- MEDICATION_STATEMENT -> PATIENT +SELECT 'MEDICATION_STATEMENT', 'patient_id', 'PATIENT', + c.patient_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_STATEMENT c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +WHERE c.patient_id IS NOT NULL AND p.id IS NULL +GROUP BY c.patient_id + +UNION ALL + +-- EPISODE_OF_CARE -> PATIENT +SELECT 'EPISODE_OF_CARE', 'patient_id', 'PATIENT', + c.patient_id, COUNT(*) +FROM OLIDS_COMMON.EPISODE_OF_CARE c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +WHERE c.patient_id IS NOT NULL AND p.id IS NULL +GROUP BY c.patient_id + +UNION ALL + +-- APPOINTMENT -> PATIENT +SELECT 'APPOINTMENT', 'patient_id', 'PATIENT', + c.patient_id, COUNT(*) +FROM OLIDS_COMMON.APPOINTMENT c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +WHERE c.patient_id IS NOT NULL AND p.id IS NULL +GROUP BY c.patient_id + +UNION ALL + +-- SCHEDULE_PRACTITIONER -> SCHEDULE +SELECT 'SCHEDULE_PRACTITIONER', 'schedule_id', 'SCHEDULE', + c.schedule_id, COUNT(*) +FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER c +LEFT JOIN OLIDS_COMMON.SCHEDULE p ON c.schedule_id = p.id +WHERE c.schedule_id IS NOT NULL AND p.id IS NULL +GROUP BY c.schedule_id + +ORDER BY child_table, fk_column, row_count DESC; diff --git a/OLIDS/Testing/investigations/investigate_registration_pds.sql b/OLIDS/Testing/investigations/investigate_registration_pds.sql new file mode 100644 index 0000000..4a2a9da --- /dev/null +++ b/OLIDS/Testing/investigations/investigate_registration_pds.sql @@ -0,0 +1,148 @@ +/* + Investigation: Registration PDS Comparison + Run: Execute directly in Snowsight or VS Code Snowflake extension. + Set the USE DATABASE below to your ICB's OLIDS database. + + Shows per-practice comparison of OLIDS vs PDS registration counts. + Reuses the same methodology as test_registration_pds.sql. + Ordered by largest absolute % difference to highlight problem practices. +*/ + +USE DATABASE "Data_Store_OLIDS_Clinical_Validation"; -- Replace with your ICB's OLIDS database name + +SET snapshot_date = LAST_DAY(DATEADD(MONTH, -1, CURRENT_DATE)); + +-- Practice codes derived from EPISODE_OF_CARE (only practices with actual data) +WITH icb_practices AS ( + SELECT DISTINCT record_owner_organisation_code AS practice_code + FROM OLIDS_COMMON.EPISODE_OF_CARE + WHERE record_owner_organisation_code IS NOT NULL +), + +eligible_patients AS ( + SELECT id AS patient_id, sk_patient_id, death_year, death_month + FROM OLIDS_MASKED.PATIENT + WHERE sk_patient_id IS NOT NULL + AND is_spine_sensitive = FALSE + AND is_confidential = FALSE + AND is_dummy_patient = FALSE +), + +patient_death_dates AS ( + SELECT + patient_id, sk_patient_id, + death_year IS NOT NULL AS is_deceased, + CASE + WHEN death_year IS NOT NULL AND death_month IS NOT NULL + THEN DATEADD(DAY, + FLOOR(DAY(LAST_DAY(TO_DATE(death_year || '-' || LPAD(death_month, 2, '0') || '-01'))) / 2), + TO_DATE(death_year || '-' || LPAD(death_month, 2, '0') || '-01')) + WHEN death_year IS NOT NULL THEN TO_DATE(death_year || '-07-01') + ELSE NULL + END AS death_date_approx + FROM eligible_patients +), + +patient_to_person AS ( + SELECT patient_id, person_id + FROM OLIDS_COMMON.PATIENT_PERSON + WHERE patient_id IS NOT NULL AND person_id IS NOT NULL +), + +episode_type_regular AS ( + SELECT source_code_id FROM OLIDS_TERMINOLOGY.CONCEPT_MAP WHERE source_code = 'Regular' +), + +episode_status_left AS ( + SELECT source_code_id FROM OLIDS_TERMINOLOGY.CONCEPT_MAP WHERE source_code = 'Left' +), + +filtered_episodes AS ( + SELECT eoc.id AS episode_id, ptp.person_id, + eoc.record_owner_organisation_code AS practice_code, + eoc.organisation_id, eoc.episode_of_care_start_date + FROM OLIDS_COMMON.EPISODE_OF_CARE eoc + INNER JOIN patient_death_dates pdd ON eoc.patient_id = pdd.patient_id + INNER JOIN patient_to_person ptp ON eoc.patient_id = ptp.patient_id + INNER JOIN episode_type_regular etr ON eoc.episode_type_source_concept_id = etr.source_code_id + LEFT JOIN episode_status_left esl ON eoc.episode_status_source_concept_id = esl.source_code_id + WHERE COALESCE(eoc.lds_is_deleted, FALSE) = FALSE + AND eoc.lds_start_date_time IS NOT NULL + AND eoc.episode_of_care_start_date IS NOT NULL + AND eoc.patient_id IS NOT NULL + AND eoc.organisation_id IS NOT NULL + AND NOT (esl.source_code_id IS NOT NULL AND eoc.episode_of_care_end_date IS NULL) + AND eoc.episode_of_care_start_date <= $snapshot_date::DATE + AND (eoc.episode_of_care_end_date IS NULL + OR eoc.episode_of_care_end_date > $snapshot_date::DATE + OR eoc.episode_of_care_end_date < eoc.episode_of_care_start_date) + AND (pdd.is_deceased = FALSE OR pdd.death_date_approx IS NULL OR pdd.death_date_approx > $snapshot_date::DATE) +), + +deduplicated_registrations AS ( + SELECT person_id, practice_code + FROM filtered_episodes + QUALIFY ROW_NUMBER() OVER ( + PARTITION BY person_id, organisation_id + ORDER BY episode_of_care_start_date DESC, episode_id DESC + ) = 1 +), + +olids_counts AS ( + SELECT practice_code, COUNT(DISTINCT person_id) AS olids_count + FROM deduplicated_registrations + GROUP BY practice_code +), + +pds_merged AS ( + SELECT + COALESCE(merger."Pseudo Superseded NHS Number", reg."Pseudo NHS Number") AS merged_sk_patient_id, + reg."Primary Care Provider" AS practice_code + FROM "Data_Store_Registries"."pds"."PDS_Patient_Care_Practice" reg + INNER JOIN icb_practices ip ON reg."Primary Care Provider" = ip.practice_code + LEFT JOIN "Data_Store_Registries"."pds"."PDS_Person_Merger" merger + ON reg."Pseudo NHS Number" = merger."Pseudo NHS Number" + AND $snapshot_date::DATE BETWEEN merger."Person Merger Business Effective From Date" + AND COALESCE(merger."Person Merger Business Effective To Date", '9999-12-31') + LEFT JOIN "Data_Store_Registries"."pds"."PDS_Person" person + ON reg."Pseudo NHS Number" = person."Pseudo NHS Number" + AND $snapshot_date::DATE BETWEEN person."Person Business Effective From Date" + AND COALESCE(person."Person Business Effective To Date", '9999-12-31') + LEFT JOIN "Data_Store_Registries"."pds"."PDS_Reason_For_Removal" rfr + ON reg."Pseudo NHS Number" = rfr."Pseudo NHS Number" + AND $snapshot_date::DATE BETWEEN rfr."Reason for Removal Business Effective From Date" + AND COALESCE(rfr."Reason for Removal Business Effective To Date", '9999-12-31') + WHERE $snapshot_date::DATE BETWEEN reg."Primary Care Provider Business Effective From Date" + AND COALESCE(reg."Primary Care Provider Business Effective To Date", '9999-12-31') + AND person."Death Status" IS NULL + AND rfr."Pseudo NHS Number" IS NULL +), + +pds_counts AS ( + SELECT practice_code, COUNT(DISTINCT merged_sk_patient_id) AS pds_count + FROM pds_merged + WHERE practice_code IS NOT NULL + GROUP BY practice_code +) + +SELECT + COALESCE(p.practice_code, o.practice_code) AS practice_code, + COALESCE(o.olids_count, 0) AS olids_count, + COALESCE(p.pds_count, 0) AS pds_count, + COALESCE(o.olids_count, 0) - COALESCE(p.pds_count, 0) AS diff, + ABS(COALESCE(o.olids_count, 0) - COALESCE(p.pds_count, 0)) AS abs_diff, + CASE WHEN COALESCE(p.pds_count, 0) > 0 + THEN ROUND(ABS(COALESCE(o.olids_count, 0) - p.pds_count) * 100.0 / p.pds_count, 2) + ELSE NULL + END AS abs_pct_diff, + CASE + WHEN p.pds_count IS NULL THEN 'OLIDS ONLY' + WHEN o.olids_count IS NULL THEN 'PDS ONLY' + WHEN ABS(COALESCE(o.olids_count, 0) - p.pds_count) * 100.0 / p.pds_count < 2 OR ABS(COALESCE(o.olids_count, 0) - p.pds_count) < 5 THEN 'PASS (<2%)' + WHEN ABS(COALESCE(o.olids_count, 0) - p.pds_count) * 100.0 / p.pds_count < 5 OR ABS(COALESCE(o.olids_count, 0) - p.pds_count) < 5 THEN 'PASS (<5%)' + ELSE 'FAIL' + END AS status, + $snapshot_date::DATE AS snapshot_date +FROM pds_counts p +FULL OUTER JOIN olids_counts o ON p.practice_code = o.practice_code +ORDER BY abs_pct_diff DESC NULLS LAST; diff --git a/OLIDS/Testing/pyproject.toml b/OLIDS/Testing/pyproject.toml new file mode 100644 index 0000000..918870d --- /dev/null +++ b/OLIDS/Testing/pyproject.toml @@ -0,0 +1,10 @@ +[project] +name = "olids-testing" +version = "0.1.0" +description = "OLIDS data quality tests" +requires-python = ">=3.9" +dependencies = [ + "snowflake-snowpark-python", + "snowflake-connector-python[secure-local-storage,pandas]", + "python-dotenv", +] \ No newline at end of file diff --git a/OLIDS/Testing/run_tests.py b/OLIDS/Testing/run_tests.py new file mode 100644 index 0000000..c6161a0 --- /dev/null +++ b/OLIDS/Testing/run_tests.py @@ -0,0 +1,312 @@ +#!/usr/bin/env python3 +""" +OLIDS Data Quality Test Runner + +Discovers and executes test_*.sql files against Snowflake. +Database context is set from SNOWFLAKE_DATABASE in .env. + +Usage: + uv run run_tests.py + uv run run_tests.py --test test_data_freshness + uv run run_tests.py --verbose +""" + +import os +import sys +import time +import argparse +from pathlib import Path +from datetime import datetime +from dotenv import load_dotenv + +# Load environment variables +load_dotenv() + +# Try to import snowflake connector +try: + from snowflake.snowpark import Session + USE_SNOWPARK = True +except ImportError: + try: + import snowflake.connector + USE_SNOWPARK = False + except ImportError: + print("ERROR: Neither snowflake-snowpark-python nor snowflake-connector-python installed") + sys.exit(1) + + +# Configuration from environment +ACCOUNT = os.getenv('SNOWFLAKE_ACCOUNT') +USER = os.getenv('SNOWFLAKE_USER') +WAREHOUSE = os.getenv('SNOWFLAKE_WAREHOUSE') +ROLE = os.getenv('SNOWFLAKE_ROLE') +DATABASE = os.getenv('SNOWFLAKE_DATABASE') + + +def validate_config(): + """Check that all required env vars are set.""" + missing = [] + for var in ['SNOWFLAKE_ACCOUNT', 'SNOWFLAKE_USER', 'SNOWFLAKE_WAREHOUSE', + 'SNOWFLAKE_ROLE', 'SNOWFLAKE_DATABASE']: + if not os.getenv(var): + missing.append(var) + if missing: + print(f"ERROR: Missing environment variables: {', '.join(missing)}") + print("Run setup.ps1 or copy .env.example to .env and fill in your credentials.") + sys.exit(1) + + +def get_connection(): + """Create Snowflake connection using SSO.""" + connection_params = { + "account": ACCOUNT, + "user": USER, + "authenticator": "externalbrowser", + "warehouse": WAREHOUSE, + "role": ROLE, + } + + if USE_SNOWPARK: + return Session.builder.configs(connection_params).create() + else: + return snowflake.connector.connect(**connection_params) + + +def discover_tests(test_dir: Path, specific_test: str = None) -> list: + """Find all test_*.sql files in the directory.""" + if specific_test: + if not specific_test.endswith('.sql'): + specific_test += '.sql' + test_file = test_dir / specific_test + if test_file.exists(): + return [test_file] + else: + print(f"ERROR: Test file not found: {specific_test}") + sys.exit(1) + + tests = sorted(test_dir.glob("test_*.sql")) + return tests + + +def split_statements(sql: str) -> list: + """Split SQL into individual statements, skipping empty/comment-only ones.""" + statements = [] + for stmt in sql.split(';'): + stmt = stmt.strip() + if not stmt: + continue + # Skip statements where every non-empty line is a -- comment + lines = [l.strip() for l in stmt.split('\n') if l.strip()] + if lines and all(l.startswith('--') for l in lines): + continue + statements.append(stmt) + return statements + + +def execute_test(conn, sql_file: Path, database: str) -> list: + """Execute USE DATABASE then the test SQL, returning result rows as dicts.""" + preamble = f'USE DATABASE "{database}"' + sql = sql_file.read_text(encoding='utf-8') + full_sql = preamble + ';\n' + sql + + statements = split_statements(full_sql) + if not statements: + return [] + + if USE_SNOWPARK: + # Execute each statement; collect results from the last one + for stmt in statements[:-1]: + conn.sql(stmt).collect() + df = conn.sql(statements[-1]).to_pandas() + return df.to_dict('records') + else: + cursor = conn.cursor() + try: + for stmt in statements: + cursor.execute(stmt) + columns = [desc[0] for desc in cursor.description] if cursor.description else [] + rows = cursor.fetchall() + return [dict(zip(columns, row)) for row in rows] + finally: + cursor.close() + + +# Standard columns that every test must return. Any additional columns +# returned by a test SQL file are automatically collected as "details" +# and shown in verbose mode. +STANDARD_COLUMNS = {'TEST_NAME', 'TABLE_NAME', 'TEST_SUBJECT', 'STATUS', + 'METRIC_VALUE', 'THRESHOLD'} + + +def _extra_columns(row: dict) -> dict: + """Return non-standard columns from a result row.""" + return {k: v for k, v in row.items() if k not in STANDARD_COLUMNS} + + +def print_results(all_results: dict, durations: dict = None, verbose: bool = False): + """Print formatted test results to console.""" + total_tests = 0 + total_pass = 0 + total_fail = 0 + total_warn = 0 + durations = durations or {} + + print("\n" + "=" * 80) + print("OLIDS DATA QUALITY TEST RESULTS") + print("=" * 80) + print(f"Execution time: {datetime.now().strftime('%Y-%m-%d %H:%M:%S')}") + print() + + for test_file, results in all_results.items(): + if not results: + print(f"\n {test_file}: No results returned") + continue + + # Count by status + pass_count = sum(1 for r in results if r.get('STATUS') == 'PASS') + fail_count = sum(1 for r in results if r.get('STATUS') == 'FAIL') + warn_count = sum(1 for r in results if r.get('STATUS') == 'WARN') + + total_tests += len(results) + total_pass += pass_count + total_fail += fail_count + total_warn += warn_count + + # Test header + status_icon = "PASS" if fail_count == 0 else "FAIL" + dur = f" ({durations[test_file]:.1f}s)" if test_file in durations else "" + print(f"\n[{status_icon}] {test_file}{dur}") + print(f" PASS: {pass_count} | FAIL: {fail_count}" + (f" | WARN: {warn_count}" if warn_count else "")) + + # Show failures + failures = [r for r in results if r.get('STATUS') == 'FAIL'] + if failures: + print("\n Failures:") + for f in failures: + table = f.get('TABLE_NAME', 'N/A') + subject = f.get('TEST_SUBJECT', 'N/A') + metric = f.get('METRIC_VALUE', 'N/A') + threshold = f.get('THRESHOLD', 'N/A') + print(f" - {table}.{subject}: {metric}% (threshold: {threshold}%)") + + if verbose: + for k, v in _extra_columns(f).items(): + print(f" {k}: {v}") + + # Show passing results + passes = [r for r in results if r.get('STATUS') == 'PASS'] + if passes and verbose: + print("\n Passed:") + for p in passes: + table = p.get('TABLE_NAME', 'N/A') + subject = p.get('TEST_SUBJECT', 'N/A') + metric = p.get('METRIC_VALUE', 'N/A') + threshold = p.get('THRESHOLD', 'N/A') + print(f" - {table}.{subject}: {metric}% (threshold: {threshold}%)") + for k, v in _extra_columns(p).items(): + print(f" {k}: {v}") + + # Show warnings + warnings = [r for r in results if r.get('STATUS') == 'WARN'] + if warnings: + print("\n Warnings:") + for w in warnings: + table = w.get('TABLE_NAME', 'N/A') + subject = w.get('TEST_SUBJECT', 'N/A') + print(f" - {table}.{subject}") + + # Summary + print("\n" + "=" * 80) + print("SUMMARY") + print("=" * 80) + print(f"Total checks: {total_tests}") + print(f"Passed: {total_pass} ({100*total_pass/total_tests:.1f}%)" if total_tests else "Passed: 0") + print(f"Failed: {total_fail} ({100*total_fail/total_tests:.1f}%)" if total_tests else "Failed: 0") + if total_warn: + print(f"Warnings: {total_warn}") + + overall = "ALL TESTS PASSED" if total_fail == 0 else f"{total_fail} TESTS FAILED" + print(f"\n{overall}") + print("=" * 80) + + return total_fail == 0 + + +def main(): + parser = argparse.ArgumentParser(description='Run OLIDS data quality tests') + parser.add_argument('--dir', '-d', default='data-quality', + help='Test subdirectory (default: data-quality)') + parser.add_argument('--test', '-t', help='Run specific test file only') + parser.add_argument('--verbose', '-v', action='store_true', help='Show detailed output') + args = parser.parse_args() + + validate_config() + + # Find tests + test_dir = Path(__file__).parent / args.dir + if not test_dir.exists(): + print(f"ERROR: Test directory not found: {test_dir}") + sys.exit(1) + + tests = discover_tests(test_dir, args.test) + + if not tests: + print(f"No test files found (test_*.sql) in {test_dir}") + sys.exit(1) + + print(f"Found {len(tests)} test file(s)") + for t in tests: + print(f" - {t.name}") + + # Connect to Snowflake + print("\nConnecting to Snowflake...") + try: + conn = get_connection() + print("Connected successfully") + except Exception as e: + print(f"ERROR: Failed to connect: {e}") + sys.exit(1) + + # Execute tests + all_results = {} + all_durations = {} + pipeline_start = time.time() + try: + for test_file in tests: + print(f"\nExecuting: {test_file.name}...") + test_start = time.time() + try: + results = execute_test(conn, test_file, DATABASE) + duration = time.time() - test_start + all_results[test_file.name] = results + all_durations[test_file.name] = duration + passed = sum(1 for r in results if r.get('STATUS') == 'PASS') + failed = sum(1 for r in results if r.get('STATUS') == 'FAIL') + warned = sum(1 for r in results if r.get('STATUS') == 'WARN') + icon = "PASS" if failed == 0 else "FAIL" + summary = f"[{icon}] {len(results)} checks: {passed} passed, {failed} failed" + if warned: + summary += f", {warned} warnings" + print(f" -> {summary} ({duration:.1f}s)") + except Exception as e: + duration = time.time() - test_start + all_durations[test_file.name] = duration + print(f" -> ERROR: {e} ({duration:.1f}s)") + all_results[test_file.name] = [] + finally: + conn.close() + print("\nConnection closed") + + # Print results + pipeline_duration = time.time() - pipeline_start + all_passed = print_results(all_results, durations=all_durations, verbose=args.verbose) + + print(f"\nTotal duration: {pipeline_duration:.1f}s") + print("=" * 80) + + # Exit code + sys.exit(0 if all_passed else 1) + + +if __name__ == '__main__': + main() diff --git a/OLIDS/Testing/setup.ps1 b/OLIDS/Testing/setup.ps1 new file mode 100644 index 0000000..9a3ff73 --- /dev/null +++ b/OLIDS/Testing/setup.ps1 @@ -0,0 +1,136 @@ +<# +.SYNOPSIS + Sets up the OLIDS testing environment. +.DESCRIPTION + Installs uv (if needed), creates a .env file with Snowflake credentials, + and installs Python dependencies. +#> + +$ErrorActionPreference = "Stop" + +Write-Host "" +Write-Host "OLIDS Testing - Setup" -ForegroundColor Cyan +Write-Host "=====================" -ForegroundColor Cyan +Write-Host "" + +# --- Step 1: Execution policy (process-scoped, no admin needed) --- +Set-ExecutionPolicy -ExecutionPolicy RemoteSigned -Scope Process -Force + +# --- Step 2: Check for uv --- +if (-not (Get-Command uv -ErrorAction SilentlyContinue)) { + Write-Host "uv not found on PATH. Installing..." -ForegroundColor Yellow + Invoke-RestMethod https://astral.sh/uv/install.ps1 | Invoke-Expression + + # Refresh PATH from registry so we pick up the new binary + $machinePath = [Environment]::GetEnvironmentVariable("Path", "Machine") + $userPath = [Environment]::GetEnvironmentVariable("Path", "User") + $env:Path = "$userPath;$machinePath" + + if (-not (Get-Command uv -ErrorAction SilentlyContinue)) { + Write-Host "ERROR: uv installation succeeded but is still not on PATH." -ForegroundColor Red + Write-Host "Close and reopen your terminal, then run this script again." -ForegroundColor Red + exit 1 + } + Write-Host "uv installed successfully." -ForegroundColor Green +} else { + Write-Host "uv found: $(uv --version)" -ForegroundColor Green +} + +# --- Step 3: Snowflake credentials --- +$envFile = Join-Path $PSScriptRoot ".env" +$needsSetup = $true + +if (Test-Path $envFile) { + # Parse existing values + $existing = @{} + Get-Content $envFile | ForEach-Object { + if ($_ -match '^([^=]+)=(.*)$') { + $existing[$Matches[1]] = $Matches[2] + } + } + + Write-Host "" + Write-Host "Existing Snowflake configuration found:" -ForegroundColor Cyan + foreach ($key in @('SNOWFLAKE_ACCOUNT', 'SNOWFLAKE_USER', 'SNOWFLAKE_WAREHOUSE', 'SNOWFLAKE_ROLE', 'SNOWFLAKE_DATABASE')) { + $val = $existing[$key] + if ($val) { + Write-Host " $key = $val" -ForegroundColor White + } + } + Write-Host "" + $change = Read-Host "Keep these settings? (Y/n)" + if ($change -eq "n") { + Remove-Item $envFile + } else { + Write-Host "Keeping existing credentials." -ForegroundColor Green + $needsSetup = $false + } +} + +if ($needsSetup -and -not (Test-Path $envFile)) { + Write-Host "" + Write-Host "Snowflake Connection Setup" -ForegroundColor Cyan + Write-Host "--------------------------" -ForegroundColor Cyan + Write-Host "" + + Write-Host "Account identifier" -ForegroundColor White + Write-Host " Tip: right-click to paste" -ForegroundColor Yellow + Write-Host " In Snowflake (https://app.snowflake.com/), click your profile (bottom-left)" -ForegroundColor DarkGray + Write-Host " and copy the 'Account identifier' value from Account Details." -ForegroundColor DarkGray + Write-Host " Format: XXXXXXX-XXX (e.g. ATKJNCU-NCL)" -ForegroundColor DarkGray + $account = Read-Host " SNOWFLAKE_ACCOUNT" + + Write-Host "" + Write-Host "Username (your Snowflake login, usually your NHS email)" -ForegroundColor DarkGray + $user = Read-Host " SNOWFLAKE_USER" + + Write-Host "" + Write-Host "Warehouse name" -ForegroundColor DarkGray + Write-Host " The compute warehouse to run queries against." -ForegroundColor DarkGray + $warehouse = Read-Host " SNOWFLAKE_WAREHOUSE" + + Write-Host "" + Write-Host "Role name" -ForegroundColor DarkGray + Write-Host " Your Snowflake role with read access to the OLIDS schemas." -ForegroundColor DarkGray + $role = Read-Host " SNOWFLAKE_ROLE" + + Write-Host "" + Write-Host "Database name" -ForegroundColor DarkGray + Write-Host " The ICB-specific OLIDS database (e.g. Data_Store_OLIDS_Alpha)." -ForegroundColor DarkGray + $database = Read-Host " SNOWFLAKE_DATABASE" + + # Write .env + @" +SNOWFLAKE_ACCOUNT=$account +SNOWFLAKE_USER=$user +SNOWFLAKE_WAREHOUSE=$warehouse +SNOWFLAKE_ROLE=$role +SNOWFLAKE_DATABASE=$database +"@ | Set-Content -Path $envFile -Encoding UTF8 + + Write-Host "" + Write-Host "Credentials saved to $envFile" -ForegroundColor Green +} + +# --- Step 4: Install/update dependencies --- +Write-Host "" +Write-Host "Installing Python dependencies..." -ForegroundColor Cyan +Push-Location $PSScriptRoot +try { + uv lock --upgrade + uv sync + Write-Host "Dependencies installed." -ForegroundColor Green +} finally { + Pop-Location +} + +# --- Done --- +Write-Host "" +Write-Host "Setup complete." -ForegroundColor Green +Write-Host "" +Write-Host "Run tests with:" -ForegroundColor White +Write-Host " cd $PSScriptRoot" -ForegroundColor Yellow +Write-Host " uv run run_tests.py" -ForegroundColor Yellow +Write-Host "" +Write-Host "Note: The first run will open a browser tab for Snowflake SSO authentication." -ForegroundColor DarkGray +Write-Host "" diff --git a/OLIDS/Testing/uv.lock b/OLIDS/Testing/uv.lock new file mode 100644 index 0000000..8e1fed2 --- /dev/null +++ b/OLIDS/Testing/uv.lock @@ -0,0 +1,1328 @@ +version = 1 +revision = 3 +requires-python = ">=3.9" +resolution-markers = [ + "python_full_version >= '3.13'", + "python_full_version == '3.12.*'", + "python_full_version == '3.11.*'", + "python_full_version == '3.10.*'", + "python_full_version < '3.10'", +] + +[[package]] +name = "asn1crypto" +version = "1.5.1" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/de/cf/d547feed25b5244fcb9392e288ff9fdc3280b10260362fc45d37a798a6ee/asn1crypto-1.5.1.tar.gz", hash = "sha256:13ae38502be632115abf8a24cbe5f4da52e3b5231990aff31123c805306ccb9c", size = 121080, upload-time = "2022-03-15T14:46:52.889Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/c9/7f/09065fd9e27da0eda08b4d6897f1c13535066174cc023af248fc2a8d5e5a/asn1crypto-1.5.1-py2.py3-none-any.whl", hash = "sha256:db4e40728b728508912cbb3d44f19ce188f218e9eba635821bb4b68564f8fd67", size = 105045, upload-time = "2022-03-15T14:46:51.055Z" }, +] + +[[package]] +name = "backports-tarfile" +version = "1.2.0" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/86/72/cd9b395f25e290e633655a100af28cb253e4393396264a98bd5f5951d50f/backports_tarfile-1.2.0.tar.gz", hash = "sha256:d75e02c268746e1b8144c278978b6e98e85de6ad16f8e4b0844a154557eca991", size = 86406, upload-time = "2024-05-28T17:01:54.731Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/b9/fa/123043af240e49752f1c4bd24da5053b6bd00cad78c2be53c0d1e8b975bc/backports.tarfile-1.2.0-py3-none-any.whl", hash = "sha256:77e284d754527b01fb1e6fa8a1afe577858ebe4e9dad8919e34c862cb399bc34", size = 30181, upload-time = "2024-05-28T17:01:53.112Z" }, +] + +[[package]] +name = "boto3" +version = "1.42.46" +source = { registry = "https://pypi.org/simple" } +dependencies = [ + { name = "botocore" }, + { name = "jmespath" }, + { name = "s3transfer" }, +] +sdist = { url = "https://files.pythonhosted.org/packages/d9/87/1ccd436a6815c18107aa74aa2b7b2745dc5a1db83cf58afc591df2755775/boto3-1.42.46.tar.gz", hash = "sha256:c8c82ab34dd8d2d4d93a562d0e75fca164efa644651d3ccddb0f4aa88a481b38", size = 112795, upload-time = "2026-02-10T20:38:10.784Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/ce/41/978d749a6604bf93e05e8be56db07eb1402ffe576e1bb9b65aa391ebcb73/boto3-1.42.46-py3-none-any.whl", hash = "sha256:679cf4930e559621653bbd1439cf6e93b138cbaf46e36e5d7d95319999b7a356", size = 140606, upload-time = "2026-02-10T20:38:08.175Z" }, +] + +[[package]] +name = "botocore" +version = "1.42.46" +source = { registry = "https://pypi.org/simple" } +dependencies = [ + { name = "jmespath" }, + { name = "python-dateutil" }, + { name = "urllib3" }, +] +sdist = { url = "https://files.pythonhosted.org/packages/86/2d/6f6101f567a69c3b2ebe3f1f81bfd56eda9d5f6f466d0d919293499ab050/botocore-1.42.46.tar.gz", hash = "sha256:fc290b33aba6e271f627c4f46b8bcebfa1a94e19157d396732da417404158c01", size = 14948751, upload-time = "2026-02-10T20:37:58.663Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/a0/88/5c2f4e65fe8dba7709a219b768e5ac89a112c6dde9527a5009cb82ee9124/botocore-1.42.46-py3-none-any.whl", hash = "sha256:f7459fcf586f38a3b0a242a172d3332141c770a3f5767bbb21e79d810db95d75", size = 14622519, upload-time = "2026-02-10T20:37:54.223Z" }, +] + +[[package]] +name = "certifi" +version = "2026.1.4" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/e0/2d/a891ca51311197f6ad14a7ef42e2399f36cf2f9bd44752b3dc4eab60fdc5/certifi-2026.1.4.tar.gz", hash = "sha256:ac726dd470482006e014ad384921ed6438c457018f4b3d204aea4281258b2120", size = 154268, upload-time = "2026-01-04T02:42:41.825Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/e6/ad/3cc14f097111b4de0040c83a525973216457bbeeb63739ef1ed275c1c021/certifi-2026.1.4-py3-none-any.whl", hash = "sha256:9943707519e4add1115f44c2bc244f782c0249876bf51b6599fee1ffbedd685c", size = 152900, upload-time = "2026-01-04T02:42:40.15Z" }, +] + +[[package]] +name = "cffi" +version = "2.0.0" +source = { registry = "https://pypi.org/simple" } +dependencies = [ + { name = "pycparser", version = "2.23", source = { registry = "https://pypi.org/simple" }, marker = "python_full_version < '3.10' and implementation_name != 'PyPy'" }, + { name = "pycparser", version = "3.0", source = { registry = "https://pypi.org/simple" }, marker = "python_full_version >= '3.10' and implementation_name != 'PyPy'" }, +] +sdist = { url = "https://files.pythonhosted.org/packages/eb/56/b1ba7935a17738ae8453301356628e8147c79dbb825bcbc73dc7401f9846/cffi-2.0.0.tar.gz", hash = "sha256:44d1b5909021139fe36001ae048dbdde8214afa20200eda0f64c068cac5d5529", size = 523588, upload-time = "2025-09-08T23:24:04.541Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/93/d7/516d984057745a6cd96575eea814fe1edd6646ee6efd552fb7b0921dec83/cffi-2.0.0-cp310-cp310-macosx_10_13_x86_64.whl", hash = "sha256:0cf2d91ecc3fcc0625c2c530fe004f82c110405f101548512cce44322fa8ac44", size = 184283, upload-time = "2025-09-08T23:22:08.01Z" }, + { url = "https://files.pythonhosted.org/packages/9e/84/ad6a0b408daa859246f57c03efd28e5dd1b33c21737c2db84cae8c237aa5/cffi-2.0.0-cp310-cp310-macosx_11_0_arm64.whl", hash = "sha256:f73b96c41e3b2adedc34a7356e64c8eb96e03a3782b535e043a986276ce12a49", size = 180504, upload-time = "2025-09-08T23:22:10.637Z" }, + { url = "https://files.pythonhosted.org/packages/50/bd/b1a6362b80628111e6653c961f987faa55262b4002fcec42308cad1db680/cffi-2.0.0-cp310-cp310-manylinux1_i686.manylinux2014_i686.manylinux_2_17_i686.manylinux_2_5_i686.whl", hash = "sha256:53f77cbe57044e88bbd5ed26ac1d0514d2acf0591dd6bb02a3ae37f76811b80c", size = 208811, upload-time = "2025-09-08T23:22:12.267Z" }, + { url = "https://files.pythonhosted.org/packages/4f/27/6933a8b2562d7bd1fb595074cf99cc81fc3789f6a6c05cdabb46284a3188/cffi-2.0.0-cp310-cp310-manylinux2014_aarch64.manylinux_2_17_aarch64.whl", hash = "sha256:3e837e369566884707ddaf85fc1744b47575005c0a229de3327f8f9a20f4efeb", size = 216402, upload-time = "2025-09-08T23:22:13.455Z" }, + { url = "https://files.pythonhosted.org/packages/05/eb/b86f2a2645b62adcfff53b0dd97e8dfafb5c8aa864bd0d9a2c2049a0d551/cffi-2.0.0-cp310-cp310-manylinux2014_ppc64le.manylinux_2_17_ppc64le.whl", hash = "sha256:5eda85d6d1879e692d546a078b44251cdd08dd1cfb98dfb77b670c97cee49ea0", size = 203217, upload-time = "2025-09-08T23:22:14.596Z" }, + { url = "https://files.pythonhosted.org/packages/9f/e0/6cbe77a53acf5acc7c08cc186c9928864bd7c005f9efd0d126884858a5fe/cffi-2.0.0-cp310-cp310-manylinux2014_s390x.manylinux_2_17_s390x.whl", hash = "sha256:9332088d75dc3241c702d852d4671613136d90fa6881da7d770a483fd05248b4", size = 203079, upload-time = "2025-09-08T23:22:15.769Z" }, + { url = "https://files.pythonhosted.org/packages/98/29/9b366e70e243eb3d14a5cb488dfd3a0b6b2f1fb001a203f653b93ccfac88/cffi-2.0.0-cp310-cp310-manylinux2014_x86_64.manylinux_2_17_x86_64.whl", hash = "sha256:fc7de24befaeae77ba923797c7c87834c73648a05a4bde34b3b7e5588973a453", size = 216475, upload-time = "2025-09-08T23:22:17.427Z" }, + { url = "https://files.pythonhosted.org/packages/21/7a/13b24e70d2f90a322f2900c5d8e1f14fa7e2a6b3332b7309ba7b2ba51a5a/cffi-2.0.0-cp310-cp310-musllinux_1_2_aarch64.whl", hash = "sha256:cf364028c016c03078a23b503f02058f1814320a56ad535686f90565636a9495", size = 218829, upload-time = "2025-09-08T23:22:19.069Z" }, + { url = "https://files.pythonhosted.org/packages/60/99/c9dc110974c59cc981b1f5b66e1d8af8af764e00f0293266824d9c4254bc/cffi-2.0.0-cp310-cp310-musllinux_1_2_i686.whl", hash = "sha256:e11e82b744887154b182fd3e7e8512418446501191994dbf9c9fc1f32cc8efd5", size = 211211, upload-time = "2025-09-08T23:22:20.588Z" }, + { url = "https://files.pythonhosted.org/packages/49/72/ff2d12dbf21aca1b32a40ed792ee6b40f6dc3a9cf1644bd7ef6e95e0ac5e/cffi-2.0.0-cp310-cp310-musllinux_1_2_x86_64.whl", hash = "sha256:8ea985900c5c95ce9db1745f7933eeef5d314f0565b27625d9a10ec9881e1bfb", size = 218036, upload-time = "2025-09-08T23:22:22.143Z" }, + { url = "https://files.pythonhosted.org/packages/e2/cc/027d7fb82e58c48ea717149b03bcadcbdc293553edb283af792bd4bcbb3f/cffi-2.0.0-cp310-cp310-win32.whl", hash = "sha256:1f72fb8906754ac8a2cc3f9f5aaa298070652a0ffae577e0ea9bd480dc3c931a", size = 172184, upload-time = "2025-09-08T23:22:23.328Z" }, + { url = "https://files.pythonhosted.org/packages/33/fa/072dd15ae27fbb4e06b437eb6e944e75b068deb09e2a2826039e49ee2045/cffi-2.0.0-cp310-cp310-win_amd64.whl", hash = "sha256:b18a3ed7d5b3bd8d9ef7a8cb226502c6bf8308df1525e1cc676c3680e7176739", size = 182790, upload-time = "2025-09-08T23:22:24.752Z" }, + { url = "https://files.pythonhosted.org/packages/12/4a/3dfd5f7850cbf0d06dc84ba9aa00db766b52ca38d8b86e3a38314d52498c/cffi-2.0.0-cp311-cp311-macosx_10_13_x86_64.whl", hash = "sha256:b4c854ef3adc177950a8dfc81a86f5115d2abd545751a304c5bcf2c2c7283cfe", size = 184344, upload-time = "2025-09-08T23:22:26.456Z" }, + { url = "https://files.pythonhosted.org/packages/4f/8b/f0e4c441227ba756aafbe78f117485b25bb26b1c059d01f137fa6d14896b/cffi-2.0.0-cp311-cp311-macosx_11_0_arm64.whl", hash = "sha256:2de9a304e27f7596cd03d16f1b7c72219bd944e99cc52b84d0145aefb07cbd3c", size = 180560, upload-time = "2025-09-08T23:22:28.197Z" }, + { url = "https://files.pythonhosted.org/packages/b1/b7/1200d354378ef52ec227395d95c2576330fd22a869f7a70e88e1447eb234/cffi-2.0.0-cp311-cp311-manylinux1_i686.manylinux2014_i686.manylinux_2_17_i686.manylinux_2_5_i686.whl", hash = "sha256:baf5215e0ab74c16e2dd324e8ec067ef59e41125d3eade2b863d294fd5035c92", size = 209613, upload-time = "2025-09-08T23:22:29.475Z" }, + { url = "https://files.pythonhosted.org/packages/b8/56/6033f5e86e8cc9bb629f0077ba71679508bdf54a9a5e112a3c0b91870332/cffi-2.0.0-cp311-cp311-manylinux2014_aarch64.manylinux_2_17_aarch64.whl", hash = "sha256:730cacb21e1bdff3ce90babf007d0a0917cc3e6492f336c2f0134101e0944f93", size = 216476, upload-time = "2025-09-08T23:22:31.063Z" }, + { url = "https://files.pythonhosted.org/packages/dc/7f/55fecd70f7ece178db2f26128ec41430d8720f2d12ca97bf8f0a628207d5/cffi-2.0.0-cp311-cp311-manylinux2014_ppc64le.manylinux_2_17_ppc64le.whl", hash = "sha256:6824f87845e3396029f3820c206e459ccc91760e8fa24422f8b0c3d1731cbec5", size = 203374, upload-time = "2025-09-08T23:22:32.507Z" }, + { url = "https://files.pythonhosted.org/packages/84/ef/a7b77c8bdc0f77adc3b46888f1ad54be8f3b7821697a7b89126e829e676a/cffi-2.0.0-cp311-cp311-manylinux2014_s390x.manylinux_2_17_s390x.whl", hash = "sha256:9de40a7b0323d889cf8d23d1ef214f565ab154443c42737dfe52ff82cf857664", size = 202597, upload-time = "2025-09-08T23:22:34.132Z" }, + { url = "https://files.pythonhosted.org/packages/d7/91/500d892b2bf36529a75b77958edfcd5ad8e2ce4064ce2ecfeab2125d72d1/cffi-2.0.0-cp311-cp311-manylinux2014_x86_64.manylinux_2_17_x86_64.whl", hash = "sha256:8941aaadaf67246224cee8c3803777eed332a19d909b47e29c9842ef1e79ac26", size = 215574, upload-time = "2025-09-08T23:22:35.443Z" }, + { url = "https://files.pythonhosted.org/packages/44/64/58f6255b62b101093d5df22dcb752596066c7e89dd725e0afaed242a61be/cffi-2.0.0-cp311-cp311-musllinux_1_2_aarch64.whl", hash = "sha256:a05d0c237b3349096d3981b727493e22147f934b20f6f125a3eba8f994bec4a9", size = 218971, upload-time = "2025-09-08T23:22:36.805Z" }, + { url = "https://files.pythonhosted.org/packages/ab/49/fa72cebe2fd8a55fbe14956f9970fe8eb1ac59e5df042f603ef7c8ba0adc/cffi-2.0.0-cp311-cp311-musllinux_1_2_i686.whl", hash = "sha256:94698a9c5f91f9d138526b48fe26a199609544591f859c870d477351dc7b2414", size = 211972, upload-time = "2025-09-08T23:22:38.436Z" }, + { url = "https://files.pythonhosted.org/packages/0b/28/dd0967a76aab36731b6ebfe64dec4e981aff7e0608f60c2d46b46982607d/cffi-2.0.0-cp311-cp311-musllinux_1_2_x86_64.whl", hash = "sha256:5fed36fccc0612a53f1d4d9a816b50a36702c28a2aa880cb8a122b3466638743", size = 217078, upload-time = "2025-09-08T23:22:39.776Z" }, + { url = "https://files.pythonhosted.org/packages/2b/c0/015b25184413d7ab0a410775fdb4a50fca20f5589b5dab1dbbfa3baad8ce/cffi-2.0.0-cp311-cp311-win32.whl", hash = "sha256:c649e3a33450ec82378822b3dad03cc228b8f5963c0c12fc3b1e0ab940f768a5", size = 172076, upload-time = "2025-09-08T23:22:40.95Z" }, + { url = "https://files.pythonhosted.org/packages/ae/8f/dc5531155e7070361eb1b7e4c1a9d896d0cb21c49f807a6c03fd63fc877e/cffi-2.0.0-cp311-cp311-win_amd64.whl", hash = "sha256:66f011380d0e49ed280c789fbd08ff0d40968ee7b665575489afa95c98196ab5", size = 182820, upload-time = "2025-09-08T23:22:42.463Z" }, + { url = "https://files.pythonhosted.org/packages/95/5c/1b493356429f9aecfd56bc171285a4c4ac8697f76e9bbbbb105e537853a1/cffi-2.0.0-cp311-cp311-win_arm64.whl", hash = "sha256:c6638687455baf640e37344fe26d37c404db8b80d037c3d29f58fe8d1c3b194d", size = 177635, upload-time = "2025-09-08T23:22:43.623Z" }, + { url = "https://files.pythonhosted.org/packages/ea/47/4f61023ea636104d4f16ab488e268b93008c3d0bb76893b1b31db1f96802/cffi-2.0.0-cp312-cp312-macosx_10_13_x86_64.whl", hash = "sha256:6d02d6655b0e54f54c4ef0b94eb6be0607b70853c45ce98bd278dc7de718be5d", size = 185271, upload-time = "2025-09-08T23:22:44.795Z" }, + { url = "https://files.pythonhosted.org/packages/df/a2/781b623f57358e360d62cdd7a8c681f074a71d445418a776eef0aadb4ab4/cffi-2.0.0-cp312-cp312-macosx_11_0_arm64.whl", hash = "sha256:8eca2a813c1cb7ad4fb74d368c2ffbbb4789d377ee5bb8df98373c2cc0dee76c", size = 181048, upload-time = "2025-09-08T23:22:45.938Z" }, + { url = "https://files.pythonhosted.org/packages/ff/df/a4f0fbd47331ceeba3d37c2e51e9dfc9722498becbeec2bd8bc856c9538a/cffi-2.0.0-cp312-cp312-manylinux1_i686.manylinux2014_i686.manylinux_2_17_i686.manylinux_2_5_i686.whl", hash = "sha256:21d1152871b019407d8ac3985f6775c079416c282e431a4da6afe7aefd2bccbe", size = 212529, upload-time = "2025-09-08T23:22:47.349Z" }, + { url = "https://files.pythonhosted.org/packages/d5/72/12b5f8d3865bf0f87cf1404d8c374e7487dcf097a1c91c436e72e6badd83/cffi-2.0.0-cp312-cp312-manylinux2014_aarch64.manylinux_2_17_aarch64.whl", hash = "sha256:b21e08af67b8a103c71a250401c78d5e0893beff75e28c53c98f4de42f774062", size = 220097, upload-time = "2025-09-08T23:22:48.677Z" }, + { url = "https://files.pythonhosted.org/packages/c2/95/7a135d52a50dfa7c882ab0ac17e8dc11cec9d55d2c18dda414c051c5e69e/cffi-2.0.0-cp312-cp312-manylinux2014_ppc64le.manylinux_2_17_ppc64le.whl", hash = "sha256:1e3a615586f05fc4065a8b22b8152f0c1b00cdbc60596d187c2a74f9e3036e4e", size = 207983, upload-time = "2025-09-08T23:22:50.06Z" }, + { url = "https://files.pythonhosted.org/packages/3a/c8/15cb9ada8895957ea171c62dc78ff3e99159ee7adb13c0123c001a2546c1/cffi-2.0.0-cp312-cp312-manylinux2014_s390x.manylinux_2_17_s390x.whl", hash = "sha256:81afed14892743bbe14dacb9e36d9e0e504cd204e0b165062c488942b9718037", size = 206519, upload-time = "2025-09-08T23:22:51.364Z" }, + { url = "https://files.pythonhosted.org/packages/78/2d/7fa73dfa841b5ac06c7b8855cfc18622132e365f5b81d02230333ff26e9e/cffi-2.0.0-cp312-cp312-manylinux2014_x86_64.manylinux_2_17_x86_64.whl", hash = "sha256:3e17ed538242334bf70832644a32a7aae3d83b57567f9fd60a26257e992b79ba", size = 219572, upload-time = "2025-09-08T23:22:52.902Z" }, + { url = "https://files.pythonhosted.org/packages/07/e0/267e57e387b4ca276b90f0434ff88b2c2241ad72b16d31836adddfd6031b/cffi-2.0.0-cp312-cp312-musllinux_1_2_aarch64.whl", hash = "sha256:3925dd22fa2b7699ed2617149842d2e6adde22b262fcbfada50e3d195e4b3a94", size = 222963, upload-time = "2025-09-08T23:22:54.518Z" }, + { url = "https://files.pythonhosted.org/packages/b6/75/1f2747525e06f53efbd878f4d03bac5b859cbc11c633d0fb81432d98a795/cffi-2.0.0-cp312-cp312-musllinux_1_2_x86_64.whl", hash = "sha256:2c8f814d84194c9ea681642fd164267891702542f028a15fc97d4674b6206187", size = 221361, upload-time = "2025-09-08T23:22:55.867Z" }, + { url = "https://files.pythonhosted.org/packages/7b/2b/2b6435f76bfeb6bbf055596976da087377ede68df465419d192acf00c437/cffi-2.0.0-cp312-cp312-win32.whl", hash = "sha256:da902562c3e9c550df360bfa53c035b2f241fed6d9aef119048073680ace4a18", size = 172932, upload-time = "2025-09-08T23:22:57.188Z" }, + { url = "https://files.pythonhosted.org/packages/f8/ed/13bd4418627013bec4ed6e54283b1959cf6db888048c7cf4b4c3b5b36002/cffi-2.0.0-cp312-cp312-win_amd64.whl", hash = "sha256:da68248800ad6320861f129cd9c1bf96ca849a2771a59e0344e88681905916f5", size = 183557, upload-time = "2025-09-08T23:22:58.351Z" }, + { url = "https://files.pythonhosted.org/packages/95/31/9f7f93ad2f8eff1dbc1c3656d7ca5bfd8fb52c9d786b4dcf19b2d02217fa/cffi-2.0.0-cp312-cp312-win_arm64.whl", hash = "sha256:4671d9dd5ec934cb9a73e7ee9676f9362aba54f7f34910956b84d727b0d73fb6", size = 177762, upload-time = "2025-09-08T23:22:59.668Z" }, + { url = "https://files.pythonhosted.org/packages/4b/8d/a0a47a0c9e413a658623d014e91e74a50cdd2c423f7ccfd44086ef767f90/cffi-2.0.0-cp313-cp313-macosx_10_13_x86_64.whl", hash = "sha256:00bdf7acc5f795150faa6957054fbbca2439db2f775ce831222b66f192f03beb", size = 185230, upload-time = "2025-09-08T23:23:00.879Z" }, + { url = "https://files.pythonhosted.org/packages/4a/d2/a6c0296814556c68ee32009d9c2ad4f85f2707cdecfd7727951ec228005d/cffi-2.0.0-cp313-cp313-macosx_11_0_arm64.whl", hash = "sha256:45d5e886156860dc35862657e1494b9bae8dfa63bf56796f2fb56e1679fc0bca", size = 181043, upload-time = "2025-09-08T23:23:02.231Z" }, + { url = "https://files.pythonhosted.org/packages/b0/1e/d22cc63332bd59b06481ceaac49d6c507598642e2230f201649058a7e704/cffi-2.0.0-cp313-cp313-manylinux1_i686.manylinux2014_i686.manylinux_2_17_i686.manylinux_2_5_i686.whl", hash = "sha256:07b271772c100085dd28b74fa0cd81c8fb1a3ba18b21e03d7c27f3436a10606b", size = 212446, upload-time = "2025-09-08T23:23:03.472Z" }, + { url = "https://files.pythonhosted.org/packages/a9/f5/a2c23eb03b61a0b8747f211eb716446c826ad66818ddc7810cc2cc19b3f2/cffi-2.0.0-cp313-cp313-manylinux2014_aarch64.manylinux_2_17_aarch64.whl", hash = "sha256:d48a880098c96020b02d5a1f7d9251308510ce8858940e6fa99ece33f610838b", size = 220101, upload-time = "2025-09-08T23:23:04.792Z" }, + { url = "https://files.pythonhosted.org/packages/f2/7f/e6647792fc5850d634695bc0e6ab4111ae88e89981d35ac269956605feba/cffi-2.0.0-cp313-cp313-manylinux2014_ppc64le.manylinux_2_17_ppc64le.whl", hash = "sha256:f93fd8e5c8c0a4aa1f424d6173f14a892044054871c771f8566e4008eaa359d2", size = 207948, upload-time = "2025-09-08T23:23:06.127Z" }, + { url = "https://files.pythonhosted.org/packages/cb/1e/a5a1bd6f1fb30f22573f76533de12a00bf274abcdc55c8edab639078abb6/cffi-2.0.0-cp313-cp313-manylinux2014_s390x.manylinux_2_17_s390x.whl", hash = "sha256:dd4f05f54a52fb558f1ba9f528228066954fee3ebe629fc1660d874d040ae5a3", size = 206422, upload-time = "2025-09-08T23:23:07.753Z" }, + { url = "https://files.pythonhosted.org/packages/98/df/0a1755e750013a2081e863e7cd37e0cdd02664372c754e5560099eb7aa44/cffi-2.0.0-cp313-cp313-manylinux2014_x86_64.manylinux_2_17_x86_64.whl", hash = "sha256:c8d3b5532fc71b7a77c09192b4a5a200ea992702734a2e9279a37f2478236f26", size = 219499, upload-time = "2025-09-08T23:23:09.648Z" }, + { url = "https://files.pythonhosted.org/packages/50/e1/a969e687fcf9ea58e6e2a928ad5e2dd88cc12f6f0ab477e9971f2309b57c/cffi-2.0.0-cp313-cp313-musllinux_1_2_aarch64.whl", hash = "sha256:d9b29c1f0ae438d5ee9acb31cadee00a58c46cc9c0b2f9038c6b0b3470877a8c", size = 222928, upload-time = "2025-09-08T23:23:10.928Z" }, + { url = "https://files.pythonhosted.org/packages/36/54/0362578dd2c9e557a28ac77698ed67323ed5b9775ca9d3fe73fe191bb5d8/cffi-2.0.0-cp313-cp313-musllinux_1_2_x86_64.whl", hash = "sha256:6d50360be4546678fc1b79ffe7a66265e28667840010348dd69a314145807a1b", size = 221302, upload-time = "2025-09-08T23:23:12.42Z" }, + { url = "https://files.pythonhosted.org/packages/eb/6d/bf9bda840d5f1dfdbf0feca87fbdb64a918a69bca42cfa0ba7b137c48cb8/cffi-2.0.0-cp313-cp313-win32.whl", hash = "sha256:74a03b9698e198d47562765773b4a8309919089150a0bb17d829ad7b44b60d27", size = 172909, upload-time = "2025-09-08T23:23:14.32Z" }, + { url = "https://files.pythonhosted.org/packages/37/18/6519e1ee6f5a1e579e04b9ddb6f1676c17368a7aba48299c3759bbc3c8b3/cffi-2.0.0-cp313-cp313-win_amd64.whl", hash = "sha256:19f705ada2530c1167abacb171925dd886168931e0a7b78f5bffcae5c6b5be75", size = 183402, upload-time = "2025-09-08T23:23:15.535Z" }, + { url = "https://files.pythonhosted.org/packages/cb/0e/02ceeec9a7d6ee63bb596121c2c8e9b3a9e150936f4fbef6ca1943e6137c/cffi-2.0.0-cp313-cp313-win_arm64.whl", hash = "sha256:256f80b80ca3853f90c21b23ee78cd008713787b1b1e93eae9f3d6a7134abd91", size = 177780, upload-time = "2025-09-08T23:23:16.761Z" }, + { url = "https://files.pythonhosted.org/packages/92/c4/3ce07396253a83250ee98564f8d7e9789fab8e58858f35d07a9a2c78de9f/cffi-2.0.0-cp314-cp314-macosx_10_13_x86_64.whl", hash = "sha256:fc33c5141b55ed366cfaad382df24fe7dcbc686de5be719b207bb248e3053dc5", size = 185320, upload-time = "2025-09-08T23:23:18.087Z" }, + { url = "https://files.pythonhosted.org/packages/59/dd/27e9fa567a23931c838c6b02d0764611c62290062a6d4e8ff7863daf9730/cffi-2.0.0-cp314-cp314-macosx_11_0_arm64.whl", hash = "sha256:c654de545946e0db659b3400168c9ad31b5d29593291482c43e3564effbcee13", size = 181487, upload-time = "2025-09-08T23:23:19.622Z" }, + { url = "https://files.pythonhosted.org/packages/d6/43/0e822876f87ea8a4ef95442c3d766a06a51fc5298823f884ef87aaad168c/cffi-2.0.0-cp314-cp314-manylinux2014_aarch64.manylinux_2_17_aarch64.whl", hash = "sha256:24b6f81f1983e6df8db3adc38562c83f7d4a0c36162885ec7f7b77c7dcbec97b", size = 220049, upload-time = "2025-09-08T23:23:20.853Z" }, + { url = "https://files.pythonhosted.org/packages/b4/89/76799151d9c2d2d1ead63c2429da9ea9d7aac304603de0c6e8764e6e8e70/cffi-2.0.0-cp314-cp314-manylinux2014_ppc64le.manylinux_2_17_ppc64le.whl", hash = "sha256:12873ca6cb9b0f0d3a0da705d6086fe911591737a59f28b7936bdfed27c0d47c", size = 207793, upload-time = "2025-09-08T23:23:22.08Z" }, + { url = "https://files.pythonhosted.org/packages/bb/dd/3465b14bb9e24ee24cb88c9e3730f6de63111fffe513492bf8c808a3547e/cffi-2.0.0-cp314-cp314-manylinux2014_s390x.manylinux_2_17_s390x.whl", hash = "sha256:d9b97165e8aed9272a6bb17c01e3cc5871a594a446ebedc996e2397a1c1ea8ef", size = 206300, upload-time = "2025-09-08T23:23:23.314Z" }, + { url = "https://files.pythonhosted.org/packages/47/d9/d83e293854571c877a92da46fdec39158f8d7e68da75bf73581225d28e90/cffi-2.0.0-cp314-cp314-manylinux2014_x86_64.manylinux_2_17_x86_64.whl", hash = "sha256:afb8db5439b81cf9c9d0c80404b60c3cc9c3add93e114dcae767f1477cb53775", size = 219244, upload-time = "2025-09-08T23:23:24.541Z" }, + { url = "https://files.pythonhosted.org/packages/2b/0f/1f177e3683aead2bb00f7679a16451d302c436b5cbf2505f0ea8146ef59e/cffi-2.0.0-cp314-cp314-musllinux_1_2_aarch64.whl", hash = "sha256:737fe7d37e1a1bffe70bd5754ea763a62a066dc5913ca57e957824b72a85e205", size = 222828, upload-time = "2025-09-08T23:23:26.143Z" }, + { url = "https://files.pythonhosted.org/packages/c6/0f/cafacebd4b040e3119dcb32fed8bdef8dfe94da653155f9d0b9dc660166e/cffi-2.0.0-cp314-cp314-musllinux_1_2_x86_64.whl", hash = "sha256:38100abb9d1b1435bc4cc340bb4489635dc2f0da7456590877030c9b3d40b0c1", size = 220926, upload-time = "2025-09-08T23:23:27.873Z" }, + { url = "https://files.pythonhosted.org/packages/3e/aa/df335faa45b395396fcbc03de2dfcab242cd61a9900e914fe682a59170b1/cffi-2.0.0-cp314-cp314-win32.whl", hash = "sha256:087067fa8953339c723661eda6b54bc98c5625757ea62e95eb4898ad5e776e9f", size = 175328, upload-time = "2025-09-08T23:23:44.61Z" }, + { url = "https://files.pythonhosted.org/packages/bb/92/882c2d30831744296ce713f0feb4c1cd30f346ef747b530b5318715cc367/cffi-2.0.0-cp314-cp314-win_amd64.whl", hash = "sha256:203a48d1fb583fc7d78a4c6655692963b860a417c0528492a6bc21f1aaefab25", size = 185650, upload-time = "2025-09-08T23:23:45.848Z" }, + { url = "https://files.pythonhosted.org/packages/9f/2c/98ece204b9d35a7366b5b2c6539c350313ca13932143e79dc133ba757104/cffi-2.0.0-cp314-cp314-win_arm64.whl", hash = "sha256:dbd5c7a25a7cb98f5ca55d258b103a2054f859a46ae11aaf23134f9cc0d356ad", size = 180687, upload-time = "2025-09-08T23:23:47.105Z" }, + { url = "https://files.pythonhosted.org/packages/3e/61/c768e4d548bfa607abcda77423448df8c471f25dbe64fb2ef6d555eae006/cffi-2.0.0-cp314-cp314t-macosx_10_13_x86_64.whl", hash = "sha256:9a67fc9e8eb39039280526379fb3a70023d77caec1852002b4da7e8b270c4dd9", size = 188773, upload-time = "2025-09-08T23:23:29.347Z" }, + { url = "https://files.pythonhosted.org/packages/2c/ea/5f76bce7cf6fcd0ab1a1058b5af899bfbef198bea4d5686da88471ea0336/cffi-2.0.0-cp314-cp314t-macosx_11_0_arm64.whl", hash = "sha256:7a66c7204d8869299919db4d5069a82f1561581af12b11b3c9f48c584eb8743d", size = 185013, upload-time = "2025-09-08T23:23:30.63Z" }, + { url = "https://files.pythonhosted.org/packages/be/b4/c56878d0d1755cf9caa54ba71e5d049479c52f9e4afc230f06822162ab2f/cffi-2.0.0-cp314-cp314t-manylinux2014_aarch64.manylinux_2_17_aarch64.whl", hash = "sha256:7cc09976e8b56f8cebd752f7113ad07752461f48a58cbba644139015ac24954c", size = 221593, upload-time = "2025-09-08T23:23:31.91Z" }, + { url = "https://files.pythonhosted.org/packages/e0/0d/eb704606dfe8033e7128df5e90fee946bbcb64a04fcdaa97321309004000/cffi-2.0.0-cp314-cp314t-manylinux2014_ppc64le.manylinux_2_17_ppc64le.whl", hash = "sha256:92b68146a71df78564e4ef48af17551a5ddd142e5190cdf2c5624d0c3ff5b2e8", size = 209354, upload-time = "2025-09-08T23:23:33.214Z" }, + { url = "https://files.pythonhosted.org/packages/d8/19/3c435d727b368ca475fb8742ab97c9cb13a0de600ce86f62eab7fa3eea60/cffi-2.0.0-cp314-cp314t-manylinux2014_s390x.manylinux_2_17_s390x.whl", hash = "sha256:b1e74d11748e7e98e2f426ab176d4ed720a64412b6a15054378afdb71e0f37dc", size = 208480, upload-time = "2025-09-08T23:23:34.495Z" }, + { url = "https://files.pythonhosted.org/packages/d0/44/681604464ed9541673e486521497406fadcc15b5217c3e326b061696899a/cffi-2.0.0-cp314-cp314t-manylinux2014_x86_64.manylinux_2_17_x86_64.whl", hash = "sha256:28a3a209b96630bca57cce802da70c266eb08c6e97e5afd61a75611ee6c64592", size = 221584, upload-time = "2025-09-08T23:23:36.096Z" }, + { url = "https://files.pythonhosted.org/packages/25/8e/342a504ff018a2825d395d44d63a767dd8ebc927ebda557fecdaca3ac33a/cffi-2.0.0-cp314-cp314t-musllinux_1_2_aarch64.whl", hash = "sha256:7553fb2090d71822f02c629afe6042c299edf91ba1bf94951165613553984512", size = 224443, upload-time = "2025-09-08T23:23:37.328Z" }, + { url = "https://files.pythonhosted.org/packages/e1/5e/b666bacbbc60fbf415ba9988324a132c9a7a0448a9a8f125074671c0f2c3/cffi-2.0.0-cp314-cp314t-musllinux_1_2_x86_64.whl", hash = "sha256:6c6c373cfc5c83a975506110d17457138c8c63016b563cc9ed6e056a82f13ce4", size = 223437, upload-time = "2025-09-08T23:23:38.945Z" }, + { url = "https://files.pythonhosted.org/packages/a0/1d/ec1a60bd1a10daa292d3cd6bb0b359a81607154fb8165f3ec95fe003b85c/cffi-2.0.0-cp314-cp314t-win32.whl", hash = "sha256:1fc9ea04857caf665289b7a75923f2c6ed559b8298a1b8c49e59f7dd95c8481e", size = 180487, upload-time = "2025-09-08T23:23:40.423Z" }, + { url = "https://files.pythonhosted.org/packages/bf/41/4c1168c74fac325c0c8156f04b6749c8b6a8f405bbf91413ba088359f60d/cffi-2.0.0-cp314-cp314t-win_amd64.whl", hash = "sha256:d68b6cef7827e8641e8ef16f4494edda8b36104d79773a334beaa1e3521430f6", size = 191726, upload-time = "2025-09-08T23:23:41.742Z" }, + { url = "https://files.pythonhosted.org/packages/ae/3a/dbeec9d1ee0844c679f6bb5d6ad4e9f198b1224f4e7a32825f47f6192b0c/cffi-2.0.0-cp314-cp314t-win_arm64.whl", hash = "sha256:0a1527a803f0a659de1af2e1fd700213caba79377e27e4693648c2923da066f9", size = 184195, upload-time = "2025-09-08T23:23:43.004Z" }, + { url = "https://files.pythonhosted.org/packages/c0/cc/08ed5a43f2996a16b462f64a7055c6e962803534924b9b2f1371d8c00b7b/cffi-2.0.0-cp39-cp39-macosx_10_13_x86_64.whl", hash = "sha256:fe562eb1a64e67dd297ccc4f5addea2501664954f2692b69a76449ec7913ecbf", size = 184288, upload-time = "2025-09-08T23:23:48.404Z" }, + { url = "https://files.pythonhosted.org/packages/3d/de/38d9726324e127f727b4ecc376bc85e505bfe61ef130eaf3f290c6847dd4/cffi-2.0.0-cp39-cp39-macosx_11_0_arm64.whl", hash = "sha256:de8dad4425a6ca6e4e5e297b27b5c824ecc7581910bf9aee86cb6835e6812aa7", size = 180509, upload-time = "2025-09-08T23:23:49.73Z" }, + { url = "https://files.pythonhosted.org/packages/9b/13/c92e36358fbcc39cf0962e83223c9522154ee8630e1df7c0b3a39a8124e2/cffi-2.0.0-cp39-cp39-manylinux1_i686.manylinux2014_i686.manylinux_2_17_i686.manylinux_2_5_i686.whl", hash = "sha256:4647afc2f90d1ddd33441e5b0e85b16b12ddec4fca55f0d9671fef036ecca27c", size = 208813, upload-time = "2025-09-08T23:23:51.263Z" }, + { url = "https://files.pythonhosted.org/packages/15/12/a7a79bd0df4c3bff744b2d7e52cc1b68d5e7e427b384252c42366dc1ecbc/cffi-2.0.0-cp39-cp39-manylinux2014_aarch64.manylinux_2_17_aarch64.whl", hash = "sha256:3f4d46d8b35698056ec29bca21546e1551a205058ae1a181d871e278b0b28165", size = 216498, upload-time = "2025-09-08T23:23:52.494Z" }, + { url = "https://files.pythonhosted.org/packages/a3/ad/5c51c1c7600bdd7ed9a24a203ec255dccdd0ebf4527f7b922a0bde2fb6ed/cffi-2.0.0-cp39-cp39-manylinux2014_ppc64le.manylinux_2_17_ppc64le.whl", hash = "sha256:e6e73b9e02893c764e7e8d5bb5ce277f1a009cd5243f8228f75f842bf937c534", size = 203243, upload-time = "2025-09-08T23:23:53.836Z" }, + { url = "https://files.pythonhosted.org/packages/32/f2/81b63e288295928739d715d00952c8c6034cb6c6a516b17d37e0c8be5600/cffi-2.0.0-cp39-cp39-manylinux2014_s390x.manylinux_2_17_s390x.whl", hash = "sha256:cb527a79772e5ef98fb1d700678fe031e353e765d1ca2d409c92263c6d43e09f", size = 203158, upload-time = "2025-09-08T23:23:55.169Z" }, + { url = "https://files.pythonhosted.org/packages/1f/74/cc4096ce66f5939042ae094e2e96f53426a979864aa1f96a621ad128be27/cffi-2.0.0-cp39-cp39-manylinux2014_x86_64.manylinux_2_17_x86_64.whl", hash = "sha256:61d028e90346df14fedc3d1e5441df818d095f3b87d286825dfcbd6459b7ef63", size = 216548, upload-time = "2025-09-08T23:23:56.506Z" }, + { url = "https://files.pythonhosted.org/packages/e8/be/f6424d1dc46b1091ffcc8964fa7c0ab0cd36839dd2761b49c90481a6ba1b/cffi-2.0.0-cp39-cp39-musllinux_1_2_aarch64.whl", hash = "sha256:0f6084a0ea23d05d20c3edcda20c3d006f9b6f3fefeac38f59262e10cef47ee2", size = 218897, upload-time = "2025-09-08T23:23:57.825Z" }, + { url = "https://files.pythonhosted.org/packages/f7/e0/dda537c2309817edf60109e39265f24f24aa7f050767e22c98c53fe7f48b/cffi-2.0.0-cp39-cp39-musllinux_1_2_i686.whl", hash = "sha256:1cd13c99ce269b3ed80b417dcd591415d3372bcac067009b6e0f59c7d4015e65", size = 211249, upload-time = "2025-09-08T23:23:59.139Z" }, + { url = "https://files.pythonhosted.org/packages/2b/e7/7c769804eb75e4c4b35e658dba01de1640a351a9653c3d49ca89d16ccc91/cffi-2.0.0-cp39-cp39-musllinux_1_2_x86_64.whl", hash = "sha256:89472c9762729b5ae1ad974b777416bfda4ac5642423fa93bd57a09204712322", size = 218041, upload-time = "2025-09-08T23:24:00.496Z" }, + { url = "https://files.pythonhosted.org/packages/aa/d9/6218d78f920dcd7507fc16a766b5ef8f3b913cc7aa938e7fc80b9978d089/cffi-2.0.0-cp39-cp39-win32.whl", hash = "sha256:2081580ebb843f759b9f617314a24ed5738c51d2aee65d31e02f6f7a2b97707a", size = 172138, upload-time = "2025-09-08T23:24:01.7Z" }, + { url = "https://files.pythonhosted.org/packages/54/8f/a1e836f82d8e32a97e6b29cc8f641779181ac7363734f12df27db803ebda/cffi-2.0.0-cp39-cp39-win_amd64.whl", hash = "sha256:b882b3df248017dba09d6b16defe9b5c407fe32fc7c65a9c69798e6175601be9", size = 182794, upload-time = "2025-09-08T23:24:02.943Z" }, +] + +[[package]] +name = "charset-normalizer" +version = "3.4.4" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/13/69/33ddede1939fdd074bce5434295f38fae7136463422fe4fd3e0e89b98062/charset_normalizer-3.4.4.tar.gz", hash = "sha256:94537985111c35f28720e43603b8e7b43a6ecfb2ce1d3058bbe955b73404e21a", size = 129418, upload-time = "2025-10-14T04:42:32.879Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/1f/b8/6d51fc1d52cbd52cd4ccedd5b5b2f0f6a11bbf6765c782298b0f3e808541/charset_normalizer-3.4.4-cp310-cp310-macosx_10_9_universal2.whl", hash = "sha256:e824f1492727fa856dd6eda4f7cee25f8518a12f3c4a56a74e8095695089cf6d", size = 209709, upload-time = "2025-10-14T04:40:11.385Z" }, + { url = "https://files.pythonhosted.org/packages/5c/af/1f9d7f7faafe2ddfb6f72a2e07a548a629c61ad510fe60f9630309908fef/charset_normalizer-3.4.4-cp310-cp310-manylinux2014_aarch64.manylinux_2_17_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:4bd5d4137d500351a30687c2d3971758aac9a19208fc110ccb9d7188fbe709e8", size = 148814, upload-time = "2025-10-14T04:40:13.135Z" }, + { url = "https://files.pythonhosted.org/packages/79/3d/f2e3ac2bbc056ca0c204298ea4e3d9db9b4afe437812638759db2c976b5f/charset_normalizer-3.4.4-cp310-cp310-manylinux2014_armv7l.manylinux_2_17_armv7l.manylinux_2_31_armv7l.whl", hash = "sha256:027f6de494925c0ab2a55eab46ae5129951638a49a34d87f4c3eda90f696b4ad", size = 144467, upload-time = "2025-10-14T04:40:14.728Z" }, + { url = "https://files.pythonhosted.org/packages/ec/85/1bf997003815e60d57de7bd972c57dc6950446a3e4ccac43bc3070721856/charset_normalizer-3.4.4-cp310-cp310-manylinux2014_ppc64le.manylinux_2_17_ppc64le.manylinux_2_28_ppc64le.whl", hash = "sha256:f820802628d2694cb7e56db99213f930856014862f3fd943d290ea8438d07ca8", size = 162280, upload-time = "2025-10-14T04:40:16.14Z" }, + { url = "https://files.pythonhosted.org/packages/3e/8e/6aa1952f56b192f54921c436b87f2aaf7c7a7c3d0d1a765547d64fd83c13/charset_normalizer-3.4.4-cp310-cp310-manylinux2014_s390x.manylinux_2_17_s390x.manylinux_2_28_s390x.whl", hash = "sha256:798d75d81754988d2565bff1b97ba5a44411867c0cf32b77a7e8f8d84796b10d", size = 159454, upload-time = "2025-10-14T04:40:17.567Z" }, + { url = "https://files.pythonhosted.org/packages/36/3b/60cbd1f8e93aa25d1c669c649b7a655b0b5fb4c571858910ea9332678558/charset_normalizer-3.4.4-cp310-cp310-manylinux2014_x86_64.manylinux_2_17_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:9d1bb833febdff5c8927f922386db610b49db6e0d4f4ee29601d71e7c2694313", size = 153609, upload-time = "2025-10-14T04:40:19.08Z" }, + { url = "https://files.pythonhosted.org/packages/64/91/6a13396948b8fd3c4b4fd5bc74d045f5637d78c9675585e8e9fbe5636554/charset_normalizer-3.4.4-cp310-cp310-manylinux_2_31_riscv64.manylinux_2_39_riscv64.whl", hash = "sha256:9cd98cdc06614a2f768d2b7286d66805f94c48cde050acdbbb7db2600ab3197e", size = 151849, upload-time = "2025-10-14T04:40:20.607Z" }, + { url = "https://files.pythonhosted.org/packages/b7/7a/59482e28b9981d105691e968c544cc0df3b7d6133152fb3dcdc8f135da7a/charset_normalizer-3.4.4-cp310-cp310-musllinux_1_2_aarch64.whl", hash = "sha256:077fbb858e903c73f6c9db43374fd213b0b6a778106bc7032446a8e8b5b38b93", size = 151586, upload-time = "2025-10-14T04:40:21.719Z" }, + { url = "https://files.pythonhosted.org/packages/92/59/f64ef6a1c4bdd2baf892b04cd78792ed8684fbc48d4c2afe467d96b4df57/charset_normalizer-3.4.4-cp310-cp310-musllinux_1_2_armv7l.whl", hash = "sha256:244bfb999c71b35de57821b8ea746b24e863398194a4014e4c76adc2bbdfeff0", size = 145290, upload-time = "2025-10-14T04:40:23.069Z" }, + { url = "https://files.pythonhosted.org/packages/6b/63/3bf9f279ddfa641ffa1962b0db6a57a9c294361cc2f5fcac997049a00e9c/charset_normalizer-3.4.4-cp310-cp310-musllinux_1_2_ppc64le.whl", hash = "sha256:64b55f9dce520635f018f907ff1b0df1fdc31f2795a922fb49dd14fbcdf48c84", size = 163663, upload-time = "2025-10-14T04:40:24.17Z" }, + { url = "https://files.pythonhosted.org/packages/ed/09/c9e38fc8fa9e0849b172b581fd9803bdf6e694041127933934184e19f8c3/charset_normalizer-3.4.4-cp310-cp310-musllinux_1_2_riscv64.whl", hash = "sha256:faa3a41b2b66b6e50f84ae4a68c64fcd0c44355741c6374813a800cd6695db9e", size = 151964, upload-time = "2025-10-14T04:40:25.368Z" }, + { url = "https://files.pythonhosted.org/packages/d2/d1/d28b747e512d0da79d8b6a1ac18b7ab2ecfd81b2944c4c710e166d8dd09c/charset_normalizer-3.4.4-cp310-cp310-musllinux_1_2_s390x.whl", hash = "sha256:6515f3182dbe4ea06ced2d9e8666d97b46ef4c75e326b79bb624110f122551db", size = 161064, upload-time = "2025-10-14T04:40:26.806Z" }, + { url = "https://files.pythonhosted.org/packages/bb/9a/31d62b611d901c3b9e5500c36aab0ff5eb442043fb3a1c254200d3d397d9/charset_normalizer-3.4.4-cp310-cp310-musllinux_1_2_x86_64.whl", hash = "sha256:cc00f04ed596e9dc0da42ed17ac5e596c6ccba999ba6bd92b0e0aef2f170f2d6", size = 155015, upload-time = "2025-10-14T04:40:28.284Z" }, + { url = "https://files.pythonhosted.org/packages/1f/f3/107e008fa2bff0c8b9319584174418e5e5285fef32f79d8ee6a430d0039c/charset_normalizer-3.4.4-cp310-cp310-win32.whl", hash = "sha256:f34be2938726fc13801220747472850852fe6b1ea75869a048d6f896838c896f", size = 99792, upload-time = "2025-10-14T04:40:29.613Z" }, + { url = "https://files.pythonhosted.org/packages/eb/66/e396e8a408843337d7315bab30dbf106c38966f1819f123257f5520f8a96/charset_normalizer-3.4.4-cp310-cp310-win_amd64.whl", hash = "sha256:a61900df84c667873b292c3de315a786dd8dac506704dea57bc957bd31e22c7d", size = 107198, upload-time = "2025-10-14T04:40:30.644Z" }, + { url = "https://files.pythonhosted.org/packages/b5/58/01b4f815bf0312704c267f2ccb6e5d42bcc7752340cd487bc9f8c3710597/charset_normalizer-3.4.4-cp310-cp310-win_arm64.whl", hash = "sha256:cead0978fc57397645f12578bfd2d5ea9138ea0fac82b2f63f7f7c6877986a69", size = 100262, upload-time = "2025-10-14T04:40:32.108Z" }, + { url = "https://files.pythonhosted.org/packages/ed/27/c6491ff4954e58a10f69ad90aca8a1b6fe9c5d3c6f380907af3c37435b59/charset_normalizer-3.4.4-cp311-cp311-macosx_10_9_universal2.whl", hash = "sha256:6e1fcf0720908f200cd21aa4e6750a48ff6ce4afe7ff5a79a90d5ed8a08296f8", size = 206988, upload-time = "2025-10-14T04:40:33.79Z" }, + { url = "https://files.pythonhosted.org/packages/94/59/2e87300fe67ab820b5428580a53cad894272dbb97f38a7a814a2a1ac1011/charset_normalizer-3.4.4-cp311-cp311-manylinux2014_aarch64.manylinux_2_17_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:5f819d5fe9234f9f82d75bdfa9aef3a3d72c4d24a6e57aeaebba32a704553aa0", size = 147324, upload-time = "2025-10-14T04:40:34.961Z" }, + { url = "https://files.pythonhosted.org/packages/07/fb/0cf61dc84b2b088391830f6274cb57c82e4da8bbc2efeac8c025edb88772/charset_normalizer-3.4.4-cp311-cp311-manylinux2014_armv7l.manylinux_2_17_armv7l.manylinux_2_31_armv7l.whl", hash = "sha256:a59cb51917aa591b1c4e6a43c132f0cdc3c76dbad6155df4e28ee626cc77a0a3", size = 142742, upload-time = "2025-10-14T04:40:36.105Z" }, + { url = "https://files.pythonhosted.org/packages/62/8b/171935adf2312cd745d290ed93cf16cf0dfe320863ab7cbeeae1dcd6535f/charset_normalizer-3.4.4-cp311-cp311-manylinux2014_ppc64le.manylinux_2_17_ppc64le.manylinux_2_28_ppc64le.whl", hash = "sha256:8ef3c867360f88ac904fd3f5e1f902f13307af9052646963ee08ff4f131adafc", size = 160863, upload-time = "2025-10-14T04:40:37.188Z" }, + { url = "https://files.pythonhosted.org/packages/09/73/ad875b192bda14f2173bfc1bc9a55e009808484a4b256748d931b6948442/charset_normalizer-3.4.4-cp311-cp311-manylinux2014_s390x.manylinux_2_17_s390x.manylinux_2_28_s390x.whl", hash = "sha256:d9e45d7faa48ee908174d8fe84854479ef838fc6a705c9315372eacbc2f02897", size = 157837, upload-time = "2025-10-14T04:40:38.435Z" }, + { url = "https://files.pythonhosted.org/packages/6d/fc/de9cce525b2c5b94b47c70a4b4fb19f871b24995c728e957ee68ab1671ea/charset_normalizer-3.4.4-cp311-cp311-manylinux2014_x86_64.manylinux_2_17_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:840c25fb618a231545cbab0564a799f101b63b9901f2569faecd6b222ac72381", size = 151550, upload-time = "2025-10-14T04:40:40.053Z" }, + { url = "https://files.pythonhosted.org/packages/55/c2/43edd615fdfba8c6f2dfbd459b25a6b3b551f24ea21981e23fb768503ce1/charset_normalizer-3.4.4-cp311-cp311-manylinux_2_31_riscv64.manylinux_2_39_riscv64.whl", hash = "sha256:ca5862d5b3928c4940729dacc329aa9102900382fea192fc5e52eb69d6093815", size = 149162, upload-time = "2025-10-14T04:40:41.163Z" }, + { url = "https://files.pythonhosted.org/packages/03/86/bde4ad8b4d0e9429a4e82c1e8f5c659993a9a863ad62c7df05cf7b678d75/charset_normalizer-3.4.4-cp311-cp311-musllinux_1_2_aarch64.whl", hash = "sha256:d9c7f57c3d666a53421049053eaacdd14bbd0a528e2186fcb2e672effd053bb0", size = 150019, upload-time = "2025-10-14T04:40:42.276Z" }, + { url = "https://files.pythonhosted.org/packages/1f/86/a151eb2af293a7e7bac3a739b81072585ce36ccfb4493039f49f1d3cae8c/charset_normalizer-3.4.4-cp311-cp311-musllinux_1_2_armv7l.whl", hash = "sha256:277e970e750505ed74c832b4bf75dac7476262ee2a013f5574dd49075879e161", size = 143310, upload-time = "2025-10-14T04:40:43.439Z" }, + { url = "https://files.pythonhosted.org/packages/b5/fe/43dae6144a7e07b87478fdfc4dbe9efd5defb0e7ec29f5f58a55aeef7bf7/charset_normalizer-3.4.4-cp311-cp311-musllinux_1_2_ppc64le.whl", hash = "sha256:31fd66405eaf47bb62e8cd575dc621c56c668f27d46a61d975a249930dd5e2a4", size = 162022, upload-time = "2025-10-14T04:40:44.547Z" }, + { url = "https://files.pythonhosted.org/packages/80/e6/7aab83774f5d2bca81f42ac58d04caf44f0cc2b65fc6db2b3b2e8a05f3b3/charset_normalizer-3.4.4-cp311-cp311-musllinux_1_2_riscv64.whl", hash = "sha256:0d3d8f15c07f86e9ff82319b3d9ef6f4bf907608f53fe9d92b28ea9ae3d1fd89", size = 149383, upload-time = "2025-10-14T04:40:46.018Z" }, + { url = "https://files.pythonhosted.org/packages/4f/e8/b289173b4edae05c0dde07f69f8db476a0b511eac556dfe0d6bda3c43384/charset_normalizer-3.4.4-cp311-cp311-musllinux_1_2_s390x.whl", hash = "sha256:9f7fcd74d410a36883701fafa2482a6af2ff5ba96b9a620e9e0721e28ead5569", size = 159098, upload-time = "2025-10-14T04:40:47.081Z" }, + { url = "https://files.pythonhosted.org/packages/d8/df/fe699727754cae3f8478493c7f45f777b17c3ef0600e28abfec8619eb49c/charset_normalizer-3.4.4-cp311-cp311-musllinux_1_2_x86_64.whl", hash = "sha256:ebf3e58c7ec8a8bed6d66a75d7fb37b55e5015b03ceae72a8e7c74495551e224", size = 152991, upload-time = "2025-10-14T04:40:48.246Z" }, + { url = "https://files.pythonhosted.org/packages/1a/86/584869fe4ddb6ffa3bd9f491b87a01568797fb9bd8933f557dba9771beaf/charset_normalizer-3.4.4-cp311-cp311-win32.whl", hash = "sha256:eecbc200c7fd5ddb9a7f16c7decb07b566c29fa2161a16cf67b8d068bd21690a", size = 99456, upload-time = "2025-10-14T04:40:49.376Z" }, + { url = "https://files.pythonhosted.org/packages/65/f6/62fdd5feb60530f50f7e38b4f6a1d5203f4d16ff4f9f0952962c044e919a/charset_normalizer-3.4.4-cp311-cp311-win_amd64.whl", hash = "sha256:5ae497466c7901d54b639cf42d5b8c1b6a4fead55215500d2f486d34db48d016", size = 106978, upload-time = "2025-10-14T04:40:50.844Z" }, + { url = "https://files.pythonhosted.org/packages/7a/9d/0710916e6c82948b3be62d9d398cb4fcf4e97b56d6a6aeccd66c4b2f2bd5/charset_normalizer-3.4.4-cp311-cp311-win_arm64.whl", hash = "sha256:65e2befcd84bc6f37095f5961e68a6f077bf44946771354a28ad434c2cce0ae1", size = 99969, upload-time = "2025-10-14T04:40:52.272Z" }, + { url = "https://files.pythonhosted.org/packages/f3/85/1637cd4af66fa687396e757dec650f28025f2a2f5a5531a3208dc0ec43f2/charset_normalizer-3.4.4-cp312-cp312-macosx_10_13_universal2.whl", hash = "sha256:0a98e6759f854bd25a58a73fa88833fba3b7c491169f86ce1180c948ab3fd394", size = 208425, upload-time = "2025-10-14T04:40:53.353Z" }, + { url = "https://files.pythonhosted.org/packages/9d/6a/04130023fef2a0d9c62d0bae2649b69f7b7d8d24ea5536feef50551029df/charset_normalizer-3.4.4-cp312-cp312-manylinux2014_aarch64.manylinux_2_17_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:b5b290ccc2a263e8d185130284f8501e3e36c5e02750fc6b6bdeb2e9e96f1e25", size = 148162, upload-time = "2025-10-14T04:40:54.558Z" }, + { url = "https://files.pythonhosted.org/packages/78/29/62328d79aa60da22c9e0b9a66539feae06ca0f5a4171ac4f7dc285b83688/charset_normalizer-3.4.4-cp312-cp312-manylinux2014_armv7l.manylinux_2_17_armv7l.manylinux_2_31_armv7l.whl", hash = "sha256:74bb723680f9f7a6234dcf67aea57e708ec1fbdf5699fb91dfd6f511b0a320ef", size = 144558, upload-time = "2025-10-14T04:40:55.677Z" }, + { url = "https://files.pythonhosted.org/packages/86/bb/b32194a4bf15b88403537c2e120b817c61cd4ecffa9b6876e941c3ee38fe/charset_normalizer-3.4.4-cp312-cp312-manylinux2014_ppc64le.manylinux_2_17_ppc64le.manylinux_2_28_ppc64le.whl", hash = "sha256:f1e34719c6ed0b92f418c7c780480b26b5d9c50349e9a9af7d76bf757530350d", size = 161497, upload-time = "2025-10-14T04:40:57.217Z" }, + { url = "https://files.pythonhosted.org/packages/19/89/a54c82b253d5b9b111dc74aca196ba5ccfcca8242d0fb64146d4d3183ff1/charset_normalizer-3.4.4-cp312-cp312-manylinux2014_s390x.manylinux_2_17_s390x.manylinux_2_28_s390x.whl", hash = "sha256:2437418e20515acec67d86e12bf70056a33abdacb5cb1655042f6538d6b085a8", size = 159240, upload-time = "2025-10-14T04:40:58.358Z" }, + { url = "https://files.pythonhosted.org/packages/c0/10/d20b513afe03acc89ec33948320a5544d31f21b05368436d580dec4e234d/charset_normalizer-3.4.4-cp312-cp312-manylinux2014_x86_64.manylinux_2_17_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:11d694519d7f29d6cd09f6ac70028dba10f92f6cdd059096db198c283794ac86", size = 153471, upload-time = "2025-10-14T04:40:59.468Z" }, + { url = "https://files.pythonhosted.org/packages/61/fa/fbf177b55bdd727010f9c0a3c49eefa1d10f960e5f09d1d887bf93c2e698/charset_normalizer-3.4.4-cp312-cp312-manylinux_2_31_riscv64.manylinux_2_39_riscv64.whl", hash = "sha256:ac1c4a689edcc530fc9d9aa11f5774b9e2f33f9a0c6a57864e90908f5208d30a", size = 150864, upload-time = "2025-10-14T04:41:00.623Z" }, + { url = "https://files.pythonhosted.org/packages/05/12/9fbc6a4d39c0198adeebbde20b619790e9236557ca59fc40e0e3cebe6f40/charset_normalizer-3.4.4-cp312-cp312-musllinux_1_2_aarch64.whl", hash = "sha256:21d142cc6c0ec30d2efee5068ca36c128a30b0f2c53c1c07bd78cb6bc1d3be5f", size = 150647, upload-time = "2025-10-14T04:41:01.754Z" }, + { url = "https://files.pythonhosted.org/packages/ad/1f/6a9a593d52e3e8c5d2b167daf8c6b968808efb57ef4c210acb907c365bc4/charset_normalizer-3.4.4-cp312-cp312-musllinux_1_2_armv7l.whl", hash = "sha256:5dbe56a36425d26d6cfb40ce79c314a2e4dd6211d51d6d2191c00bed34f354cc", size = 145110, upload-time = "2025-10-14T04:41:03.231Z" }, + { url = "https://files.pythonhosted.org/packages/30/42/9a52c609e72471b0fc54386dc63c3781a387bb4fe61c20231a4ebcd58bdd/charset_normalizer-3.4.4-cp312-cp312-musllinux_1_2_ppc64le.whl", hash = "sha256:5bfbb1b9acf3334612667b61bd3002196fe2a1eb4dd74d247e0f2a4d50ec9bbf", size = 162839, upload-time = "2025-10-14T04:41:04.715Z" }, + { url = "https://files.pythonhosted.org/packages/c4/5b/c0682bbf9f11597073052628ddd38344a3d673fda35a36773f7d19344b23/charset_normalizer-3.4.4-cp312-cp312-musllinux_1_2_riscv64.whl", hash = "sha256:d055ec1e26e441f6187acf818b73564e6e6282709e9bcb5b63f5b23068356a15", size = 150667, upload-time = "2025-10-14T04:41:05.827Z" }, + { url = "https://files.pythonhosted.org/packages/e4/24/a41afeab6f990cf2daf6cb8c67419b63b48cf518e4f56022230840c9bfb2/charset_normalizer-3.4.4-cp312-cp312-musllinux_1_2_s390x.whl", hash = "sha256:af2d8c67d8e573d6de5bc30cdb27e9b95e49115cd9baad5ddbd1a6207aaa82a9", size = 160535, upload-time = "2025-10-14T04:41:06.938Z" }, + { url = "https://files.pythonhosted.org/packages/2a/e5/6a4ce77ed243c4a50a1fecca6aaaab419628c818a49434be428fe24c9957/charset_normalizer-3.4.4-cp312-cp312-musllinux_1_2_x86_64.whl", hash = "sha256:780236ac706e66881f3b7f2f32dfe90507a09e67d1d454c762cf642e6e1586e0", size = 154816, upload-time = "2025-10-14T04:41:08.101Z" }, + { url = "https://files.pythonhosted.org/packages/a8/ef/89297262b8092b312d29cdb2517cb1237e51db8ecef2e9af5edbe7b683b1/charset_normalizer-3.4.4-cp312-cp312-win32.whl", hash = "sha256:5833d2c39d8896e4e19b689ffc198f08ea58116bee26dea51e362ecc7cd3ed26", size = 99694, upload-time = "2025-10-14T04:41:09.23Z" }, + { url = "https://files.pythonhosted.org/packages/3d/2d/1e5ed9dd3b3803994c155cd9aacb60c82c331bad84daf75bcb9c91b3295e/charset_normalizer-3.4.4-cp312-cp312-win_amd64.whl", hash = "sha256:a79cfe37875f822425b89a82333404539ae63dbdddf97f84dcbc3d339aae9525", size = 107131, upload-time = "2025-10-14T04:41:10.467Z" }, + { url = "https://files.pythonhosted.org/packages/d0/d9/0ed4c7098a861482a7b6a95603edce4c0d9db2311af23da1fb2b75ec26fc/charset_normalizer-3.4.4-cp312-cp312-win_arm64.whl", hash = "sha256:376bec83a63b8021bb5c8ea75e21c4ccb86e7e45ca4eb81146091b56599b80c3", size = 100390, upload-time = "2025-10-14T04:41:11.915Z" }, + { url = "https://files.pythonhosted.org/packages/97/45/4b3a1239bbacd321068ea6e7ac28875b03ab8bc0aa0966452db17cd36714/charset_normalizer-3.4.4-cp313-cp313-macosx_10_13_universal2.whl", hash = "sha256:e1f185f86a6f3403aa2420e815904c67b2f9ebc443f045edd0de921108345794", size = 208091, upload-time = "2025-10-14T04:41:13.346Z" }, + { url = "https://files.pythonhosted.org/packages/7d/62/73a6d7450829655a35bb88a88fca7d736f9882a27eacdca2c6d505b57e2e/charset_normalizer-3.4.4-cp313-cp313-manylinux2014_aarch64.manylinux_2_17_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:6b39f987ae8ccdf0d2642338faf2abb1862340facc796048b604ef14919e55ed", size = 147936, upload-time = "2025-10-14T04:41:14.461Z" }, + { url = "https://files.pythonhosted.org/packages/89/c5/adb8c8b3d6625bef6d88b251bbb0d95f8205831b987631ab0c8bb5d937c2/charset_normalizer-3.4.4-cp313-cp313-manylinux2014_armv7l.manylinux_2_17_armv7l.manylinux_2_31_armv7l.whl", hash = "sha256:3162d5d8ce1bb98dd51af660f2121c55d0fa541b46dff7bb9b9f86ea1d87de72", size = 144180, upload-time = "2025-10-14T04:41:15.588Z" }, + { url = "https://files.pythonhosted.org/packages/91/ed/9706e4070682d1cc219050b6048bfd293ccf67b3d4f5a4f39207453d4b99/charset_normalizer-3.4.4-cp313-cp313-manylinux2014_ppc64le.manylinux_2_17_ppc64le.manylinux_2_28_ppc64le.whl", hash = "sha256:81d5eb2a312700f4ecaa977a8235b634ce853200e828fbadf3a9c50bab278328", size = 161346, upload-time = "2025-10-14T04:41:16.738Z" }, + { url = "https://files.pythonhosted.org/packages/d5/0d/031f0d95e4972901a2f6f09ef055751805ff541511dc1252ba3ca1f80cf5/charset_normalizer-3.4.4-cp313-cp313-manylinux2014_s390x.manylinux_2_17_s390x.manylinux_2_28_s390x.whl", hash = "sha256:5bd2293095d766545ec1a8f612559f6b40abc0eb18bb2f5d1171872d34036ede", size = 158874, upload-time = "2025-10-14T04:41:17.923Z" }, + { url = "https://files.pythonhosted.org/packages/f5/83/6ab5883f57c9c801ce5e5677242328aa45592be8a00644310a008d04f922/charset_normalizer-3.4.4-cp313-cp313-manylinux2014_x86_64.manylinux_2_17_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:a8a8b89589086a25749f471e6a900d3f662d1d3b6e2e59dcecf787b1cc3a1894", size = 153076, upload-time = "2025-10-14T04:41:19.106Z" }, + { url = "https://files.pythonhosted.org/packages/75/1e/5ff781ddf5260e387d6419959ee89ef13878229732732ee73cdae01800f2/charset_normalizer-3.4.4-cp313-cp313-manylinux_2_31_riscv64.manylinux_2_39_riscv64.whl", hash = "sha256:bc7637e2f80d8530ee4a78e878bce464f70087ce73cf7c1caf142416923b98f1", size = 150601, upload-time = "2025-10-14T04:41:20.245Z" }, + { url = "https://files.pythonhosted.org/packages/d7/57/71be810965493d3510a6ca79b90c19e48696fb1ff964da319334b12677f0/charset_normalizer-3.4.4-cp313-cp313-musllinux_1_2_aarch64.whl", hash = "sha256:f8bf04158c6b607d747e93949aa60618b61312fe647a6369f88ce2ff16043490", size = 150376, upload-time = "2025-10-14T04:41:21.398Z" }, + { url = "https://files.pythonhosted.org/packages/e5/d5/c3d057a78c181d007014feb7e9f2e65905a6c4ef182c0ddf0de2924edd65/charset_normalizer-3.4.4-cp313-cp313-musllinux_1_2_armv7l.whl", hash = "sha256:554af85e960429cf30784dd47447d5125aaa3b99a6f0683589dbd27e2f45da44", size = 144825, upload-time = "2025-10-14T04:41:22.583Z" }, + { url = "https://files.pythonhosted.org/packages/e6/8c/d0406294828d4976f275ffbe66f00266c4b3136b7506941d87c00cab5272/charset_normalizer-3.4.4-cp313-cp313-musllinux_1_2_ppc64le.whl", hash = "sha256:74018750915ee7ad843a774364e13a3db91682f26142baddf775342c3f5b1133", size = 162583, upload-time = "2025-10-14T04:41:23.754Z" }, + { url = "https://files.pythonhosted.org/packages/d7/24/e2aa1f18c8f15c4c0e932d9287b8609dd30ad56dbe41d926bd846e22fb8d/charset_normalizer-3.4.4-cp313-cp313-musllinux_1_2_riscv64.whl", hash = "sha256:c0463276121fdee9c49b98908b3a89c39be45d86d1dbaa22957e38f6321d4ce3", size = 150366, upload-time = "2025-10-14T04:41:25.27Z" }, + { url = "https://files.pythonhosted.org/packages/e4/5b/1e6160c7739aad1e2df054300cc618b06bf784a7a164b0f238360721ab86/charset_normalizer-3.4.4-cp313-cp313-musllinux_1_2_s390x.whl", hash = "sha256:362d61fd13843997c1c446760ef36f240cf81d3ebf74ac62652aebaf7838561e", size = 160300, upload-time = "2025-10-14T04:41:26.725Z" }, + { url = "https://files.pythonhosted.org/packages/7a/10/f882167cd207fbdd743e55534d5d9620e095089d176d55cb22d5322f2afd/charset_normalizer-3.4.4-cp313-cp313-musllinux_1_2_x86_64.whl", hash = "sha256:9a26f18905b8dd5d685d6d07b0cdf98a79f3c7a918906af7cc143ea2e164c8bc", size = 154465, upload-time = "2025-10-14T04:41:28.322Z" }, + { url = "https://files.pythonhosted.org/packages/89/66/c7a9e1b7429be72123441bfdbaf2bc13faab3f90b933f664db506dea5915/charset_normalizer-3.4.4-cp313-cp313-win32.whl", hash = "sha256:9b35f4c90079ff2e2edc5b26c0c77925e5d2d255c42c74fdb70fb49b172726ac", size = 99404, upload-time = "2025-10-14T04:41:29.95Z" }, + { url = "https://files.pythonhosted.org/packages/c4/26/b9924fa27db384bdcd97ab83b4f0a8058d96ad9626ead570674d5e737d90/charset_normalizer-3.4.4-cp313-cp313-win_amd64.whl", hash = "sha256:b435cba5f4f750aa6c0a0d92c541fb79f69a387c91e61f1795227e4ed9cece14", size = 107092, upload-time = "2025-10-14T04:41:31.188Z" }, + { url = "https://files.pythonhosted.org/packages/af/8f/3ed4bfa0c0c72a7ca17f0380cd9e4dd842b09f664e780c13cff1dcf2ef1b/charset_normalizer-3.4.4-cp313-cp313-win_arm64.whl", hash = "sha256:542d2cee80be6f80247095cc36c418f7bddd14f4a6de45af91dfad36d817bba2", size = 100408, upload-time = "2025-10-14T04:41:32.624Z" }, + { url = "https://files.pythonhosted.org/packages/2a/35/7051599bd493e62411d6ede36fd5af83a38f37c4767b92884df7301db25d/charset_normalizer-3.4.4-cp314-cp314-macosx_10_13_universal2.whl", hash = "sha256:da3326d9e65ef63a817ecbcc0df6e94463713b754fe293eaa03da99befb9a5bd", size = 207746, upload-time = "2025-10-14T04:41:33.773Z" }, + { url = "https://files.pythonhosted.org/packages/10/9a/97c8d48ef10d6cd4fcead2415523221624bf58bcf68a802721a6bc807c8f/charset_normalizer-3.4.4-cp314-cp314-manylinux2014_aarch64.manylinux_2_17_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:8af65f14dc14a79b924524b1e7fffe304517b2bff5a58bf64f30b98bbc5079eb", size = 147889, upload-time = "2025-10-14T04:41:34.897Z" }, + { url = "https://files.pythonhosted.org/packages/10/bf/979224a919a1b606c82bd2c5fa49b5c6d5727aa47b4312bb27b1734f53cd/charset_normalizer-3.4.4-cp314-cp314-manylinux2014_armv7l.manylinux_2_17_armv7l.manylinux_2_31_armv7l.whl", hash = "sha256:74664978bb272435107de04e36db5a9735e78232b85b77d45cfb38f758efd33e", size = 143641, upload-time = "2025-10-14T04:41:36.116Z" }, + { url = "https://files.pythonhosted.org/packages/ba/33/0ad65587441fc730dc7bd90e9716b30b4702dc7b617e6ba4997dc8651495/charset_normalizer-3.4.4-cp314-cp314-manylinux2014_ppc64le.manylinux_2_17_ppc64le.manylinux_2_28_ppc64le.whl", hash = "sha256:752944c7ffbfdd10c074dc58ec2d5a8a4cd9493b314d367c14d24c17684ddd14", size = 160779, upload-time = "2025-10-14T04:41:37.229Z" }, + { url = "https://files.pythonhosted.org/packages/67/ed/331d6b249259ee71ddea93f6f2f0a56cfebd46938bde6fcc6f7b9a3d0e09/charset_normalizer-3.4.4-cp314-cp314-manylinux2014_s390x.manylinux_2_17_s390x.manylinux_2_28_s390x.whl", hash = "sha256:d1f13550535ad8cff21b8d757a3257963e951d96e20ec82ab44bc64aeb62a191", size = 159035, upload-time = "2025-10-14T04:41:38.368Z" }, + { url = "https://files.pythonhosted.org/packages/67/ff/f6b948ca32e4f2a4576aa129d8bed61f2e0543bf9f5f2b7fc3758ed005c9/charset_normalizer-3.4.4-cp314-cp314-manylinux2014_x86_64.manylinux_2_17_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:ecaae4149d99b1c9e7b88bb03e3221956f68fd6d50be2ef061b2381b61d20838", size = 152542, upload-time = "2025-10-14T04:41:39.862Z" }, + { url = "https://files.pythonhosted.org/packages/16/85/276033dcbcc369eb176594de22728541a925b2632f9716428c851b149e83/charset_normalizer-3.4.4-cp314-cp314-manylinux_2_31_riscv64.manylinux_2_39_riscv64.whl", hash = "sha256:cb6254dc36b47a990e59e1068afacdcd02958bdcce30bb50cc1700a8b9d624a6", size = 149524, upload-time = "2025-10-14T04:41:41.319Z" }, + { url = "https://files.pythonhosted.org/packages/9e/f2/6a2a1f722b6aba37050e626530a46a68f74e63683947a8acff92569f979a/charset_normalizer-3.4.4-cp314-cp314-musllinux_1_2_aarch64.whl", hash = "sha256:c8ae8a0f02f57a6e61203a31428fa1d677cbe50c93622b4149d5c0f319c1d19e", size = 150395, upload-time = "2025-10-14T04:41:42.539Z" }, + { url = "https://files.pythonhosted.org/packages/60/bb/2186cb2f2bbaea6338cad15ce23a67f9b0672929744381e28b0592676824/charset_normalizer-3.4.4-cp314-cp314-musllinux_1_2_armv7l.whl", hash = "sha256:47cc91b2f4dd2833fddaedd2893006b0106129d4b94fdb6af1f4ce5a9965577c", size = 143680, upload-time = "2025-10-14T04:41:43.661Z" }, + { url = "https://files.pythonhosted.org/packages/7d/a5/bf6f13b772fbb2a90360eb620d52ed8f796f3c5caee8398c3b2eb7b1c60d/charset_normalizer-3.4.4-cp314-cp314-musllinux_1_2_ppc64le.whl", hash = "sha256:82004af6c302b5d3ab2cfc4cc5f29db16123b1a8417f2e25f9066f91d4411090", size = 162045, upload-time = "2025-10-14T04:41:44.821Z" }, + { url = "https://files.pythonhosted.org/packages/df/c5/d1be898bf0dc3ef9030c3825e5d3b83f2c528d207d246cbabe245966808d/charset_normalizer-3.4.4-cp314-cp314-musllinux_1_2_riscv64.whl", hash = "sha256:2b7d8f6c26245217bd2ad053761201e9f9680f8ce52f0fcd8d0755aeae5b2152", size = 149687, upload-time = "2025-10-14T04:41:46.442Z" }, + { url = "https://files.pythonhosted.org/packages/a5/42/90c1f7b9341eef50c8a1cb3f098ac43b0508413f33affd762855f67a410e/charset_normalizer-3.4.4-cp314-cp314-musllinux_1_2_s390x.whl", hash = "sha256:799a7a5e4fb2d5898c60b640fd4981d6a25f1c11790935a44ce38c54e985f828", size = 160014, upload-time = "2025-10-14T04:41:47.631Z" }, + { url = "https://files.pythonhosted.org/packages/76/be/4d3ee471e8145d12795ab655ece37baed0929462a86e72372fd25859047c/charset_normalizer-3.4.4-cp314-cp314-musllinux_1_2_x86_64.whl", hash = "sha256:99ae2cffebb06e6c22bdc25801d7b30f503cc87dbd283479e7b606f70aff57ec", size = 154044, upload-time = "2025-10-14T04:41:48.81Z" }, + { url = "https://files.pythonhosted.org/packages/b0/6f/8f7af07237c34a1defe7defc565a9bc1807762f672c0fde711a4b22bf9c0/charset_normalizer-3.4.4-cp314-cp314-win32.whl", hash = "sha256:f9d332f8c2a2fcbffe1378594431458ddbef721c1769d78e2cbc06280d8155f9", size = 99940, upload-time = "2025-10-14T04:41:49.946Z" }, + { url = "https://files.pythonhosted.org/packages/4b/51/8ade005e5ca5b0d80fb4aff72a3775b325bdc3d27408c8113811a7cbe640/charset_normalizer-3.4.4-cp314-cp314-win_amd64.whl", hash = "sha256:8a6562c3700cce886c5be75ade4a5db4214fda19fede41d9792d100288d8f94c", size = 107104, upload-time = "2025-10-14T04:41:51.051Z" }, + { url = "https://files.pythonhosted.org/packages/da/5f/6b8f83a55bb8278772c5ae54a577f3099025f9ade59d0136ac24a0df4bde/charset_normalizer-3.4.4-cp314-cp314-win_arm64.whl", hash = "sha256:de00632ca48df9daf77a2c65a484531649261ec9f25489917f09e455cb09ddb2", size = 100743, upload-time = "2025-10-14T04:41:52.122Z" }, + { url = "https://files.pythonhosted.org/packages/46/7c/0c4760bccf082737ca7ab84a4c2034fcc06b1f21cf3032ea98bd6feb1725/charset_normalizer-3.4.4-cp39-cp39-macosx_10_9_universal2.whl", hash = "sha256:a9768c477b9d7bd54bc0c86dbaebdec6f03306675526c9927c0e8a04e8f94af9", size = 209609, upload-time = "2025-10-14T04:42:10.922Z" }, + { url = "https://files.pythonhosted.org/packages/bb/a4/69719daef2f3d7f1819de60c9a6be981b8eeead7542d5ec4440f3c80e111/charset_normalizer-3.4.4-cp39-cp39-manylinux2014_aarch64.manylinux_2_17_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:1bee1e43c28aa63cb16e5c14e582580546b08e535299b8b6158a7c9c768a1f3d", size = 149029, upload-time = "2025-10-14T04:42:12.38Z" }, + { url = "https://files.pythonhosted.org/packages/e6/21/8d4e1d6c1e6070d3672908b8e4533a71b5b53e71d16828cc24d0efec564c/charset_normalizer-3.4.4-cp39-cp39-manylinux2014_armv7l.manylinux_2_17_armv7l.manylinux_2_31_armv7l.whl", hash = "sha256:fd44c878ea55ba351104cb93cc85e74916eb8fa440ca7903e57575e97394f608", size = 144580, upload-time = "2025-10-14T04:42:13.549Z" }, + { url = "https://files.pythonhosted.org/packages/a7/0a/a616d001b3f25647a9068e0b9199f697ce507ec898cacb06a0d5a1617c99/charset_normalizer-3.4.4-cp39-cp39-manylinux2014_ppc64le.manylinux_2_17_ppc64le.manylinux_2_28_ppc64le.whl", hash = "sha256:0f04b14ffe5fdc8c4933862d8306109a2c51e0704acfa35d51598eb45a1e89fc", size = 162340, upload-time = "2025-10-14T04:42:14.892Z" }, + { url = "https://files.pythonhosted.org/packages/85/93/060b52deb249a5450460e0585c88a904a83aec474ab8e7aba787f45e79f2/charset_normalizer-3.4.4-cp39-cp39-manylinux2014_s390x.manylinux_2_17_s390x.manylinux_2_28_s390x.whl", hash = "sha256:cd09d08005f958f370f539f186d10aec3377d55b9eeb0d796025d4886119d76e", size = 159619, upload-time = "2025-10-14T04:42:16.676Z" }, + { url = "https://files.pythonhosted.org/packages/dd/21/0274deb1cc0632cd587a9a0ec6b4674d9108e461cb4cd40d457adaeb0564/charset_normalizer-3.4.4-cp39-cp39-manylinux2014_x86_64.manylinux_2_17_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:4fe7859a4e3e8457458e2ff592f15ccb02f3da787fcd31e0183879c3ad4692a1", size = 153980, upload-time = "2025-10-14T04:42:17.917Z" }, + { url = "https://files.pythonhosted.org/packages/28/2b/e3d7d982858dccc11b31906976323d790dded2017a0572f093ff982d692f/charset_normalizer-3.4.4-cp39-cp39-manylinux_2_31_riscv64.manylinux_2_39_riscv64.whl", hash = "sha256:fa09f53c465e532f4d3db095e0c55b615f010ad81803d383195b6b5ca6cbf5f3", size = 152174, upload-time = "2025-10-14T04:42:19.018Z" }, + { url = "https://files.pythonhosted.org/packages/6e/ff/4a269f8e35f1e58b2df52c131a1fa019acb7ef3f8697b7d464b07e9b492d/charset_normalizer-3.4.4-cp39-cp39-musllinux_1_2_aarch64.whl", hash = "sha256:7fa17817dc5625de8a027cb8b26d9fefa3ea28c8253929b8d6649e705d2835b6", size = 151666, upload-time = "2025-10-14T04:42:20.171Z" }, + { url = "https://files.pythonhosted.org/packages/da/c9/ec39870f0b330d58486001dd8e532c6b9a905f5765f58a6f8204926b4a93/charset_normalizer-3.4.4-cp39-cp39-musllinux_1_2_armv7l.whl", hash = "sha256:5947809c8a2417be3267efc979c47d76a079758166f7d43ef5ae8e9f92751f88", size = 145550, upload-time = "2025-10-14T04:42:21.324Z" }, + { url = "https://files.pythonhosted.org/packages/75/8f/d186ab99e40e0ed9f82f033d6e49001701c81244d01905dd4a6924191a30/charset_normalizer-3.4.4-cp39-cp39-musllinux_1_2_ppc64le.whl", hash = "sha256:4902828217069c3c5c71094537a8e623f5d097858ac6ca8252f7b4d10b7560f1", size = 163721, upload-time = "2025-10-14T04:42:22.46Z" }, + { url = "https://files.pythonhosted.org/packages/96/b1/6047663b9744df26a7e479ac1e77af7134b1fcf9026243bb48ee2d18810f/charset_normalizer-3.4.4-cp39-cp39-musllinux_1_2_riscv64.whl", hash = "sha256:7c308f7e26e4363d79df40ca5b2be1c6ba9f02bdbccfed5abddb7859a6ce72cf", size = 152127, upload-time = "2025-10-14T04:42:23.712Z" }, + { url = "https://files.pythonhosted.org/packages/59/78/e5a6eac9179f24f704d1be67d08704c3c6ab9f00963963524be27c18ed87/charset_normalizer-3.4.4-cp39-cp39-musllinux_1_2_s390x.whl", hash = "sha256:2c9d3c380143a1fedbff95a312aa798578371eb29da42106a29019368a475318", size = 161175, upload-time = "2025-10-14T04:42:24.87Z" }, + { url = "https://files.pythonhosted.org/packages/e5/43/0e626e42d54dd2f8dd6fc5e1c5ff00f05fbca17cb699bedead2cae69c62f/charset_normalizer-3.4.4-cp39-cp39-musllinux_1_2_x86_64.whl", hash = "sha256:cb01158d8b88ee68f15949894ccc6712278243d95f344770fa7593fa2d94410c", size = 155375, upload-time = "2025-10-14T04:42:27.246Z" }, + { url = "https://files.pythonhosted.org/packages/e9/91/d9615bf2e06f35e4997616ff31248c3657ed649c5ab9d35ea12fce54e380/charset_normalizer-3.4.4-cp39-cp39-win32.whl", hash = "sha256:2677acec1a2f8ef614c6888b5b4ae4060cc184174a938ed4e8ef690e15d3e505", size = 99692, upload-time = "2025-10-14T04:42:28.425Z" }, + { url = "https://files.pythonhosted.org/packages/d1/a9/6c040053909d9d1ef4fcab45fddec083aedc9052c10078339b47c8573ea8/charset_normalizer-3.4.4-cp39-cp39-win_amd64.whl", hash = "sha256:f8e160feb2aed042cd657a72acc0b481212ed28b1b9a95c0cee1621b524e1966", size = 107192, upload-time = "2025-10-14T04:42:29.482Z" }, + { url = "https://files.pythonhosted.org/packages/f0/c6/4fa536b2c0cd3edfb7ccf8469fa0f363ea67b7213a842b90909ca33dd851/charset_normalizer-3.4.4-cp39-cp39-win_arm64.whl", hash = "sha256:b5d84d37db046c5ca74ee7bb47dd6cbc13f80665fdde3e8040bdd3fb015ecb50", size = 100220, upload-time = "2025-10-14T04:42:30.632Z" }, + { url = "https://files.pythonhosted.org/packages/0a/4c/925909008ed5a988ccbb72dcc897407e5d6d3bd72410d69e051fc0c14647/charset_normalizer-3.4.4-py3-none-any.whl", hash = "sha256:7a32c560861a02ff789ad905a2fe94e3f840803362c84fecf1851cb4cf3dc37f", size = 53402, upload-time = "2025-10-14T04:42:31.76Z" }, +] + +[[package]] +name = "cloudpickle" +version = "3.1.1" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/52/39/069100b84d7418bc358d81669d5748efb14b9cceacd2f9c75f550424132f/cloudpickle-3.1.1.tar.gz", hash = "sha256:b216fa8ae4019d5482a8ac3c95d8f6346115d8835911fd4aefd1a445e4242c64", size = 22113, upload-time = "2025-01-14T17:02:05.085Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/7e/e8/64c37fadfc2816a7701fa8a6ed8d87327c7d54eacfbfb6edab14a2f2be75/cloudpickle-3.1.1-py3-none-any.whl", hash = "sha256:c8c5a44295039331ee9dad40ba100a9c7297b6f988e50e87ccdf3765a668350e", size = 20992, upload-time = "2025-01-14T17:02:02.417Z" }, +] + +[[package]] +name = "cryptography" +version = "46.0.5" +source = { registry = "https://pypi.org/simple" } +dependencies = [ + { name = "cffi", marker = "platform_python_implementation != 'PyPy'" }, + { name = "typing-extensions", marker = "python_full_version < '3.11'" }, +] +sdist = { url = "https://files.pythonhosted.org/packages/60/04/ee2a9e8542e4fa2773b81771ff8349ff19cdd56b7258a0cc442639052edb/cryptography-46.0.5.tar.gz", hash = "sha256:abace499247268e3757271b2f1e244b36b06f8515cf27c4d49468fc9eb16e93d", size = 750064, upload-time = "2026-02-10T19:18:38.255Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/f7/81/b0bb27f2ba931a65409c6b8a8b358a7f03c0e46eceacddff55f7c84b1f3b/cryptography-46.0.5-cp311-abi3-macosx_10_9_universal2.whl", hash = "sha256:351695ada9ea9618b3500b490ad54c739860883df6c1f555e088eaf25b1bbaad", size = 7176289, upload-time = "2026-02-10T19:17:08.274Z" }, + { url = "https://files.pythonhosted.org/packages/ff/9e/6b4397a3e3d15123de3b1806ef342522393d50736c13b20ec4c9ea6693a6/cryptography-46.0.5-cp311-abi3-manylinux2014_aarch64.manylinux_2_17_aarch64.whl", hash = "sha256:c18ff11e86df2e28854939acde2d003f7984f721eba450b56a200ad90eeb0e6b", size = 4275637, upload-time = "2026-02-10T19:17:10.53Z" }, + { url = "https://files.pythonhosted.org/packages/63/e7/471ab61099a3920b0c77852ea3f0ea611c9702f651600397ac567848b897/cryptography-46.0.5-cp311-abi3-manylinux2014_x86_64.manylinux_2_17_x86_64.whl", hash = "sha256:4d7e3d356b8cd4ea5aff04f129d5f66ebdc7b6f8eae802b93739ed520c47c79b", size = 4424742, upload-time = "2026-02-10T19:17:12.388Z" }, + { url = "https://files.pythonhosted.org/packages/37/53/a18500f270342d66bf7e4d9f091114e31e5ee9e7375a5aba2e85a91e0044/cryptography-46.0.5-cp311-abi3-manylinux_2_28_aarch64.whl", hash = "sha256:50bfb6925eff619c9c023b967d5b77a54e04256c4281b0e21336a130cd7fc263", size = 4277528, upload-time = "2026-02-10T19:17:13.853Z" }, + { url = "https://files.pythonhosted.org/packages/22/29/c2e812ebc38c57b40e7c583895e73c8c5adb4d1e4a0cc4c5a4fdab2b1acc/cryptography-46.0.5-cp311-abi3-manylinux_2_28_ppc64le.whl", hash = "sha256:803812e111e75d1aa73690d2facc295eaefd4439be1023fefc4995eaea2af90d", size = 4947993, upload-time = "2026-02-10T19:17:15.618Z" }, + { url = "https://files.pythonhosted.org/packages/6b/e7/237155ae19a9023de7e30ec64e5d99a9431a567407ac21170a046d22a5a3/cryptography-46.0.5-cp311-abi3-manylinux_2_28_x86_64.whl", hash = "sha256:3ee190460e2fbe447175cda91b88b84ae8322a104fc27766ad09428754a618ed", size = 4456855, upload-time = "2026-02-10T19:17:17.221Z" }, + { url = "https://files.pythonhosted.org/packages/2d/87/fc628a7ad85b81206738abbd213b07702bcbdada1dd43f72236ef3cffbb5/cryptography-46.0.5-cp311-abi3-manylinux_2_31_armv7l.whl", hash = "sha256:f145bba11b878005c496e93e257c1e88f154d278d2638e6450d17e0f31e558d2", size = 3984635, upload-time = "2026-02-10T19:17:18.792Z" }, + { url = "https://files.pythonhosted.org/packages/84/29/65b55622bde135aedf4565dc509d99b560ee4095e56989e815f8fd2aa910/cryptography-46.0.5-cp311-abi3-manylinux_2_34_aarch64.whl", hash = "sha256:e9251e3be159d1020c4030bd2e5f84d6a43fe54b6c19c12f51cde9542a2817b2", size = 4277038, upload-time = "2026-02-10T19:17:20.256Z" }, + { url = "https://files.pythonhosted.org/packages/bc/36/45e76c68d7311432741faf1fbf7fac8a196a0a735ca21f504c75d37e2558/cryptography-46.0.5-cp311-abi3-manylinux_2_34_ppc64le.whl", hash = "sha256:47fb8a66058b80e509c47118ef8a75d14c455e81ac369050f20ba0d23e77fee0", size = 4912181, upload-time = "2026-02-10T19:17:21.825Z" }, + { url = "https://files.pythonhosted.org/packages/6d/1a/c1ba8fead184d6e3d5afcf03d569acac5ad063f3ac9fb7258af158f7e378/cryptography-46.0.5-cp311-abi3-manylinux_2_34_x86_64.whl", hash = "sha256:4c3341037c136030cb46e4b1e17b7418ea4cbd9dd207e4a6f3b2b24e0d4ac731", size = 4456482, upload-time = "2026-02-10T19:17:25.133Z" }, + { url = "https://files.pythonhosted.org/packages/f9/e5/3fb22e37f66827ced3b902cf895e6a6bc1d095b5b26be26bd13c441fdf19/cryptography-46.0.5-cp311-abi3-musllinux_1_2_aarch64.whl", hash = "sha256:890bcb4abd5a2d3f852196437129eb3667d62630333aacc13dfd470fad3aaa82", size = 4405497, upload-time = "2026-02-10T19:17:26.66Z" }, + { url = "https://files.pythonhosted.org/packages/1a/df/9d58bb32b1121a8a2f27383fabae4d63080c7ca60b9b5c88be742be04ee7/cryptography-46.0.5-cp311-abi3-musllinux_1_2_x86_64.whl", hash = "sha256:80a8d7bfdf38f87ca30a5391c0c9ce4ed2926918e017c29ddf643d0ed2778ea1", size = 4667819, upload-time = "2026-02-10T19:17:28.569Z" }, + { url = "https://files.pythonhosted.org/packages/ea/ed/325d2a490c5e94038cdb0117da9397ece1f11201f425c4e9c57fe5b9f08b/cryptography-46.0.5-cp311-abi3-win32.whl", hash = "sha256:60ee7e19e95104d4c03871d7d7dfb3d22ef8a9b9c6778c94e1c8fcc8365afd48", size = 3028230, upload-time = "2026-02-10T19:17:30.518Z" }, + { url = "https://files.pythonhosted.org/packages/e9/5a/ac0f49e48063ab4255d9e3b79f5def51697fce1a95ea1370f03dc9db76f6/cryptography-46.0.5-cp311-abi3-win_amd64.whl", hash = "sha256:38946c54b16c885c72c4f59846be9743d699eee2b69b6988e0a00a01f46a61a4", size = 3480909, upload-time = "2026-02-10T19:17:32.083Z" }, + { url = "https://files.pythonhosted.org/packages/00/13/3d278bfa7a15a96b9dc22db5a12ad1e48a9eb3d40e1827ef66a5df75d0d0/cryptography-46.0.5-cp314-cp314t-macosx_10_9_universal2.whl", hash = "sha256:94a76daa32eb78d61339aff7952ea819b1734b46f73646a07decb40e5b3448e2", size = 7119287, upload-time = "2026-02-10T19:17:33.801Z" }, + { url = "https://files.pythonhosted.org/packages/67/c8/581a6702e14f0898a0848105cbefd20c058099e2c2d22ef4e476dfec75d7/cryptography-46.0.5-cp314-cp314t-manylinux2014_aarch64.manylinux_2_17_aarch64.whl", hash = "sha256:5be7bf2fb40769e05739dd0046e7b26f9d4670badc7b032d6ce4db64dddc0678", size = 4265728, upload-time = "2026-02-10T19:17:35.569Z" }, + { url = "https://files.pythonhosted.org/packages/dd/4a/ba1a65ce8fc65435e5a849558379896c957870dd64fecea97b1ad5f46a37/cryptography-46.0.5-cp314-cp314t-manylinux2014_x86_64.manylinux_2_17_x86_64.whl", hash = "sha256:fe346b143ff9685e40192a4960938545c699054ba11d4f9029f94751e3f71d87", size = 4408287, upload-time = "2026-02-10T19:17:36.938Z" }, + { url = "https://files.pythonhosted.org/packages/f8/67/8ffdbf7b65ed1ac224d1c2df3943553766914a8ca718747ee3871da6107e/cryptography-46.0.5-cp314-cp314t-manylinux_2_28_aarch64.whl", hash = "sha256:c69fd885df7d089548a42d5ec05be26050ebcd2283d89b3d30676eb32ff87dee", size = 4270291, upload-time = "2026-02-10T19:17:38.748Z" }, + { url = "https://files.pythonhosted.org/packages/f8/e5/f52377ee93bc2f2bba55a41a886fd208c15276ffbd2569f2ddc89d50e2c5/cryptography-46.0.5-cp314-cp314t-manylinux_2_28_ppc64le.whl", hash = "sha256:8293f3dea7fc929ef7240796ba231413afa7b68ce38fd21da2995549f5961981", size = 4927539, upload-time = "2026-02-10T19:17:40.241Z" }, + { url = "https://files.pythonhosted.org/packages/3b/02/cfe39181b02419bbbbcf3abdd16c1c5c8541f03ca8bda240debc467d5a12/cryptography-46.0.5-cp314-cp314t-manylinux_2_28_x86_64.whl", hash = "sha256:1abfdb89b41c3be0365328a410baa9df3ff8a9110fb75e7b52e66803ddabc9a9", size = 4442199, upload-time = "2026-02-10T19:17:41.789Z" }, + { url = "https://files.pythonhosted.org/packages/c0/96/2fcaeb4873e536cf71421a388a6c11b5bc846e986b2b069c79363dc1648e/cryptography-46.0.5-cp314-cp314t-manylinux_2_31_armv7l.whl", hash = "sha256:d66e421495fdb797610a08f43b05269e0a5ea7f5e652a89bfd5a7d3c1dee3648", size = 3960131, upload-time = "2026-02-10T19:17:43.379Z" }, + { url = "https://files.pythonhosted.org/packages/d8/d2/b27631f401ddd644e94c5cf33c9a4069f72011821cf3dc7309546b0642a0/cryptography-46.0.5-cp314-cp314t-manylinux_2_34_aarch64.whl", hash = "sha256:4e817a8920bfbcff8940ecfd60f23d01836408242b30f1a708d93198393a80b4", size = 4270072, upload-time = "2026-02-10T19:17:45.481Z" }, + { url = "https://files.pythonhosted.org/packages/f4/a7/60d32b0370dae0b4ebe55ffa10e8599a2a59935b5ece1b9f06edb73abdeb/cryptography-46.0.5-cp314-cp314t-manylinux_2_34_ppc64le.whl", hash = "sha256:68f68d13f2e1cb95163fa3b4db4bf9a159a418f5f6e7242564fc75fcae667fd0", size = 4892170, upload-time = "2026-02-10T19:17:46.997Z" }, + { url = "https://files.pythonhosted.org/packages/d2/b9/cf73ddf8ef1164330eb0b199a589103c363afa0cf794218c24d524a58eab/cryptography-46.0.5-cp314-cp314t-manylinux_2_34_x86_64.whl", hash = "sha256:a3d1fae9863299076f05cb8a778c467578262fae09f9dc0ee9b12eb4268ce663", size = 4441741, upload-time = "2026-02-10T19:17:48.661Z" }, + { url = "https://files.pythonhosted.org/packages/5f/eb/eee00b28c84c726fe8fa0158c65afe312d9c3b78d9d01daf700f1f6e37ff/cryptography-46.0.5-cp314-cp314t-musllinux_1_2_aarch64.whl", hash = "sha256:c4143987a42a2397f2fc3b4d7e3a7d313fbe684f67ff443999e803dd75a76826", size = 4396728, upload-time = "2026-02-10T19:17:50.058Z" }, + { url = "https://files.pythonhosted.org/packages/65/f4/6bc1a9ed5aef7145045114b75b77c2a8261b4d38717bd8dea111a63c3442/cryptography-46.0.5-cp314-cp314t-musllinux_1_2_x86_64.whl", hash = "sha256:7d731d4b107030987fd61a7f8ab512b25b53cef8f233a97379ede116f30eb67d", size = 4652001, upload-time = "2026-02-10T19:17:51.54Z" }, + { url = "https://files.pythonhosted.org/packages/86/ef/5d00ef966ddd71ac2e6951d278884a84a40ffbd88948ef0e294b214ae9e4/cryptography-46.0.5-cp314-cp314t-win32.whl", hash = "sha256:c3bcce8521d785d510b2aad26ae2c966092b7daa8f45dd8f44734a104dc0bc1a", size = 3003637, upload-time = "2026-02-10T19:17:52.997Z" }, + { url = "https://files.pythonhosted.org/packages/b7/57/f3f4160123da6d098db78350fdfd9705057aad21de7388eacb2401dceab9/cryptography-46.0.5-cp314-cp314t-win_amd64.whl", hash = "sha256:4d8ae8659ab18c65ced284993c2265910f6c9e650189d4e3f68445ef82a810e4", size = 3469487, upload-time = "2026-02-10T19:17:54.549Z" }, + { url = "https://files.pythonhosted.org/packages/e2/fa/a66aa722105ad6a458bebd64086ca2b72cdd361fed31763d20390f6f1389/cryptography-46.0.5-cp38-abi3-macosx_10_9_universal2.whl", hash = "sha256:4108d4c09fbbf2789d0c926eb4152ae1760d5a2d97612b92d508d96c861e4d31", size = 7170514, upload-time = "2026-02-10T19:17:56.267Z" }, + { url = "https://files.pythonhosted.org/packages/0f/04/c85bdeab78c8bc77b701bf0d9bdcf514c044e18a46dcff330df5448631b0/cryptography-46.0.5-cp38-abi3-manylinux2014_aarch64.manylinux_2_17_aarch64.whl", hash = "sha256:7d1f30a86d2757199cb2d56e48cce14deddf1f9c95f1ef1b64ee91ea43fe2e18", size = 4275349, upload-time = "2026-02-10T19:17:58.419Z" }, + { url = "https://files.pythonhosted.org/packages/5c/32/9b87132a2f91ee7f5223b091dc963055503e9b442c98fc0b8a5ca765fab0/cryptography-46.0.5-cp38-abi3-manylinux2014_x86_64.manylinux_2_17_x86_64.whl", hash = "sha256:039917b0dc418bb9f6edce8a906572d69e74bd330b0b3fea4f79dab7f8ddd235", size = 4420667, upload-time = "2026-02-10T19:18:00.619Z" }, + { url = "https://files.pythonhosted.org/packages/a1/a6/a7cb7010bec4b7c5692ca6f024150371b295ee1c108bdc1c400e4c44562b/cryptography-46.0.5-cp38-abi3-manylinux_2_28_aarch64.whl", hash = "sha256:ba2a27ff02f48193fc4daeadf8ad2590516fa3d0adeeb34336b96f7fa64c1e3a", size = 4276980, upload-time = "2026-02-10T19:18:02.379Z" }, + { url = "https://files.pythonhosted.org/packages/8e/7c/c4f45e0eeff9b91e3f12dbd0e165fcf2a38847288fcfd889deea99fb7b6d/cryptography-46.0.5-cp38-abi3-manylinux_2_28_ppc64le.whl", hash = "sha256:61aa400dce22cb001a98014f647dc21cda08f7915ceb95df0c9eaf84b4b6af76", size = 4939143, upload-time = "2026-02-10T19:18:03.964Z" }, + { url = "https://files.pythonhosted.org/packages/37/19/e1b8f964a834eddb44fa1b9a9976f4e414cbb7aa62809b6760c8803d22d1/cryptography-46.0.5-cp38-abi3-manylinux_2_28_x86_64.whl", hash = "sha256:3ce58ba46e1bc2aac4f7d9290223cead56743fa6ab94a5d53292ffaac6a91614", size = 4453674, upload-time = "2026-02-10T19:18:05.588Z" }, + { url = "https://files.pythonhosted.org/packages/db/ed/db15d3956f65264ca204625597c410d420e26530c4e2943e05a0d2f24d51/cryptography-46.0.5-cp38-abi3-manylinux_2_31_armv7l.whl", hash = "sha256:420d0e909050490d04359e7fdb5ed7e667ca5c3c402b809ae2563d7e66a92229", size = 3978801, upload-time = "2026-02-10T19:18:07.167Z" }, + { url = "https://files.pythonhosted.org/packages/41/e2/df40a31d82df0a70a0daf69791f91dbb70e47644c58581d654879b382d11/cryptography-46.0.5-cp38-abi3-manylinux_2_34_aarch64.whl", hash = "sha256:582f5fcd2afa31622f317f80426a027f30dc792e9c80ffee87b993200ea115f1", size = 4276755, upload-time = "2026-02-10T19:18:09.813Z" }, + { url = "https://files.pythonhosted.org/packages/33/45/726809d1176959f4a896b86907b98ff4391a8aa29c0aaaf9450a8a10630e/cryptography-46.0.5-cp38-abi3-manylinux_2_34_ppc64le.whl", hash = "sha256:bfd56bb4b37ed4f330b82402f6f435845a5f5648edf1ad497da51a8452d5d62d", size = 4901539, upload-time = "2026-02-10T19:18:11.263Z" }, + { url = "https://files.pythonhosted.org/packages/99/0f/a3076874e9c88ecb2ecc31382f6e7c21b428ede6f55aafa1aa272613e3cd/cryptography-46.0.5-cp38-abi3-manylinux_2_34_x86_64.whl", hash = "sha256:a3d507bb6a513ca96ba84443226af944b0f7f47dcc9a399d110cd6146481d24c", size = 4452794, upload-time = "2026-02-10T19:18:12.914Z" }, + { url = "https://files.pythonhosted.org/packages/02/ef/ffeb542d3683d24194a38f66ca17c0a4b8bf10631feef44a7ef64e631b1a/cryptography-46.0.5-cp38-abi3-musllinux_1_2_aarch64.whl", hash = "sha256:9f16fbdf4da055efb21c22d81b89f155f02ba420558db21288b3d0035bafd5f4", size = 4404160, upload-time = "2026-02-10T19:18:14.375Z" }, + { url = "https://files.pythonhosted.org/packages/96/93/682d2b43c1d5f1406ed048f377c0fc9fc8f7b0447a478d5c65ab3d3a66eb/cryptography-46.0.5-cp38-abi3-musllinux_1_2_x86_64.whl", hash = "sha256:ced80795227d70549a411a4ab66e8ce307899fad2220ce5ab2f296e687eacde9", size = 4667123, upload-time = "2026-02-10T19:18:15.886Z" }, + { url = "https://files.pythonhosted.org/packages/45/2d/9c5f2926cb5300a8eefc3f4f0b3f3df39db7f7ce40c8365444c49363cbda/cryptography-46.0.5-cp38-abi3-win32.whl", hash = "sha256:02f547fce831f5096c9a567fd41bc12ca8f11df260959ecc7c3202555cc47a72", size = 3010220, upload-time = "2026-02-10T19:18:17.361Z" }, + { url = "https://files.pythonhosted.org/packages/48/ef/0c2f4a8e31018a986949d34a01115dd057bf536905dca38897bacd21fac3/cryptography-46.0.5-cp38-abi3-win_amd64.whl", hash = "sha256:556e106ee01aa13484ce9b0239bca667be5004efb0aabbed28d353df86445595", size = 3467050, upload-time = "2026-02-10T19:18:18.899Z" }, + { url = "https://files.pythonhosted.org/packages/eb/dd/2d9fdb07cebdf3d51179730afb7d5e576153c6744c3ff8fded23030c204e/cryptography-46.0.5-pp311-pypy311_pp73-macosx_11_0_arm64.whl", hash = "sha256:3b4995dc971c9fb83c25aa44cf45f02ba86f71ee600d81091c2f0cbae116b06c", size = 3476964, upload-time = "2026-02-10T19:18:20.687Z" }, + { url = "https://files.pythonhosted.org/packages/e9/6f/6cc6cc9955caa6eaf83660b0da2b077c7fe8ff9950a3c5e45d605038d439/cryptography-46.0.5-pp311-pypy311_pp73-manylinux_2_28_aarch64.whl", hash = "sha256:bc84e875994c3b445871ea7181d424588171efec3e185dced958dad9e001950a", size = 4218321, upload-time = "2026-02-10T19:18:22.349Z" }, + { url = "https://files.pythonhosted.org/packages/3e/5d/c4da701939eeee699566a6c1367427ab91a8b7088cc2328c09dbee940415/cryptography-46.0.5-pp311-pypy311_pp73-manylinux_2_28_x86_64.whl", hash = "sha256:2ae6971afd6246710480e3f15824ed3029a60fc16991db250034efd0b9fb4356", size = 4381786, upload-time = "2026-02-10T19:18:24.529Z" }, + { url = "https://files.pythonhosted.org/packages/ac/97/a538654732974a94ff96c1db621fa464f455c02d4bb7d2652f4edc21d600/cryptography-46.0.5-pp311-pypy311_pp73-manylinux_2_34_aarch64.whl", hash = "sha256:d861ee9e76ace6cf36a6a89b959ec08e7bc2493ee39d07ffe5acb23ef46d27da", size = 4217990, upload-time = "2026-02-10T19:18:25.957Z" }, + { url = "https://files.pythonhosted.org/packages/ae/11/7e500d2dd3ba891197b9efd2da5454b74336d64a7cc419aa7327ab74e5f6/cryptography-46.0.5-pp311-pypy311_pp73-manylinux_2_34_x86_64.whl", hash = "sha256:2b7a67c9cd56372f3249b39699f2ad479f6991e62ea15800973b956f4b73e257", size = 4381252, upload-time = "2026-02-10T19:18:27.496Z" }, + { url = "https://files.pythonhosted.org/packages/bc/58/6b3d24e6b9bc474a2dcdee65dfd1f008867015408a271562e4b690561a4d/cryptography-46.0.5-pp311-pypy311_pp73-win_amd64.whl", hash = "sha256:8456928655f856c6e1533ff59d5be76578a7157224dbd9ce6872f25055ab9ab7", size = 3407605, upload-time = "2026-02-10T19:18:29.233Z" }, +] + +[[package]] +name = "filelock" +version = "3.19.1" +source = { registry = "https://pypi.org/simple" } +resolution-markers = [ + "python_full_version < '3.10'", +] +sdist = { url = "https://files.pythonhosted.org/packages/40/bb/0ab3e58d22305b6f5440629d20683af28959bf793d98d11950e305c1c326/filelock-3.19.1.tar.gz", hash = "sha256:66eda1888b0171c998b35be2bcc0f6d75c388a7ce20c3f3f37aa8e96c2dddf58", size = 17687, upload-time = "2025-08-14T16:56:03.016Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/42/14/42b2651a2f46b022ccd948bca9f2d5af0fd8929c4eec235b8d6d844fbe67/filelock-3.19.1-py3-none-any.whl", hash = "sha256:d38e30481def20772f5baf097c122c3babc4fcdb7e14e57049eb9d88c6dc017d", size = 15988, upload-time = "2025-08-14T16:56:01.633Z" }, +] + +[[package]] +name = "filelock" +version = "3.20.3" +source = { registry = "https://pypi.org/simple" } +resolution-markers = [ + "python_full_version >= '3.13'", + "python_full_version == '3.12.*'", + "python_full_version == '3.11.*'", + "python_full_version == '3.10.*'", +] +sdist = { url = "https://files.pythonhosted.org/packages/1d/65/ce7f1b70157833bf3cb851b556a37d4547ceafc158aa9b34b36782f23696/filelock-3.20.3.tar.gz", hash = "sha256:18c57ee915c7ec61cff0ecf7f0f869936c7c30191bb0cf406f1341778d0834e1", size = 19485, upload-time = "2026-01-09T17:55:05.421Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/b5/36/7fb70f04bf00bc646cd5bb45aa9eddb15e19437a28b8fb2b4a5249fac770/filelock-3.20.3-py3-none-any.whl", hash = "sha256:4b0dda527ee31078689fc205ec4f1c1bf7d56cf88b6dc9426c4f230e46c2dce1", size = 16701, upload-time = "2026-01-09T17:55:04.334Z" }, +] + +[[package]] +name = "idna" +version = "3.11" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/6f/6d/0703ccc57f3a7233505399edb88de3cbd678da106337b9fcde432b65ed60/idna-3.11.tar.gz", hash = "sha256:795dafcc9c04ed0c1fb032c2aa73654d8e8c5023a7df64a53f39190ada629902", size = 194582, upload-time = "2025-10-12T14:55:20.501Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/0e/61/66938bbb5fc52dbdf84594873d5b51fb1f7c7794e9c0f5bd885f30bc507b/idna-3.11-py3-none-any.whl", hash = "sha256:771a87f49d9defaf64091e6e6fe9c18d4833f140bd19464795bc32d966ca37ea", size = 71008, upload-time = "2025-10-12T14:55:18.883Z" }, +] + +[[package]] +name = "importlib-metadata" +version = "8.7.1" +source = { registry = "https://pypi.org/simple" } +dependencies = [ + { name = "zipp", marker = "python_full_version < '3.13'" }, +] +sdist = { url = "https://files.pythonhosted.org/packages/f3/49/3b30cad09e7771a4982d9975a8cbf64f00d4a1ececb53297f1d9a7be1b10/importlib_metadata-8.7.1.tar.gz", hash = "sha256:49fef1ae6440c182052f407c8d34a68f72efc36db9ca90dc0113398f2fdde8bb", size = 57107, upload-time = "2025-12-21T10:00:19.278Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/fa/5e/f8e9a1d23b9c20a551a8a02ea3637b4642e22c2626e3a13a9a29cdea99eb/importlib_metadata-8.7.1-py3-none-any.whl", hash = "sha256:5a1f80bf1daa489495071efbb095d75a634cf28a8bc299581244063b53176151", size = 27865, upload-time = "2025-12-21T10:00:18.329Z" }, +] + +[[package]] +name = "jaraco-classes" +version = "3.4.0" +source = { registry = "https://pypi.org/simple" } +dependencies = [ + { name = "more-itertools" }, +] +sdist = { url = "https://files.pythonhosted.org/packages/06/c0/ed4a27bc5571b99e3cff68f8a9fa5b56ff7df1c2251cc715a652ddd26402/jaraco.classes-3.4.0.tar.gz", hash = "sha256:47a024b51d0239c0dd8c8540c6c7f484be3b8fcf0b2d85c13825780d3b3f3acd", size = 11780, upload-time = "2024-03-31T07:27:36.643Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/7f/66/b15ce62552d84bbfcec9a4873ab79d993a1dd4edb922cbfccae192bd5b5f/jaraco.classes-3.4.0-py3-none-any.whl", hash = "sha256:f662826b6bed8cace05e7ff873ce0f9283b5c924470fe664fff1c2f00f581790", size = 6777, upload-time = "2024-03-31T07:27:34.792Z" }, +] + +[[package]] +name = "jaraco-context" +version = "6.1.0" +source = { registry = "https://pypi.org/simple" } +dependencies = [ + { name = "backports-tarfile", marker = "python_full_version < '3.12'" }, +] +sdist = { url = "https://files.pythonhosted.org/packages/cb/9c/a788f5bb29c61e456b8ee52ce76dbdd32fd72cd73dd67bc95f42c7a8d13c/jaraco_context-6.1.0.tar.gz", hash = "sha256:129a341b0a85a7db7879e22acd66902fda67882db771754574338898b2d5d86f", size = 15850, upload-time = "2026-01-13T02:53:53.847Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/8d/48/aa685dbf1024c7bd82bede569e3a85f82c32fd3d79ba5fea578f0159571a/jaraco_context-6.1.0-py3-none-any.whl", hash = "sha256:a43b5ed85815223d0d3cfdb6d7ca0d2bc8946f28f30b6f3216bda070f68badda", size = 7065, upload-time = "2026-01-13T02:53:53.031Z" }, +] + +[[package]] +name = "jaraco-functools" +version = "4.4.0" +source = { registry = "https://pypi.org/simple" } +dependencies = [ + { name = "more-itertools" }, +] +sdist = { url = "https://files.pythonhosted.org/packages/0f/27/056e0638a86749374d6f57d0b0db39f29509cce9313cf91bdc0ac4d91084/jaraco_functools-4.4.0.tar.gz", hash = "sha256:da21933b0417b89515562656547a77b4931f98176eb173644c0d35032a33d6bb", size = 19943, upload-time = "2025-12-21T09:29:43.6Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/fd/c4/813bb09f0985cb21e959f21f2464169eca882656849adf727ac7bb7e1767/jaraco_functools-4.4.0-py3-none-any.whl", hash = "sha256:9eec1e36f45c818d9bf307c8948eb03b2b56cd44087b3cdc989abca1f20b9176", size = 10481, upload-time = "2025-12-21T09:29:42.27Z" }, +] + +[[package]] +name = "jeepney" +version = "0.9.0" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/7b/6f/357efd7602486741aa73ffc0617fb310a29b588ed0fd69c2399acbb85b0c/jeepney-0.9.0.tar.gz", hash = "sha256:cf0e9e845622b81e4a28df94c40345400256ec608d0e55bb8a3feaa9163f5732", size = 106758, upload-time = "2025-02-27T18:51:01.684Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/b2/a3/e137168c9c44d18eff0376253da9f1e9234d0239e0ee230d2fee6cea8e55/jeepney-0.9.0-py3-none-any.whl", hash = "sha256:97e5714520c16fc0a45695e5365a2e11b81ea79bba796e26f9f1d178cb182683", size = 49010, upload-time = "2025-02-27T18:51:00.104Z" }, +] + +[[package]] +name = "jmespath" +version = "1.1.0" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/d3/59/322338183ecda247fb5d1763a6cbe46eff7222eaeebafd9fa65d4bf5cb11/jmespath-1.1.0.tar.gz", hash = "sha256:472c87d80f36026ae83c6ddd0f1d05d4e510134ed462851fd5f754c8c3cbb88d", size = 27377, upload-time = "2026-01-22T16:35:26.279Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/14/2f/967ba146e6d58cf6a652da73885f52fc68001525b4197effc174321d70b4/jmespath-1.1.0-py3-none-any.whl", hash = "sha256:a5663118de4908c91729bea0acadca56526eb2698e83de10cd116ae0f4e97c64", size = 20419, upload-time = "2026-01-22T16:35:24.919Z" }, +] + +[[package]] +name = "keyring" +version = "25.7.0" +source = { registry = "https://pypi.org/simple" } +dependencies = [ + { name = "importlib-metadata", marker = "python_full_version < '3.12'" }, + { name = "jaraco-classes" }, + { name = "jaraco-context" }, + { name = "jaraco-functools" }, + { name = "jeepney", marker = "sys_platform == 'linux'" }, + { name = "pywin32-ctypes", marker = "sys_platform == 'win32'" }, + { name = "secretstorage", version = "3.3.3", source = { registry = "https://pypi.org/simple" }, marker = "python_full_version < '3.10' and sys_platform == 'linux'" }, + { name = "secretstorage", version = "3.5.0", source = { registry = "https://pypi.org/simple" }, marker = "python_full_version >= '3.10' and sys_platform == 'linux'" }, +] +sdist = { url = "https://files.pythonhosted.org/packages/43/4b/674af6ef2f97d56f0ab5153bf0bfa28ccb6c3ed4d1babf4305449668807b/keyring-25.7.0.tar.gz", hash = "sha256:fe01bd85eb3f8fb3dd0405defdeac9a5b4f6f0439edbb3149577f244a2e8245b", size = 63516, upload-time = "2025-11-16T16:26:09.482Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/81/db/e655086b7f3a705df045bf0933bdd9c2f79bb3c97bfef1384598bb79a217/keyring-25.7.0-py3-none-any.whl", hash = "sha256:be4a0b195f149690c166e850609a477c532ddbfbaed96a404d4e43f8d5e2689f", size = 39160, upload-time = "2025-11-16T16:26:08.402Z" }, +] + +[[package]] +name = "more-itertools" +version = "10.8.0" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/ea/5d/38b681d3fce7a266dd9ab73c66959406d565b3e85f21d5e66e1181d93721/more_itertools-10.8.0.tar.gz", hash = "sha256:f638ddf8a1a0d134181275fb5d58b086ead7c6a72429ad725c67503f13ba30bd", size = 137431, upload-time = "2025-09-02T15:23:11.018Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/a4/8e/469e5a4a2f5855992e425f3cb33804cc07bf18d48f2db061aec61ce50270/more_itertools-10.8.0-py3-none-any.whl", hash = "sha256:52d4362373dcf7c52546bc4af9a86ee7c4579df9a8dc268be0a2f949d376cc9b", size = 69667, upload-time = "2025-09-02T15:23:09.635Z" }, +] + +[[package]] +name = "numpy" +version = "2.0.2" +source = { registry = "https://pypi.org/simple" } +resolution-markers = [ + "python_full_version < '3.10'", +] +sdist = { url = "https://files.pythonhosted.org/packages/a9/75/10dd1f8116a8b796cb2c737b674e02d02e80454bda953fa7e65d8c12b016/numpy-2.0.2.tar.gz", hash = "sha256:883c987dee1880e2a864ab0dc9892292582510604156762362d9326444636e78", size = 18902015, upload-time = "2024-08-26T20:19:40.945Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/21/91/3495b3237510f79f5d81f2508f9f13fea78ebfdf07538fc7444badda173d/numpy-2.0.2-cp310-cp310-macosx_10_9_x86_64.whl", hash = "sha256:51129a29dbe56f9ca83438b706e2e69a39892b5eda6cedcb6b0c9fdc9b0d3ece", size = 21165245, upload-time = "2024-08-26T20:04:14.625Z" }, + { url = "https://files.pythonhosted.org/packages/05/33/26178c7d437a87082d11019292dce6d3fe6f0e9026b7b2309cbf3e489b1d/numpy-2.0.2-cp310-cp310-macosx_11_0_arm64.whl", hash = "sha256:f15975dfec0cf2239224d80e32c3170b1d168335eaedee69da84fbe9f1f9cd04", size = 13738540, upload-time = "2024-08-26T20:04:36.784Z" }, + { url = "https://files.pythonhosted.org/packages/ec/31/cc46e13bf07644efc7a4bf68df2df5fb2a1a88d0cd0da9ddc84dc0033e51/numpy-2.0.2-cp310-cp310-macosx_14_0_arm64.whl", hash = "sha256:8c5713284ce4e282544c68d1c3b2c7161d38c256d2eefc93c1d683cf47683e66", size = 5300623, upload-time = "2024-08-26T20:04:46.491Z" }, + { url = "https://files.pythonhosted.org/packages/6e/16/7bfcebf27bb4f9d7ec67332ffebee4d1bf085c84246552d52dbb548600e7/numpy-2.0.2-cp310-cp310-macosx_14_0_x86_64.whl", hash = "sha256:becfae3ddd30736fe1889a37f1f580e245ba79a5855bff5f2a29cb3ccc22dd7b", size = 6901774, upload-time = "2024-08-26T20:04:58.173Z" }, + { url = "https://files.pythonhosted.org/packages/f9/a3/561c531c0e8bf082c5bef509d00d56f82e0ea7e1e3e3a7fc8fa78742a6e5/numpy-2.0.2-cp310-cp310-manylinux_2_17_aarch64.manylinux2014_aarch64.whl", hash = "sha256:2da5960c3cf0df7eafefd806d4e612c5e19358de82cb3c343631188991566ccd", size = 13907081, upload-time = "2024-08-26T20:05:19.098Z" }, + { url = "https://files.pythonhosted.org/packages/fa/66/f7177ab331876200ac7563a580140643d1179c8b4b6a6b0fc9838de2a9b8/numpy-2.0.2-cp310-cp310-manylinux_2_17_x86_64.manylinux2014_x86_64.whl", hash = "sha256:496f71341824ed9f3d2fd36cf3ac57ae2e0165c143b55c3a035ee219413f3318", size = 19523451, upload-time = "2024-08-26T20:05:47.479Z" }, + { url = "https://files.pythonhosted.org/packages/25/7f/0b209498009ad6453e4efc2c65bcdf0ae08a182b2b7877d7ab38a92dc542/numpy-2.0.2-cp310-cp310-musllinux_1_1_x86_64.whl", hash = "sha256:a61ec659f68ae254e4d237816e33171497e978140353c0c2038d46e63282d0c8", size = 19927572, upload-time = "2024-08-26T20:06:17.137Z" }, + { url = "https://files.pythonhosted.org/packages/3e/df/2619393b1e1b565cd2d4c4403bdd979621e2c4dea1f8532754b2598ed63b/numpy-2.0.2-cp310-cp310-musllinux_1_2_aarch64.whl", hash = "sha256:d731a1c6116ba289c1e9ee714b08a8ff882944d4ad631fd411106a30f083c326", size = 14400722, upload-time = "2024-08-26T20:06:39.16Z" }, + { url = "https://files.pythonhosted.org/packages/22/ad/77e921b9f256d5da36424ffb711ae79ca3f451ff8489eeca544d0701d74a/numpy-2.0.2-cp310-cp310-win32.whl", hash = "sha256:984d96121c9f9616cd33fbd0618b7f08e0cfc9600a7ee1d6fd9b239186d19d97", size = 6472170, upload-time = "2024-08-26T20:06:50.361Z" }, + { url = "https://files.pythonhosted.org/packages/10/05/3442317535028bc29cf0c0dd4c191a4481e8376e9f0db6bcf29703cadae6/numpy-2.0.2-cp310-cp310-win_amd64.whl", hash = "sha256:c7b0be4ef08607dd04da4092faee0b86607f111d5ae68036f16cc787e250a131", size = 15905558, upload-time = "2024-08-26T20:07:13.881Z" }, + { url = "https://files.pythonhosted.org/packages/8b/cf/034500fb83041aa0286e0fb16e7c76e5c8b67c0711bb6e9e9737a717d5fe/numpy-2.0.2-cp311-cp311-macosx_10_9_x86_64.whl", hash = "sha256:49ca4decb342d66018b01932139c0961a8f9ddc7589611158cb3c27cbcf76448", size = 21169137, upload-time = "2024-08-26T20:07:45.345Z" }, + { url = "https://files.pythonhosted.org/packages/4a/d9/32de45561811a4b87fbdee23b5797394e3d1504b4a7cf40c10199848893e/numpy-2.0.2-cp311-cp311-macosx_11_0_arm64.whl", hash = "sha256:11a76c372d1d37437857280aa142086476136a8c0f373b2e648ab2c8f18fb195", size = 13703552, upload-time = "2024-08-26T20:08:06.666Z" }, + { url = "https://files.pythonhosted.org/packages/c1/ca/2f384720020c7b244d22508cb7ab23d95f179fcfff33c31a6eeba8d6c512/numpy-2.0.2-cp311-cp311-macosx_14_0_arm64.whl", hash = "sha256:807ec44583fd708a21d4a11d94aedf2f4f3c3719035c76a2bbe1fe8e217bdc57", size = 5298957, upload-time = "2024-08-26T20:08:15.83Z" }, + { url = "https://files.pythonhosted.org/packages/0e/78/a3e4f9fb6aa4e6fdca0c5428e8ba039408514388cf62d89651aade838269/numpy-2.0.2-cp311-cp311-macosx_14_0_x86_64.whl", hash = "sha256:8cafab480740e22f8d833acefed5cc87ce276f4ece12fdaa2e8903db2f82897a", size = 6905573, upload-time = "2024-08-26T20:08:27.185Z" }, + { url = "https://files.pythonhosted.org/packages/a0/72/cfc3a1beb2caf4efc9d0b38a15fe34025230da27e1c08cc2eb9bfb1c7231/numpy-2.0.2-cp311-cp311-manylinux_2_17_aarch64.manylinux2014_aarch64.whl", hash = "sha256:a15f476a45e6e5a3a79d8a14e62161d27ad897381fecfa4a09ed5322f2085669", size = 13914330, upload-time = "2024-08-26T20:08:48.058Z" }, + { url = "https://files.pythonhosted.org/packages/ba/a8/c17acf65a931ce551fee11b72e8de63bf7e8a6f0e21add4c937c83563538/numpy-2.0.2-cp311-cp311-manylinux_2_17_x86_64.manylinux2014_x86_64.whl", hash = "sha256:13e689d772146140a252c3a28501da66dfecd77490b498b168b501835041f951", size = 19534895, upload-time = "2024-08-26T20:09:16.536Z" }, + { url = "https://files.pythonhosted.org/packages/ba/86/8767f3d54f6ae0165749f84648da9dcc8cd78ab65d415494962c86fac80f/numpy-2.0.2-cp311-cp311-musllinux_1_1_x86_64.whl", hash = "sha256:9ea91dfb7c3d1c56a0e55657c0afb38cf1eeae4544c208dc465c3c9f3a7c09f9", size = 19937253, upload-time = "2024-08-26T20:09:46.263Z" }, + { url = "https://files.pythonhosted.org/packages/df/87/f76450e6e1c14e5bb1eae6836478b1028e096fd02e85c1c37674606ab752/numpy-2.0.2-cp311-cp311-musllinux_1_2_aarch64.whl", hash = "sha256:c1c9307701fec8f3f7a1e6711f9089c06e6284b3afbbcd259f7791282d660a15", size = 14414074, upload-time = "2024-08-26T20:10:08.483Z" }, + { url = "https://files.pythonhosted.org/packages/5c/ca/0f0f328e1e59f73754f06e1adfb909de43726d4f24c6a3f8805f34f2b0fa/numpy-2.0.2-cp311-cp311-win32.whl", hash = "sha256:a392a68bd329eafac5817e5aefeb39038c48b671afd242710b451e76090e81f4", size = 6470640, upload-time = "2024-08-26T20:10:19.732Z" }, + { url = "https://files.pythonhosted.org/packages/eb/57/3a3f14d3a759dcf9bf6e9eda905794726b758819df4663f217d658a58695/numpy-2.0.2-cp311-cp311-win_amd64.whl", hash = "sha256:286cd40ce2b7d652a6f22efdfc6d1edf879440e53e76a75955bc0c826c7e64dc", size = 15910230, upload-time = "2024-08-26T20:10:43.413Z" }, + { url = "https://files.pythonhosted.org/packages/45/40/2e117be60ec50d98fa08c2f8c48e09b3edea93cfcabd5a9ff6925d54b1c2/numpy-2.0.2-cp312-cp312-macosx_10_9_x86_64.whl", hash = "sha256:df55d490dea7934f330006d0f81e8551ba6010a5bf035a249ef61a94f21c500b", size = 20895803, upload-time = "2024-08-26T20:11:13.916Z" }, + { url = "https://files.pythonhosted.org/packages/46/92/1b8b8dee833f53cef3e0a3f69b2374467789e0bb7399689582314df02651/numpy-2.0.2-cp312-cp312-macosx_11_0_arm64.whl", hash = "sha256:8df823f570d9adf0978347d1f926b2a867d5608f434a7cff7f7908c6570dcf5e", size = 13471835, upload-time = "2024-08-26T20:11:34.779Z" }, + { url = "https://files.pythonhosted.org/packages/7f/19/e2793bde475f1edaea6945be141aef6c8b4c669b90c90a300a8954d08f0a/numpy-2.0.2-cp312-cp312-macosx_14_0_arm64.whl", hash = "sha256:9a92ae5c14811e390f3767053ff54eaee3bf84576d99a2456391401323f4ec2c", size = 5038499, upload-time = "2024-08-26T20:11:43.902Z" }, + { url = "https://files.pythonhosted.org/packages/e3/ff/ddf6dac2ff0dd50a7327bcdba45cb0264d0e96bb44d33324853f781a8f3c/numpy-2.0.2-cp312-cp312-macosx_14_0_x86_64.whl", hash = "sha256:a842d573724391493a97a62ebbb8e731f8a5dcc5d285dfc99141ca15a3302d0c", size = 6633497, upload-time = "2024-08-26T20:11:55.09Z" }, + { url = "https://files.pythonhosted.org/packages/72/21/67f36eac8e2d2cd652a2e69595a54128297cdcb1ff3931cfc87838874bd4/numpy-2.0.2-cp312-cp312-manylinux_2_17_aarch64.manylinux2014_aarch64.whl", hash = "sha256:c05e238064fc0610c840d1cf6a13bf63d7e391717d247f1bf0318172e759e692", size = 13621158, upload-time = "2024-08-26T20:12:14.95Z" }, + { url = "https://files.pythonhosted.org/packages/39/68/e9f1126d757653496dbc096cb429014347a36b228f5a991dae2c6b6cfd40/numpy-2.0.2-cp312-cp312-manylinux_2_17_x86_64.manylinux2014_x86_64.whl", hash = "sha256:0123ffdaa88fa4ab64835dcbde75dcdf89c453c922f18dced6e27c90d1d0ec5a", size = 19236173, upload-time = "2024-08-26T20:12:44.049Z" }, + { url = "https://files.pythonhosted.org/packages/d1/e9/1f5333281e4ebf483ba1c888b1d61ba7e78d7e910fdd8e6499667041cc35/numpy-2.0.2-cp312-cp312-musllinux_1_1_x86_64.whl", hash = "sha256:96a55f64139912d61de9137f11bf39a55ec8faec288c75a54f93dfd39f7eb40c", size = 19634174, upload-time = "2024-08-26T20:13:13.634Z" }, + { url = "https://files.pythonhosted.org/packages/71/af/a469674070c8d8408384e3012e064299f7a2de540738a8e414dcfd639996/numpy-2.0.2-cp312-cp312-musllinux_1_2_aarch64.whl", hash = "sha256:ec9852fb39354b5a45a80bdab5ac02dd02b15f44b3804e9f00c556bf24b4bded", size = 14099701, upload-time = "2024-08-26T20:13:34.851Z" }, + { url = "https://files.pythonhosted.org/packages/d0/3d/08ea9f239d0e0e939b6ca52ad403c84a2bce1bde301a8eb4888c1c1543f1/numpy-2.0.2-cp312-cp312-win32.whl", hash = "sha256:671bec6496f83202ed2d3c8fdc486a8fc86942f2e69ff0e986140339a63bcbe5", size = 6174313, upload-time = "2024-08-26T20:13:45.653Z" }, + { url = "https://files.pythonhosted.org/packages/b2/b5/4ac39baebf1fdb2e72585c8352c56d063b6126be9fc95bd2bb5ef5770c20/numpy-2.0.2-cp312-cp312-win_amd64.whl", hash = "sha256:cfd41e13fdc257aa5778496b8caa5e856dc4896d4ccf01841daee1d96465467a", size = 15606179, upload-time = "2024-08-26T20:14:08.786Z" }, + { url = "https://files.pythonhosted.org/packages/43/c1/41c8f6df3162b0c6ffd4437d729115704bd43363de0090c7f913cfbc2d89/numpy-2.0.2-cp39-cp39-macosx_10_9_x86_64.whl", hash = "sha256:9059e10581ce4093f735ed23f3b9d283b9d517ff46009ddd485f1747eb22653c", size = 21169942, upload-time = "2024-08-26T20:14:40.108Z" }, + { url = "https://files.pythonhosted.org/packages/39/bc/fd298f308dcd232b56a4031fd6ddf11c43f9917fbc937e53762f7b5a3bb1/numpy-2.0.2-cp39-cp39-macosx_11_0_arm64.whl", hash = "sha256:423e89b23490805d2a5a96fe40ec507407b8ee786d66f7328be214f9679df6dd", size = 13711512, upload-time = "2024-08-26T20:15:00.985Z" }, + { url = "https://files.pythonhosted.org/packages/96/ff/06d1aa3eeb1c614eda245c1ba4fb88c483bee6520d361641331872ac4b82/numpy-2.0.2-cp39-cp39-macosx_14_0_arm64.whl", hash = "sha256:2b2955fa6f11907cf7a70dab0d0755159bca87755e831e47932367fc8f2f2d0b", size = 5306976, upload-time = "2024-08-26T20:15:10.876Z" }, + { url = "https://files.pythonhosted.org/packages/2d/98/121996dcfb10a6087a05e54453e28e58694a7db62c5a5a29cee14c6e047b/numpy-2.0.2-cp39-cp39-macosx_14_0_x86_64.whl", hash = "sha256:97032a27bd9d8988b9a97a8c4d2c9f2c15a81f61e2f21404d7e8ef00cb5be729", size = 6906494, upload-time = "2024-08-26T20:15:22.055Z" }, + { url = "https://files.pythonhosted.org/packages/15/31/9dffc70da6b9bbf7968f6551967fc21156207366272c2a40b4ed6008dc9b/numpy-2.0.2-cp39-cp39-manylinux_2_17_aarch64.manylinux2014_aarch64.whl", hash = "sha256:1e795a8be3ddbac43274f18588329c72939870a16cae810c2b73461c40718ab1", size = 13912596, upload-time = "2024-08-26T20:15:42.452Z" }, + { url = "https://files.pythonhosted.org/packages/b9/14/78635daab4b07c0930c919d451b8bf8c164774e6a3413aed04a6d95758ce/numpy-2.0.2-cp39-cp39-manylinux_2_17_x86_64.manylinux2014_x86_64.whl", hash = "sha256:f26b258c385842546006213344c50655ff1555a9338e2e5e02a0756dc3e803dd", size = 19526099, upload-time = "2024-08-26T20:16:11.048Z" }, + { url = "https://files.pythonhosted.org/packages/26/4c/0eeca4614003077f68bfe7aac8b7496f04221865b3a5e7cb230c9d055afd/numpy-2.0.2-cp39-cp39-musllinux_1_1_x86_64.whl", hash = "sha256:5fec9451a7789926bcf7c2b8d187292c9f93ea30284802a0ab3f5be8ab36865d", size = 19932823, upload-time = "2024-08-26T20:16:40.171Z" }, + { url = "https://files.pythonhosted.org/packages/f1/46/ea25b98b13dccaebddf1a803f8c748680d972e00507cd9bc6dcdb5aa2ac1/numpy-2.0.2-cp39-cp39-musllinux_1_2_aarch64.whl", hash = "sha256:9189427407d88ff25ecf8f12469d4d39d35bee1db5d39fc5c168c6f088a6956d", size = 14404424, upload-time = "2024-08-26T20:17:02.604Z" }, + { url = "https://files.pythonhosted.org/packages/c8/a6/177dd88d95ecf07e722d21008b1b40e681a929eb9e329684d449c36586b2/numpy-2.0.2-cp39-cp39-win32.whl", hash = "sha256:905d16e0c60200656500c95b6b8dca5d109e23cb24abc701d41c02d74c6b3afa", size = 6476809, upload-time = "2024-08-26T20:17:13.553Z" }, + { url = "https://files.pythonhosted.org/packages/ea/2b/7fc9f4e7ae5b507c1a3a21f0f15ed03e794c1242ea8a242ac158beb56034/numpy-2.0.2-cp39-cp39-win_amd64.whl", hash = "sha256:a3f4ab0caa7f053f6797fcd4e1e25caee367db3112ef2b6ef82d749530768c73", size = 15911314, upload-time = "2024-08-26T20:17:36.72Z" }, + { url = "https://files.pythonhosted.org/packages/8f/3b/df5a870ac6a3be3a86856ce195ef42eec7ae50d2a202be1f5a4b3b340e14/numpy-2.0.2-pp39-pypy39_pp73-macosx_10_9_x86_64.whl", hash = "sha256:7f0a0c6f12e07fa94133c8a67404322845220c06a9e80e85999afe727f7438b8", size = 21025288, upload-time = "2024-08-26T20:18:07.732Z" }, + { url = "https://files.pythonhosted.org/packages/2c/97/51af92f18d6f6f2d9ad8b482a99fb74e142d71372da5d834b3a2747a446e/numpy-2.0.2-pp39-pypy39_pp73-macosx_14_0_x86_64.whl", hash = "sha256:312950fdd060354350ed123c0e25a71327d3711584beaef30cdaa93320c392d4", size = 6762793, upload-time = "2024-08-26T20:18:19.125Z" }, + { url = "https://files.pythonhosted.org/packages/12/46/de1fbd0c1b5ccaa7f9a005b66761533e2f6a3e560096682683a223631fe9/numpy-2.0.2-pp39-pypy39_pp73-manylinux_2_17_x86_64.manylinux2014_x86_64.whl", hash = "sha256:26df23238872200f63518dd2aa984cfca675d82469535dc7162dc2ee52d9dd5c", size = 19334885, upload-time = "2024-08-26T20:18:47.237Z" }, + { url = "https://files.pythonhosted.org/packages/cc/dc/d330a6faefd92b446ec0f0dfea4c3207bb1fef3c4771d19cf4543efd2c78/numpy-2.0.2-pp39-pypy39_pp73-win_amd64.whl", hash = "sha256:a46288ec55ebbd58947d31d72be2c63cbf839f0a63b49cb755022310792a3385", size = 15828784, upload-time = "2024-08-26T20:19:11.19Z" }, +] + +[[package]] +name = "numpy" +version = "2.2.6" +source = { registry = "https://pypi.org/simple" } +resolution-markers = [ + "python_full_version == '3.10.*'", +] +sdist = { url = "https://files.pythonhosted.org/packages/76/21/7d2a95e4bba9dc13d043ee156a356c0a8f0c6309dff6b21b4d71a073b8a8/numpy-2.2.6.tar.gz", hash = "sha256:e29554e2bef54a90aa5cc07da6ce955accb83f21ab5de01a62c8478897b264fd", size = 20276440, upload-time = "2025-05-17T22:38:04.611Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/9a/3e/ed6db5be21ce87955c0cbd3009f2803f59fa08df21b5df06862e2d8e2bdd/numpy-2.2.6-cp310-cp310-macosx_10_9_x86_64.whl", hash = "sha256:b412caa66f72040e6d268491a59f2c43bf03eb6c96dd8f0307829feb7fa2b6fb", size = 21165245, upload-time = "2025-05-17T21:27:58.555Z" }, + { url = "https://files.pythonhosted.org/packages/22/c2/4b9221495b2a132cc9d2eb862e21d42a009f5a60e45fc44b00118c174bff/numpy-2.2.6-cp310-cp310-macosx_11_0_arm64.whl", hash = "sha256:8e41fd67c52b86603a91c1a505ebaef50b3314de0213461c7a6e99c9a3beff90", size = 14360048, upload-time = "2025-05-17T21:28:21.406Z" }, + { url = "https://files.pythonhosted.org/packages/fd/77/dc2fcfc66943c6410e2bf598062f5959372735ffda175b39906d54f02349/numpy-2.2.6-cp310-cp310-macosx_14_0_arm64.whl", hash = "sha256:37e990a01ae6ec7fe7fa1c26c55ecb672dd98b19c3d0e1d1f326fa13cb38d163", size = 5340542, upload-time = "2025-05-17T21:28:30.931Z" }, + { url = "https://files.pythonhosted.org/packages/7a/4f/1cb5fdc353a5f5cc7feb692db9b8ec2c3d6405453f982435efc52561df58/numpy-2.2.6-cp310-cp310-macosx_14_0_x86_64.whl", hash = "sha256:5a6429d4be8ca66d889b7cf70f536a397dc45ba6faeb5f8c5427935d9592e9cf", size = 6878301, upload-time = "2025-05-17T21:28:41.613Z" }, + { url = "https://files.pythonhosted.org/packages/eb/17/96a3acd228cec142fcb8723bd3cc39c2a474f7dcf0a5d16731980bcafa95/numpy-2.2.6-cp310-cp310-manylinux_2_17_aarch64.manylinux2014_aarch64.whl", hash = "sha256:efd28d4e9cd7d7a8d39074a4d44c63eda73401580c5c76acda2ce969e0a38e83", size = 14297320, upload-time = "2025-05-17T21:29:02.78Z" }, + { url = "https://files.pythonhosted.org/packages/b4/63/3de6a34ad7ad6646ac7d2f55ebc6ad439dbbf9c4370017c50cf403fb19b5/numpy-2.2.6-cp310-cp310-manylinux_2_17_x86_64.manylinux2014_x86_64.whl", hash = "sha256:fc7b73d02efb0e18c000e9ad8b83480dfcd5dfd11065997ed4c6747470ae8915", size = 16801050, upload-time = "2025-05-17T21:29:27.675Z" }, + { url = "https://files.pythonhosted.org/packages/07/b6/89d837eddef52b3d0cec5c6ba0456c1bf1b9ef6a6672fc2b7873c3ec4e2e/numpy-2.2.6-cp310-cp310-musllinux_1_2_aarch64.whl", hash = "sha256:74d4531beb257d2c3f4b261bfb0fc09e0f9ebb8842d82a7b4209415896adc680", size = 15807034, upload-time = "2025-05-17T21:29:51.102Z" }, + { url = "https://files.pythonhosted.org/packages/01/c8/dc6ae86e3c61cfec1f178e5c9f7858584049b6093f843bca541f94120920/numpy-2.2.6-cp310-cp310-musllinux_1_2_x86_64.whl", hash = "sha256:8fc377d995680230e83241d8a96def29f204b5782f371c532579b4f20607a289", size = 18614185, upload-time = "2025-05-17T21:30:18.703Z" }, + { url = "https://files.pythonhosted.org/packages/5b/c5/0064b1b7e7c89137b471ccec1fd2282fceaae0ab3a9550f2568782d80357/numpy-2.2.6-cp310-cp310-win32.whl", hash = "sha256:b093dd74e50a8cba3e873868d9e93a85b78e0daf2e98c6797566ad8044e8363d", size = 6527149, upload-time = "2025-05-17T21:30:29.788Z" }, + { url = "https://files.pythonhosted.org/packages/a3/dd/4b822569d6b96c39d1215dbae0582fd99954dcbcf0c1a13c61783feaca3f/numpy-2.2.6-cp310-cp310-win_amd64.whl", hash = "sha256:f0fd6321b839904e15c46e0d257fdd101dd7f530fe03fd6359c1ea63738703f3", size = 12904620, upload-time = "2025-05-17T21:30:48.994Z" }, + { url = "https://files.pythonhosted.org/packages/da/a8/4f83e2aa666a9fbf56d6118faaaf5f1974d456b1823fda0a176eff722839/numpy-2.2.6-cp311-cp311-macosx_10_9_x86_64.whl", hash = "sha256:f9f1adb22318e121c5c69a09142811a201ef17ab257a1e66ca3025065b7f53ae", size = 21176963, upload-time = "2025-05-17T21:31:19.36Z" }, + { url = "https://files.pythonhosted.org/packages/b3/2b/64e1affc7972decb74c9e29e5649fac940514910960ba25cd9af4488b66c/numpy-2.2.6-cp311-cp311-macosx_11_0_arm64.whl", hash = "sha256:c820a93b0255bc360f53eca31a0e676fd1101f673dda8da93454a12e23fc5f7a", size = 14406743, upload-time = "2025-05-17T21:31:41.087Z" }, + { url = "https://files.pythonhosted.org/packages/4a/9f/0121e375000b5e50ffdd8b25bf78d8e1a5aa4cca3f185d41265198c7b834/numpy-2.2.6-cp311-cp311-macosx_14_0_arm64.whl", hash = "sha256:3d70692235e759f260c3d837193090014aebdf026dfd167834bcba43e30c2a42", size = 5352616, upload-time = "2025-05-17T21:31:50.072Z" }, + { url = "https://files.pythonhosted.org/packages/31/0d/b48c405c91693635fbe2dcd7bc84a33a602add5f63286e024d3b6741411c/numpy-2.2.6-cp311-cp311-macosx_14_0_x86_64.whl", hash = "sha256:481b49095335f8eed42e39e8041327c05b0f6f4780488f61286ed3c01368d491", size = 6889579, upload-time = "2025-05-17T21:32:01.712Z" }, + { url = "https://files.pythonhosted.org/packages/52/b8/7f0554d49b565d0171eab6e99001846882000883998e7b7d9f0d98b1f934/numpy-2.2.6-cp311-cp311-manylinux_2_17_aarch64.manylinux2014_aarch64.whl", hash = "sha256:b64d8d4d17135e00c8e346e0a738deb17e754230d7e0810ac5012750bbd85a5a", size = 14312005, upload-time = "2025-05-17T21:32:23.332Z" }, + { url = "https://files.pythonhosted.org/packages/b3/dd/2238b898e51bd6d389b7389ffb20d7f4c10066d80351187ec8e303a5a475/numpy-2.2.6-cp311-cp311-manylinux_2_17_x86_64.manylinux2014_x86_64.whl", hash = "sha256:ba10f8411898fc418a521833e014a77d3ca01c15b0c6cdcce6a0d2897e6dbbdf", size = 16821570, upload-time = "2025-05-17T21:32:47.991Z" }, + { url = "https://files.pythonhosted.org/packages/83/6c/44d0325722cf644f191042bf47eedad61c1e6df2432ed65cbe28509d404e/numpy-2.2.6-cp311-cp311-musllinux_1_2_aarch64.whl", hash = "sha256:bd48227a919f1bafbdda0583705e547892342c26fb127219d60a5c36882609d1", size = 15818548, upload-time = "2025-05-17T21:33:11.728Z" }, + { url = "https://files.pythonhosted.org/packages/ae/9d/81e8216030ce66be25279098789b665d49ff19eef08bfa8cb96d4957f422/numpy-2.2.6-cp311-cp311-musllinux_1_2_x86_64.whl", hash = "sha256:9551a499bf125c1d4f9e250377c1ee2eddd02e01eac6644c080162c0c51778ab", size = 18620521, upload-time = "2025-05-17T21:33:39.139Z" }, + { url = "https://files.pythonhosted.org/packages/6a/fd/e19617b9530b031db51b0926eed5345ce8ddc669bb3bc0044b23e275ebe8/numpy-2.2.6-cp311-cp311-win32.whl", hash = "sha256:0678000bb9ac1475cd454c6b8c799206af8107e310843532b04d49649c717a47", size = 6525866, upload-time = "2025-05-17T21:33:50.273Z" }, + { url = "https://files.pythonhosted.org/packages/31/0a/f354fb7176b81747d870f7991dc763e157a934c717b67b58456bc63da3df/numpy-2.2.6-cp311-cp311-win_amd64.whl", hash = "sha256:e8213002e427c69c45a52bbd94163084025f533a55a59d6f9c5b820774ef3303", size = 12907455, upload-time = "2025-05-17T21:34:09.135Z" }, + { url = "https://files.pythonhosted.org/packages/82/5d/c00588b6cf18e1da539b45d3598d3557084990dcc4331960c15ee776ee41/numpy-2.2.6-cp312-cp312-macosx_10_13_x86_64.whl", hash = "sha256:41c5a21f4a04fa86436124d388f6ed60a9343a6f767fced1a8a71c3fbca038ff", size = 20875348, upload-time = "2025-05-17T21:34:39.648Z" }, + { url = "https://files.pythonhosted.org/packages/66/ee/560deadcdde6c2f90200450d5938f63a34b37e27ebff162810f716f6a230/numpy-2.2.6-cp312-cp312-macosx_11_0_arm64.whl", hash = "sha256:de749064336d37e340f640b05f24e9e3dd678c57318c7289d222a8a2f543e90c", size = 14119362, upload-time = "2025-05-17T21:35:01.241Z" }, + { url = "https://files.pythonhosted.org/packages/3c/65/4baa99f1c53b30adf0acd9a5519078871ddde8d2339dc5a7fde80d9d87da/numpy-2.2.6-cp312-cp312-macosx_14_0_arm64.whl", hash = "sha256:894b3a42502226a1cac872f840030665f33326fc3dac8e57c607905773cdcde3", size = 5084103, upload-time = "2025-05-17T21:35:10.622Z" }, + { url = "https://files.pythonhosted.org/packages/cc/89/e5a34c071a0570cc40c9a54eb472d113eea6d002e9ae12bb3a8407fb912e/numpy-2.2.6-cp312-cp312-macosx_14_0_x86_64.whl", hash = "sha256:71594f7c51a18e728451bb50cc60a3ce4e6538822731b2933209a1f3614e9282", size = 6625382, upload-time = "2025-05-17T21:35:21.414Z" }, + { url = "https://files.pythonhosted.org/packages/f8/35/8c80729f1ff76b3921d5c9487c7ac3de9b2a103b1cd05e905b3090513510/numpy-2.2.6-cp312-cp312-manylinux_2_17_aarch64.manylinux2014_aarch64.whl", hash = "sha256:f2618db89be1b4e05f7a1a847a9c1c0abd63e63a1607d892dd54668dd92faf87", size = 14018462, upload-time = "2025-05-17T21:35:42.174Z" }, + { url = "https://files.pythonhosted.org/packages/8c/3d/1e1db36cfd41f895d266b103df00ca5b3cbe965184df824dec5c08c6b803/numpy-2.2.6-cp312-cp312-manylinux_2_17_x86_64.manylinux2014_x86_64.whl", hash = "sha256:fd83c01228a688733f1ded5201c678f0c53ecc1006ffbc404db9f7a899ac6249", size = 16527618, upload-time = "2025-05-17T21:36:06.711Z" }, + { url = "https://files.pythonhosted.org/packages/61/c6/03ed30992602c85aa3cd95b9070a514f8b3c33e31124694438d88809ae36/numpy-2.2.6-cp312-cp312-musllinux_1_2_aarch64.whl", hash = "sha256:37c0ca431f82cd5fa716eca9506aefcabc247fb27ba69c5062a6d3ade8cf8f49", size = 15505511, upload-time = "2025-05-17T21:36:29.965Z" }, + { url = "https://files.pythonhosted.org/packages/b7/25/5761d832a81df431e260719ec45de696414266613c9ee268394dd5ad8236/numpy-2.2.6-cp312-cp312-musllinux_1_2_x86_64.whl", hash = "sha256:fe27749d33bb772c80dcd84ae7e8df2adc920ae8297400dabec45f0dedb3f6de", size = 18313783, upload-time = "2025-05-17T21:36:56.883Z" }, + { url = "https://files.pythonhosted.org/packages/57/0a/72d5a3527c5ebffcd47bde9162c39fae1f90138c961e5296491ce778e682/numpy-2.2.6-cp312-cp312-win32.whl", hash = "sha256:4eeaae00d789f66c7a25ac5f34b71a7035bb474e679f410e5e1a94deb24cf2d4", size = 6246506, upload-time = "2025-05-17T21:37:07.368Z" }, + { url = "https://files.pythonhosted.org/packages/36/fa/8c9210162ca1b88529ab76b41ba02d433fd54fecaf6feb70ef9f124683f1/numpy-2.2.6-cp312-cp312-win_amd64.whl", hash = "sha256:c1f9540be57940698ed329904db803cf7a402f3fc200bfe599334c9bd84a40b2", size = 12614190, upload-time = "2025-05-17T21:37:26.213Z" }, + { url = "https://files.pythonhosted.org/packages/f9/5c/6657823f4f594f72b5471f1db1ab12e26e890bb2e41897522d134d2a3e81/numpy-2.2.6-cp313-cp313-macosx_10_13_x86_64.whl", hash = "sha256:0811bb762109d9708cca4d0b13c4f67146e3c3b7cf8d34018c722adb2d957c84", size = 20867828, upload-time = "2025-05-17T21:37:56.699Z" }, + { url = "https://files.pythonhosted.org/packages/dc/9e/14520dc3dadf3c803473bd07e9b2bd1b69bc583cb2497b47000fed2fa92f/numpy-2.2.6-cp313-cp313-macosx_11_0_arm64.whl", hash = "sha256:287cc3162b6f01463ccd86be154f284d0893d2b3ed7292439ea97eafa8170e0b", size = 14143006, upload-time = "2025-05-17T21:38:18.291Z" }, + { url = "https://files.pythonhosted.org/packages/4f/06/7e96c57d90bebdce9918412087fc22ca9851cceaf5567a45c1f404480e9e/numpy-2.2.6-cp313-cp313-macosx_14_0_arm64.whl", hash = "sha256:f1372f041402e37e5e633e586f62aa53de2eac8d98cbfb822806ce4bbefcb74d", size = 5076765, upload-time = "2025-05-17T21:38:27.319Z" }, + { url = "https://files.pythonhosted.org/packages/73/ed/63d920c23b4289fdac96ddbdd6132e9427790977d5457cd132f18e76eae0/numpy-2.2.6-cp313-cp313-macosx_14_0_x86_64.whl", hash = "sha256:55a4d33fa519660d69614a9fad433be87e5252f4b03850642f88993f7b2ca566", size = 6617736, upload-time = "2025-05-17T21:38:38.141Z" }, + { url = "https://files.pythonhosted.org/packages/85/c5/e19c8f99d83fd377ec8c7e0cf627a8049746da54afc24ef0a0cb73d5dfb5/numpy-2.2.6-cp313-cp313-manylinux_2_17_aarch64.manylinux2014_aarch64.whl", hash = "sha256:f92729c95468a2f4f15e9bb94c432a9229d0d50de67304399627a943201baa2f", size = 14010719, upload-time = "2025-05-17T21:38:58.433Z" }, + { url = "https://files.pythonhosted.org/packages/19/49/4df9123aafa7b539317bf6d342cb6d227e49f7a35b99c287a6109b13dd93/numpy-2.2.6-cp313-cp313-manylinux_2_17_x86_64.manylinux2014_x86_64.whl", hash = "sha256:1bc23a79bfabc5d056d106f9befb8d50c31ced2fbc70eedb8155aec74a45798f", size = 16526072, upload-time = "2025-05-17T21:39:22.638Z" }, + { url = "https://files.pythonhosted.org/packages/b2/6c/04b5f47f4f32f7c2b0e7260442a8cbcf8168b0e1a41ff1495da42f42a14f/numpy-2.2.6-cp313-cp313-musllinux_1_2_aarch64.whl", hash = "sha256:e3143e4451880bed956e706a3220b4e5cf6172ef05fcc397f6f36a550b1dd868", size = 15503213, upload-time = "2025-05-17T21:39:45.865Z" }, + { url = "https://files.pythonhosted.org/packages/17/0a/5cd92e352c1307640d5b6fec1b2ffb06cd0dabe7d7b8227f97933d378422/numpy-2.2.6-cp313-cp313-musllinux_1_2_x86_64.whl", hash = "sha256:b4f13750ce79751586ae2eb824ba7e1e8dba64784086c98cdbbcc6a42112ce0d", size = 18316632, upload-time = "2025-05-17T21:40:13.331Z" }, + { url = "https://files.pythonhosted.org/packages/f0/3b/5cba2b1d88760ef86596ad0f3d484b1cbff7c115ae2429678465057c5155/numpy-2.2.6-cp313-cp313-win32.whl", hash = "sha256:5beb72339d9d4fa36522fc63802f469b13cdbe4fdab4a288f0c441b74272ebfd", size = 6244532, upload-time = "2025-05-17T21:43:46.099Z" }, + { url = "https://files.pythonhosted.org/packages/cb/3b/d58c12eafcb298d4e6d0d40216866ab15f59e55d148a5658bb3132311fcf/numpy-2.2.6-cp313-cp313-win_amd64.whl", hash = "sha256:b0544343a702fa80c95ad5d3d608ea3599dd54d4632df855e4c8d24eb6ecfa1c", size = 12610885, upload-time = "2025-05-17T21:44:05.145Z" }, + { url = "https://files.pythonhosted.org/packages/6b/9e/4bf918b818e516322db999ac25d00c75788ddfd2d2ade4fa66f1f38097e1/numpy-2.2.6-cp313-cp313t-macosx_10_13_x86_64.whl", hash = "sha256:0bca768cd85ae743b2affdc762d617eddf3bcf8724435498a1e80132d04879e6", size = 20963467, upload-time = "2025-05-17T21:40:44Z" }, + { url = "https://files.pythonhosted.org/packages/61/66/d2de6b291507517ff2e438e13ff7b1e2cdbdb7cb40b3ed475377aece69f9/numpy-2.2.6-cp313-cp313t-macosx_11_0_arm64.whl", hash = "sha256:fc0c5673685c508a142ca65209b4e79ed6740a4ed6b2267dbba90f34b0b3cfda", size = 14225144, upload-time = "2025-05-17T21:41:05.695Z" }, + { url = "https://files.pythonhosted.org/packages/e4/25/480387655407ead912e28ba3a820bc69af9adf13bcbe40b299d454ec011f/numpy-2.2.6-cp313-cp313t-macosx_14_0_arm64.whl", hash = "sha256:5bd4fc3ac8926b3819797a7c0e2631eb889b4118a9898c84f585a54d475b7e40", size = 5200217, upload-time = "2025-05-17T21:41:15.903Z" }, + { url = "https://files.pythonhosted.org/packages/aa/4a/6e313b5108f53dcbf3aca0c0f3e9c92f4c10ce57a0a721851f9785872895/numpy-2.2.6-cp313-cp313t-macosx_14_0_x86_64.whl", hash = "sha256:fee4236c876c4e8369388054d02d0e9bb84821feb1a64dd59e137e6511a551f8", size = 6712014, upload-time = "2025-05-17T21:41:27.321Z" }, + { url = "https://files.pythonhosted.org/packages/b7/30/172c2d5c4be71fdf476e9de553443cf8e25feddbe185e0bd88b096915bcc/numpy-2.2.6-cp313-cp313t-manylinux_2_17_aarch64.manylinux2014_aarch64.whl", hash = "sha256:e1dda9c7e08dc141e0247a5b8f49cf05984955246a327d4c48bda16821947b2f", size = 14077935, upload-time = "2025-05-17T21:41:49.738Z" }, + { url = "https://files.pythonhosted.org/packages/12/fb/9e743f8d4e4d3c710902cf87af3512082ae3d43b945d5d16563f26ec251d/numpy-2.2.6-cp313-cp313t-manylinux_2_17_x86_64.manylinux2014_x86_64.whl", hash = "sha256:f447e6acb680fd307f40d3da4852208af94afdfab89cf850986c3ca00562f4fa", size = 16600122, upload-time = "2025-05-17T21:42:14.046Z" }, + { url = "https://files.pythonhosted.org/packages/12/75/ee20da0e58d3a66f204f38916757e01e33a9737d0b22373b3eb5a27358f9/numpy-2.2.6-cp313-cp313t-musllinux_1_2_aarch64.whl", hash = "sha256:389d771b1623ec92636b0786bc4ae56abafad4a4c513d36a55dce14bd9ce8571", size = 15586143, upload-time = "2025-05-17T21:42:37.464Z" }, + { url = "https://files.pythonhosted.org/packages/76/95/bef5b37f29fc5e739947e9ce5179ad402875633308504a52d188302319c8/numpy-2.2.6-cp313-cp313t-musllinux_1_2_x86_64.whl", hash = "sha256:8e9ace4a37db23421249ed236fdcdd457d671e25146786dfc96835cd951aa7c1", size = 18385260, upload-time = "2025-05-17T21:43:05.189Z" }, + { url = "https://files.pythonhosted.org/packages/09/04/f2f83279d287407cf36a7a8053a5abe7be3622a4363337338f2585e4afda/numpy-2.2.6-cp313-cp313t-win32.whl", hash = "sha256:038613e9fb8c72b0a41f025a7e4c3f0b7a1b5d768ece4796b674c8f3fe13efff", size = 6377225, upload-time = "2025-05-17T21:43:16.254Z" }, + { url = "https://files.pythonhosted.org/packages/67/0e/35082d13c09c02c011cf21570543d202ad929d961c02a147493cb0c2bdf5/numpy-2.2.6-cp313-cp313t-win_amd64.whl", hash = "sha256:6031dd6dfecc0cf9f668681a37648373bddd6421fff6c66ec1624eed0180ee06", size = 12771374, upload-time = "2025-05-17T21:43:35.479Z" }, + { url = "https://files.pythonhosted.org/packages/9e/3b/d94a75f4dbf1ef5d321523ecac21ef23a3cd2ac8b78ae2aac40873590229/numpy-2.2.6-pp310-pypy310_pp73-macosx_10_15_x86_64.whl", hash = "sha256:0b605b275d7bd0c640cad4e5d30fa701a8d59302e127e5f79138ad62762c3e3d", size = 21040391, upload-time = "2025-05-17T21:44:35.948Z" }, + { url = "https://files.pythonhosted.org/packages/17/f4/09b2fa1b58f0fb4f7c7963a1649c64c4d315752240377ed74d9cd878f7b5/numpy-2.2.6-pp310-pypy310_pp73-macosx_14_0_x86_64.whl", hash = "sha256:7befc596a7dc9da8a337f79802ee8adb30a552a94f792b9c9d18c840055907db", size = 6786754, upload-time = "2025-05-17T21:44:47.446Z" }, + { url = "https://files.pythonhosted.org/packages/af/30/feba75f143bdc868a1cc3f44ccfa6c4b9ec522b36458e738cd00f67b573f/numpy-2.2.6-pp310-pypy310_pp73-manylinux_2_17_x86_64.manylinux2014_x86_64.whl", hash = "sha256:ce47521a4754c8f4593837384bd3424880629f718d87c5d44f8ed763edd63543", size = 16643476, upload-time = "2025-05-17T21:45:11.871Z" }, + { url = "https://files.pythonhosted.org/packages/37/48/ac2a9584402fb6c0cd5b5d1a91dcf176b15760130dd386bbafdbfe3640bf/numpy-2.2.6-pp310-pypy310_pp73-win_amd64.whl", hash = "sha256:d042d24c90c41b54fd506da306759e06e568864df8ec17ccc17e9e884634fd00", size = 12812666, upload-time = "2025-05-17T21:45:31.426Z" }, +] + +[[package]] +name = "numpy" +version = "2.4.2" +source = { registry = "https://pypi.org/simple" } +resolution-markers = [ + "python_full_version >= '3.13'", + "python_full_version == '3.12.*'", + "python_full_version == '3.11.*'", +] +sdist = { url = "https://files.pythonhosted.org/packages/57/fd/0005efbd0af48e55eb3c7208af93f2862d4b1a56cd78e84309a2d959208d/numpy-2.4.2.tar.gz", hash = "sha256:659a6107e31a83c4e33f763942275fd278b21d095094044eb35569e86a21ddae", size = 20723651, upload-time = "2026-01-31T23:13:10.135Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/d3/44/71852273146957899753e69986246d6a176061ea183407e95418c2aa4d9a/numpy-2.4.2-cp311-cp311-macosx_10_9_x86_64.whl", hash = "sha256:e7e88598032542bd49af7c4747541422884219056c268823ef6e5e89851c8825", size = 16955478, upload-time = "2026-01-31T23:10:25.623Z" }, + { url = "https://files.pythonhosted.org/packages/74/41/5d17d4058bd0cd96bcbd4d9ff0fb2e21f52702aab9a72e4a594efa18692f/numpy-2.4.2-cp311-cp311-macosx_11_0_arm64.whl", hash = "sha256:7edc794af8b36ca37ef5fcb5e0d128c7e0595c7b96a2318d1badb6fcd8ee86b1", size = 14965467, upload-time = "2026-01-31T23:10:28.186Z" }, + { url = "https://files.pythonhosted.org/packages/49/48/fb1ce8136c19452ed15f033f8aee91d5defe515094e330ce368a0647846f/numpy-2.4.2-cp311-cp311-macosx_14_0_arm64.whl", hash = "sha256:6e9f61981ace1360e42737e2bae58b27bf28a1b27e781721047d84bd754d32e7", size = 5475172, upload-time = "2026-01-31T23:10:30.848Z" }, + { url = "https://files.pythonhosted.org/packages/40/a9/3feb49f17bbd1300dd2570432961f5c8a4ffeff1db6f02c7273bd020a4c9/numpy-2.4.2-cp311-cp311-macosx_14_0_x86_64.whl", hash = "sha256:cb7bbb88aa74908950d979eeaa24dbdf1a865e3c7e45ff0121d8f70387b55f73", size = 6805145, upload-time = "2026-01-31T23:10:32.352Z" }, + { url = "https://files.pythonhosted.org/packages/3f/39/fdf35cbd6d6e2fcad42fcf85ac04a85a0d0fbfbf34b30721c98d602fd70a/numpy-2.4.2-cp311-cp311-manylinux_2_27_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:4f069069931240b3fc703f1e23df63443dbd6390614c8c44a87d96cd0ec81eb1", size = 15966084, upload-time = "2026-01-31T23:10:34.502Z" }, + { url = "https://files.pythonhosted.org/packages/1b/46/6fa4ea94f1ddf969b2ee941290cca6f1bfac92b53c76ae5f44afe17ceb69/numpy-2.4.2-cp311-cp311-manylinux_2_27_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:c02ef4401a506fb60b411467ad501e1429a3487abca4664871d9ae0b46c8ba32", size = 16899477, upload-time = "2026-01-31T23:10:37.075Z" }, + { url = "https://files.pythonhosted.org/packages/09/a1/2a424e162b1a14a5bd860a464ab4e07513916a64ab1683fae262f735ccd2/numpy-2.4.2-cp311-cp311-musllinux_1_2_aarch64.whl", hash = "sha256:2653de5c24910e49c2b106499803124dde62a5a1fe0eedeaecf4309a5f639390", size = 17323429, upload-time = "2026-01-31T23:10:39.704Z" }, + { url = "https://files.pythonhosted.org/packages/ce/a2/73014149ff250628df72c58204822ac01d768697913881aacf839ff78680/numpy-2.4.2-cp311-cp311-musllinux_1_2_x86_64.whl", hash = "sha256:1ae241bbfc6ae276f94a170b14785e561cb5e7f626b6688cf076af4110887413", size = 18635109, upload-time = "2026-01-31T23:10:41.924Z" }, + { url = "https://files.pythonhosted.org/packages/6c/0c/73e8be2f1accd56df74abc1c5e18527822067dced5ec0861b5bb882c2ce0/numpy-2.4.2-cp311-cp311-win32.whl", hash = "sha256:df1b10187212b198dd45fa943d8985a3c8cf854aed4923796e0e019e113a1bda", size = 6237915, upload-time = "2026-01-31T23:10:45.26Z" }, + { url = "https://files.pythonhosted.org/packages/76/ae/e0265e0163cf127c24c3969d29f1c4c64551a1e375d95a13d32eab25d364/numpy-2.4.2-cp311-cp311-win_amd64.whl", hash = "sha256:b9c618d56a29c9cb1c4da979e9899be7578d2e0b3c24d52079c166324c9e8695", size = 12607972, upload-time = "2026-01-31T23:10:47.021Z" }, + { url = "https://files.pythonhosted.org/packages/29/a5/c43029af9b8014d6ea157f192652c50042e8911f4300f8f6ed3336bf437f/numpy-2.4.2-cp311-cp311-win_arm64.whl", hash = "sha256:47c5a6ed21d9452b10227e5e8a0e1c22979811cad7dcc19d8e3e2fb8fa03f1a3", size = 10485763, upload-time = "2026-01-31T23:10:50.087Z" }, + { url = "https://files.pythonhosted.org/packages/51/6e/6f394c9c77668153e14d4da83bcc247beb5952f6ead7699a1a2992613bea/numpy-2.4.2-cp312-cp312-macosx_10_13_x86_64.whl", hash = "sha256:21982668592194c609de53ba4933a7471880ccbaadcc52352694a59ecc860b3a", size = 16667963, upload-time = "2026-01-31T23:10:52.147Z" }, + { url = "https://files.pythonhosted.org/packages/1f/f8/55483431f2b2fd015ae6ed4fe62288823ce908437ed49db5a03d15151678/numpy-2.4.2-cp312-cp312-macosx_11_0_arm64.whl", hash = "sha256:40397bda92382fcec844066efb11f13e1c9a3e2a8e8f318fb72ed8b6db9f60f1", size = 14693571, upload-time = "2026-01-31T23:10:54.789Z" }, + { url = "https://files.pythonhosted.org/packages/2f/20/18026832b1845cdc82248208dd929ca14c9d8f2bac391f67440707fff27c/numpy-2.4.2-cp312-cp312-macosx_14_0_arm64.whl", hash = "sha256:b3a24467af63c67829bfaa61eecf18d5432d4f11992688537be59ecd6ad32f5e", size = 5203469, upload-time = "2026-01-31T23:10:57.343Z" }, + { url = "https://files.pythonhosted.org/packages/7d/33/2eb97c8a77daaba34eaa3fa7241a14ac5f51c46a6bd5911361b644c4a1e2/numpy-2.4.2-cp312-cp312-macosx_14_0_x86_64.whl", hash = "sha256:805cc8de9fd6e7a22da5aed858e0ab16be5a4db6c873dde1d7451c541553aa27", size = 6550820, upload-time = "2026-01-31T23:10:59.429Z" }, + { url = "https://files.pythonhosted.org/packages/b1/91/b97fdfd12dc75b02c44e26c6638241cc004d4079a0321a69c62f51470c4c/numpy-2.4.2-cp312-cp312-manylinux_2_27_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:6d82351358ffbcdcd7b686b90742a9b86632d6c1c051016484fa0b326a0a1548", size = 15663067, upload-time = "2026-01-31T23:11:01.291Z" }, + { url = "https://files.pythonhosted.org/packages/f5/c6/a18e59f3f0b8071cc85cbc8d80cd02d68aa9710170b2553a117203d46936/numpy-2.4.2-cp312-cp312-manylinux_2_27_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:9e35d3e0144137d9fdae62912e869136164534d64a169f86438bc9561b6ad49f", size = 16619782, upload-time = "2026-01-31T23:11:03.669Z" }, + { url = "https://files.pythonhosted.org/packages/b7/83/9751502164601a79e18847309f5ceec0b1446d7b6aa12305759b72cf98b2/numpy-2.4.2-cp312-cp312-musllinux_1_2_aarch64.whl", hash = "sha256:adb6ed2ad29b9e15321d167d152ee909ec73395901b70936f029c3bc6d7f4460", size = 17013128, upload-time = "2026-01-31T23:11:05.913Z" }, + { url = "https://files.pythonhosted.org/packages/61/c4/c4066322256ec740acc1c8923a10047818691d2f8aec254798f3dd90f5f2/numpy-2.4.2-cp312-cp312-musllinux_1_2_x86_64.whl", hash = "sha256:8906e71fd8afcb76580404e2a950caef2685df3d2a57fe82a86ac8d33cc007ba", size = 18345324, upload-time = "2026-01-31T23:11:08.248Z" }, + { url = "https://files.pythonhosted.org/packages/ab/af/6157aa6da728fa4525a755bfad486ae7e3f76d4c1864138003eb84328497/numpy-2.4.2-cp312-cp312-win32.whl", hash = "sha256:ec055f6dae239a6299cace477b479cca2fc125c5675482daf1dd886933a1076f", size = 5960282, upload-time = "2026-01-31T23:11:10.497Z" }, + { url = "https://files.pythonhosted.org/packages/92/0f/7ceaaeaacb40567071e94dbf2c9480c0ae453d5bb4f52bea3892c39dc83c/numpy-2.4.2-cp312-cp312-win_amd64.whl", hash = "sha256:209fae046e62d0ce6435fcfe3b1a10537e858249b3d9b05829e2a05218296a85", size = 12314210, upload-time = "2026-01-31T23:11:12.176Z" }, + { url = "https://files.pythonhosted.org/packages/2f/a3/56c5c604fae6dd40fa2ed3040d005fca97e91bd320d232ac9931d77ba13c/numpy-2.4.2-cp312-cp312-win_arm64.whl", hash = "sha256:fbde1b0c6e81d56f5dccd95dd4a711d9b95df1ae4009a60887e56b27e8d903fa", size = 10220171, upload-time = "2026-01-31T23:11:14.684Z" }, + { url = "https://files.pythonhosted.org/packages/a1/22/815b9fe25d1d7ae7d492152adbc7226d3eff731dffc38fe970589fcaaa38/numpy-2.4.2-cp313-cp313-macosx_10_13_x86_64.whl", hash = "sha256:25f2059807faea4b077a2b6837391b5d830864b3543627f381821c646f31a63c", size = 16663696, upload-time = "2026-01-31T23:11:17.516Z" }, + { url = "https://files.pythonhosted.org/packages/09/f0/817d03a03f93ba9c6c8993de509277d84e69f9453601915e4a69554102a1/numpy-2.4.2-cp313-cp313-macosx_11_0_arm64.whl", hash = "sha256:bd3a7a9f5847d2fb8c2c6d1c862fa109c31a9abeca1a3c2bd5a64572955b2979", size = 14688322, upload-time = "2026-01-31T23:11:19.883Z" }, + { url = "https://files.pythonhosted.org/packages/da/b4/f805ab79293c728b9a99438775ce51885fd4f31b76178767cfc718701a39/numpy-2.4.2-cp313-cp313-macosx_14_0_arm64.whl", hash = "sha256:8e4549f8a3c6d13d55041925e912bfd834285ef1dd64d6bc7d542583355e2e98", size = 5198157, upload-time = "2026-01-31T23:11:22.375Z" }, + { url = "https://files.pythonhosted.org/packages/74/09/826e4289844eccdcd64aac27d13b0fd3f32039915dd5b9ba01baae1f436c/numpy-2.4.2-cp313-cp313-macosx_14_0_x86_64.whl", hash = "sha256:aea4f66ff44dfddf8c2cffd66ba6538c5ec67d389285292fe428cb2c738c8aef", size = 6546330, upload-time = "2026-01-31T23:11:23.958Z" }, + { url = "https://files.pythonhosted.org/packages/19/fb/cbfdbfa3057a10aea5422c558ac57538e6acc87ec1669e666d32ac198da7/numpy-2.4.2-cp313-cp313-manylinux_2_27_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:c3cd545784805de05aafe1dde61752ea49a359ccba9760c1e5d1c88a93bbf2b7", size = 15660968, upload-time = "2026-01-31T23:11:25.713Z" }, + { url = "https://files.pythonhosted.org/packages/04/dc/46066ce18d01645541f0186877377b9371b8fa8017fa8262002b4ef22612/numpy-2.4.2-cp313-cp313-manylinux_2_27_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:d0d9b7c93578baafcbc5f0b83eaf17b79d345c6f36917ba0c67f45226911d499", size = 16607311, upload-time = "2026-01-31T23:11:28.117Z" }, + { url = "https://files.pythonhosted.org/packages/14/d9/4b5adfc39a43fa6bf918c6d544bc60c05236cc2f6339847fc5b35e6cb5b0/numpy-2.4.2-cp313-cp313-musllinux_1_2_aarch64.whl", hash = "sha256:f74f0f7779cc7ae07d1810aab8ac6b1464c3eafb9e283a40da7309d5e6e48fbb", size = 17012850, upload-time = "2026-01-31T23:11:30.888Z" }, + { url = "https://files.pythonhosted.org/packages/b7/20/adb6e6adde6d0130046e6fdfb7675cc62bc2f6b7b02239a09eb58435753d/numpy-2.4.2-cp313-cp313-musllinux_1_2_x86_64.whl", hash = "sha256:c7ac672d699bf36275c035e16b65539931347d68b70667d28984c9fb34e07fa7", size = 18334210, upload-time = "2026-01-31T23:11:33.214Z" }, + { url = "https://files.pythonhosted.org/packages/78/0e/0a73b3dff26803a8c02baa76398015ea2a5434d9b8265a7898a6028c1591/numpy-2.4.2-cp313-cp313-win32.whl", hash = "sha256:8e9afaeb0beff068b4d9cd20d322ba0ee1cecfb0b08db145e4ab4dd44a6b5110", size = 5958199, upload-time = "2026-01-31T23:11:35.385Z" }, + { url = "https://files.pythonhosted.org/packages/43/bc/6352f343522fcb2c04dbaf94cb30cca6fd32c1a750c06ad6231b4293708c/numpy-2.4.2-cp313-cp313-win_amd64.whl", hash = "sha256:7df2de1e4fba69a51c06c28f5a3de36731eb9639feb8e1cf7e4a7b0daf4cf622", size = 12310848, upload-time = "2026-01-31T23:11:38.001Z" }, + { url = "https://files.pythonhosted.org/packages/6e/8d/6da186483e308da5da1cc6918ce913dcfe14ffde98e710bfeff2a6158d4e/numpy-2.4.2-cp313-cp313-win_arm64.whl", hash = "sha256:0fece1d1f0a89c16b03442eae5c56dc0be0c7883b5d388e0c03f53019a4bfd71", size = 10221082, upload-time = "2026-01-31T23:11:40.392Z" }, + { url = "https://files.pythonhosted.org/packages/25/a1/9510aa43555b44781968935c7548a8926274f815de42ad3997e9e83680dd/numpy-2.4.2-cp313-cp313t-macosx_11_0_arm64.whl", hash = "sha256:5633c0da313330fd20c484c78cdd3f9b175b55e1a766c4a174230c6b70ad8262", size = 14815866, upload-time = "2026-01-31T23:11:42.495Z" }, + { url = "https://files.pythonhosted.org/packages/36/30/6bbb5e76631a5ae46e7923dd16ca9d3f1c93cfa8d4ed79a129814a9d8db3/numpy-2.4.2-cp313-cp313t-macosx_14_0_arm64.whl", hash = "sha256:d9f64d786b3b1dd742c946c42d15b07497ed14af1a1f3ce840cce27daa0ce913", size = 5325631, upload-time = "2026-01-31T23:11:44.7Z" }, + { url = "https://files.pythonhosted.org/packages/46/00/3a490938800c1923b567b3a15cd17896e68052e2145d8662aaf3e1ffc58f/numpy-2.4.2-cp313-cp313t-macosx_14_0_x86_64.whl", hash = "sha256:b21041e8cb6a1eb5312dd1d2f80a94d91efffb7a06b70597d44f1bd2dfc315ab", size = 6646254, upload-time = "2026-01-31T23:11:46.341Z" }, + { url = "https://files.pythonhosted.org/packages/d3/e9/fac0890149898a9b609caa5af7455a948b544746e4b8fe7c212c8edd71f8/numpy-2.4.2-cp313-cp313t-manylinux_2_27_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:00ab83c56211a1d7c07c25e3217ea6695e50a3e2f255053686b081dc0b091a82", size = 15720138, upload-time = "2026-01-31T23:11:48.082Z" }, + { url = "https://files.pythonhosted.org/packages/ea/5c/08887c54e68e1e28df53709f1893ce92932cc6f01f7c3d4dc952f61ffd4e/numpy-2.4.2-cp313-cp313t-manylinux_2_27_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:2fb882da679409066b4603579619341c6d6898fc83a8995199d5249f986e8e8f", size = 16655398, upload-time = "2026-01-31T23:11:50.293Z" }, + { url = "https://files.pythonhosted.org/packages/4d/89/253db0fa0e66e9129c745e4ef25631dc37d5f1314dad2b53e907b8538e6d/numpy-2.4.2-cp313-cp313t-musllinux_1_2_aarch64.whl", hash = "sha256:66cb9422236317f9d44b67b4d18f44efe6e9c7f8794ac0462978513359461554", size = 17079064, upload-time = "2026-01-31T23:11:52.927Z" }, + { url = "https://files.pythonhosted.org/packages/2a/d5/cbade46ce97c59c6c3da525e8d95b7abe8a42974a1dc5c1d489c10433e88/numpy-2.4.2-cp313-cp313t-musllinux_1_2_x86_64.whl", hash = "sha256:0f01dcf33e73d80bd8dc0f20a71303abbafa26a19e23f6b68d1aa9990af90257", size = 18379680, upload-time = "2026-01-31T23:11:55.22Z" }, + { url = "https://files.pythonhosted.org/packages/40/62/48f99ae172a4b63d981babe683685030e8a3df4f246c893ea5c6ef99f018/numpy-2.4.2-cp313-cp313t-win32.whl", hash = "sha256:52b913ec40ff7ae845687b0b34d8d93b60cb66dcee06996dd5c99f2fc9328657", size = 6082433, upload-time = "2026-01-31T23:11:58.096Z" }, + { url = "https://files.pythonhosted.org/packages/07/38/e054a61cfe48ad9f1ed0d188e78b7e26859d0b60ef21cd9de4897cdb5326/numpy-2.4.2-cp313-cp313t-win_amd64.whl", hash = "sha256:5eea80d908b2c1f91486eb95b3fb6fab187e569ec9752ab7d9333d2e66bf2d6b", size = 12451181, upload-time = "2026-01-31T23:11:59.782Z" }, + { url = "https://files.pythonhosted.org/packages/6e/a4/a05c3a6418575e185dd84d0b9680b6bb2e2dc3e4202f036b7b4e22d6e9dc/numpy-2.4.2-cp313-cp313t-win_arm64.whl", hash = "sha256:fd49860271d52127d61197bb50b64f58454e9f578cb4b2c001a6de8b1f50b0b1", size = 10290756, upload-time = "2026-01-31T23:12:02.438Z" }, + { url = "https://files.pythonhosted.org/packages/18/88/b7df6050bf18fdcfb7046286c6535cabbdd2064a3440fca3f069d319c16e/numpy-2.4.2-cp314-cp314-macosx_10_15_x86_64.whl", hash = "sha256:444be170853f1f9d528428eceb55f12918e4fda5d8805480f36a002f1415e09b", size = 16663092, upload-time = "2026-01-31T23:12:04.521Z" }, + { url = "https://files.pythonhosted.org/packages/25/7a/1fee4329abc705a469a4afe6e69b1ef7e915117747886327104a8493a955/numpy-2.4.2-cp314-cp314-macosx_11_0_arm64.whl", hash = "sha256:d1240d50adff70c2a88217698ca844723068533f3f5c5fa6ee2e3220e3bdb000", size = 14698770, upload-time = "2026-01-31T23:12:06.96Z" }, + { url = "https://files.pythonhosted.org/packages/fb/0b/f9e49ba6c923678ad5bc38181c08ac5e53b7a5754dbca8e581aa1a56b1ff/numpy-2.4.2-cp314-cp314-macosx_14_0_arm64.whl", hash = "sha256:7cdde6de52fb6664b00b056341265441192d1291c130e99183ec0d4b110ff8b1", size = 5208562, upload-time = "2026-01-31T23:12:09.632Z" }, + { url = "https://files.pythonhosted.org/packages/7d/12/d7de8f6f53f9bb76997e5e4c069eda2051e3fe134e9181671c4391677bb2/numpy-2.4.2-cp314-cp314-macosx_14_0_x86_64.whl", hash = "sha256:cda077c2e5b780200b6b3e09d0b42205a3d1c68f30c6dceb90401c13bff8fe74", size = 6543710, upload-time = "2026-01-31T23:12:11.969Z" }, + { url = "https://files.pythonhosted.org/packages/09/63/c66418c2e0268a31a4cf8a8b512685748200f8e8e8ec6c507ce14e773529/numpy-2.4.2-cp314-cp314-manylinux_2_27_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:d30291931c915b2ab5717c2974bb95ee891a1cf22ebc16a8006bd59cd210d40a", size = 15677205, upload-time = "2026-01-31T23:12:14.33Z" }, + { url = "https://files.pythonhosted.org/packages/5d/6c/7f237821c9642fb2a04d2f1e88b4295677144ca93285fd76eff3bcba858d/numpy-2.4.2-cp314-cp314-manylinux_2_27_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:bba37bc29d4d85761deed3954a1bc62be7cf462b9510b51d367b769a8c8df325", size = 16611738, upload-time = "2026-01-31T23:12:16.525Z" }, + { url = "https://files.pythonhosted.org/packages/c2/a7/39c4cdda9f019b609b5c473899d87abff092fc908cfe4d1ecb2fcff453b0/numpy-2.4.2-cp314-cp314-musllinux_1_2_aarch64.whl", hash = "sha256:b2f0073ed0868db1dcd86e052d37279eef185b9c8db5bf61f30f46adac63c909", size = 17028888, upload-time = "2026-01-31T23:12:19.306Z" }, + { url = "https://files.pythonhosted.org/packages/da/b3/e84bb64bdfea967cc10950d71090ec2d84b49bc691df0025dddb7c26e8e3/numpy-2.4.2-cp314-cp314-musllinux_1_2_x86_64.whl", hash = "sha256:7f54844851cdb630ceb623dcec4db3240d1ac13d4990532446761baede94996a", size = 18339556, upload-time = "2026-01-31T23:12:21.816Z" }, + { url = "https://files.pythonhosted.org/packages/88/f5/954a291bc1192a27081706862ac62bb5920fbecfbaa302f64682aa90beed/numpy-2.4.2-cp314-cp314-win32.whl", hash = "sha256:12e26134a0331d8dbd9351620f037ec470b7c75929cb8a1537f6bfe411152a1a", size = 6006899, upload-time = "2026-01-31T23:12:24.14Z" }, + { url = "https://files.pythonhosted.org/packages/05/cb/eff72a91b2efdd1bc98b3b8759f6a1654aa87612fc86e3d87d6fe4f948c4/numpy-2.4.2-cp314-cp314-win_amd64.whl", hash = "sha256:068cdb2d0d644cdb45670810894f6a0600797a69c05f1ac478e8d31670b8ee75", size = 12443072, upload-time = "2026-01-31T23:12:26.33Z" }, + { url = "https://files.pythonhosted.org/packages/37/75/62726948db36a56428fce4ba80a115716dc4fad6a3a4352487f8bb950966/numpy-2.4.2-cp314-cp314-win_arm64.whl", hash = "sha256:6ed0be1ee58eef41231a5c943d7d1375f093142702d5723ca2eb07db9b934b05", size = 10494886, upload-time = "2026-01-31T23:12:28.488Z" }, + { url = "https://files.pythonhosted.org/packages/36/2f/ee93744f1e0661dc267e4b21940870cabfae187c092e1433b77b09b50ac4/numpy-2.4.2-cp314-cp314t-macosx_11_0_arm64.whl", hash = "sha256:98f16a80e917003a12c0580f97b5f875853ebc33e2eaa4bccfc8201ac6869308", size = 14818567, upload-time = "2026-01-31T23:12:30.709Z" }, + { url = "https://files.pythonhosted.org/packages/a7/24/6535212add7d76ff938d8bdc654f53f88d35cddedf807a599e180dcb8e66/numpy-2.4.2-cp314-cp314t-macosx_14_0_arm64.whl", hash = "sha256:20abd069b9cda45874498b245c8015b18ace6de8546bf50dfa8cea1696ed06ef", size = 5328372, upload-time = "2026-01-31T23:12:32.962Z" }, + { url = "https://files.pythonhosted.org/packages/5e/9d/c48f0a035725f925634bf6b8994253b43f2047f6778a54147d7e213bc5a7/numpy-2.4.2-cp314-cp314t-macosx_14_0_x86_64.whl", hash = "sha256:e98c97502435b53741540a5717a6749ac2ada901056c7db951d33e11c885cc7d", size = 6649306, upload-time = "2026-01-31T23:12:34.797Z" }, + { url = "https://files.pythonhosted.org/packages/81/05/7c73a9574cd4a53a25907bad38b59ac83919c0ddc8234ec157f344d57d9a/numpy-2.4.2-cp314-cp314t-manylinux_2_27_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:da6cad4e82cb893db4b69105c604d805e0c3ce11501a55b5e9f9083b47d2ffe8", size = 15722394, upload-time = "2026-01-31T23:12:36.565Z" }, + { url = "https://files.pythonhosted.org/packages/35/fa/4de10089f21fc7d18442c4a767ab156b25c2a6eaf187c0db6d9ecdaeb43f/numpy-2.4.2-cp314-cp314t-manylinux_2_27_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:9e4424677ce4b47fe73c8b5556d876571f7c6945d264201180db2dc34f676ab5", size = 16653343, upload-time = "2026-01-31T23:12:39.188Z" }, + { url = "https://files.pythonhosted.org/packages/b8/f9/d33e4ffc857f3763a57aa85650f2e82486832d7492280ac21ba9efda80da/numpy-2.4.2-cp314-cp314t-musllinux_1_2_aarch64.whl", hash = "sha256:2b8f157c8a6f20eb657e240f8985cc135598b2b46985c5bccbde7616dc9c6b1e", size = 17078045, upload-time = "2026-01-31T23:12:42.041Z" }, + { url = "https://files.pythonhosted.org/packages/c8/b8/54bdb43b6225badbea6389fa038c4ef868c44f5890f95dd530a218706da3/numpy-2.4.2-cp314-cp314t-musllinux_1_2_x86_64.whl", hash = "sha256:5daf6f3914a733336dab21a05cdec343144600e964d2fcdabaac0c0269874b2a", size = 18380024, upload-time = "2026-01-31T23:12:44.331Z" }, + { url = "https://files.pythonhosted.org/packages/a5/55/6e1a61ded7af8df04016d81b5b02daa59f2ea9252ee0397cb9f631efe9e5/numpy-2.4.2-cp314-cp314t-win32.whl", hash = "sha256:8c50dd1fc8826f5b26a5ee4d77ca55d88a895f4e4819c7ecc2a9f5905047a443", size = 6153937, upload-time = "2026-01-31T23:12:47.229Z" }, + { url = "https://files.pythonhosted.org/packages/45/aa/fa6118d1ed6d776b0983f3ceac9b1a5558e80df9365b1c3aa6d42bf9eee4/numpy-2.4.2-cp314-cp314t-win_amd64.whl", hash = "sha256:fcf92bee92742edd401ba41135185866f7026c502617f422eb432cfeca4fe236", size = 12631844, upload-time = "2026-01-31T23:12:48.997Z" }, + { url = "https://files.pythonhosted.org/packages/32/0a/2ec5deea6dcd158f254a7b372fb09cfba5719419c8d66343bab35237b3fb/numpy-2.4.2-cp314-cp314t-win_arm64.whl", hash = "sha256:1f92f53998a17265194018d1cc321b2e96e900ca52d54c7c77837b71b9465181", size = 10565379, upload-time = "2026-01-31T23:12:51.345Z" }, + { url = "https://files.pythonhosted.org/packages/f4/f8/50e14d36d915ef64d8f8bc4a087fc8264d82c785eda6711f80ab7e620335/numpy-2.4.2-pp311-pypy311_pp73-macosx_10_15_x86_64.whl", hash = "sha256:89f7268c009bc492f506abd6f5265defa7cb3f7487dc21d357c3d290add45082", size = 16833179, upload-time = "2026-01-31T23:12:53.5Z" }, + { url = "https://files.pythonhosted.org/packages/17/17/809b5cad63812058a8189e91a1e2d55a5a18fd04611dbad244e8aeae465c/numpy-2.4.2-pp311-pypy311_pp73-macosx_11_0_arm64.whl", hash = "sha256:e6dee3bb76aa4009d5a912180bf5b2de012532998d094acee25d9cb8dee3e44a", size = 14889755, upload-time = "2026-01-31T23:12:55.933Z" }, + { url = "https://files.pythonhosted.org/packages/3e/ea/181b9bcf7627fc8371720316c24db888dcb9829b1c0270abf3d288b2e29b/numpy-2.4.2-pp311-pypy311_pp73-macosx_14_0_arm64.whl", hash = "sha256:cd2bd2bbed13e213d6b55dc1d035a4f91748a7d3edc9480c13898b0353708920", size = 5399500, upload-time = "2026-01-31T23:12:58.671Z" }, + { url = "https://files.pythonhosted.org/packages/33/9f/413adf3fc955541ff5536b78fcf0754680b3c6d95103230252a2c9408d23/numpy-2.4.2-pp311-pypy311_pp73-macosx_14_0_x86_64.whl", hash = "sha256:cf28c0c1d4c4bf00f509fa7eb02c58d7caf221b50b467bcb0d9bbf1584d5c821", size = 6714252, upload-time = "2026-01-31T23:13:00.518Z" }, + { url = "https://files.pythonhosted.org/packages/91/da/643aad274e29ccbdf42ecd94dafe524b81c87bcb56b83872d54827f10543/numpy-2.4.2-pp311-pypy311_pp73-manylinux_2_27_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:e04ae107ac591763a47398bb45b568fc38f02dbc4aa44c063f67a131f99346cb", size = 15797142, upload-time = "2026-01-31T23:13:02.219Z" }, + { url = "https://files.pythonhosted.org/packages/66/27/965b8525e9cb5dc16481b30a1b3c21e50c7ebf6e9dbd48d0c4d0d5089c7e/numpy-2.4.2-pp311-pypy311_pp73-manylinux_2_27_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:602f65afdef699cda27ec0b9224ae5dc43e328f4c24c689deaf77133dbee74d0", size = 16727979, upload-time = "2026-01-31T23:13:04.62Z" }, + { url = "https://files.pythonhosted.org/packages/de/e5/b7d20451657664b07986c2f6e3be564433f5dcaf3482d68eaecd79afaf03/numpy-2.4.2-pp311-pypy311_pp73-win_amd64.whl", hash = "sha256:be71bf1edb48ebbbf7f6337b5bfd2f895d1902f6335a5830b20141fc126ffba0", size = 12502577, upload-time = "2026-01-31T23:13:07.08Z" }, +] + +[[package]] +name = "olids-testing" +version = "0.1.0" +source = { virtual = "." } +dependencies = [ + { name = "python-dotenv" }, + { name = "snowflake-connector-python", extra = ["pandas", "secure-local-storage"] }, + { name = "snowflake-snowpark-python" }, +] + +[package.metadata] +requires-dist = [ + { name = "python-dotenv" }, + { name = "snowflake-connector-python", extras = ["secure-local-storage", "pandas"] }, + { name = "snowflake-snowpark-python" }, +] + +[[package]] +name = "packaging" +version = "26.0" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/65/ee/299d360cdc32edc7d2cf530f3accf79c4fca01e96ffc950d8a52213bd8e4/packaging-26.0.tar.gz", hash = "sha256:00243ae351a257117b6a241061796684b084ed1c516a08c48a3f7e147a9d80b4", size = 143416, upload-time = "2026-01-21T20:50:39.064Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/b7/b9/c538f279a4e237a006a2c98387d081e9eb060d203d8ed34467cc0f0b9b53/packaging-26.0-py3-none-any.whl", hash = "sha256:b36f1fef9334a5588b4166f8bcd26a14e521f2b55e6b9de3aaa80d3ff7a37529", size = 74366, upload-time = "2026-01-21T20:50:37.788Z" }, +] + +[[package]] +name = "pandas" +version = "2.3.3" +source = { registry = "https://pypi.org/simple" } +dependencies = [ + { name = "numpy", version = "2.0.2", source = { registry = "https://pypi.org/simple" }, marker = "python_full_version < '3.10'" }, + { name = "numpy", version = "2.2.6", source = { registry = "https://pypi.org/simple" }, marker = "python_full_version == '3.10.*'" }, + { name = "numpy", version = "2.4.2", source = { registry = "https://pypi.org/simple" }, marker = "python_full_version >= '3.11'" }, + { name = "python-dateutil" }, + { name = "pytz" }, + { name = "tzdata" }, +] +sdist = { url = "https://files.pythonhosted.org/packages/33/01/d40b85317f86cf08d853a4f495195c73815fdf205eef3993821720274518/pandas-2.3.3.tar.gz", hash = "sha256:e05e1af93b977f7eafa636d043f9f94c7ee3ac81af99c13508215942e64c993b", size = 4495223, upload-time = "2025-09-29T23:34:51.853Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/3d/f7/f425a00df4fcc22b292c6895c6831c0c8ae1d9fac1e024d16f98a9ce8749/pandas-2.3.3-cp310-cp310-macosx_10_9_x86_64.whl", hash = "sha256:376c6446ae31770764215a6c937f72d917f214b43560603cd60da6408f183b6c", size = 11555763, upload-time = "2025-09-29T23:16:53.287Z" }, + { url = "https://files.pythonhosted.org/packages/13/4f/66d99628ff8ce7857aca52fed8f0066ce209f96be2fede6cef9f84e8d04f/pandas-2.3.3-cp310-cp310-macosx_11_0_arm64.whl", hash = "sha256:e19d192383eab2f4ceb30b412b22ea30690c9e618f78870357ae1d682912015a", size = 10801217, upload-time = "2025-09-29T23:17:04.522Z" }, + { url = "https://files.pythonhosted.org/packages/1d/03/3fc4a529a7710f890a239cc496fc6d50ad4a0995657dccc1d64695adb9f4/pandas-2.3.3-cp310-cp310-manylinux_2_24_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:5caf26f64126b6c7aec964f74266f435afef1c1b13da3b0636c7518a1fa3e2b1", size = 12148791, upload-time = "2025-09-29T23:17:18.444Z" }, + { url = "https://files.pythonhosted.org/packages/40/a8/4dac1f8f8235e5d25b9955d02ff6f29396191d4e665d71122c3722ca83c5/pandas-2.3.3-cp310-cp310-manylinux_2_24_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:dd7478f1463441ae4ca7308a70e90b33470fa593429f9d4c578dd00d1fa78838", size = 12769373, upload-time = "2025-09-29T23:17:35.846Z" }, + { url = "https://files.pythonhosted.org/packages/df/91/82cc5169b6b25440a7fc0ef3a694582418d875c8e3ebf796a6d6470aa578/pandas-2.3.3-cp310-cp310-musllinux_1_2_aarch64.whl", hash = "sha256:4793891684806ae50d1288c9bae9330293ab4e083ccd1c5e383c34549c6e4250", size = 13200444, upload-time = "2025-09-29T23:17:49.341Z" }, + { url = "https://files.pythonhosted.org/packages/10/ae/89b3283800ab58f7af2952704078555fa60c807fff764395bb57ea0b0dbd/pandas-2.3.3-cp310-cp310-musllinux_1_2_x86_64.whl", hash = "sha256:28083c648d9a99a5dd035ec125d42439c6c1c525098c58af0fc38dd1a7a1b3d4", size = 13858459, upload-time = "2025-09-29T23:18:03.722Z" }, + { url = "https://files.pythonhosted.org/packages/85/72/530900610650f54a35a19476eca5104f38555afccda1aa11a92ee14cb21d/pandas-2.3.3-cp310-cp310-win_amd64.whl", hash = "sha256:503cf027cf9940d2ceaa1a93cfb5f8c8c7e6e90720a2850378f0b3f3b1e06826", size = 11346086, upload-time = "2025-09-29T23:18:18.505Z" }, + { url = "https://files.pythonhosted.org/packages/c1/fa/7ac648108144a095b4fb6aa3de1954689f7af60a14cf25583f4960ecb878/pandas-2.3.3-cp311-cp311-macosx_10_9_x86_64.whl", hash = "sha256:602b8615ebcc4a0c1751e71840428ddebeb142ec02c786e8ad6b1ce3c8dec523", size = 11578790, upload-time = "2025-09-29T23:18:30.065Z" }, + { url = "https://files.pythonhosted.org/packages/9b/35/74442388c6cf008882d4d4bdfc4109be87e9b8b7ccd097ad1e7f006e2e95/pandas-2.3.3-cp311-cp311-macosx_11_0_arm64.whl", hash = "sha256:8fe25fc7b623b0ef6b5009149627e34d2a4657e880948ec3c840e9402e5c1b45", size = 10833831, upload-time = "2025-09-29T23:38:56.071Z" }, + { url = "https://files.pythonhosted.org/packages/fe/e4/de154cbfeee13383ad58d23017da99390b91d73f8c11856f2095e813201b/pandas-2.3.3-cp311-cp311-manylinux_2_24_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:b468d3dad6ff947df92dcb32ede5b7bd41a9b3cceef0a30ed925f6d01fb8fa66", size = 12199267, upload-time = "2025-09-29T23:18:41.627Z" }, + { url = "https://files.pythonhosted.org/packages/bf/c9/63f8d545568d9ab91476b1818b4741f521646cbdd151c6efebf40d6de6f7/pandas-2.3.3-cp311-cp311-manylinux_2_24_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:b98560e98cb334799c0b07ca7967ac361a47326e9b4e5a7dfb5ab2b1c9d35a1b", size = 12789281, upload-time = "2025-09-29T23:18:56.834Z" }, + { url = "https://files.pythonhosted.org/packages/f2/00/a5ac8c7a0e67fd1a6059e40aa08fa1c52cc00709077d2300e210c3ce0322/pandas-2.3.3-cp311-cp311-musllinux_1_2_aarch64.whl", hash = "sha256:1d37b5848ba49824e5c30bedb9c830ab9b7751fd049bc7914533e01c65f79791", size = 13240453, upload-time = "2025-09-29T23:19:09.247Z" }, + { url = "https://files.pythonhosted.org/packages/27/4d/5c23a5bc7bd209231618dd9e606ce076272c9bc4f12023a70e03a86b4067/pandas-2.3.3-cp311-cp311-musllinux_1_2_x86_64.whl", hash = "sha256:db4301b2d1f926ae677a751eb2bd0e8c5f5319c9cb3f88b0becbbb0b07b34151", size = 13890361, upload-time = "2025-09-29T23:19:25.342Z" }, + { url = "https://files.pythonhosted.org/packages/8e/59/712db1d7040520de7a4965df15b774348980e6df45c129b8c64d0dbe74ef/pandas-2.3.3-cp311-cp311-win_amd64.whl", hash = "sha256:f086f6fe114e19d92014a1966f43a3e62285109afe874f067f5abbdcbb10e59c", size = 11348702, upload-time = "2025-09-29T23:19:38.296Z" }, + { url = "https://files.pythonhosted.org/packages/9c/fb/231d89e8637c808b997d172b18e9d4a4bc7bf31296196c260526055d1ea0/pandas-2.3.3-cp312-cp312-macosx_10_13_x86_64.whl", hash = "sha256:6d21f6d74eb1725c2efaa71a2bfc661a0689579b58e9c0ca58a739ff0b002b53", size = 11597846, upload-time = "2025-09-29T23:19:48.856Z" }, + { url = "https://files.pythonhosted.org/packages/5c/bd/bf8064d9cfa214294356c2d6702b716d3cf3bb24be59287a6a21e24cae6b/pandas-2.3.3-cp312-cp312-macosx_11_0_arm64.whl", hash = "sha256:3fd2f887589c7aa868e02632612ba39acb0b8948faf5cc58f0850e165bd46f35", size = 10729618, upload-time = "2025-09-29T23:39:08.659Z" }, + { url = "https://files.pythonhosted.org/packages/57/56/cf2dbe1a3f5271370669475ead12ce77c61726ffd19a35546e31aa8edf4e/pandas-2.3.3-cp312-cp312-manylinux_2_24_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:ecaf1e12bdc03c86ad4a7ea848d66c685cb6851d807a26aa245ca3d2017a1908", size = 11737212, upload-time = "2025-09-29T23:19:59.765Z" }, + { url = "https://files.pythonhosted.org/packages/e5/63/cd7d615331b328e287d8233ba9fdf191a9c2d11b6af0c7a59cfcec23de68/pandas-2.3.3-cp312-cp312-manylinux_2_24_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:b3d11d2fda7eb164ef27ffc14b4fcab16a80e1ce67e9f57e19ec0afaf715ba89", size = 12362693, upload-time = "2025-09-29T23:20:14.098Z" }, + { url = "https://files.pythonhosted.org/packages/a6/de/8b1895b107277d52f2b42d3a6806e69cfef0d5cf1d0ba343470b9d8e0a04/pandas-2.3.3-cp312-cp312-musllinux_1_2_aarch64.whl", hash = "sha256:a68e15f780eddf2b07d242e17a04aa187a7ee12b40b930bfdd78070556550e98", size = 12771002, upload-time = "2025-09-29T23:20:26.76Z" }, + { url = "https://files.pythonhosted.org/packages/87/21/84072af3187a677c5893b170ba2c8fbe450a6ff911234916da889b698220/pandas-2.3.3-cp312-cp312-musllinux_1_2_x86_64.whl", hash = "sha256:371a4ab48e950033bcf52b6527eccb564f52dc826c02afd9a1bc0ab731bba084", size = 13450971, upload-time = "2025-09-29T23:20:41.344Z" }, + { url = "https://files.pythonhosted.org/packages/86/41/585a168330ff063014880a80d744219dbf1dd7a1c706e75ab3425a987384/pandas-2.3.3-cp312-cp312-win_amd64.whl", hash = "sha256:a16dcec078a01eeef8ee61bf64074b4e524a2a3f4b3be9326420cabe59c4778b", size = 10992722, upload-time = "2025-09-29T23:20:54.139Z" }, + { url = "https://files.pythonhosted.org/packages/cd/4b/18b035ee18f97c1040d94debd8f2e737000ad70ccc8f5513f4eefad75f4b/pandas-2.3.3-cp313-cp313-macosx_10_13_x86_64.whl", hash = "sha256:56851a737e3470de7fa88e6131f41281ed440d29a9268dcbf0002da5ac366713", size = 11544671, upload-time = "2025-09-29T23:21:05.024Z" }, + { url = "https://files.pythonhosted.org/packages/31/94/72fac03573102779920099bcac1c3b05975c2cb5f01eac609faf34bed1ca/pandas-2.3.3-cp313-cp313-macosx_11_0_arm64.whl", hash = "sha256:bdcd9d1167f4885211e401b3036c0c8d9e274eee67ea8d0758a256d60704cfe8", size = 10680807, upload-time = "2025-09-29T23:21:15.979Z" }, + { url = "https://files.pythonhosted.org/packages/16/87/9472cf4a487d848476865321de18cc8c920b8cab98453ab79dbbc98db63a/pandas-2.3.3-cp313-cp313-manylinux_2_24_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:e32e7cc9af0f1cc15548288a51a3b681cc2a219faa838e995f7dc53dbab1062d", size = 11709872, upload-time = "2025-09-29T23:21:27.165Z" }, + { url = "https://files.pythonhosted.org/packages/15/07/284f757f63f8a8d69ed4472bfd85122bd086e637bf4ed09de572d575a693/pandas-2.3.3-cp313-cp313-manylinux_2_24_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:318d77e0e42a628c04dc56bcef4b40de67918f7041c2b061af1da41dcff670ac", size = 12306371, upload-time = "2025-09-29T23:21:40.532Z" }, + { url = "https://files.pythonhosted.org/packages/33/81/a3afc88fca4aa925804a27d2676d22dcd2031c2ebe08aabd0ae55b9ff282/pandas-2.3.3-cp313-cp313-musllinux_1_2_aarch64.whl", hash = "sha256:4e0a175408804d566144e170d0476b15d78458795bb18f1304fb94160cabf40c", size = 12765333, upload-time = "2025-09-29T23:21:55.77Z" }, + { url = "https://files.pythonhosted.org/packages/8d/0f/b4d4ae743a83742f1153464cf1a8ecfafc3ac59722a0b5c8602310cb7158/pandas-2.3.3-cp313-cp313-musllinux_1_2_x86_64.whl", hash = "sha256:93c2d9ab0fc11822b5eece72ec9587e172f63cff87c00b062f6e37448ced4493", size = 13418120, upload-time = "2025-09-29T23:22:10.109Z" }, + { url = "https://files.pythonhosted.org/packages/4f/c7/e54682c96a895d0c808453269e0b5928a07a127a15704fedb643e9b0a4c8/pandas-2.3.3-cp313-cp313-win_amd64.whl", hash = "sha256:f8bfc0e12dc78f777f323f55c58649591b2cd0c43534e8355c51d3fede5f4dee", size = 10993991, upload-time = "2025-09-29T23:25:04.889Z" }, + { url = "https://files.pythonhosted.org/packages/f9/ca/3f8d4f49740799189e1395812f3bf23b5e8fc7c190827d55a610da72ce55/pandas-2.3.3-cp313-cp313t-macosx_10_13_x86_64.whl", hash = "sha256:75ea25f9529fdec2d2e93a42c523962261e567d250b0013b16210e1d40d7c2e5", size = 12048227, upload-time = "2025-09-29T23:22:24.343Z" }, + { url = "https://files.pythonhosted.org/packages/0e/5a/f43efec3e8c0cc92c4663ccad372dbdff72b60bdb56b2749f04aa1d07d7e/pandas-2.3.3-cp313-cp313t-macosx_11_0_arm64.whl", hash = "sha256:74ecdf1d301e812db96a465a525952f4dde225fdb6d8e5a521d47e1f42041e21", size = 11411056, upload-time = "2025-09-29T23:22:37.762Z" }, + { url = "https://files.pythonhosted.org/packages/46/b1/85331edfc591208c9d1a63a06baa67b21d332e63b7a591a5ba42a10bb507/pandas-2.3.3-cp313-cp313t-manylinux_2_24_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:6435cb949cb34ec11cc9860246ccb2fdc9ecd742c12d3304989017d53f039a78", size = 11645189, upload-time = "2025-09-29T23:22:51.688Z" }, + { url = "https://files.pythonhosted.org/packages/44/23/78d645adc35d94d1ac4f2a3c4112ab6f5b8999f4898b8cdf01252f8df4a9/pandas-2.3.3-cp313-cp313t-manylinux_2_24_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:900f47d8f20860de523a1ac881c4c36d65efcb2eb850e6948140fa781736e110", size = 12121912, upload-time = "2025-09-29T23:23:05.042Z" }, + { url = "https://files.pythonhosted.org/packages/53/da/d10013df5e6aaef6b425aa0c32e1fc1f3e431e4bcabd420517dceadce354/pandas-2.3.3-cp313-cp313t-musllinux_1_2_aarch64.whl", hash = "sha256:a45c765238e2ed7d7c608fc5bc4a6f88b642f2f01e70c0c23d2224dd21829d86", size = 12712160, upload-time = "2025-09-29T23:23:28.57Z" }, + { url = "https://files.pythonhosted.org/packages/bd/17/e756653095a083d8a37cbd816cb87148debcfcd920129b25f99dd8d04271/pandas-2.3.3-cp313-cp313t-musllinux_1_2_x86_64.whl", hash = "sha256:c4fc4c21971a1a9f4bdb4c73978c7f7256caa3e62b323f70d6cb80db583350bc", size = 13199233, upload-time = "2025-09-29T23:24:24.876Z" }, + { url = "https://files.pythonhosted.org/packages/04/fd/74903979833db8390b73b3a8a7d30d146d710bd32703724dd9083950386f/pandas-2.3.3-cp314-cp314-macosx_10_13_x86_64.whl", hash = "sha256:ee15f284898e7b246df8087fc82b87b01686f98ee67d85a17b7ab44143a3a9a0", size = 11540635, upload-time = "2025-09-29T23:25:52.486Z" }, + { url = "https://files.pythonhosted.org/packages/21/00/266d6b357ad5e6d3ad55093a7e8efc7dd245f5a842b584db9f30b0f0a287/pandas-2.3.3-cp314-cp314-macosx_11_0_arm64.whl", hash = "sha256:1611aedd912e1ff81ff41c745822980c49ce4a7907537be8692c8dbc31924593", size = 10759079, upload-time = "2025-09-29T23:26:33.204Z" }, + { url = "https://files.pythonhosted.org/packages/ca/05/d01ef80a7a3a12b2f8bbf16daba1e17c98a2f039cbc8e2f77a2c5a63d382/pandas-2.3.3-cp314-cp314-manylinux_2_24_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:6d2cefc361461662ac48810cb14365a365ce864afe85ef1f447ff5a1e99ea81c", size = 11814049, upload-time = "2025-09-29T23:27:15.384Z" }, + { url = "https://files.pythonhosted.org/packages/15/b2/0e62f78c0c5ba7e3d2c5945a82456f4fac76c480940f805e0b97fcbc2f65/pandas-2.3.3-cp314-cp314-manylinux_2_24_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:ee67acbbf05014ea6c763beb097e03cd629961c8a632075eeb34247120abcb4b", size = 12332638, upload-time = "2025-09-29T23:27:51.625Z" }, + { url = "https://files.pythonhosted.org/packages/c5/33/dd70400631b62b9b29c3c93d2feee1d0964dc2bae2e5ad7a6c73a7f25325/pandas-2.3.3-cp314-cp314-musllinux_1_2_aarch64.whl", hash = "sha256:c46467899aaa4da076d5abc11084634e2d197e9460643dd455ac3db5856b24d6", size = 12886834, upload-time = "2025-09-29T23:28:21.289Z" }, + { url = "https://files.pythonhosted.org/packages/d3/18/b5d48f55821228d0d2692b34fd5034bb185e854bdb592e9c640f6290e012/pandas-2.3.3-cp314-cp314-musllinux_1_2_x86_64.whl", hash = "sha256:6253c72c6a1d990a410bc7de641d34053364ef8bcd3126f7e7450125887dffe3", size = 13409925, upload-time = "2025-09-29T23:28:58.261Z" }, + { url = "https://files.pythonhosted.org/packages/a6/3d/124ac75fcd0ecc09b8fdccb0246ef65e35b012030defb0e0eba2cbbbe948/pandas-2.3.3-cp314-cp314-win_amd64.whl", hash = "sha256:1b07204a219b3b7350abaae088f451860223a52cfb8a6c53358e7948735158e5", size = 11109071, upload-time = "2025-09-29T23:32:27.484Z" }, + { url = "https://files.pythonhosted.org/packages/89/9c/0e21c895c38a157e0faa1fb64587a9226d6dd46452cac4532d80c3c4a244/pandas-2.3.3-cp314-cp314t-macosx_10_13_x86_64.whl", hash = "sha256:2462b1a365b6109d275250baaae7b760fd25c726aaca0054649286bcfbb3e8ec", size = 12048504, upload-time = "2025-09-29T23:29:31.47Z" }, + { url = "https://files.pythonhosted.org/packages/d7/82/b69a1c95df796858777b68fbe6a81d37443a33319761d7c652ce77797475/pandas-2.3.3-cp314-cp314t-macosx_11_0_arm64.whl", hash = "sha256:0242fe9a49aa8b4d78a4fa03acb397a58833ef6199e9aa40a95f027bb3a1b6e7", size = 11410702, upload-time = "2025-09-29T23:29:54.591Z" }, + { url = "https://files.pythonhosted.org/packages/f9/88/702bde3ba0a94b8c73a0181e05144b10f13f29ebfc2150c3a79062a8195d/pandas-2.3.3-cp314-cp314t-manylinux_2_24_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:a21d830e78df0a515db2b3d2f5570610f5e6bd2e27749770e8bb7b524b89b450", size = 11634535, upload-time = "2025-09-29T23:30:21.003Z" }, + { url = "https://files.pythonhosted.org/packages/a4/1e/1bac1a839d12e6a82ec6cb40cda2edde64a2013a66963293696bbf31fbbb/pandas-2.3.3-cp314-cp314t-manylinux_2_24_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:2e3ebdb170b5ef78f19bfb71b0dc5dc58775032361fa188e814959b74d726dd5", size = 12121582, upload-time = "2025-09-29T23:30:43.391Z" }, + { url = "https://files.pythonhosted.org/packages/44/91/483de934193e12a3b1d6ae7c8645d083ff88dec75f46e827562f1e4b4da6/pandas-2.3.3-cp314-cp314t-musllinux_1_2_aarch64.whl", hash = "sha256:d051c0e065b94b7a3cea50eb1ec32e912cd96dba41647eb24104b6c6c14c5788", size = 12699963, upload-time = "2025-09-29T23:31:10.009Z" }, + { url = "https://files.pythonhosted.org/packages/70/44/5191d2e4026f86a2a109053e194d3ba7a31a2d10a9c2348368c63ed4e85a/pandas-2.3.3-cp314-cp314t-musllinux_1_2_x86_64.whl", hash = "sha256:3869faf4bd07b3b66a9f462417d0ca3a9df29a9f6abd5d0d0dbab15dac7abe87", size = 13202175, upload-time = "2025-09-29T23:31:59.173Z" }, + { url = "https://files.pythonhosted.org/packages/56/b4/52eeb530a99e2a4c55ffcd352772b599ed4473a0f892d127f4147cf0f88e/pandas-2.3.3-cp39-cp39-macosx_10_9_x86_64.whl", hash = "sha256:c503ba5216814e295f40711470446bc3fd00f0faea8a086cbc688808e26f92a2", size = 11567720, upload-time = "2025-09-29T23:33:06.209Z" }, + { url = "https://files.pythonhosted.org/packages/48/4a/2d8b67632a021bced649ba940455ed441ca854e57d6e7658a6024587b083/pandas-2.3.3-cp39-cp39-macosx_11_0_arm64.whl", hash = "sha256:a637c5cdfa04b6d6e2ecedcb81fc52ffb0fd78ce2ebccc9ea964df9f658de8c8", size = 10810302, upload-time = "2025-09-29T23:33:35.846Z" }, + { url = "https://files.pythonhosted.org/packages/13/e6/d2465010ee0569a245c975dc6967b801887068bc893e908239b1f4b6c1ac/pandas-2.3.3-cp39-cp39-manylinux_2_24_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:854d00d556406bffe66a4c0802f334c9ad5a96b4f1f868adf036a21b11ef13ff", size = 12154874, upload-time = "2025-09-29T23:33:49.939Z" }, + { url = "https://files.pythonhosted.org/packages/1f/18/aae8c0aa69a386a3255940e9317f793808ea79d0a525a97a903366bb2569/pandas-2.3.3-cp39-cp39-manylinux_2_24_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:bf1f8a81d04ca90e32a0aceb819d34dbd378a98bf923b6398b9a3ec0bf44de29", size = 12790141, upload-time = "2025-09-29T23:34:05.655Z" }, + { url = "https://files.pythonhosted.org/packages/f7/26/617f98de789de00c2a444fbe6301bb19e66556ac78cff933d2c98f62f2b4/pandas-2.3.3-cp39-cp39-musllinux_1_2_aarch64.whl", hash = "sha256:23ebd657a4d38268c7dfbdf089fbc31ea709d82e4923c5ffd4fbd5747133ce73", size = 13208697, upload-time = "2025-09-29T23:34:21.835Z" }, + { url = "https://files.pythonhosted.org/packages/b9/fb/25709afa4552042bd0e15717c75e9b4a2294c3dc4f7e6ea50f03c5136600/pandas-2.3.3-cp39-cp39-musllinux_1_2_x86_64.whl", hash = "sha256:5554c929ccc317d41a5e3d1234f3be588248e61f08a74dd17c9eabb535777dc9", size = 13879233, upload-time = "2025-09-29T23:34:35.079Z" }, + { url = "https://files.pythonhosted.org/packages/98/af/7be05277859a7bc399da8ba68b88c96b27b48740b6cf49688899c6eb4176/pandas-2.3.3-cp39-cp39-win_amd64.whl", hash = "sha256:d3e28b3e83862ccf4d85ff19cf8c20b2ae7e503881711ff2d534dc8f761131aa", size = 11359119, upload-time = "2025-09-29T23:34:46.339Z" }, +] + +[[package]] +name = "platformdirs" +version = "4.4.0" +source = { registry = "https://pypi.org/simple" } +resolution-markers = [ + "python_full_version < '3.10'", +] +sdist = { url = "https://files.pythonhosted.org/packages/23/e8/21db9c9987b0e728855bd57bff6984f67952bea55d6f75e055c46b5383e8/platformdirs-4.4.0.tar.gz", hash = "sha256:ca753cf4d81dc309bc67b0ea38fd15dc97bc30ce419a7f58d13eb3bf14c4febf", size = 21634, upload-time = "2025-08-26T14:32:04.268Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/40/4b/2028861e724d3bd36227adfa20d3fd24c3fc6d52032f4a93c133be5d17ce/platformdirs-4.4.0-py3-none-any.whl", hash = "sha256:abd01743f24e5287cd7a5db3752faf1a2d65353f38ec26d98e25a6db65958c85", size = 18654, upload-time = "2025-08-26T14:32:02.735Z" }, +] + +[[package]] +name = "platformdirs" +version = "4.5.1" +source = { registry = "https://pypi.org/simple" } +resolution-markers = [ + "python_full_version >= '3.13'", + "python_full_version == '3.12.*'", + "python_full_version == '3.11.*'", + "python_full_version == '3.10.*'", +] +sdist = { url = "https://files.pythonhosted.org/packages/cf/86/0248f086a84f01b37aaec0fa567b397df1a119f73c16f6c7a9aac73ea309/platformdirs-4.5.1.tar.gz", hash = "sha256:61d5cdcc6065745cdd94f0f878977f8de9437be93de97c1c12f853c9c0cdcbda", size = 21715, upload-time = "2025-12-05T13:52:58.638Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/cb/28/3bfe2fa5a7b9c46fe7e13c97bda14c895fb10fa2ebf1d0abb90e0cea7ee1/platformdirs-4.5.1-py3-none-any.whl", hash = "sha256:d03afa3963c806a9bed9d5125c8f4cb2fdaf74a55ab60e5d59b3fde758104d31", size = 18731, upload-time = "2025-12-05T13:52:56.823Z" }, +] + +[[package]] +name = "protobuf" +version = "6.33.5" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/ba/25/7c72c307aafc96fa87062aa6291d9f7c94836e43214d43722e86037aac02/protobuf-6.33.5.tar.gz", hash = "sha256:6ddcac2a081f8b7b9642c09406bc6a4290128fce5f471cddd165960bb9119e5c", size = 444465, upload-time = "2026-01-29T21:51:33.494Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/b1/79/af92d0a8369732b027e6d6084251dd8e782c685c72da161bd4a2e00fbabb/protobuf-6.33.5-cp310-abi3-win32.whl", hash = "sha256:d71b040839446bac0f4d162e758bea99c8251161dae9d0983a3b88dee345153b", size = 425769, upload-time = "2026-01-29T21:51:21.751Z" }, + { url = "https://files.pythonhosted.org/packages/55/75/bb9bc917d10e9ee13dee8607eb9ab963b7cf8be607c46e7862c748aa2af7/protobuf-6.33.5-cp310-abi3-win_amd64.whl", hash = "sha256:3093804752167bcab3998bec9f1048baae6e29505adaf1afd14a37bddede533c", size = 437118, upload-time = "2026-01-29T21:51:24.022Z" }, + { url = "https://files.pythonhosted.org/packages/a2/6b/e48dfc1191bc5b52950246275bf4089773e91cb5ba3592621723cdddca62/protobuf-6.33.5-cp39-abi3-macosx_10_9_universal2.whl", hash = "sha256:a5cb85982d95d906df1e2210e58f8e4f1e3cdc088e52c921a041f9c9a0386de5", size = 427766, upload-time = "2026-01-29T21:51:25.413Z" }, + { url = "https://files.pythonhosted.org/packages/4e/b1/c79468184310de09d75095ed1314b839eb2f72df71097db9d1404a1b2717/protobuf-6.33.5-cp39-abi3-manylinux2014_aarch64.whl", hash = "sha256:9b71e0281f36f179d00cbcb119cb19dec4d14a81393e5ea220f64b286173e190", size = 324638, upload-time = "2026-01-29T21:51:26.423Z" }, + { url = "https://files.pythonhosted.org/packages/c5/f5/65d838092fd01c44d16037953fd4c2cc851e783de9b8f02b27ec4ffd906f/protobuf-6.33.5-cp39-abi3-manylinux2014_s390x.whl", hash = "sha256:8afa18e1d6d20af15b417e728e9f60f3aa108ee76f23c3b2c07a2c3b546d3afd", size = 339411, upload-time = "2026-01-29T21:51:27.446Z" }, + { url = "https://files.pythonhosted.org/packages/9b/53/a9443aa3ca9ba8724fdfa02dd1887c1bcd8e89556b715cfbacca6b63dbec/protobuf-6.33.5-cp39-abi3-manylinux2014_x86_64.whl", hash = "sha256:cbf16ba3350fb7b889fca858fb215967792dc125b35c7976ca4818bee3521cf0", size = 323465, upload-time = "2026-01-29T21:51:28.925Z" }, + { url = "https://files.pythonhosted.org/packages/08/60/84d5f6dcda9165e4d6a56ac8433c9f40a8906bf2966150b8a0cfde097d78/protobuf-6.33.5-cp39-cp39-win32.whl", hash = "sha256:a3157e62729aafb8df6da2c03aa5c0937c7266c626ce11a278b6eb7963c4e37c", size = 425892, upload-time = "2026-01-29T21:51:30.382Z" }, + { url = "https://files.pythonhosted.org/packages/68/19/33d7dc2dc84439587fa1e21e1c0026c01ad2af0a62f58fd54002a7546307/protobuf-6.33.5-cp39-cp39-win_amd64.whl", hash = "sha256:8f04fa32763dcdb4973d537d6b54e615cc61108c7cb38fe59310c3192d29510a", size = 437137, upload-time = "2026-01-29T21:51:31.456Z" }, + { url = "https://files.pythonhosted.org/packages/57/bf/2086963c69bdac3d7cff1cc7ff79b8ce5ea0bec6797a017e1be338a46248/protobuf-6.33.5-py3-none-any.whl", hash = "sha256:69915a973dd0f60f31a08b8318b73eab2bd6a392c79184b3612226b0a3f8ec02", size = 170687, upload-time = "2026-01-29T21:51:32.557Z" }, +] + +[[package]] +name = "pyarrow" +version = "21.0.0" +source = { registry = "https://pypi.org/simple" } +resolution-markers = [ + "python_full_version < '3.10'", +] +sdist = { url = "https://files.pythonhosted.org/packages/ef/c2/ea068b8f00905c06329a3dfcd40d0fcc2b7d0f2e355bdb25b65e0a0e4cd4/pyarrow-21.0.0.tar.gz", hash = "sha256:5051f2dccf0e283ff56335760cbc8622cf52264d67e359d5569541ac11b6d5bc", size = 1133487, upload-time = "2025-07-18T00:57:31.761Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/17/d9/110de31880016e2afc52d8580b397dbe47615defbf09ca8cf55f56c62165/pyarrow-21.0.0-cp310-cp310-macosx_12_0_arm64.whl", hash = "sha256:e563271e2c5ff4d4a4cbeb2c83d5cf0d4938b891518e676025f7268c6fe5fe26", size = 31196837, upload-time = "2025-07-18T00:54:34.755Z" }, + { url = "https://files.pythonhosted.org/packages/df/5f/c1c1997613abf24fceb087e79432d24c19bc6f7259cab57c2c8e5e545fab/pyarrow-21.0.0-cp310-cp310-macosx_12_0_x86_64.whl", hash = "sha256:fee33b0ca46f4c85443d6c450357101e47d53e6c3f008d658c27a2d020d44c79", size = 32659470, upload-time = "2025-07-18T00:54:38.329Z" }, + { url = "https://files.pythonhosted.org/packages/3e/ed/b1589a777816ee33ba123ba1e4f8f02243a844fed0deec97bde9fb21a5cf/pyarrow-21.0.0-cp310-cp310-manylinux_2_28_aarch64.whl", hash = "sha256:7be45519b830f7c24b21d630a31d48bcebfd5d4d7f9d3bdb49da9cdf6d764edb", size = 41055619, upload-time = "2025-07-18T00:54:42.172Z" }, + { url = "https://files.pythonhosted.org/packages/44/28/b6672962639e85dc0ac36f71ab3a8f5f38e01b51343d7aa372a6b56fa3f3/pyarrow-21.0.0-cp310-cp310-manylinux_2_28_x86_64.whl", hash = "sha256:26bfd95f6bff443ceae63c65dc7e048670b7e98bc892210acba7e4995d3d4b51", size = 42733488, upload-time = "2025-07-18T00:54:47.132Z" }, + { url = "https://files.pythonhosted.org/packages/f8/cc/de02c3614874b9089c94eac093f90ca5dfa6d5afe45de3ba847fd950fdf1/pyarrow-21.0.0-cp310-cp310-musllinux_1_2_aarch64.whl", hash = "sha256:bd04ec08f7f8bd113c55868bd3fc442a9db67c27af098c5f814a3091e71cc61a", size = 43329159, upload-time = "2025-07-18T00:54:51.686Z" }, + { url = "https://files.pythonhosted.org/packages/a6/3e/99473332ac40278f196e105ce30b79ab8affab12f6194802f2593d6b0be2/pyarrow-21.0.0-cp310-cp310-musllinux_1_2_x86_64.whl", hash = "sha256:9b0b14b49ac10654332a805aedfc0147fb3469cbf8ea951b3d040dab12372594", size = 45050567, upload-time = "2025-07-18T00:54:56.679Z" }, + { url = "https://files.pythonhosted.org/packages/7b/f5/c372ef60593d713e8bfbb7e0c743501605f0ad00719146dc075faf11172b/pyarrow-21.0.0-cp310-cp310-win_amd64.whl", hash = "sha256:9d9f8bcb4c3be7738add259738abdeddc363de1b80e3310e04067aa1ca596634", size = 26217959, upload-time = "2025-07-18T00:55:00.482Z" }, + { url = "https://files.pythonhosted.org/packages/94/dc/80564a3071a57c20b7c32575e4a0120e8a330ef487c319b122942d665960/pyarrow-21.0.0-cp311-cp311-macosx_12_0_arm64.whl", hash = "sha256:c077f48aab61738c237802836fc3844f85409a46015635198761b0d6a688f87b", size = 31243234, upload-time = "2025-07-18T00:55:03.812Z" }, + { url = "https://files.pythonhosted.org/packages/ea/cc/3b51cb2db26fe535d14f74cab4c79b191ed9a8cd4cbba45e2379b5ca2746/pyarrow-21.0.0-cp311-cp311-macosx_12_0_x86_64.whl", hash = "sha256:689f448066781856237eca8d1975b98cace19b8dd2ab6145bf49475478bcaa10", size = 32714370, upload-time = "2025-07-18T00:55:07.495Z" }, + { url = "https://files.pythonhosted.org/packages/24/11/a4431f36d5ad7d83b87146f515c063e4d07ef0b7240876ddb885e6b44f2e/pyarrow-21.0.0-cp311-cp311-manylinux_2_28_aarch64.whl", hash = "sha256:479ee41399fcddc46159a551705b89c05f11e8b8cb8e968f7fec64f62d91985e", size = 41135424, upload-time = "2025-07-18T00:55:11.461Z" }, + { url = "https://files.pythonhosted.org/packages/74/dc/035d54638fc5d2971cbf1e987ccd45f1091c83bcf747281cf6cc25e72c88/pyarrow-21.0.0-cp311-cp311-manylinux_2_28_x86_64.whl", hash = "sha256:40ebfcb54a4f11bcde86bc586cbd0272bac0d516cfa539c799c2453768477569", size = 42823810, upload-time = "2025-07-18T00:55:16.301Z" }, + { url = "https://files.pythonhosted.org/packages/2e/3b/89fced102448a9e3e0d4dded1f37fa3ce4700f02cdb8665457fcc8015f5b/pyarrow-21.0.0-cp311-cp311-musllinux_1_2_aarch64.whl", hash = "sha256:8d58d8497814274d3d20214fbb24abcad2f7e351474357d552a8d53bce70c70e", size = 43391538, upload-time = "2025-07-18T00:55:23.82Z" }, + { url = "https://files.pythonhosted.org/packages/fb/bb/ea7f1bd08978d39debd3b23611c293f64a642557e8141c80635d501e6d53/pyarrow-21.0.0-cp311-cp311-musllinux_1_2_x86_64.whl", hash = "sha256:585e7224f21124dd57836b1530ac8f2df2afc43c861d7bf3d58a4870c42ae36c", size = 45120056, upload-time = "2025-07-18T00:55:28.231Z" }, + { url = "https://files.pythonhosted.org/packages/6e/0b/77ea0600009842b30ceebc3337639a7380cd946061b620ac1a2f3cb541e2/pyarrow-21.0.0-cp311-cp311-win_amd64.whl", hash = "sha256:555ca6935b2cbca2c0e932bedd853e9bc523098c39636de9ad4693b5b1df86d6", size = 26220568, upload-time = "2025-07-18T00:55:32.122Z" }, + { url = "https://files.pythonhosted.org/packages/ca/d4/d4f817b21aacc30195cf6a46ba041dd1be827efa4a623cc8bf39a1c2a0c0/pyarrow-21.0.0-cp312-cp312-macosx_12_0_arm64.whl", hash = "sha256:3a302f0e0963db37e0a24a70c56cf91a4faa0bca51c23812279ca2e23481fccd", size = 31160305, upload-time = "2025-07-18T00:55:35.373Z" }, + { url = "https://files.pythonhosted.org/packages/a2/9c/dcd38ce6e4b4d9a19e1d36914cb8e2b1da4e6003dd075474c4cfcdfe0601/pyarrow-21.0.0-cp312-cp312-macosx_12_0_x86_64.whl", hash = "sha256:b6b27cf01e243871390474a211a7922bfbe3bda21e39bc9160daf0da3fe48876", size = 32684264, upload-time = "2025-07-18T00:55:39.303Z" }, + { url = "https://files.pythonhosted.org/packages/4f/74/2a2d9f8d7a59b639523454bec12dba35ae3d0a07d8ab529dc0809f74b23c/pyarrow-21.0.0-cp312-cp312-manylinux_2_28_aarch64.whl", hash = "sha256:e72a8ec6b868e258a2cd2672d91f2860ad532d590ce94cdf7d5e7ec674ccf03d", size = 41108099, upload-time = "2025-07-18T00:55:42.889Z" }, + { url = "https://files.pythonhosted.org/packages/ad/90/2660332eeb31303c13b653ea566a9918484b6e4d6b9d2d46879a33ab0622/pyarrow-21.0.0-cp312-cp312-manylinux_2_28_x86_64.whl", hash = "sha256:b7ae0bbdc8c6674259b25bef5d2a1d6af5d39d7200c819cf99e07f7dfef1c51e", size = 42829529, upload-time = "2025-07-18T00:55:47.069Z" }, + { url = "https://files.pythonhosted.org/packages/33/27/1a93a25c92717f6aa0fca06eb4700860577d016cd3ae51aad0e0488ac899/pyarrow-21.0.0-cp312-cp312-musllinux_1_2_aarch64.whl", hash = "sha256:58c30a1729f82d201627c173d91bd431db88ea74dcaa3885855bc6203e433b82", size = 43367883, upload-time = "2025-07-18T00:55:53.069Z" }, + { url = "https://files.pythonhosted.org/packages/05/d9/4d09d919f35d599bc05c6950095e358c3e15148ead26292dfca1fb659b0c/pyarrow-21.0.0-cp312-cp312-musllinux_1_2_x86_64.whl", hash = "sha256:072116f65604b822a7f22945a7a6e581cfa28e3454fdcc6939d4ff6090126623", size = 45133802, upload-time = "2025-07-18T00:55:57.714Z" }, + { url = "https://files.pythonhosted.org/packages/71/30/f3795b6e192c3ab881325ffe172e526499eb3780e306a15103a2764916a2/pyarrow-21.0.0-cp312-cp312-win_amd64.whl", hash = "sha256:cf56ec8b0a5c8c9d7021d6fd754e688104f9ebebf1bf4449613c9531f5346a18", size = 26203175, upload-time = "2025-07-18T00:56:01.364Z" }, + { url = "https://files.pythonhosted.org/packages/16/ca/c7eaa8e62db8fb37ce942b1ea0c6d7abfe3786ca193957afa25e71b81b66/pyarrow-21.0.0-cp313-cp313-macosx_12_0_arm64.whl", hash = "sha256:e99310a4ebd4479bcd1964dff9e14af33746300cb014aa4a3781738ac63baf4a", size = 31154306, upload-time = "2025-07-18T00:56:04.42Z" }, + { url = "https://files.pythonhosted.org/packages/ce/e8/e87d9e3b2489302b3a1aea709aaca4b781c5252fcb812a17ab6275a9a484/pyarrow-21.0.0-cp313-cp313-macosx_12_0_x86_64.whl", hash = "sha256:d2fe8e7f3ce329a71b7ddd7498b3cfac0eeb200c2789bd840234f0dc271a8efe", size = 32680622, upload-time = "2025-07-18T00:56:07.505Z" }, + { url = "https://files.pythonhosted.org/packages/84/52/79095d73a742aa0aba370c7942b1b655f598069489ab387fe47261a849e1/pyarrow-21.0.0-cp313-cp313-manylinux_2_28_aarch64.whl", hash = "sha256:f522e5709379d72fb3da7785aa489ff0bb87448a9dc5a75f45763a795a089ebd", size = 41104094, upload-time = "2025-07-18T00:56:10.994Z" }, + { url = "https://files.pythonhosted.org/packages/89/4b/7782438b551dbb0468892a276b8c789b8bbdb25ea5c5eb27faadd753e037/pyarrow-21.0.0-cp313-cp313-manylinux_2_28_x86_64.whl", hash = "sha256:69cbbdf0631396e9925e048cfa5bce4e8c3d3b41562bbd70c685a8eb53a91e61", size = 42825576, upload-time = "2025-07-18T00:56:15.569Z" }, + { url = "https://files.pythonhosted.org/packages/b3/62/0f29de6e0a1e33518dec92c65be0351d32d7ca351e51ec5f4f837a9aab91/pyarrow-21.0.0-cp313-cp313-musllinux_1_2_aarch64.whl", hash = "sha256:731c7022587006b755d0bdb27626a1a3bb004bb56b11fb30d98b6c1b4718579d", size = 43368342, upload-time = "2025-07-18T00:56:19.531Z" }, + { url = "https://files.pythonhosted.org/packages/90/c7/0fa1f3f29cf75f339768cc698c8ad4ddd2481c1742e9741459911c9ac477/pyarrow-21.0.0-cp313-cp313-musllinux_1_2_x86_64.whl", hash = "sha256:dc56bc708f2d8ac71bd1dcb927e458c93cec10b98eb4120206a4091db7b67b99", size = 45131218, upload-time = "2025-07-18T00:56:23.347Z" }, + { url = "https://files.pythonhosted.org/packages/01/63/581f2076465e67b23bc5a37d4a2abff8362d389d29d8105832e82c9c811c/pyarrow-21.0.0-cp313-cp313-win_amd64.whl", hash = "sha256:186aa00bca62139f75b7de8420f745f2af12941595bbbfa7ed3870ff63e25636", size = 26087551, upload-time = "2025-07-18T00:56:26.758Z" }, + { url = "https://files.pythonhosted.org/packages/c9/ab/357d0d9648bb8241ee7348e564f2479d206ebe6e1c47ac5027c2e31ecd39/pyarrow-21.0.0-cp313-cp313t-macosx_12_0_arm64.whl", hash = "sha256:a7a102574faa3f421141a64c10216e078df467ab9576684d5cd696952546e2da", size = 31290064, upload-time = "2025-07-18T00:56:30.214Z" }, + { url = "https://files.pythonhosted.org/packages/3f/8a/5685d62a990e4cac2043fc76b4661bf38d06efed55cf45a334b455bd2759/pyarrow-21.0.0-cp313-cp313t-macosx_12_0_x86_64.whl", hash = "sha256:1e005378c4a2c6db3ada3ad4c217b381f6c886f0a80d6a316fe586b90f77efd7", size = 32727837, upload-time = "2025-07-18T00:56:33.935Z" }, + { url = "https://files.pythonhosted.org/packages/fc/de/c0828ee09525c2bafefd3e736a248ebe764d07d0fd762d4f0929dbc516c9/pyarrow-21.0.0-cp313-cp313t-manylinux_2_28_aarch64.whl", hash = "sha256:65f8e85f79031449ec8706b74504a316805217b35b6099155dd7e227eef0d4b6", size = 41014158, upload-time = "2025-07-18T00:56:37.528Z" }, + { url = "https://files.pythonhosted.org/packages/6e/26/a2865c420c50b7a3748320b614f3484bfcde8347b2639b2b903b21ce6a72/pyarrow-21.0.0-cp313-cp313t-manylinux_2_28_x86_64.whl", hash = "sha256:3a81486adc665c7eb1a2bde0224cfca6ceaba344a82a971ef059678417880eb8", size = 42667885, upload-time = "2025-07-18T00:56:41.483Z" }, + { url = "https://files.pythonhosted.org/packages/0a/f9/4ee798dc902533159250fb4321267730bc0a107d8c6889e07c3add4fe3a5/pyarrow-21.0.0-cp313-cp313t-musllinux_1_2_aarch64.whl", hash = "sha256:fc0d2f88b81dcf3ccf9a6ae17f89183762c8a94a5bdcfa09e05cfe413acf0503", size = 43276625, upload-time = "2025-07-18T00:56:48.002Z" }, + { url = "https://files.pythonhosted.org/packages/5a/da/e02544d6997037a4b0d22d8e5f66bc9315c3671371a8b18c79ade1cefe14/pyarrow-21.0.0-cp313-cp313t-musllinux_1_2_x86_64.whl", hash = "sha256:6299449adf89df38537837487a4f8d3bd91ec94354fdd2a7d30bc11c48ef6e79", size = 44951890, upload-time = "2025-07-18T00:56:52.568Z" }, + { url = "https://files.pythonhosted.org/packages/e5/4e/519c1bc1876625fe6b71e9a28287c43ec2f20f73c658b9ae1d485c0c206e/pyarrow-21.0.0-cp313-cp313t-win_amd64.whl", hash = "sha256:222c39e2c70113543982c6b34f3077962b44fca38c0bd9e68bb6781534425c10", size = 26371006, upload-time = "2025-07-18T00:56:56.379Z" }, + { url = "https://files.pythonhosted.org/packages/3e/cc/ce4939f4b316457a083dc5718b3982801e8c33f921b3c98e7a93b7c7491f/pyarrow-21.0.0-cp39-cp39-macosx_12_0_arm64.whl", hash = "sha256:a7f6524e3747e35f80744537c78e7302cd41deee8baa668d56d55f77d9c464b3", size = 31211248, upload-time = "2025-07-18T00:56:59.7Z" }, + { url = "https://files.pythonhosted.org/packages/1f/c2/7a860931420d73985e2f340f06516b21740c15b28d24a0e99a900bb27d2b/pyarrow-21.0.0-cp39-cp39-macosx_12_0_x86_64.whl", hash = "sha256:203003786c9fd253ebcafa44b03c06983c9c8d06c3145e37f1b76a1f317aeae1", size = 32676896, upload-time = "2025-07-18T00:57:03.884Z" }, + { url = "https://files.pythonhosted.org/packages/68/a8/197f989b9a75e59b4ca0db6a13c56f19a0ad8a298c68da9cc28145e0bb97/pyarrow-21.0.0-cp39-cp39-manylinux_2_28_aarch64.whl", hash = "sha256:3b4d97e297741796fead24867a8dabf86c87e4584ccc03167e4a811f50fdf74d", size = 41067862, upload-time = "2025-07-18T00:57:07.587Z" }, + { url = "https://files.pythonhosted.org/packages/fa/82/6ecfa89487b35aa21accb014b64e0a6b814cc860d5e3170287bf5135c7d8/pyarrow-21.0.0-cp39-cp39-manylinux_2_28_x86_64.whl", hash = "sha256:898afce396b80fdda05e3086b4256f8677c671f7b1d27a6976fa011d3fd0a86e", size = 42747508, upload-time = "2025-07-18T00:57:13.917Z" }, + { url = "https://files.pythonhosted.org/packages/3b/b7/ba252f399bbf3addc731e8643c05532cf32e74cebb5e32f8f7409bc243cf/pyarrow-21.0.0-cp39-cp39-musllinux_1_2_aarch64.whl", hash = "sha256:067c66ca29aaedae08218569a114e413b26e742171f526e828e1064fcdec13f4", size = 43345293, upload-time = "2025-07-18T00:57:19.828Z" }, + { url = "https://files.pythonhosted.org/packages/ff/0a/a20819795bd702b9486f536a8eeb70a6aa64046fce32071c19ec8230dbaa/pyarrow-21.0.0-cp39-cp39-musllinux_1_2_x86_64.whl", hash = "sha256:0c4e75d13eb76295a49e0ea056eb18dbd87d81450bfeb8afa19a7e5a75ae2ad7", size = 45060670, upload-time = "2025-07-18T00:57:24.477Z" }, + { url = "https://files.pythonhosted.org/packages/10/15/6b30e77872012bbfe8265d42a01d5b3c17ef0ac0f2fae531ad91b6a6c02e/pyarrow-21.0.0-cp39-cp39-win_amd64.whl", hash = "sha256:cdc4c17afda4dab2a9c0b79148a43a7f4e1094916b3e18d8975bfd6d6d52241f", size = 26227521, upload-time = "2025-07-18T00:57:29.119Z" }, +] + +[[package]] +name = "pyarrow" +version = "23.0.0" +source = { registry = "https://pypi.org/simple" } +resolution-markers = [ + "python_full_version >= '3.13'", + "python_full_version == '3.12.*'", + "python_full_version == '3.11.*'", + "python_full_version == '3.10.*'", +] +sdist = { url = "https://files.pythonhosted.org/packages/01/33/ffd9c3eb087fa41dd79c3cf20c4c0ae3cdb877c4f8e1107a446006344924/pyarrow-23.0.0.tar.gz", hash = "sha256:180e3150e7edfcd182d3d9afba72f7cf19839a497cc76555a8dce998a8f67615", size = 1167185, upload-time = "2026-01-18T16:19:42.218Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/ae/2f/23e042a5aa99bcb15e794e14030e8d065e00827e846e53a66faec73c7cd6/pyarrow-23.0.0-cp310-cp310-macosx_12_0_arm64.whl", hash = "sha256:cbdc2bf5947aa4d462adcf8453cf04aee2f7932653cb67a27acd96e5e8528a67", size = 34281861, upload-time = "2026-01-18T16:13:34.332Z" }, + { url = "https://files.pythonhosted.org/packages/8b/65/1651933f504b335ec9cd8f99463718421eb08d883ed84f0abd2835a16cad/pyarrow-23.0.0-cp310-cp310-macosx_12_0_x86_64.whl", hash = "sha256:4d38c836930ce15cd31dce20114b21ba082da231c884bdc0a7b53e1477fe7f07", size = 35825067, upload-time = "2026-01-18T16:13:42.549Z" }, + { url = "https://files.pythonhosted.org/packages/84/ec/d6fceaec050c893f4e35c0556b77d4cc9973fcc24b0a358a5781b1234582/pyarrow-23.0.0-cp310-cp310-manylinux_2_28_aarch64.whl", hash = "sha256:4222ff8f76919ecf6c716175a0e5fddb5599faeed4c56d9ea41a2c42be4998b2", size = 44458539, upload-time = "2026-01-18T16:13:52.975Z" }, + { url = "https://files.pythonhosted.org/packages/fd/d9/369f134d652b21db62fe3ec1c5c2357e695f79eb67394b8a93f3a2b2cffa/pyarrow-23.0.0-cp310-cp310-manylinux_2_28_x86_64.whl", hash = "sha256:87f06159cbe38125852657716889296c83c37b4d09a5e58f3d10245fd1f69795", size = 47535889, upload-time = "2026-01-18T16:14:03.693Z" }, + { url = "https://files.pythonhosted.org/packages/a3/95/f37b6a252fdbf247a67a78fb3f61a529fe0600e304c4d07741763d3522b1/pyarrow-23.0.0-cp310-cp310-musllinux_1_2_aarch64.whl", hash = "sha256:1675c374570d8b91ea6d4edd4608fa55951acd44e0c31bd146e091b4005de24f", size = 48157777, upload-time = "2026-01-18T16:14:12.483Z" }, + { url = "https://files.pythonhosted.org/packages/ab/ab/fb94923108c9c6415dab677cf1f066d3307798eafc03f9a65ab4abc61056/pyarrow-23.0.0-cp310-cp310-musllinux_1_2_x86_64.whl", hash = "sha256:247374428fde4f668f138b04031a7e7077ba5fa0b5b1722fdf89a017bf0b7ee0", size = 50580441, upload-time = "2026-01-18T16:14:20.187Z" }, + { url = "https://files.pythonhosted.org/packages/ae/78/897ba6337b517fc8e914891e1bd918da1c4eb8e936a553e95862e67b80f6/pyarrow-23.0.0-cp310-cp310-win_amd64.whl", hash = "sha256:de53b1bd3b88a2ee93c9af412c903e57e738c083be4f6392288294513cd8b2c1", size = 27530028, upload-time = "2026-01-18T16:14:27.353Z" }, + { url = "https://files.pythonhosted.org/packages/aa/c0/57fe251102ca834fee0ef69a84ad33cc0ff9d5dfc50f50b466846356ecd7/pyarrow-23.0.0-cp311-cp311-macosx_12_0_arm64.whl", hash = "sha256:5574d541923efcbfdf1294a2746ae3b8c2498a2dc6cd477882f6f4e7b1ac08d3", size = 34276762, upload-time = "2026-01-18T16:14:34.128Z" }, + { url = "https://files.pythonhosted.org/packages/f8/4e/24130286548a5bc250cbed0b6bbf289a2775378a6e0e6f086ae8c68fc098/pyarrow-23.0.0-cp311-cp311-macosx_12_0_x86_64.whl", hash = "sha256:2ef0075c2488932e9d3c2eb3482f9459c4be629aa673b725d5e3cf18f777f8e4", size = 35821420, upload-time = "2026-01-18T16:14:40.699Z" }, + { url = "https://files.pythonhosted.org/packages/ee/55/a869e8529d487aa2e842d6c8865eb1e2c9ec33ce2786eb91104d2c3e3f10/pyarrow-23.0.0-cp311-cp311-manylinux_2_28_aarch64.whl", hash = "sha256:65666fc269669af1ef1c14478c52222a2aa5c907f28b68fb50a203c777e4f60c", size = 44457412, upload-time = "2026-01-18T16:14:49.051Z" }, + { url = "https://files.pythonhosted.org/packages/36/81/1de4f0edfa9a483bbdf0082a05790bd6a20ed2169ea12a65039753be3a01/pyarrow-23.0.0-cp311-cp311-manylinux_2_28_x86_64.whl", hash = "sha256:4d85cb6177198f3812db4788e394b757223f60d9a9f5ad6634b3e32be1525803", size = 47534285, upload-time = "2026-01-18T16:14:56.748Z" }, + { url = "https://files.pythonhosted.org/packages/f2/04/464a052d673b5ece074518f27377861662449f3c1fdb39ce740d646fd098/pyarrow-23.0.0-cp311-cp311-musllinux_1_2_aarch64.whl", hash = "sha256:1a9ff6fa4141c24a03a1a434c63c8fa97ce70f8f36bccabc18ebba905ddf0f17", size = 48157913, upload-time = "2026-01-18T16:15:05.114Z" }, + { url = "https://files.pythonhosted.org/packages/f4/1b/32a4de9856ee6688c670ca2def588382e573cce45241a965af04c2f61687/pyarrow-23.0.0-cp311-cp311-musllinux_1_2_x86_64.whl", hash = "sha256:84839d060a54ae734eb60a756aeacb62885244aaa282f3c968f5972ecc7b1ecc", size = 50582529, upload-time = "2026-01-18T16:15:12.846Z" }, + { url = "https://files.pythonhosted.org/packages/db/c7/d6581f03e9b9e44ea60b52d1750ee1a7678c484c06f939f45365a45f7eef/pyarrow-23.0.0-cp311-cp311-win_amd64.whl", hash = "sha256:a149a647dbfe928ce8830a713612aa0b16e22c64feac9d1761529778e4d4eaa5", size = 27542646, upload-time = "2026-01-18T16:15:18.89Z" }, + { url = "https://files.pythonhosted.org/packages/3d/bd/c861d020831ee57609b73ea721a617985ece817684dc82415b0bc3e03ac3/pyarrow-23.0.0-cp312-cp312-macosx_12_0_arm64.whl", hash = "sha256:5961a9f646c232697c24f54d3419e69b4261ba8a8b66b0ac54a1851faffcbab8", size = 34189116, upload-time = "2026-01-18T16:15:28.054Z" }, + { url = "https://files.pythonhosted.org/packages/8c/23/7725ad6cdcbaf6346221391e7b3eecd113684c805b0a95f32014e6fa0736/pyarrow-23.0.0-cp312-cp312-macosx_12_0_x86_64.whl", hash = "sha256:632b3e7c3d232f41d64e1a4a043fb82d44f8a349f339a1188c6a0dd9d2d47d8a", size = 35803831, upload-time = "2026-01-18T16:15:33.798Z" }, + { url = "https://files.pythonhosted.org/packages/57/06/684a421543455cdc2944d6a0c2cc3425b028a4c6b90e34b35580c4899743/pyarrow-23.0.0-cp312-cp312-manylinux_2_28_aarch64.whl", hash = "sha256:76242c846db1411f1d6c2cc3823be6b86b40567ee24493344f8226ba34a81333", size = 44436452, upload-time = "2026-01-18T16:15:41.598Z" }, + { url = "https://files.pythonhosted.org/packages/c6/6f/8f9eb40c2328d66e8b097777ddcf38494115ff9f1b5bc9754ba46991191e/pyarrow-23.0.0-cp312-cp312-manylinux_2_28_x86_64.whl", hash = "sha256:b73519f8b52ae28127000986bf228fda781e81d3095cd2d3ece76eb5cf760e1b", size = 47557396, upload-time = "2026-01-18T16:15:51.252Z" }, + { url = "https://files.pythonhosted.org/packages/10/6e/f08075f1472e5159553501fde2cc7bc6700944bdabe49a03f8a035ee6ccd/pyarrow-23.0.0-cp312-cp312-musllinux_1_2_aarch64.whl", hash = "sha256:068701f6823449b1b6469120f399a1239766b117d211c5d2519d4ed5861f75de", size = 48147129, upload-time = "2026-01-18T16:16:00.299Z" }, + { url = "https://files.pythonhosted.org/packages/7d/82/d5a680cd507deed62d141cc7f07f7944a6766fc51019f7f118e4d8ad0fb8/pyarrow-23.0.0-cp312-cp312-musllinux_1_2_x86_64.whl", hash = "sha256:1801ba947015d10e23bca9dd6ef5d0e9064a81569a89b6e9a63b59224fd060df", size = 50596642, upload-time = "2026-01-18T16:16:08.502Z" }, + { url = "https://files.pythonhosted.org/packages/a9/26/4f29c61b3dce9fa7780303b86895ec6a0917c9af927101daaaf118fbe462/pyarrow-23.0.0-cp312-cp312-win_amd64.whl", hash = "sha256:52265266201ec25b6839bf6bd4ea918ca6d50f31d13e1cf200b4261cd11dc25c", size = 27660628, upload-time = "2026-01-18T16:16:15.28Z" }, + { url = "https://files.pythonhosted.org/packages/66/34/564db447d083ec7ff93e0a883a597d2f214e552823bfc178a2d0b1f2c257/pyarrow-23.0.0-cp313-cp313-macosx_12_0_arm64.whl", hash = "sha256:ad96a597547af7827342ffb3c503c8316e5043bb09b47a84885ce39394c96e00", size = 34184630, upload-time = "2026-01-18T16:16:22.141Z" }, + { url = "https://files.pythonhosted.org/packages/aa/3a/3999daebcb5e6119690c92a621c4d78eef2ffba7a0a1b56386d2875fcd77/pyarrow-23.0.0-cp313-cp313-macosx_12_0_x86_64.whl", hash = "sha256:b9edf990df77c2901e79608f08c13fbde60202334a4fcadb15c1f57bf7afee43", size = 35796820, upload-time = "2026-01-18T16:16:29.441Z" }, + { url = "https://files.pythonhosted.org/packages/ec/ee/39195233056c6a8d0976d7d1ac1cd4fe21fb0ec534eca76bc23ef3f60e11/pyarrow-23.0.0-cp313-cp313-manylinux_2_28_aarch64.whl", hash = "sha256:36d1b5bc6ddcaff0083ceec7e2561ed61a51f49cce8be079ee8ed406acb6fdef", size = 44438735, upload-time = "2026-01-18T16:16:38.79Z" }, + { url = "https://files.pythonhosted.org/packages/2c/41/6a7328ee493527e7afc0c88d105ecca69a3580e29f2faaeac29308369fd7/pyarrow-23.0.0-cp313-cp313-manylinux_2_28_x86_64.whl", hash = "sha256:4292b889cd224f403304ddda8b63a36e60f92911f89927ec8d98021845ea21be", size = 47557263, upload-time = "2026-01-18T16:16:46.248Z" }, + { url = "https://files.pythonhosted.org/packages/c6/ee/34e95b21ee84db494eae60083ddb4383477b31fb1fd19fd866d794881696/pyarrow-23.0.0-cp313-cp313-musllinux_1_2_aarch64.whl", hash = "sha256:dfd9e133e60eaa847fd80530a1b89a052f09f695d0b9c34c235ea6b2e0924cf7", size = 48153529, upload-time = "2026-01-18T16:16:53.412Z" }, + { url = "https://files.pythonhosted.org/packages/52/88/8a8d83cea30f4563efa1b7bf51d241331ee5cd1b185a7e063f5634eca415/pyarrow-23.0.0-cp313-cp313-musllinux_1_2_x86_64.whl", hash = "sha256:832141cc09fac6aab1cd3719951d23301396968de87080c57c9a7634e0ecd068", size = 50598851, upload-time = "2026-01-18T16:17:01.133Z" }, + { url = "https://files.pythonhosted.org/packages/c6/4c/2929c4be88723ba025e7b3453047dc67e491c9422965c141d24bab6b5962/pyarrow-23.0.0-cp313-cp313-win_amd64.whl", hash = "sha256:7a7d067c9a88faca655c71bcc30ee2782038d59c802d57950826a07f60d83c4c", size = 27577747, upload-time = "2026-01-18T16:18:02.413Z" }, + { url = "https://files.pythonhosted.org/packages/64/52/564a61b0b82d72bd68ec3aef1adda1e3eba776f89134b9ebcb5af4b13cb6/pyarrow-23.0.0-cp313-cp313t-macosx_12_0_arm64.whl", hash = "sha256:ce9486e0535a843cf85d990e2ec5820a47918235183a5c7b8b97ed7e92c2d47d", size = 34446038, upload-time = "2026-01-18T16:17:07.861Z" }, + { url = "https://files.pythonhosted.org/packages/cc/c9/232d4f9855fd1de0067c8a7808a363230d223c83aeee75e0fe6eab851ba9/pyarrow-23.0.0-cp313-cp313t-macosx_12_0_x86_64.whl", hash = "sha256:075c29aeaa685fd1182992a9ed2499c66f084ee54eea47da3eb76e125e06064c", size = 35921142, upload-time = "2026-01-18T16:17:15.401Z" }, + { url = "https://files.pythonhosted.org/packages/96/f2/60af606a3748367b906bb82d41f0032e059f075444445d47e32a7ff1df62/pyarrow-23.0.0-cp313-cp313t-manylinux_2_28_aarch64.whl", hash = "sha256:799965a5379589510d888be3094c2296efd186a17ca1cef5b77703d4d5121f53", size = 44490374, upload-time = "2026-01-18T16:17:23.93Z" }, + { url = "https://files.pythonhosted.org/packages/ff/2d/7731543050a678ea3a413955a2d5d80d2a642f270aa57a3cb7d5a86e3f46/pyarrow-23.0.0-cp313-cp313t-manylinux_2_28_x86_64.whl", hash = "sha256:ef7cac8fe6fccd8b9e7617bfac785b0371a7fe26af59463074e4882747145d40", size = 47527896, upload-time = "2026-01-18T16:17:33.393Z" }, + { url = "https://files.pythonhosted.org/packages/5a/90/f3342553b7ac9879413aed46500f1637296f3c8222107523a43a1c08b42a/pyarrow-23.0.0-cp313-cp313t-musllinux_1_2_aarch64.whl", hash = "sha256:15a414f710dc927132dd67c361f78c194447479555af57317066ee5116b90e9e", size = 48210401, upload-time = "2026-01-18T16:17:42.012Z" }, + { url = "https://files.pythonhosted.org/packages/f3/da/9862ade205ecc46c172b6ce5038a74b5151c7401e36255f15975a45878b2/pyarrow-23.0.0-cp313-cp313t-musllinux_1_2_x86_64.whl", hash = "sha256:3e0d2e6915eca7d786be6a77bf227fbc06d825a75b5b5fe9bcbef121dec32685", size = 50579677, upload-time = "2026-01-18T16:17:50.241Z" }, + { url = "https://files.pythonhosted.org/packages/c2/4c/f11f371f5d4740a5dafc2e11c76bcf42d03dfdb2d68696da97de420b6963/pyarrow-23.0.0-cp313-cp313t-win_amd64.whl", hash = "sha256:4b317ea6e800b5704e5e5929acb6e2dc13e9276b708ea97a39eb8b345aa2658b", size = 27631889, upload-time = "2026-01-18T16:17:56.55Z" }, + { url = "https://files.pythonhosted.org/packages/97/bb/15aec78bcf43a0c004067bd33eb5352836a29a49db8581fc56f2b6ca88b7/pyarrow-23.0.0-cp314-cp314-macosx_12_0_arm64.whl", hash = "sha256:20b187ed9550d233a872074159f765f52f9d92973191cd4b93f293a19efbe377", size = 34213265, upload-time = "2026-01-18T16:18:07.904Z" }, + { url = "https://files.pythonhosted.org/packages/f6/6c/deb2c594bbba41c37c5d9aa82f510376998352aa69dfcb886cb4b18ad80f/pyarrow-23.0.0-cp314-cp314-macosx_12_0_x86_64.whl", hash = "sha256:18ec84e839b493c3886b9b5e06861962ab4adfaeb79b81c76afbd8d84c7d5fda", size = 35819211, upload-time = "2026-01-18T16:18:13.94Z" }, + { url = "https://files.pythonhosted.org/packages/e0/e5/ee82af693cb7b5b2b74f6524cdfede0e6ace779d7720ebca24d68b57c36b/pyarrow-23.0.0-cp314-cp314-manylinux_2_28_aarch64.whl", hash = "sha256:e438dd3f33894e34fd02b26bd12a32d30d006f5852315f611aa4add6c7fab4bc", size = 44502313, upload-time = "2026-01-18T16:18:20.367Z" }, + { url = "https://files.pythonhosted.org/packages/9c/86/95c61ad82236495f3c31987e85135926ba3ec7f3819296b70a68d8066b49/pyarrow-23.0.0-cp314-cp314-manylinux_2_28_x86_64.whl", hash = "sha256:a244279f240c81f135631be91146d7fa0e9e840e1dfed2aba8483eba25cd98e6", size = 47585886, upload-time = "2026-01-18T16:18:27.544Z" }, + { url = "https://files.pythonhosted.org/packages/bb/6e/a72d901f305201802f016d015de1e05def7706fff68a1dedefef5dc7eff7/pyarrow-23.0.0-cp314-cp314-musllinux_1_2_aarch64.whl", hash = "sha256:c4692e83e42438dba512a570c6eaa42be2f8b6c0f492aea27dec54bdc495103a", size = 48207055, upload-time = "2026-01-18T16:18:35.425Z" }, + { url = "https://files.pythonhosted.org/packages/f9/e5/5de029c537630ca18828db45c30e2a78da03675a70ac6c3528203c416fe3/pyarrow-23.0.0-cp314-cp314-musllinux_1_2_x86_64.whl", hash = "sha256:ae7f30f898dfe44ea69654a35c93e8da4cef6606dc4c72394068fd95f8e9f54a", size = 50619812, upload-time = "2026-01-18T16:18:43.553Z" }, + { url = "https://files.pythonhosted.org/packages/59/8d/2af846cd2412e67a087f5bda4a8e23dfd4ebd570f777db2e8686615dafc1/pyarrow-23.0.0-cp314-cp314-win_amd64.whl", hash = "sha256:5b86bb649e4112fb0614294b7d0a175c7513738876b89655605ebb87c804f861", size = 28263851, upload-time = "2026-01-18T16:19:38.567Z" }, + { url = "https://files.pythonhosted.org/packages/7b/7f/caab863e587041156f6786c52e64151b7386742c8c27140f637176e9230e/pyarrow-23.0.0-cp314-cp314t-macosx_12_0_arm64.whl", hash = "sha256:ebc017d765d71d80a3f8584ca0566b53e40464586585ac64176115baa0ada7d3", size = 34463240, upload-time = "2026-01-18T16:18:49.755Z" }, + { url = "https://files.pythonhosted.org/packages/c9/fa/3a5b8c86c958e83622b40865e11af0857c48ec763c11d472c87cd518283d/pyarrow-23.0.0-cp314-cp314t-macosx_12_0_x86_64.whl", hash = "sha256:0800cc58a6d17d159df823f87ad66cefebf105b982493d4bad03ee7fab84b993", size = 35935712, upload-time = "2026-01-18T16:18:55.626Z" }, + { url = "https://files.pythonhosted.org/packages/c5/08/17a62078fc1a53decb34a9aa79cf9009efc74d63d2422e5ade9fed2f99e3/pyarrow-23.0.0-cp314-cp314t-manylinux_2_28_aarch64.whl", hash = "sha256:3a7c68c722da9bb5b0f8c10e3eae71d9825a4b429b40b32709df5d1fa55beb3d", size = 44503523, upload-time = "2026-01-18T16:19:03.958Z" }, + { url = "https://files.pythonhosted.org/packages/cc/70/84d45c74341e798aae0323d33b7c39194e23b1abc439ceaf60a68a7a969a/pyarrow-23.0.0-cp314-cp314t-manylinux_2_28_x86_64.whl", hash = "sha256:bd5556c24622df90551063ea41f559b714aa63ca953db884cfb958559087a14e", size = 47542490, upload-time = "2026-01-18T16:19:11.208Z" }, + { url = "https://files.pythonhosted.org/packages/61/d9/d1274b0e6f19e235de17441e53224f4716574b2ca837022d55702f24d71d/pyarrow-23.0.0-cp314-cp314t-musllinux_1_2_aarch64.whl", hash = "sha256:54810f6e6afc4ffee7c2e0051b61722fbea9a4961b46192dcfae8ea12fa09059", size = 48233605, upload-time = "2026-01-18T16:19:19.544Z" }, + { url = "https://files.pythonhosted.org/packages/39/07/e4e2d568cb57543d84482f61e510732820cddb0f47c4bb7df629abfed852/pyarrow-23.0.0-cp314-cp314t-musllinux_1_2_x86_64.whl", hash = "sha256:14de7d48052cf4b0ed174533eafa3cfe0711b8076ad70bede32cf59f744f0d7c", size = 50603979, upload-time = "2026-01-18T16:19:26.717Z" }, + { url = "https://files.pythonhosted.org/packages/72/9c/47693463894b610f8439b2e970b82ef81e9599c757bf2049365e40ff963c/pyarrow-23.0.0-cp314-cp314t-win_amd64.whl", hash = "sha256:427deac1f535830a744a4f04a6ac183a64fcac4341b3f618e693c41b7b98d2b0", size = 28338905, upload-time = "2026-01-18T16:19:32.93Z" }, +] + +[[package]] +name = "pycparser" +version = "2.23" +source = { registry = "https://pypi.org/simple" } +resolution-markers = [ + "python_full_version < '3.10'", +] +sdist = { url = "https://files.pythonhosted.org/packages/fe/cf/d2d3b9f5699fb1e4615c8e32ff220203e43b248e1dfcc6736ad9057731ca/pycparser-2.23.tar.gz", hash = "sha256:78816d4f24add8f10a06d6f05b4d424ad9e96cfebf68a4ddc99c65c0720d00c2", size = 173734, upload-time = "2025-09-09T13:23:47.91Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/a0/e3/59cd50310fc9b59512193629e1984c1f95e5c8ae6e5d8c69532ccc65a7fe/pycparser-2.23-py3-none-any.whl", hash = "sha256:e5c6e8d3fbad53479cab09ac03729e0a9faf2bee3db8208a550daf5af81a5934", size = 118140, upload-time = "2025-09-09T13:23:46.651Z" }, +] + +[[package]] +name = "pycparser" +version = "3.0" +source = { registry = "https://pypi.org/simple" } +resolution-markers = [ + "python_full_version >= '3.13'", + "python_full_version == '3.12.*'", + "python_full_version == '3.11.*'", + "python_full_version == '3.10.*'", +] +sdist = { url = "https://files.pythonhosted.org/packages/1b/7d/92392ff7815c21062bea51aa7b87d45576f649f16458d78b7cf94b9ab2e6/pycparser-3.0.tar.gz", hash = "sha256:600f49d217304a5902ac3c37e1281c9fe94e4d0489de643a9504c5cdfdfc6b29", size = 103492, upload-time = "2026-01-21T14:26:51.89Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/0c/c3/44f3fbbfa403ea2a7c779186dc20772604442dde72947e7d01069cbe98e3/pycparser-3.0-py3-none-any.whl", hash = "sha256:b727414169a36b7d524c1c3e31839a521725078d7b2ff038656844266160a992", size = 48172, upload-time = "2026-01-21T14:26:50.693Z" }, +] + +[[package]] +name = "pyjwt" +version = "2.11.0" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/5c/5a/b46fa56bf322901eee5b0454a34343cdbdae202cd421775a8ee4e42fd519/pyjwt-2.11.0.tar.gz", hash = "sha256:35f95c1f0fbe5d5ba6e43f00271c275f7a1a4db1dab27bf708073b75318ea623", size = 98019, upload-time = "2026-01-30T19:59:55.694Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/6f/01/c26ce75ba460d5cd503da9e13b21a33804d38c2165dec7b716d06b13010c/pyjwt-2.11.0-py3-none-any.whl", hash = "sha256:94a6bde30eb5c8e04fee991062b534071fd1439ef58d2adc9ccb823e7bcd0469", size = 28224, upload-time = "2026-01-30T19:59:54.539Z" }, +] + +[[package]] +name = "pyopenssl" +version = "25.3.0" +source = { registry = "https://pypi.org/simple" } +dependencies = [ + { name = "cryptography" }, + { name = "typing-extensions", marker = "python_full_version < '3.13'" }, +] +sdist = { url = "https://files.pythonhosted.org/packages/80/be/97b83a464498a79103036bc74d1038df4a7ef0e402cfaf4d5e113fb14759/pyopenssl-25.3.0.tar.gz", hash = "sha256:c981cb0a3fd84e8602d7afc209522773b94c1c2446a3c710a75b06fe1beae329", size = 184073, upload-time = "2025-09-17T00:32:21.037Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/d1/81/ef2b1dfd1862567d573a4fdbc9f969067621764fbb74338496840a1d2977/pyopenssl-25.3.0-py3-none-any.whl", hash = "sha256:1fda6fc034d5e3d179d39e59c1895c9faeaf40a79de5fc4cbbfbe0d36f4a77b6", size = 57268, upload-time = "2025-09-17T00:32:19.474Z" }, +] + +[[package]] +name = "python-dateutil" +version = "2.9.0.post0" +source = { registry = "https://pypi.org/simple" } +dependencies = [ + { name = "six" }, +] +sdist = { url = "https://files.pythonhosted.org/packages/66/c0/0c8b6ad9f17a802ee498c46e004a0eb49bc148f2fd230864601a86dcf6db/python-dateutil-2.9.0.post0.tar.gz", hash = "sha256:37dd54208da7e1cd875388217d5e00ebd4179249f90fb72437e91a35459a0ad3", size = 342432, upload-time = "2024-03-01T18:36:20.211Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/ec/57/56b9bcc3c9c6a792fcbaf139543cee77261f3651ca9da0c93f5c1221264b/python_dateutil-2.9.0.post0-py2.py3-none-any.whl", hash = "sha256:a8b2bc7bffae282281c8140a97d3aa9c14da0b136dfe83f850eea9a5f7470427", size = 229892, upload-time = "2024-03-01T18:36:18.57Z" }, +] + +[[package]] +name = "python-dotenv" +version = "1.2.1" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/f0/26/19cadc79a718c5edbec86fd4919a6b6d3f681039a2f6d66d14be94e75fb9/python_dotenv-1.2.1.tar.gz", hash = "sha256:42667e897e16ab0d66954af0e60a9caa94f0fd4ecf3aaf6d2d260eec1aa36ad6", size = 44221, upload-time = "2025-10-26T15:12:10.434Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/14/1b/a298b06749107c305e1fe0f814c6c74aea7b2f1e10989cb30f544a1b3253/python_dotenv-1.2.1-py3-none-any.whl", hash = "sha256:b81ee9561e9ca4004139c6cbba3a238c32b03e4894671e181b671e8cb8425d61", size = 21230, upload-time = "2025-10-26T15:12:09.109Z" }, +] + +[[package]] +name = "pytz" +version = "2025.2" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/f8/bf/abbd3cdfb8fbc7fb3d4d38d320f2441b1e7cbe29be4f23797b4a2b5d8aac/pytz-2025.2.tar.gz", hash = "sha256:360b9e3dbb49a209c21ad61809c7fb453643e048b38924c765813546746e81c3", size = 320884, upload-time = "2025-03-25T02:25:00.538Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/81/c4/34e93fe5f5429d7570ec1fa436f1986fb1f00c3e0f43a589fe2bbcd22c3f/pytz-2025.2-py2.py3-none-any.whl", hash = "sha256:5ddf76296dd8c44c26eb8f4b6f35488f3ccbf6fbbd7adee0b7262d43f0ec2f00", size = 509225, upload-time = "2025-03-25T02:24:58.468Z" }, +] + +[[package]] +name = "pywin32-ctypes" +version = "0.2.3" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/85/9f/01a1a99704853cb63f253eea009390c88e7131c67e66a0a02099a8c917cb/pywin32-ctypes-0.2.3.tar.gz", hash = "sha256:d162dc04946d704503b2edc4d55f3dba5c1d539ead017afa00142c38b9885755", size = 29471, upload-time = "2024-08-14T10:15:34.626Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/de/3d/8161f7711c017e01ac9f008dfddd9410dff3674334c233bde66e7ba65bbf/pywin32_ctypes-0.2.3-py3-none-any.whl", hash = "sha256:8a1513379d709975552d202d942d9837758905c8d01eb82b8bcc30918929e7b8", size = 30756, upload-time = "2024-08-14T10:15:33.187Z" }, +] + +[[package]] +name = "pyyaml" +version = "6.0.3" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/05/8e/961c0007c59b8dd7729d542c61a4d537767a59645b82a0b521206e1e25c2/pyyaml-6.0.3.tar.gz", hash = "sha256:d76623373421df22fb4cf8817020cbb7ef15c725b9d5e45f17e189bfc384190f", size = 130960, upload-time = "2025-09-25T21:33:16.546Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/f4/a0/39350dd17dd6d6c6507025c0e53aef67a9293a6d37d3511f23ea510d5800/pyyaml-6.0.3-cp310-cp310-macosx_10_13_x86_64.whl", hash = "sha256:214ed4befebe12df36bcc8bc2b64b396ca31be9304b8f59e25c11cf94a4c033b", size = 184227, upload-time = "2025-09-25T21:31:46.04Z" }, + { url = "https://files.pythonhosted.org/packages/05/14/52d505b5c59ce73244f59c7a50ecf47093ce4765f116cdb98286a71eeca2/pyyaml-6.0.3-cp310-cp310-macosx_11_0_arm64.whl", hash = "sha256:02ea2dfa234451bbb8772601d7b8e426c2bfa197136796224e50e35a78777956", size = 174019, upload-time = "2025-09-25T21:31:47.706Z" }, + { url = "https://files.pythonhosted.org/packages/43/f7/0e6a5ae5599c838c696adb4e6330a59f463265bfa1e116cfd1fbb0abaaae/pyyaml-6.0.3-cp310-cp310-manylinux2014_aarch64.manylinux_2_17_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:b30236e45cf30d2b8e7b3e85881719e98507abed1011bf463a8fa23e9c3e98a8", size = 740646, upload-time = "2025-09-25T21:31:49.21Z" }, + { url = "https://files.pythonhosted.org/packages/2f/3a/61b9db1d28f00f8fd0ae760459a5c4bf1b941baf714e207b6eb0657d2578/pyyaml-6.0.3-cp310-cp310-manylinux2014_s390x.manylinux_2_17_s390x.manylinux_2_28_s390x.whl", hash = "sha256:66291b10affd76d76f54fad28e22e51719ef9ba22b29e1d7d03d6777a9174198", size = 840793, upload-time = "2025-09-25T21:31:50.735Z" }, + { url = "https://files.pythonhosted.org/packages/7a/1e/7acc4f0e74c4b3d9531e24739e0ab832a5edf40e64fbae1a9c01941cabd7/pyyaml-6.0.3-cp310-cp310-manylinux2014_x86_64.manylinux_2_17_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:9c7708761fccb9397fe64bbc0395abcae8c4bf7b0eac081e12b809bf47700d0b", size = 770293, upload-time = "2025-09-25T21:31:51.828Z" }, + { url = "https://files.pythonhosted.org/packages/8b/ef/abd085f06853af0cd59fa5f913d61a8eab65d7639ff2a658d18a25d6a89d/pyyaml-6.0.3-cp310-cp310-musllinux_1_2_aarch64.whl", hash = "sha256:418cf3f2111bc80e0933b2cd8cd04f286338bb88bdc7bc8e6dd775ebde60b5e0", size = 732872, upload-time = "2025-09-25T21:31:53.282Z" }, + { url = "https://files.pythonhosted.org/packages/1f/15/2bc9c8faf6450a8b3c9fc5448ed869c599c0a74ba2669772b1f3a0040180/pyyaml-6.0.3-cp310-cp310-musllinux_1_2_x86_64.whl", hash = "sha256:5e0b74767e5f8c593e8c9b5912019159ed0533c70051e9cce3e8b6aa699fcd69", size = 758828, upload-time = "2025-09-25T21:31:54.807Z" }, + { url = "https://files.pythonhosted.org/packages/a3/00/531e92e88c00f4333ce359e50c19b8d1de9fe8d581b1534e35ccfbc5f393/pyyaml-6.0.3-cp310-cp310-win32.whl", hash = "sha256:28c8d926f98f432f88adc23edf2e6d4921ac26fb084b028c733d01868d19007e", size = 142415, upload-time = "2025-09-25T21:31:55.885Z" }, + { url = "https://files.pythonhosted.org/packages/2a/fa/926c003379b19fca39dd4634818b00dec6c62d87faf628d1394e137354d4/pyyaml-6.0.3-cp310-cp310-win_amd64.whl", hash = "sha256:bdb2c67c6c1390b63c6ff89f210c8fd09d9a1217a465701eac7316313c915e4c", size = 158561, upload-time = "2025-09-25T21:31:57.406Z" }, + { url = "https://files.pythonhosted.org/packages/6d/16/a95b6757765b7b031c9374925bb718d55e0a9ba8a1b6a12d25962ea44347/pyyaml-6.0.3-cp311-cp311-macosx_10_13_x86_64.whl", hash = "sha256:44edc647873928551a01e7a563d7452ccdebee747728c1080d881d68af7b997e", size = 185826, upload-time = "2025-09-25T21:31:58.655Z" }, + { url = "https://files.pythonhosted.org/packages/16/19/13de8e4377ed53079ee996e1ab0a9c33ec2faf808a4647b7b4c0d46dd239/pyyaml-6.0.3-cp311-cp311-macosx_11_0_arm64.whl", hash = "sha256:652cb6edd41e718550aad172851962662ff2681490a8a711af6a4d288dd96824", size = 175577, upload-time = "2025-09-25T21:32:00.088Z" }, + { url = "https://files.pythonhosted.org/packages/0c/62/d2eb46264d4b157dae1275b573017abec435397aa59cbcdab6fc978a8af4/pyyaml-6.0.3-cp311-cp311-manylinux2014_aarch64.manylinux_2_17_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:10892704fc220243f5305762e276552a0395f7beb4dbf9b14ec8fd43b57f126c", size = 775556, upload-time = "2025-09-25T21:32:01.31Z" }, + { url = "https://files.pythonhosted.org/packages/10/cb/16c3f2cf3266edd25aaa00d6c4350381c8b012ed6f5276675b9eba8d9ff4/pyyaml-6.0.3-cp311-cp311-manylinux2014_s390x.manylinux_2_17_s390x.manylinux_2_28_s390x.whl", hash = "sha256:850774a7879607d3a6f50d36d04f00ee69e7fc816450e5f7e58d7f17f1ae5c00", size = 882114, upload-time = "2025-09-25T21:32:03.376Z" }, + { url = "https://files.pythonhosted.org/packages/71/60/917329f640924b18ff085ab889a11c763e0b573da888e8404ff486657602/pyyaml-6.0.3-cp311-cp311-manylinux2014_x86_64.manylinux_2_17_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:b8bb0864c5a28024fac8a632c443c87c5aa6f215c0b126c449ae1a150412f31d", size = 806638, upload-time = "2025-09-25T21:32:04.553Z" }, + { url = "https://files.pythonhosted.org/packages/dd/6f/529b0f316a9fd167281a6c3826b5583e6192dba792dd55e3203d3f8e655a/pyyaml-6.0.3-cp311-cp311-musllinux_1_2_aarch64.whl", hash = "sha256:1d37d57ad971609cf3c53ba6a7e365e40660e3be0e5175fa9f2365a379d6095a", size = 767463, upload-time = "2025-09-25T21:32:06.152Z" }, + { url = "https://files.pythonhosted.org/packages/f2/6a/b627b4e0c1dd03718543519ffb2f1deea4a1e6d42fbab8021936a4d22589/pyyaml-6.0.3-cp311-cp311-musllinux_1_2_x86_64.whl", hash = "sha256:37503bfbfc9d2c40b344d06b2199cf0e96e97957ab1c1b546fd4f87e53e5d3e4", size = 794986, upload-time = "2025-09-25T21:32:07.367Z" }, + { url = "https://files.pythonhosted.org/packages/45/91/47a6e1c42d9ee337c4839208f30d9f09caa9f720ec7582917b264defc875/pyyaml-6.0.3-cp311-cp311-win32.whl", hash = "sha256:8098f252adfa6c80ab48096053f512f2321f0b998f98150cea9bd23d83e1467b", size = 142543, upload-time = "2025-09-25T21:32:08.95Z" }, + { url = "https://files.pythonhosted.org/packages/da/e3/ea007450a105ae919a72393cb06f122f288ef60bba2dc64b26e2646fa315/pyyaml-6.0.3-cp311-cp311-win_amd64.whl", hash = "sha256:9f3bfb4965eb874431221a3ff3fdcddc7e74e3b07799e0e84ca4a0f867d449bf", size = 158763, upload-time = "2025-09-25T21:32:09.96Z" }, + { url = "https://files.pythonhosted.org/packages/d1/33/422b98d2195232ca1826284a76852ad5a86fe23e31b009c9886b2d0fb8b2/pyyaml-6.0.3-cp312-cp312-macosx_10_13_x86_64.whl", hash = "sha256:7f047e29dcae44602496db43be01ad42fc6f1cc0d8cd6c83d342306c32270196", size = 182063, upload-time = "2025-09-25T21:32:11.445Z" }, + { url = "https://files.pythonhosted.org/packages/89/a0/6cf41a19a1f2f3feab0e9c0b74134aa2ce6849093d5517a0c550fe37a648/pyyaml-6.0.3-cp312-cp312-macosx_11_0_arm64.whl", hash = "sha256:fc09d0aa354569bc501d4e787133afc08552722d3ab34836a80547331bb5d4a0", size = 173973, upload-time = "2025-09-25T21:32:12.492Z" }, + { url = "https://files.pythonhosted.org/packages/ed/23/7a778b6bd0b9a8039df8b1b1d80e2e2ad78aa04171592c8a5c43a56a6af4/pyyaml-6.0.3-cp312-cp312-manylinux2014_aarch64.manylinux_2_17_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:9149cad251584d5fb4981be1ecde53a1ca46c891a79788c0df828d2f166bda28", size = 775116, upload-time = "2025-09-25T21:32:13.652Z" }, + { url = "https://files.pythonhosted.org/packages/65/30/d7353c338e12baef4ecc1b09e877c1970bd3382789c159b4f89d6a70dc09/pyyaml-6.0.3-cp312-cp312-manylinux2014_s390x.manylinux_2_17_s390x.manylinux_2_28_s390x.whl", hash = "sha256:5fdec68f91a0c6739b380c83b951e2c72ac0197ace422360e6d5a959d8d97b2c", size = 844011, upload-time = "2025-09-25T21:32:15.21Z" }, + { url = "https://files.pythonhosted.org/packages/8b/9d/b3589d3877982d4f2329302ef98a8026e7f4443c765c46cfecc8858c6b4b/pyyaml-6.0.3-cp312-cp312-manylinux2014_x86_64.manylinux_2_17_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:ba1cc08a7ccde2d2ec775841541641e4548226580ab850948cbfda66a1befcdc", size = 807870, upload-time = "2025-09-25T21:32:16.431Z" }, + { url = "https://files.pythonhosted.org/packages/05/c0/b3be26a015601b822b97d9149ff8cb5ead58c66f981e04fedf4e762f4bd4/pyyaml-6.0.3-cp312-cp312-musllinux_1_2_aarch64.whl", hash = "sha256:8dc52c23056b9ddd46818a57b78404882310fb473d63f17b07d5c40421e47f8e", size = 761089, upload-time = "2025-09-25T21:32:17.56Z" }, + { url = "https://files.pythonhosted.org/packages/be/8e/98435a21d1d4b46590d5459a22d88128103f8da4c2d4cb8f14f2a96504e1/pyyaml-6.0.3-cp312-cp312-musllinux_1_2_x86_64.whl", hash = "sha256:41715c910c881bc081f1e8872880d3c650acf13dfa8214bad49ed4cede7c34ea", size = 790181, upload-time = "2025-09-25T21:32:18.834Z" }, + { url = "https://files.pythonhosted.org/packages/74/93/7baea19427dcfbe1e5a372d81473250b379f04b1bd3c4c5ff825e2327202/pyyaml-6.0.3-cp312-cp312-win32.whl", hash = "sha256:96b533f0e99f6579b3d4d4995707cf36df9100d67e0c8303a0c55b27b5f99bc5", size = 137658, upload-time = "2025-09-25T21:32:20.209Z" }, + { url = "https://files.pythonhosted.org/packages/86/bf/899e81e4cce32febab4fb42bb97dcdf66bc135272882d1987881a4b519e9/pyyaml-6.0.3-cp312-cp312-win_amd64.whl", hash = "sha256:5fcd34e47f6e0b794d17de1b4ff496c00986e1c83f7ab2fb8fcfe9616ff7477b", size = 154003, upload-time = "2025-09-25T21:32:21.167Z" }, + { url = "https://files.pythonhosted.org/packages/1a/08/67bd04656199bbb51dbed1439b7f27601dfb576fb864099c7ef0c3e55531/pyyaml-6.0.3-cp312-cp312-win_arm64.whl", hash = "sha256:64386e5e707d03a7e172c0701abfb7e10f0fb753ee1d773128192742712a98fd", size = 140344, upload-time = "2025-09-25T21:32:22.617Z" }, + { url = "https://files.pythonhosted.org/packages/d1/11/0fd08f8192109f7169db964b5707a2f1e8b745d4e239b784a5a1dd80d1db/pyyaml-6.0.3-cp313-cp313-macosx_10_13_x86_64.whl", hash = "sha256:8da9669d359f02c0b91ccc01cac4a67f16afec0dac22c2ad09f46bee0697eba8", size = 181669, upload-time = "2025-09-25T21:32:23.673Z" }, + { url = "https://files.pythonhosted.org/packages/b1/16/95309993f1d3748cd644e02e38b75d50cbc0d9561d21f390a76242ce073f/pyyaml-6.0.3-cp313-cp313-macosx_11_0_arm64.whl", hash = "sha256:2283a07e2c21a2aa78d9c4442724ec1eb15f5e42a723b99cb3d822d48f5f7ad1", size = 173252, upload-time = "2025-09-25T21:32:25.149Z" }, + { url = "https://files.pythonhosted.org/packages/50/31/b20f376d3f810b9b2371e72ef5adb33879b25edb7a6d072cb7ca0c486398/pyyaml-6.0.3-cp313-cp313-manylinux2014_aarch64.manylinux_2_17_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:ee2922902c45ae8ccada2c5b501ab86c36525b883eff4255313a253a3160861c", size = 767081, upload-time = "2025-09-25T21:32:26.575Z" }, + { url = "https://files.pythonhosted.org/packages/49/1e/a55ca81e949270d5d4432fbbd19dfea5321eda7c41a849d443dc92fd1ff7/pyyaml-6.0.3-cp313-cp313-manylinux2014_s390x.manylinux_2_17_s390x.manylinux_2_28_s390x.whl", hash = "sha256:a33284e20b78bd4a18c8c2282d549d10bc8408a2a7ff57653c0cf0b9be0afce5", size = 841159, upload-time = "2025-09-25T21:32:27.727Z" }, + { url = "https://files.pythonhosted.org/packages/74/27/e5b8f34d02d9995b80abcef563ea1f8b56d20134d8f4e5e81733b1feceb2/pyyaml-6.0.3-cp313-cp313-manylinux2014_x86_64.manylinux_2_17_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:0f29edc409a6392443abf94b9cf89ce99889a1dd5376d94316ae5145dfedd5d6", size = 801626, upload-time = "2025-09-25T21:32:28.878Z" }, + { url = "https://files.pythonhosted.org/packages/f9/11/ba845c23988798f40e52ba45f34849aa8a1f2d4af4b798588010792ebad6/pyyaml-6.0.3-cp313-cp313-musllinux_1_2_aarch64.whl", hash = "sha256:f7057c9a337546edc7973c0d3ba84ddcdf0daa14533c2065749c9075001090e6", size = 753613, upload-time = "2025-09-25T21:32:30.178Z" }, + { url = "https://files.pythonhosted.org/packages/3d/e0/7966e1a7bfc0a45bf0a7fb6b98ea03fc9b8d84fa7f2229e9659680b69ee3/pyyaml-6.0.3-cp313-cp313-musllinux_1_2_x86_64.whl", hash = "sha256:eda16858a3cab07b80edaf74336ece1f986ba330fdb8ee0d6c0d68fe82bc96be", size = 794115, upload-time = "2025-09-25T21:32:31.353Z" }, + { url = "https://files.pythonhosted.org/packages/de/94/980b50a6531b3019e45ddeada0626d45fa85cbe22300844a7983285bed3b/pyyaml-6.0.3-cp313-cp313-win32.whl", hash = "sha256:d0eae10f8159e8fdad514efdc92d74fd8d682c933a6dd088030f3834bc8e6b26", size = 137427, upload-time = "2025-09-25T21:32:32.58Z" }, + { url = "https://files.pythonhosted.org/packages/97/c9/39d5b874e8b28845e4ec2202b5da735d0199dbe5b8fb85f91398814a9a46/pyyaml-6.0.3-cp313-cp313-win_amd64.whl", hash = "sha256:79005a0d97d5ddabfeeea4cf676af11e647e41d81c9a7722a193022accdb6b7c", size = 154090, upload-time = "2025-09-25T21:32:33.659Z" }, + { url = "https://files.pythonhosted.org/packages/73/e8/2bdf3ca2090f68bb3d75b44da7bbc71843b19c9f2b9cb9b0f4ab7a5a4329/pyyaml-6.0.3-cp313-cp313-win_arm64.whl", hash = "sha256:5498cd1645aa724a7c71c8f378eb29ebe23da2fc0d7a08071d89469bf1d2defb", size = 140246, upload-time = "2025-09-25T21:32:34.663Z" }, + { url = "https://files.pythonhosted.org/packages/9d/8c/f4bd7f6465179953d3ac9bc44ac1a8a3e6122cf8ada906b4f96c60172d43/pyyaml-6.0.3-cp314-cp314-macosx_10_13_x86_64.whl", hash = "sha256:8d1fab6bb153a416f9aeb4b8763bc0f22a5586065f86f7664fc23339fc1c1fac", size = 181814, upload-time = "2025-09-25T21:32:35.712Z" }, + { url = "https://files.pythonhosted.org/packages/bd/9c/4d95bb87eb2063d20db7b60faa3840c1b18025517ae857371c4dd55a6b3a/pyyaml-6.0.3-cp314-cp314-macosx_11_0_arm64.whl", hash = "sha256:34d5fcd24b8445fadc33f9cf348c1047101756fd760b4dacb5c3e99755703310", size = 173809, upload-time = "2025-09-25T21:32:36.789Z" }, + { url = "https://files.pythonhosted.org/packages/92/b5/47e807c2623074914e29dabd16cbbdd4bf5e9b2db9f8090fa64411fc5382/pyyaml-6.0.3-cp314-cp314-manylinux2014_aarch64.manylinux_2_17_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:501a031947e3a9025ed4405a168e6ef5ae3126c59f90ce0cd6f2bfc477be31b7", size = 766454, upload-time = "2025-09-25T21:32:37.966Z" }, + { url = "https://files.pythonhosted.org/packages/02/9e/e5e9b168be58564121efb3de6859c452fccde0ab093d8438905899a3a483/pyyaml-6.0.3-cp314-cp314-manylinux2014_s390x.manylinux_2_17_s390x.manylinux_2_28_s390x.whl", hash = "sha256:b3bc83488de33889877a0f2543ade9f70c67d66d9ebb4ac959502e12de895788", size = 836355, upload-time = "2025-09-25T21:32:39.178Z" }, + { url = "https://files.pythonhosted.org/packages/88/f9/16491d7ed2a919954993e48aa941b200f38040928474c9e85ea9e64222c3/pyyaml-6.0.3-cp314-cp314-manylinux2014_x86_64.manylinux_2_17_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:c458b6d084f9b935061bc36216e8a69a7e293a2f1e68bf956dcd9e6cbcd143f5", size = 794175, upload-time = "2025-09-25T21:32:40.865Z" }, + { url = "https://files.pythonhosted.org/packages/dd/3f/5989debef34dc6397317802b527dbbafb2b4760878a53d4166579111411e/pyyaml-6.0.3-cp314-cp314-musllinux_1_2_aarch64.whl", hash = "sha256:7c6610def4f163542a622a73fb39f534f8c101d690126992300bf3207eab9764", size = 755228, upload-time = "2025-09-25T21:32:42.084Z" }, + { url = "https://files.pythonhosted.org/packages/d7/ce/af88a49043cd2e265be63d083fc75b27b6ed062f5f9fd6cdc223ad62f03e/pyyaml-6.0.3-cp314-cp314-musllinux_1_2_x86_64.whl", hash = "sha256:5190d403f121660ce8d1d2c1bb2ef1bd05b5f68533fc5c2ea899bd15f4399b35", size = 789194, upload-time = "2025-09-25T21:32:43.362Z" }, + { url = "https://files.pythonhosted.org/packages/23/20/bb6982b26a40bb43951265ba29d4c246ef0ff59c9fdcdf0ed04e0687de4d/pyyaml-6.0.3-cp314-cp314-win_amd64.whl", hash = "sha256:4a2e8cebe2ff6ab7d1050ecd59c25d4c8bd7e6f400f5f82b96557ac0abafd0ac", size = 156429, upload-time = "2025-09-25T21:32:57.844Z" }, + { url = "https://files.pythonhosted.org/packages/f4/f4/a4541072bb9422c8a883ab55255f918fa378ecf083f5b85e87fc2b4eda1b/pyyaml-6.0.3-cp314-cp314-win_arm64.whl", hash = "sha256:93dda82c9c22deb0a405ea4dc5f2d0cda384168e466364dec6255b293923b2f3", size = 143912, upload-time = "2025-09-25T21:32:59.247Z" }, + { url = "https://files.pythonhosted.org/packages/7c/f9/07dd09ae774e4616edf6cda684ee78f97777bdd15847253637a6f052a62f/pyyaml-6.0.3-cp314-cp314t-macosx_10_13_x86_64.whl", hash = "sha256:02893d100e99e03eda1c8fd5c441d8c60103fd175728e23e431db1b589cf5ab3", size = 189108, upload-time = "2025-09-25T21:32:44.377Z" }, + { url = "https://files.pythonhosted.org/packages/4e/78/8d08c9fb7ce09ad8c38ad533c1191cf27f7ae1effe5bb9400a46d9437fcf/pyyaml-6.0.3-cp314-cp314t-macosx_11_0_arm64.whl", hash = "sha256:c1ff362665ae507275af2853520967820d9124984e0f7466736aea23d8611fba", size = 183641, upload-time = "2025-09-25T21:32:45.407Z" }, + { url = "https://files.pythonhosted.org/packages/7b/5b/3babb19104a46945cf816d047db2788bcaf8c94527a805610b0289a01c6b/pyyaml-6.0.3-cp314-cp314t-manylinux2014_aarch64.manylinux_2_17_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:6adc77889b628398debc7b65c073bcb99c4a0237b248cacaf3fe8a557563ef6c", size = 831901, upload-time = "2025-09-25T21:32:48.83Z" }, + { url = "https://files.pythonhosted.org/packages/8b/cc/dff0684d8dc44da4d22a13f35f073d558c268780ce3c6ba1b87055bb0b87/pyyaml-6.0.3-cp314-cp314t-manylinux2014_s390x.manylinux_2_17_s390x.manylinux_2_28_s390x.whl", hash = "sha256:a80cb027f6b349846a3bf6d73b5e95e782175e52f22108cfa17876aaeff93702", size = 861132, upload-time = "2025-09-25T21:32:50.149Z" }, + { url = "https://files.pythonhosted.org/packages/b1/5e/f77dc6b9036943e285ba76b49e118d9ea929885becb0a29ba8a7c75e29fe/pyyaml-6.0.3-cp314-cp314t-manylinux2014_x86_64.manylinux_2_17_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:00c4bdeba853cc34e7dd471f16b4114f4162dc03e6b7afcc2128711f0eca823c", size = 839261, upload-time = "2025-09-25T21:32:51.808Z" }, + { url = "https://files.pythonhosted.org/packages/ce/88/a9db1376aa2a228197c58b37302f284b5617f56a5d959fd1763fb1675ce6/pyyaml-6.0.3-cp314-cp314t-musllinux_1_2_aarch64.whl", hash = "sha256:66e1674c3ef6f541c35191caae2d429b967b99e02040f5ba928632d9a7f0f065", size = 805272, upload-time = "2025-09-25T21:32:52.941Z" }, + { url = "https://files.pythonhosted.org/packages/da/92/1446574745d74df0c92e6aa4a7b0b3130706a4142b2d1a5869f2eaa423c6/pyyaml-6.0.3-cp314-cp314t-musllinux_1_2_x86_64.whl", hash = "sha256:16249ee61e95f858e83976573de0f5b2893b3677ba71c9dd36b9cf8be9ac6d65", size = 829923, upload-time = "2025-09-25T21:32:54.537Z" }, + { url = "https://files.pythonhosted.org/packages/f0/7a/1c7270340330e575b92f397352af856a8c06f230aa3e76f86b39d01b416a/pyyaml-6.0.3-cp314-cp314t-win_amd64.whl", hash = "sha256:4ad1906908f2f5ae4e5a8ddfce73c320c2a1429ec52eafd27138b7f1cbe341c9", size = 174062, upload-time = "2025-09-25T21:32:55.767Z" }, + { url = "https://files.pythonhosted.org/packages/f1/12/de94a39c2ef588c7e6455cfbe7343d3b2dc9d6b6b2f40c4c6565744c873d/pyyaml-6.0.3-cp314-cp314t-win_arm64.whl", hash = "sha256:ebc55a14a21cb14062aa4162f906cd962b28e2e9ea38f9b4391244cd8de4ae0b", size = 149341, upload-time = "2025-09-25T21:32:56.828Z" }, + { url = "https://files.pythonhosted.org/packages/9f/62/67fc8e68a75f738c9200422bf65693fb79a4cd0dc5b23310e5202e978090/pyyaml-6.0.3-cp39-cp39-macosx_10_13_x86_64.whl", hash = "sha256:b865addae83924361678b652338317d1bd7e79b1f4596f96b96c77a5a34b34da", size = 184450, upload-time = "2025-09-25T21:33:00.618Z" }, + { url = "https://files.pythonhosted.org/packages/ae/92/861f152ce87c452b11b9d0977952259aa7df792d71c1053365cc7b09cc08/pyyaml-6.0.3-cp39-cp39-macosx_11_0_arm64.whl", hash = "sha256:c3355370a2c156cffb25e876646f149d5d68f5e0a3ce86a5084dd0b64a994917", size = 174319, upload-time = "2025-09-25T21:33:02.086Z" }, + { url = "https://files.pythonhosted.org/packages/d0/cd/f0cfc8c74f8a030017a2b9c771b7f47e5dd702c3e28e5b2071374bda2948/pyyaml-6.0.3-cp39-cp39-manylinux2014_aarch64.manylinux_2_17_aarch64.manylinux_2_28_aarch64.whl", hash = "sha256:3c5677e12444c15717b902a5798264fa7909e41153cdf9ef7ad571b704a63dd9", size = 737631, upload-time = "2025-09-25T21:33:03.25Z" }, + { url = "https://files.pythonhosted.org/packages/ef/b2/18f2bd28cd2055a79a46c9b0895c0b3d987ce40ee471cecf58a1a0199805/pyyaml-6.0.3-cp39-cp39-manylinux2014_s390x.manylinux_2_17_s390x.manylinux_2_28_s390x.whl", hash = "sha256:5ed875a24292240029e4483f9d4a4b8a1ae08843b9c54f43fcc11e404532a8a5", size = 836795, upload-time = "2025-09-25T21:33:05.014Z" }, + { url = "https://files.pythonhosted.org/packages/73/b9/793686b2d54b531203c160ef12bec60228a0109c79bae6c1277961026770/pyyaml-6.0.3-cp39-cp39-manylinux2014_x86_64.manylinux_2_17_x86_64.manylinux_2_28_x86_64.whl", hash = "sha256:0150219816b6a1fa26fb4699fb7daa9caf09eb1999f3b70fb6e786805e80375a", size = 750767, upload-time = "2025-09-25T21:33:06.398Z" }, + { url = "https://files.pythonhosted.org/packages/a9/86/a137b39a611def2ed78b0e66ce2fe13ee701a07c07aebe55c340ed2a050e/pyyaml-6.0.3-cp39-cp39-musllinux_1_2_aarch64.whl", hash = "sha256:fa160448684b4e94d80416c0fa4aac48967a969efe22931448d853ada8baf926", size = 727982, upload-time = "2025-09-25T21:33:08.708Z" }, + { url = "https://files.pythonhosted.org/packages/dd/62/71c27c94f457cf4418ef8ccc71735324c549f7e3ea9d34aba50874563561/pyyaml-6.0.3-cp39-cp39-musllinux_1_2_x86_64.whl", hash = "sha256:27c0abcb4a5dac13684a37f76e701e054692a9b2d3064b70f5e4eb54810553d7", size = 755677, upload-time = "2025-09-25T21:33:09.876Z" }, + { url = "https://files.pythonhosted.org/packages/29/3d/6f5e0d58bd924fb0d06c3a6bad00effbdae2de5adb5cda5648006ffbd8d3/pyyaml-6.0.3-cp39-cp39-win32.whl", hash = "sha256:1ebe39cb5fc479422b83de611d14e2c0d3bb2a18bbcb01f229ab3cfbd8fee7a0", size = 142592, upload-time = "2025-09-25T21:33:10.983Z" }, + { url = "https://files.pythonhosted.org/packages/f0/0c/25113e0b5e103d7f1490c0e947e303fe4a696c10b501dea7a9f49d4e876c/pyyaml-6.0.3-cp39-cp39-win_amd64.whl", hash = "sha256:2e71d11abed7344e42a8849600193d15b6def118602c4c176f748e4583246007", size = 158777, upload-time = "2025-09-25T21:33:15.55Z" }, +] + +[[package]] +name = "requests" +version = "2.32.5" +source = { registry = "https://pypi.org/simple" } +dependencies = [ + { name = "certifi" }, + { name = "charset-normalizer" }, + { name = "idna" }, + { name = "urllib3" }, +] +sdist = { url = "https://files.pythonhosted.org/packages/c9/74/b3ff8e6c8446842c3f5c837e9c3dfcfe2018ea6ecef224c710c85ef728f4/requests-2.32.5.tar.gz", hash = "sha256:dbba0bac56e100853db0ea71b82b4dfd5fe2bf6d3754a8893c3af500cec7d7cf", size = 134517, upload-time = "2025-08-18T20:46:02.573Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/1e/db/4254e3eabe8020b458f1a747140d32277ec7a271daf1d235b70dc0b4e6e3/requests-2.32.5-py3-none-any.whl", hash = "sha256:2462f94637a34fd532264295e186976db0f5d453d1cdd31473c85a6a161affb6", size = 64738, upload-time = "2025-08-18T20:46:00.542Z" }, +] + +[[package]] +name = "s3transfer" +version = "0.16.0" +source = { registry = "https://pypi.org/simple" } +dependencies = [ + { name = "botocore" }, +] +sdist = { url = "https://files.pythonhosted.org/packages/05/04/74127fc843314818edfa81b5540e26dd537353b123a4edc563109d8f17dd/s3transfer-0.16.0.tar.gz", hash = "sha256:8e990f13268025792229cd52fa10cb7163744bf56e719e0b9cb925ab79abf920", size = 153827, upload-time = "2025-12-01T02:30:59.114Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/fc/51/727abb13f44c1fcf6d145979e1535a35794db0f6e450a0cb46aa24732fe2/s3transfer-0.16.0-py3-none-any.whl", hash = "sha256:18e25d66fed509e3868dc1572b3f427ff947dd2c56f844a5bf09481ad3f3b2fe", size = 86830, upload-time = "2025-12-01T02:30:57.729Z" }, +] + +[[package]] +name = "secretstorage" +version = "3.3.3" +source = { registry = "https://pypi.org/simple" } +resolution-markers = [ + "python_full_version < '3.10'", +] +dependencies = [ + { name = "cryptography", marker = "python_full_version < '3.10'" }, + { name = "jeepney", marker = "python_full_version < '3.10'" }, +] +sdist = { url = "https://files.pythonhosted.org/packages/53/a4/f48c9d79cb507ed1373477dbceaba7401fd8a23af63b837fa61f1dcd3691/SecretStorage-3.3.3.tar.gz", hash = "sha256:2403533ef369eca6d2ba81718576c5e0f564d5cca1b58f73a8b23e7d4eeebd77", size = 19739, upload-time = "2022-08-13T16:22:46.976Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/54/24/b4293291fa1dd830f353d2cb163295742fa87f179fcc8a20a306a81978b7/SecretStorage-3.3.3-py3-none-any.whl", hash = "sha256:f356e6628222568e3af06f2eba8df495efa13b3b63081dafd4f7d9a7b7bc9f99", size = 15221, upload-time = "2022-08-13T16:22:44.457Z" }, +] + +[[package]] +name = "secretstorage" +version = "3.5.0" +source = { registry = "https://pypi.org/simple" } +resolution-markers = [ + "python_full_version >= '3.13'", + "python_full_version == '3.12.*'", + "python_full_version == '3.11.*'", + "python_full_version == '3.10.*'", +] +dependencies = [ + { name = "cryptography", marker = "python_full_version >= '3.10'" }, + { name = "jeepney", marker = "python_full_version >= '3.10'" }, +] +sdist = { url = "https://files.pythonhosted.org/packages/1c/03/e834bcd866f2f8a49a85eaff47340affa3bfa391ee9912a952a1faa68c7b/secretstorage-3.5.0.tar.gz", hash = "sha256:f04b8e4689cbce351744d5537bf6b1329c6fc68f91fa666f60a380edddcd11be", size = 19884, upload-time = "2025-11-23T19:02:53.191Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/b7/46/f5af3402b579fd5e11573ce652019a67074317e18c1935cc0b4ba9b35552/secretstorage-3.5.0-py3-none-any.whl", hash = "sha256:0ce65888c0725fcb2c5bc0fdb8e5438eece02c523557ea40ce0703c266248137", size = 15554, upload-time = "2025-11-23T19:02:51.545Z" }, +] + +[[package]] +name = "setuptools" +version = "82.0.0" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/82/f3/748f4d6f65d1756b9ae577f329c951cda23fb900e4de9f70900ced962085/setuptools-82.0.0.tar.gz", hash = "sha256:22e0a2d69474c6ae4feb01951cb69d515ed23728cf96d05513d36e42b62b37cb", size = 1144893, upload-time = "2026-02-08T15:08:40.206Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/e1/c6/76dc613121b793286a3f91621d7b75a2b493e0390ddca50f11993eadf192/setuptools-82.0.0-py3-none-any.whl", hash = "sha256:70b18734b607bd1da571d097d236cfcfacaf01de45717d59e6e04b96877532e0", size = 1003468, upload-time = "2026-02-08T15:08:38.723Z" }, +] + +[[package]] +name = "six" +version = "1.17.0" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/94/e7/b2c673351809dca68a0e064b6af791aa332cf192da575fd474ed7d6f16a2/six-1.17.0.tar.gz", hash = "sha256:ff70335d468e7eb6ec65b95b99d3a2836546063f63acc5171de367e834932a81", size = 34031, upload-time = "2024-12-04T17:35:28.174Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/b7/ce/149a00dd41f10bc29e5921b496af8b574d8413afcd5e30dfa0ed46c2cc5e/six-1.17.0-py2.py3-none-any.whl", hash = "sha256:4721f391ed90541fddacab5acf947aa0d3dc7d27b2e1e8eda2be8970586c3274", size = 11050, upload-time = "2024-12-04T17:35:26.475Z" }, +] + +[[package]] +name = "snowflake-connector-python" +version = "4.2.0" +source = { registry = "https://pypi.org/simple" } +dependencies = [ + { name = "asn1crypto" }, + { name = "boto3" }, + { name = "botocore" }, + { name = "certifi" }, + { name = "charset-normalizer" }, + { name = "cryptography" }, + { name = "filelock", version = "3.19.1", source = { registry = "https://pypi.org/simple" }, marker = "python_full_version < '3.10'" }, + { name = "filelock", version = "3.20.3", source = { registry = "https://pypi.org/simple" }, marker = "python_full_version >= '3.10'" }, + { name = "idna" }, + { name = "packaging" }, + { name = "platformdirs", version = "4.4.0", source = { registry = "https://pypi.org/simple" }, marker = "python_full_version < '3.10'" }, + { name = "platformdirs", version = "4.5.1", source = { registry = "https://pypi.org/simple" }, marker = "python_full_version >= '3.10'" }, + { name = "pyjwt" }, + { name = "pyopenssl" }, + { name = "pytz" }, + { name = "requests" }, + { name = "sortedcontainers" }, + { name = "tomlkit" }, + { name = "typing-extensions" }, + { name = "urllib3", marker = "python_full_version < '3.10'" }, +] +sdist = { url = "https://files.pythonhosted.org/packages/13/d2/4ae9fc7a0df36ad0ac06bc959757dfbfc58f160f58e1d62e7cebe9901fc7/snowflake_connector_python-4.2.0.tar.gz", hash = "sha256:74b1028caee3af4550a366ef89b33de80940bbf856844dd4d788a6b7a6511aff", size = 915327, upload-time = "2026-01-07T16:44:32.541Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/a4/34/2c5c059b12db84113bb01761bd3fdab3e0c0d8d4ccc0c9631be5479960c2/snowflake_connector_python-4.2.0-cp310-cp310-macosx_11_0_arm64.whl", hash = "sha256:2e1c60e578ddcdf99b46d7c329706aa87ea98c1c877cbe50560e034cc904231e", size = 11908869, upload-time = "2026-01-07T16:44:35.243Z" }, + { url = "https://files.pythonhosted.org/packages/c9/27/07ab3485f43d92c139fefb30b68a60498b508f2e941d9191f1ec3ac42a20/snowflake_connector_python-4.2.0-cp310-cp310-macosx_11_0_x86_64.whl", hash = "sha256:cf1805be7e124aa12bdcbb6c7f7f7bd11277aa4fe4d616cfee7633617bba9651", size = 11921560, upload-time = "2026-01-07T16:44:37.995Z" }, + { url = "https://files.pythonhosted.org/packages/d5/12/ba6bb6cd26bc584637aa63f3e579cb929b9c3637fa830e43b77c2b2e8901/snowflake_connector_python-4.2.0-cp310-cp310-manylinux_2_17_aarch64.manylinux2014_aarch64.whl", hash = "sha256:0b877cf5fc086818d86e289fc88453bc354df87a664e57f9b75d8dd7550d2df3", size = 2786595, upload-time = "2026-01-07T16:44:14.314Z" }, + { url = "https://files.pythonhosted.org/packages/9f/80/bf900ac5ddd5b60a72f0c3f7c276c9b0f29b375997c294f28bd746e9f721/snowflake_connector_python-4.2.0-cp310-cp310-manylinux_2_17_x86_64.manylinux2014_x86_64.whl", hash = "sha256:3654c3923b7ce88aab3be459bad3dba39fe4f989a4871421925a8a48f9a553ca", size = 2814560, upload-time = "2026-01-07T16:44:15.988Z" }, + { url = "https://files.pythonhosted.org/packages/8e/04/e070116ff779fcd16c5e25ef8b045afb8cc53b12b3494663457718a7d877/snowflake_connector_python-4.2.0-cp310-cp310-win_amd64.whl", hash = "sha256:cdaf91edf94d801fef6cb15c90ba321826b8342826a82375799319d509e6787a", size = 12059955, upload-time = "2026-01-07T16:45:05.556Z" }, + { url = "https://files.pythonhosted.org/packages/24/5f/2e3ac52d4b433e850c83f91b801b7c4e9935a4d1c4f2ea4fd0c3782c5a3d/snowflake_connector_python-4.2.0-cp311-cp311-macosx_11_0_arm64.whl", hash = "sha256:e2971212e2bf38b19ed3d71d433102b09cda09ddca02fe4c813cb73f504a31e8", size = 11908767, upload-time = "2026-01-07T16:44:39.982Z" }, + { url = "https://files.pythonhosted.org/packages/31/f6/74d75623ed75244c4aad1722b83923c806a67f601b41314e8a6b30e160c0/snowflake_connector_python-4.2.0-cp311-cp311-macosx_11_0_x86_64.whl", hash = "sha256:786d9ad591439996ff5a6014c3730441bcfdc8c6d60f05d98f6576cb2cfa0f05", size = 11921016, upload-time = "2026-01-07T16:44:41.917Z" }, + { url = "https://files.pythonhosted.org/packages/31/53/ab0d2eed42f1309de2e7656651fdab6ae454032bcc485089ce5e0697b5c2/snowflake_connector_python-4.2.0-cp311-cp311-manylinux_2_17_aarch64.manylinux2014_aarch64.whl", hash = "sha256:74d3d2bcce62bbb7a8fb3adaae37dc2aaeb4e93549509db2f957fb704ce4aa18", size = 2797881, upload-time = "2026-01-07T16:44:17.319Z" }, + { url = "https://files.pythonhosted.org/packages/2a/6f/2aa88f57107fdf0daabd113b479ba50e22d566ae36e860d4dbe68bcb6437/snowflake_connector_python-4.2.0-cp311-cp311-manylinux_2_17_x86_64.manylinux2014_x86_64.whl", hash = "sha256:2cbdffcf5b12199f3060297353e69c5a4c1fc4dfacd0062acbe9a1ace7e50882", size = 2827340, upload-time = "2026-01-07T16:44:19.434Z" }, + { url = "https://files.pythonhosted.org/packages/f4/5b/d03f1d8dfeab8c81bd1f65cad93385932789971a640db1c6369b5850cc5b/snowflake_connector_python-4.2.0-cp311-cp311-win_amd64.whl", hash = "sha256:939e687ec4667d903b3bca3644b22946606361a2201158e137e448a6cd44605d", size = 12059905, upload-time = "2026-01-07T16:45:07.679Z" }, + { url = "https://files.pythonhosted.org/packages/3c/90/90df1e0bbc8ba22534af48518e71eb669a3bb6243989a93d59f9db9d8897/snowflake_connector_python-4.2.0-cp312-cp312-macosx_11_0_arm64.whl", hash = "sha256:b6e5dde4794fb190add6baee616f0f9a9b5c31502089b680a5be4441926b5173", size = 11907736, upload-time = "2026-01-07T16:44:44.598Z" }, + { url = "https://files.pythonhosted.org/packages/8e/d1/4e9015d37a869022729a146f4c7f312f089938e1f51ac7620f6961f7ce66/snowflake_connector_python-4.2.0-cp312-cp312-macosx_11_0_x86_64.whl", hash = "sha256:f80f180092d218b578f05da145dd2640edb3c8807264d69169bc4dfb88b8b86c", size = 11919401, upload-time = "2026-01-07T16:44:47.524Z" }, + { url = "https://files.pythonhosted.org/packages/c3/5a/c65134dedd438f9d8d6eaeb7f573cb95abe4141385a4353cfe88d8c96fb1/snowflake_connector_python-4.2.0-cp312-cp312-manylinux_2_17_aarch64.manylinux2014_aarch64.whl", hash = "sha256:94a59566d3096a662b09423770aede8f99f1d06807d7b884dba8d9f767f0b2cd", size = 2854461, upload-time = "2026-01-07T16:44:21.305Z" }, + { url = "https://files.pythonhosted.org/packages/94/6d/dd526a07042ca33ce05b8c642ef3da4a72e2cbe09e305170cb866021acd6/snowflake_connector_python-4.2.0-cp312-cp312-manylinux_2_17_x86_64.manylinux2014_x86_64.whl", hash = "sha256:11241089efc6e8d69ea1aa58bb17abe85298e66d278fed4d13381fc362f02564", size = 2887953, upload-time = "2026-01-07T16:44:23.221Z" }, + { url = "https://files.pythonhosted.org/packages/3f/e0/d2db617da5791ec03d17bfd96db6f4c867a3498c4b4d480befc6a1854522/snowflake_connector_python-4.2.0-cp312-cp312-win_amd64.whl", hash = "sha256:823ca257d9639b5468f53a816dc5acaea7c56991f518633c9c5f0fcf0d324721", size = 12058975, upload-time = "2026-01-07T16:45:10.293Z" }, + { url = "https://files.pythonhosted.org/packages/7a/34/cb523e85f9da46e22ee3c07a4f66a090ab935a1c6e59e4e9638cf8e7bc36/snowflake_connector_python-4.2.0-cp313-cp313-macosx_11_0_arm64.whl", hash = "sha256:2d103ab3d9175251c1e391c4a155d99faaadd6a1e3c1c36429a711862f7ab021", size = 11908616, upload-time = "2026-01-07T16:44:49.512Z" }, + { url = "https://files.pythonhosted.org/packages/5b/eb/7a5c2a4dc275048e0b0b67b6b542b4cfdf60da158af8a315e5dd1021f443/snowflake_connector_python-4.2.0-cp313-cp313-macosx_11_0_x86_64.whl", hash = "sha256:2db02486bf72b2d4da6338bad59c58e18d0be4026b33d62b894db8cb04de403e", size = 11920460, upload-time = "2026-01-07T16:44:51.845Z" }, + { url = "https://files.pythonhosted.org/packages/37/a2/7f85a01fc13982391166c5458f4fd1078546e6f19f9e0bb184dbf6ec5f53/snowflake_connector_python-4.2.0-cp313-cp313-manylinux_2_17_aarch64.manylinux2014_aarch64.whl", hash = "sha256:b93b0195746c7734ab66889430a418ac7fd66441c11addb683bc15e364bb77c8", size = 2820920, upload-time = "2026-01-07T16:44:24.728Z" }, + { url = "https://files.pythonhosted.org/packages/aa/80/322dafc03f77f28f1ede160e4989ae758dd27dc94529e424348865bba501/snowflake_connector_python-4.2.0-cp313-cp313-manylinux_2_17_x86_64.manylinux2014_x86_64.whl", hash = "sha256:4773949e33c2503f369c20ac8fd59697e493670fed653fea7349d465ea5a0171", size = 2854097, upload-time = "2026-01-07T16:44:26.817Z" }, + { url = "https://files.pythonhosted.org/packages/06/05/64d3de8c98f783a3065e60107519b701d1ab7ef15efefa279d338f3fba64/snowflake_connector_python-4.2.0-cp313-cp313-win_amd64.whl", hash = "sha256:3665eae47a6ccaf00ca567936cb16d5cbdd5b9f8ab3ee3a3f072bf3c4b76986c", size = 12058956, upload-time = "2026-01-07T16:45:13.063Z" }, + { url = "https://files.pythonhosted.org/packages/43/fe/36a83105acc347d8df375e713a2f2dbc1f2744ca176697a78e61430432d0/snowflake_connector_python-4.2.0-cp39-cp39-macosx_11_0_arm64.whl", hash = "sha256:84ce2c959f6ca215338bd6844fca51c15cdd906af40747b704387c1f11cff412", size = 11909236, upload-time = "2026-01-07T16:44:53.867Z" }, + { url = "https://files.pythonhosted.org/packages/44/48/119fa0570d0605a9605a69728334636438a27cfdad745de8e3ae9529507e/snowflake_connector_python-4.2.0-cp39-cp39-macosx_11_0_x86_64.whl", hash = "sha256:d91e558ba13f076b9fd16d0a04e28c6c11263fde0184acd020ddf7a4fae8e6f0", size = 11921930, upload-time = "2026-01-07T16:45:02.676Z" }, + { url = "https://files.pythonhosted.org/packages/b1/c0/bdca92bc19eb2a8f0c9d97fdee71bd5c183d10fecf5be0a7cfea55bece24/snowflake_connector_python-4.2.0-cp39-cp39-manylinux_2_17_aarch64.manylinux2014_aarch64.whl", hash = "sha256:6a713794ce5376e18c02de37ef4035da6d903b980cd48376e83f32b39797322f", size = 2783203, upload-time = "2026-01-07T16:44:28.711Z" }, + { url = "https://files.pythonhosted.org/packages/47/e1/c1536454c30c830cc64d06ad6a14831652578438f7deed710dc5c41f0808/snowflake_connector_python-4.2.0-cp39-cp39-manylinux_2_17_x86_64.manylinux2014_x86_64.whl", hash = "sha256:545c7af3bde36465fd0426afe2c12d4a8d2752d7df45df6f1a6364f10f5f3027", size = 2811552, upload-time = "2026-01-07T16:44:30.7Z" }, + { url = "https://files.pythonhosted.org/packages/d9/f5/0cc6fd791fc1e76e7a221b1d93a68b0d5c190fcfb9c3b48f01e3fb1b5964/snowflake_connector_python-4.2.0-cp39-cp39-win_amd64.whl", hash = "sha256:8ca1a5ad3595784bf9b8bf3346227b47406150c07a1a5996e42c646effd14674", size = 12061086, upload-time = "2026-01-07T16:45:15.532Z" }, +] + +[package.optional-dependencies] +pandas = [ + { name = "pandas" }, + { name = "pyarrow", version = "21.0.0", source = { registry = "https://pypi.org/simple" }, marker = "python_full_version < '3.10'" }, + { name = "pyarrow", version = "23.0.0", source = { registry = "https://pypi.org/simple" }, marker = "python_full_version >= '3.10'" }, +] +secure-local-storage = [ + { name = "keyring" }, +] + +[[package]] +name = "snowflake-snowpark-python" +version = "1.45.0" +source = { registry = "https://pypi.org/simple" } +dependencies = [ + { name = "cloudpickle" }, + { name = "protobuf" }, + { name = "python-dateutil" }, + { name = "pyyaml" }, + { name = "setuptools" }, + { name = "snowflake-connector-python" }, + { name = "typing-extensions" }, + { name = "tzlocal" }, + { name = "wheel" }, +] +sdist = { url = "https://files.pythonhosted.org/packages/36/6a/f5d5944a3e33ae9e7d81b7f125182333e11905d30c8eac8e3dbb3c9dace8/snowflake_snowpark_python-1.45.0.tar.gz", hash = "sha256:2b557d11d0369109b6205dfafbe7b1b42b2b3ffb17f35321dcd53d6532928b80", size = 1731888, upload-time = "2026-02-02T23:10:47.926Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/e5/ed/b55d5425a916529a2e4d080950a6284f9fd42cd3f9ee63d2203e306e1c97/snowflake_snowpark_python-1.45.0-py3-none-any.whl", hash = "sha256:2f5edd96c9f735a79b7aeba07cb629dacd729d9f8fbe769c2a0087da648f0693", size = 1822927, upload-time = "2026-02-02T23:10:46.144Z" }, +] + +[[package]] +name = "sortedcontainers" +version = "2.4.0" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/e8/c4/ba2f8066cceb6f23394729afe52f3bf7adec04bf9ed2c820b39e19299111/sortedcontainers-2.4.0.tar.gz", hash = "sha256:25caa5a06cc30b6b83d11423433f65d1f9d76c4c6a0c90e3379eaa43b9bfdb88", size = 30594, upload-time = "2021-05-16T22:03:42.897Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/32/46/9cb0e58b2deb7f82b84065f37f3bffeb12413f947f9388e4cac22c4621ce/sortedcontainers-2.4.0-py2.py3-none-any.whl", hash = "sha256:a163dcaede0f1c021485e957a39245190e74249897e2ae4b2aa38595db237ee0", size = 29575, upload-time = "2021-05-16T22:03:41.177Z" }, +] + +[[package]] +name = "tomlkit" +version = "0.14.0" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/c3/af/14b24e41977adb296d6bd1fb59402cf7d60ce364f90c890bd2ec65c43b5a/tomlkit-0.14.0.tar.gz", hash = "sha256:cf00efca415dbd57575befb1f6634c4f42d2d87dbba376128adb42c121b87064", size = 187167, upload-time = "2026-01-13T01:14:53.304Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/b5/11/87d6d29fb5d237229d67973a6c9e06e048f01cf4994dee194ab0ea841814/tomlkit-0.14.0-py3-none-any.whl", hash = "sha256:592064ed85b40fa213469f81ac584f67a4f2992509a7c3ea2d632208623a3680", size = 39310, upload-time = "2026-01-13T01:14:51.965Z" }, +] + +[[package]] +name = "typing-extensions" +version = "4.15.0" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/72/94/1a15dd82efb362ac84269196e94cf00f187f7ed21c242792a923cdb1c61f/typing_extensions-4.15.0.tar.gz", hash = "sha256:0cea48d173cc12fa28ecabc3b837ea3cf6f38c6d1136f85cbaaf598984861466", size = 109391, upload-time = "2025-08-25T13:49:26.313Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/18/67/36e9267722cc04a6b9f15c7f3441c2363321a3ea07da7ae0c0707beb2a9c/typing_extensions-4.15.0-py3-none-any.whl", hash = "sha256:f0fa19c6845758ab08074a0cfa8b7aecb71c999ca73d62883bc25cc018c4e548", size = 44614, upload-time = "2025-08-25T13:49:24.86Z" }, +] + +[[package]] +name = "tzdata" +version = "2025.3" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/5e/a7/c202b344c5ca7daf398f3b8a477eeb205cf3b6f32e7ec3a6bac0629ca975/tzdata-2025.3.tar.gz", hash = "sha256:de39c2ca5dc7b0344f2eba86f49d614019d29f060fc4ebc8a417896a620b56a7", size = 196772, upload-time = "2025-12-13T17:45:35.667Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/c7/b0/003792df09decd6849a5e39c28b513c06e84436a54440380862b5aeff25d/tzdata-2025.3-py2.py3-none-any.whl", hash = "sha256:06a47e5700f3081aab02b2e513160914ff0694bce9947d6b76ebd6bf57cfc5d1", size = 348521, upload-time = "2025-12-13T17:45:33.889Z" }, +] + +[[package]] +name = "tzlocal" +version = "5.3.1" +source = { registry = "https://pypi.org/simple" } +dependencies = [ + { name = "tzdata", marker = "sys_platform == 'win32'" }, +] +sdist = { url = "https://files.pythonhosted.org/packages/8b/2e/c14812d3d4d9cd1773c6be938f89e5735a1f11a9f184ac3639b93cef35d5/tzlocal-5.3.1.tar.gz", hash = "sha256:cceffc7edecefea1f595541dbd6e990cb1ea3d19bf01b2809f362a03dd7921fd", size = 30761, upload-time = "2025-03-05T21:17:41.549Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/c2/14/e2a54fabd4f08cd7af1c07030603c3356b74da07f7cc056e600436edfa17/tzlocal-5.3.1-py3-none-any.whl", hash = "sha256:eb1a66c3ef5847adf7a834f1be0800581b683b5608e74f86ecbcef8ab91bb85d", size = 18026, upload-time = "2025-03-05T21:17:39.857Z" }, +] + +[[package]] +name = "urllib3" +version = "1.26.20" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/e4/e8/6ff5e6bc22095cfc59b6ea711b687e2b7ed4bdb373f7eeec370a97d7392f/urllib3-1.26.20.tar.gz", hash = "sha256:40c2dc0c681e47eb8f90e7e27bf6ff7df2e677421fd46756da1161c39ca70d32", size = 307380, upload-time = "2024-08-29T15:43:11.37Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/33/cf/8435d5a7159e2a9c83a95896ed596f68cf798005fe107cc655b5c5c14704/urllib3-1.26.20-py2.py3-none-any.whl", hash = "sha256:0ed14ccfbf1c30a9072c7ca157e4319b70d65f623e91e7b32fadb2853431016e", size = 144225, upload-time = "2024-08-29T15:43:08.921Z" }, +] + +[[package]] +name = "wheel" +version = "0.46.3" +source = { registry = "https://pypi.org/simple" } +dependencies = [ + { name = "packaging" }, +] +sdist = { url = "https://files.pythonhosted.org/packages/89/24/a2eb353a6edac9a0303977c4cb048134959dd2a51b48a269dfc9dde00c8a/wheel-0.46.3.tar.gz", hash = "sha256:e3e79874b07d776c40bd6033f8ddf76a7dad46a7b8aa1b2787a83083519a1803", size = 60605, upload-time = "2026-01-22T12:39:49.136Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/87/22/b76d483683216dde3d67cba61fb2444be8d5be289bf628c13fc0fd90e5f9/wheel-0.46.3-py3-none-any.whl", hash = "sha256:4b399d56c9d9338230118d705d9737a2a468ccca63d5e813e2a4fc7815d8bc4d", size = 30557, upload-time = "2026-01-22T12:39:48.099Z" }, +] + +[[package]] +name = "zipp" +version = "3.23.0" +source = { registry = "https://pypi.org/simple" } +sdist = { url = "https://files.pythonhosted.org/packages/e3/02/0f2892c661036d50ede074e376733dca2ae7c6eb617489437771209d4180/zipp-3.23.0.tar.gz", hash = "sha256:a07157588a12518c9d4034df3fbbee09c814741a33ff63c05fa29d26a2404166", size = 25547, upload-time = "2025-06-08T17:06:39.4Z" } +wheels = [ + { url = "https://files.pythonhosted.org/packages/2e/54/647ade08bf0db230bfea292f893923872fd20be6ac6f53b2b936ba839d75/zipp-3.23.0-py3-none-any.whl", hash = "sha256:071652d6115ed432f5ce1d34c336c0adfd6a884660d1e9712a256d3d3bd4b14e", size = 10276, upload-time = "2025-06-08T17:06:38.034Z" }, +] From acbb0f83b76d2f87cef235d2ff994d3f70a8d7bb Mon Sep 17 00:00:00 2001 From: EddieDavison92 <143042680+EddieDavison92@users.noreply.github.com> Date: Wed, 11 Feb 2026 20:53:16 +0000 Subject: [PATCH 02/15] fix: clarify empty table warnings in column completeness test test_subject now shows '(empty table)' for WARN status rows so the output explains why the check couldn't run. --- OLIDS/Testing/data-quality/test_column_completeness.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/OLIDS/Testing/data-quality/test_column_completeness.sql b/OLIDS/Testing/data-quality/test_column_completeness.sql index bc46fd9..28a5b38 100644 --- a/OLIDS/Testing/data-quality/test_column_completeness.sql +++ b/OLIDS/Testing/data-quality/test_column_completeness.sql @@ -195,7 +195,7 @@ WITH checks AS ( SELECT 'column_completeness' AS test_name, table_name, - column_name AS test_subject, + CASE WHEN total_rows = 0 THEN column_name || ' (empty table)' ELSE column_name END AS test_subject, CASE WHEN total_rows = 0 THEN 'WARN' WHEN ROUND(100.0 * null_count / total_rows, 4) <= threshold THEN 'PASS' From 5d01e480b460e58663cdf70aadcf896ce4f9fcda Mon Sep 17 00:00:00 2001 From: EddieDavison92 <143042680+EddieDavison92@users.noreply.github.com> Date: Wed, 11 Feb 2026 23:05:08 +0000 Subject: [PATCH 03/15] fix: address review findings across test suite and investigations - Tiered completeness thresholds (0% PKs, 0.5% FKs, 1% dates, 5% concepts) - Add PERSON and PATIENT_PERSON table coverage - Add person_id->PERSON FK checks and PATIENT_PERSON FK checks - WARN instead of skip for empty FK relationships - Validate full concept mapping chain (CONCEPT_MAP + target CONCEPT) - PDS snapshot derived from OLIDS data freshness, snapped to month-end - LIMIT 1 on concept lookup CTEs in registration test - Better USE DATABASE error handling in runner - Mirror all fixes in investigation scripts --- OLIDS/Testing/README.md | 2 +- .../data-quality/test_column_completeness.sql | 113 +++++++------- .../data-quality/test_concept_mapping.sql | 140 +++++++++--------- .../data-quality/test_data_freshness.sql | 4 + .../test_referential_integrity.sql | 105 ++++++++++++- .../data-quality/test_registration_pds.sql | 24 ++- .../investigate_column_completeness.sql | 23 ++- .../investigate_concept_mapping.sql | 110 +++++++++----- .../investigate_referential_integrity.sql | 50 +++++++ .../investigate_registration_pds.sql | 13 +- OLIDS/Testing/run_tests.py | 24 ++- OLIDS/Testing/setup.ps1 | 2 +- 12 files changed, 428 insertions(+), 182 deletions(-) diff --git a/OLIDS/Testing/README.md b/OLIDS/Testing/README.md index 01bfd18..36b6317 100644 --- a/OLIDS/Testing/README.md +++ b/OLIDS/Testing/README.md @@ -80,7 +80,7 @@ Use `UNION ALL` to return multiple checks from one file. Any extra columns beyon Other notes: - Use `SET var = value;` and `$var` for Snowflake session variables (e.g. thresholds) - Use schema-qualified names (`OLIDS_COMMON.TABLE`) without the database prefix — the runner injects `USE DATABASE` -- Avoid semicolons in comments (the runner splits statements on `;`) +- Avoid semicolons inside comments or string literals — the runner naively splits on `;` to execute statements individually ## Investigating Failures diff --git a/OLIDS/Testing/data-quality/test_column_completeness.sql b/OLIDS/Testing/data-quality/test_column_completeness.sql index 28a5b38..b056428 100644 --- a/OLIDS/Testing/data-quality/test_column_completeness.sql +++ b/OLIDS/Testing/data-quality/test_column_completeness.sql @@ -7,8 +7,11 @@ How it works: 1. The 'checks' CTE has one row per column check. Each row counts total rows and NULL rows for that column in a single table scan. - 2. The 'threshold' value is the max allowed NULL % for that column. - Primary keys use 0.0 (no NULLs allowed). Most columns use 1.0. + 2. The 'threshold' value is the max allowed NULL % for that column: + - 0.0%: Primary keys (no NULLs allowed) + - 0.5%: Core foreign keys (patient_id, person_id, sk_patient_id) + - 1.0%: System/clinical dates (lds_start_date_time, clinical_effective_date) + - 5.0%: Concept fields (*_concept_id) — higher tolerance for optional coding 3. The final SELECT computes the completeness % (100 - null%) and compares against the threshold. Empty tables return WARN. @@ -28,122 +31,130 @@ WITH checks AS ( -- Each row: table, column, max allowed NULL %, total rows, NULL count -- PATIENT (OLIDS_MASKED) SELECT 'PATIENT' AS table_name, 'id' AS column_name, 0.0 AS threshold, COUNT(*) AS total_rows, SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) AS null_count FROM OLIDS_MASKED.PATIENT - UNION ALL SELECT 'PATIENT', 'sk_patient_id', 1.0, COUNT(*), SUM(CASE WHEN sk_patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'sk_patient_id', 0.5, COUNT(*), SUM(CASE WHEN sk_patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT UNION ALL SELECT 'PATIENT', 'birth_year', 1.0, COUNT(*), SUM(CASE WHEN birth_year IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT UNION ALL SELECT 'PATIENT', 'birth_month', 1.0, COUNT(*), SUM(CASE WHEN birth_month IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT - UNION ALL SELECT 'PATIENT', 'gender_concept_id', 1.0, COUNT(*), SUM(CASE WHEN gender_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'gender_concept_id', 5.0, COUNT(*), SUM(CASE WHEN gender_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT UNION ALL SELECT 'PATIENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + -- PERSON (OLIDS_MASKED) + UNION ALL SELECT 'PERSON', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PERSON + UNION ALL SELECT 'PERSON', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PERSON + -- PATIENT_ADDRESS (OLIDS_MASKED) UNION ALL SELECT 'PATIENT_ADDRESS', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS - UNION ALL SELECT 'PATIENT_ADDRESS', 'address_type_concept_id', 1.0, COUNT(*), SUM(CASE WHEN address_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS + UNION ALL SELECT 'PATIENT_ADDRESS', 'address_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN address_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS UNION ALL SELECT 'PATIENT_ADDRESS', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS -- PATIENT_CONTACT (OLIDS_MASKED) UNION ALL SELECT 'PATIENT_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT - UNION ALL SELECT 'PATIENT_CONTACT', 'contact_type_concept_id', 1.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT + UNION ALL SELECT 'PATIENT_CONTACT', 'contact_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT UNION ALL SELECT 'PATIENT_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT -- PATIENT_UPRN (OLIDS_MASKED) UNION ALL SELECT 'PATIENT_UPRN', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_UPRN UNION ALL SELECT 'PATIENT_UPRN', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_UPRN + -- PATIENT_PERSON (OLIDS_COMMON) + UNION ALL SELECT 'PATIENT_PERSON', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_PERSON + UNION ALL SELECT 'PATIENT_PERSON', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_PERSON + -- EPISODE_OF_CARE (OLIDS_COMMON) UNION ALL SELECT 'EPISODE_OF_CARE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE - UNION ALL SELECT 'EPISODE_OF_CARE', 'patient_id', 1.0, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE - UNION ALL SELECT 'EPISODE_OF_CARE', 'person_id', 1.0, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_of_care_start_date', 1.0, COUNT(*), SUM(CASE WHEN episode_of_care_start_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE UNION ALL SELECT 'EPISODE_OF_CARE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE - UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_type_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN episode_type_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE - UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_status_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN episode_status_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_type_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_type_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_status_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_status_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE -- OBSERVATION (OLIDS_COMMON) UNION ALL SELECT 'OBSERVATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'patient_id', 1.0, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'person_id', 1.0, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION UNION ALL SELECT 'OBSERVATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION UNION ALL SELECT 'OBSERVATION', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'observation_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN observation_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'result_value_units_concept_id', 1.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'date_precision_concept_id', 1.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'episodicity_concept_id', 1.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'observation_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN observation_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'result_value_units_concept_id', 5.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'episodicity_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION -- MEDICATION_STATEMENT (OLIDS_COMMON) UNION ALL SELECT 'MEDICATION_STATEMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT - UNION ALL SELECT 'MEDICATION_STATEMENT', 'patient_id', 1.0, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT - UNION ALL SELECT 'MEDICATION_STATEMENT', 'person_id', 1.0, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT UNION ALL SELECT 'MEDICATION_STATEMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT UNION ALL SELECT 'MEDICATION_STATEMENT', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT - UNION ALL SELECT 'MEDICATION_STATEMENT', 'medication_statement_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN medication_statement_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT - UNION ALL SELECT 'MEDICATION_STATEMENT', 'authorisation_type_concept_id', 1.0, COUNT(*), SUM(CASE WHEN authorisation_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT - UNION ALL SELECT 'MEDICATION_STATEMENT', 'date_precision_concept_id', 1.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'medication_statement_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN medication_statement_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'authorisation_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN authorisation_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT -- MEDICATION_ORDER (OLIDS_COMMON) UNION ALL SELECT 'MEDICATION_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER - UNION ALL SELECT 'MEDICATION_ORDER', 'patient_id', 1.0, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER - UNION ALL SELECT 'MEDICATION_ORDER', 'person_id', 1.0, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER UNION ALL SELECT 'MEDICATION_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER UNION ALL SELECT 'MEDICATION_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER - UNION ALL SELECT 'MEDICATION_ORDER', 'medication_order_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN medication_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER - UNION ALL SELECT 'MEDICATION_ORDER', 'date_precision_concept_id', 1.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'medication_order_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN medication_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER -- DIAGNOSTIC_ORDER (OLIDS_COMMON) UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'patient_id', 1.0, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'person_id', 1.0, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'diagnostic_order_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN diagnostic_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'result_value_units_concept_id', 1.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'date_precision_concept_id', 1.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'episodicity_concept_id', 1.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'diagnostic_order_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN diagnostic_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'result_value_units_concept_id', 5.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'episodicity_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER -- ENCOUNTER (OLIDS_COMMON) UNION ALL SELECT 'ENCOUNTER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER - UNION ALL SELECT 'ENCOUNTER', 'patient_id', 1.0, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER - UNION ALL SELECT 'ENCOUNTER', 'person_id', 1.0, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER UNION ALL SELECT 'ENCOUNTER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER UNION ALL SELECT 'ENCOUNTER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER - UNION ALL SELECT 'ENCOUNTER', 'encounter_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN encounter_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER - UNION ALL SELECT 'ENCOUNTER', 'date_precision_concept_id', 1.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'encounter_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN encounter_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER -- ALLERGY_INTOLERANCE (OLIDS_COMMON) UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'patient_id', 1.0, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'person_id', 1.0, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'allergy_intolerance_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN allergy_intolerance_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'date_precision_concept_id', 1.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'allergy_intolerance_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN allergy_intolerance_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE -- PROCEDURE_REQUEST (OLIDS_COMMON) UNION ALL SELECT 'PROCEDURE_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST UNION ALL SELECT 'PROCEDURE_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST UNION ALL SELECT 'PROCEDURE_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST - UNION ALL SELECT 'PROCEDURE_REQUEST', 'procedure_request_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN procedure_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST - UNION ALL SELECT 'PROCEDURE_REQUEST', 'date_precision_concept_id', 1.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST - UNION ALL SELECT 'PROCEDURE_REQUEST', 'status_concept_id', 1.0, COUNT(*), SUM(CASE WHEN status_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'procedure_request_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN procedure_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'status_concept_id', 5.0, COUNT(*), SUM(CASE WHEN status_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST -- REFERRAL_REQUEST (OLIDS_COMMON) UNION ALL SELECT 'REFERRAL_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST UNION ALL SELECT 'REFERRAL_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST UNION ALL SELECT 'REFERRAL_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST - UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN referral_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST - UNION ALL SELECT 'REFERRAL_REQUEST', 'date_precision_concept_id', 1.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST - UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_priority_concept_id', 1.0, COUNT(*), SUM(CASE WHEN referral_request_priority_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST - UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_type_concept_id', 1.0, COUNT(*), SUM(CASE WHEN referral_request_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST - UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_specialty_concept_id', 1.0, COUNT(*), SUM(CASE WHEN referral_request_specialty_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_priority_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_priority_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_specialty_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_specialty_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST -- LOCATION_CONTACT (OLIDS_COMMON) UNION ALL SELECT 'LOCATION_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT - UNION ALL SELECT 'LOCATION_CONTACT', 'contact_type_concept_id', 1.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT + UNION ALL SELECT 'LOCATION_CONTACT', 'contact_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT UNION ALL SELECT 'LOCATION_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT -- APPOINTMENT (OLIDS_COMMON) UNION ALL SELECT 'APPOINTMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT - UNION ALL SELECT 'APPOINTMENT', 'appointment_status_concept_id', 1.0, COUNT(*), SUM(CASE WHEN appointment_status_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT - UNION ALL SELECT 'APPOINTMENT', 'booking_method_concept_id', 1.0, COUNT(*), SUM(CASE WHEN booking_method_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT - UNION ALL SELECT 'APPOINTMENT', 'contact_mode_concept_id', 1.0, COUNT(*), SUM(CASE WHEN contact_mode_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'appointment_status_concept_id', 5.0, COUNT(*), SUM(CASE WHEN appointment_status_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'booking_method_concept_id', 5.0, COUNT(*), SUM(CASE WHEN booking_method_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'contact_mode_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_mode_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT UNION ALL SELECT 'APPOINTMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT -- APPOINTMENT_PRACTITIONER (OLIDS_COMMON) diff --git a/OLIDS/Testing/data-quality/test_concept_mapping.sql b/OLIDS/Testing/data-quality/test_concept_mapping.sql index 319d6d5..84c0f85 100644 --- a/OLIDS/Testing/data-quality/test_concept_mapping.sql +++ b/OLIDS/Testing/data-quality/test_concept_mapping.sql @@ -9,7 +9,9 @@ How it works: 1. The 'checks' CTE tests each concept_id column in each table. For each, it LEFT JOINs to CONCEPT_MAP (source lookup) and CONCEPT - (target lookup), then counts how many distinct concept IDs have no match. + (target lookup), then counts how many distinct concept IDs fail to + map through the full chain (missing from CONCEPT_MAP or target + CONCEPT record doesn't exist). 2. Only non-NULL concept values are checked (NULLs are a completeness issue, not a mapping issue). 3. FAIL if any concept IDs are unmapped. The test_subject shows the @@ -34,8 +36,8 @@ WITH checks AS ( SELECT 'OBSERVATION' AS table_name, 'observation_source_concept_id' AS concept_field, COUNT(DISTINCT base.observation_source_concept_id) AS total_distinct, COUNT(*) AS total_rows, - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.observation_source_concept_id END) AS unmapped_concepts, - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) AS unmapped_rows + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.observation_source_concept_id END) AS unmapped_concepts, + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) AS unmapped_rows FROM OLIDS_COMMON.OBSERVATION base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.observation_source_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -45,8 +47,8 @@ WITH checks AS ( SELECT 'OBSERVATION', 'result_value_units_concept_id', COUNT(DISTINCT base.result_value_units_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.result_value_units_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.result_value_units_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.result_value_units_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -56,8 +58,8 @@ WITH checks AS ( SELECT 'OBSERVATION', 'date_precision_concept_id', COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.date_precision_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -67,8 +69,8 @@ WITH checks AS ( SELECT 'OBSERVATION', 'episodicity_concept_id', COUNT(DISTINCT base.episodicity_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.episodicity_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.episodicity_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.episodicity_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -79,8 +81,8 @@ WITH checks AS ( -- MEDICATION_STATEMENT SELECT 'MEDICATION_STATEMENT', 'medication_statement_source_concept_id', COUNT(DISTINCT base.medication_statement_source_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.medication_statement_source_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.medication_statement_source_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.medication_statement_source_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -90,8 +92,8 @@ WITH checks AS ( SELECT 'MEDICATION_STATEMENT', 'authorisation_type_concept_id', COUNT(DISTINCT base.authorisation_type_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.authorisation_type_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.authorisation_type_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.authorisation_type_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -101,8 +103,8 @@ WITH checks AS ( SELECT 'MEDICATION_STATEMENT', 'date_precision_concept_id', COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.date_precision_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -113,8 +115,8 @@ WITH checks AS ( -- MEDICATION_ORDER SELECT 'MEDICATION_ORDER', 'medication_order_source_concept_id', COUNT(DISTINCT base.medication_order_source_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.medication_order_source_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.medication_order_source_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.medication_order_source_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -124,8 +126,8 @@ WITH checks AS ( SELECT 'MEDICATION_ORDER', 'date_precision_concept_id', COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.date_precision_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -136,8 +138,8 @@ WITH checks AS ( -- DIAGNOSTIC_ORDER SELECT 'DIAGNOSTIC_ORDER', 'diagnostic_order_source_concept_id', COUNT(DISTINCT base.diagnostic_order_source_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.diagnostic_order_source_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.diagnostic_order_source_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.diagnostic_order_source_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -147,8 +149,8 @@ WITH checks AS ( SELECT 'DIAGNOSTIC_ORDER', 'result_value_units_concept_id', COUNT(DISTINCT base.result_value_units_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.result_value_units_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.result_value_units_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.result_value_units_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -158,8 +160,8 @@ WITH checks AS ( SELECT 'DIAGNOSTIC_ORDER', 'date_precision_concept_id', COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.date_precision_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -169,8 +171,8 @@ WITH checks AS ( SELECT 'DIAGNOSTIC_ORDER', 'episodicity_concept_id', COUNT(DISTINCT base.episodicity_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.episodicity_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.episodicity_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.episodicity_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -181,8 +183,8 @@ WITH checks AS ( -- PROCEDURE_REQUEST SELECT 'PROCEDURE_REQUEST', 'procedure_request_source_concept_id', COUNT(DISTINCT base.procedure_request_source_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.procedure_request_source_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.procedure_request_source_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.procedure_request_source_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -192,8 +194,8 @@ WITH checks AS ( SELECT 'PROCEDURE_REQUEST', 'date_precision_concept_id', COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.date_precision_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -203,8 +205,8 @@ WITH checks AS ( SELECT 'PROCEDURE_REQUEST', 'status_concept_id', COUNT(DISTINCT base.status_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.status_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.status_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.status_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -215,8 +217,8 @@ WITH checks AS ( -- REFERRAL_REQUEST SELECT 'REFERRAL_REQUEST', 'referral_request_source_concept_id', COUNT(DISTINCT base.referral_request_source_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.referral_request_source_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.referral_request_source_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_source_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -226,8 +228,8 @@ WITH checks AS ( SELECT 'REFERRAL_REQUEST', 'date_precision_concept_id', COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.date_precision_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -237,8 +239,8 @@ WITH checks AS ( SELECT 'REFERRAL_REQUEST', 'referral_request_priority_concept_id', COUNT(DISTINCT base.referral_request_priority_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.referral_request_priority_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.referral_request_priority_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_priority_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -248,8 +250,8 @@ WITH checks AS ( SELECT 'REFERRAL_REQUEST', 'referral_request_type_concept_id', COUNT(DISTINCT base.referral_request_type_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.referral_request_type_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.referral_request_type_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_type_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -259,8 +261,8 @@ WITH checks AS ( SELECT 'REFERRAL_REQUEST', 'referral_request_specialty_concept_id', COUNT(DISTINCT base.referral_request_specialty_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.referral_request_specialty_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.referral_request_specialty_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_specialty_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -271,8 +273,8 @@ WITH checks AS ( -- ALLERGY_INTOLERANCE SELECT 'ALLERGY_INTOLERANCE', 'allergy_intolerance_source_concept_id', COUNT(DISTINCT base.allergy_intolerance_source_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.allergy_intolerance_source_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.allergy_intolerance_source_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.allergy_intolerance_source_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -282,8 +284,8 @@ WITH checks AS ( SELECT 'ALLERGY_INTOLERANCE', 'date_precision_concept_id', COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.date_precision_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -294,8 +296,8 @@ WITH checks AS ( -- ENCOUNTER SELECT 'ENCOUNTER', 'encounter_source_concept_id', COUNT(DISTINCT base.encounter_source_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.encounter_source_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.encounter_source_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.encounter_source_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -305,8 +307,8 @@ WITH checks AS ( SELECT 'ENCOUNTER', 'date_precision_concept_id', COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.date_precision_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -317,8 +319,8 @@ WITH checks AS ( -- EPISODE_OF_CARE SELECT 'EPISODE_OF_CARE', 'episode_type_source_concept_id', COUNT(DISTINCT base.episode_type_source_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.episode_type_source_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.episode_type_source_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.episode_type_source_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -328,8 +330,8 @@ WITH checks AS ( SELECT 'EPISODE_OF_CARE', 'episode_status_source_concept_id', COUNT(DISTINCT base.episode_status_source_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.episode_status_source_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.episode_status_source_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.episode_status_source_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -340,8 +342,8 @@ WITH checks AS ( -- LOCATION_CONTACT SELECT 'LOCATION_CONTACT', 'contact_type_concept_id', COUNT(DISTINCT base.contact_type_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.contact_type_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.contact_type_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.contact_type_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -352,8 +354,8 @@ WITH checks AS ( -- APPOINTMENT SELECT 'APPOINTMENT', 'appointment_status_concept_id', COUNT(DISTINCT base.appointment_status_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.appointment_status_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.appointment_status_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.appointment_status_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -363,8 +365,8 @@ WITH checks AS ( SELECT 'APPOINTMENT', 'booking_method_concept_id', COUNT(DISTINCT base.booking_method_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.booking_method_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.booking_method_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.booking_method_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -374,8 +376,8 @@ WITH checks AS ( SELECT 'APPOINTMENT', 'contact_mode_concept_id', COUNT(DISTINCT base.contact_mode_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.contact_mode_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.contact_mode_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.contact_mode_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -386,8 +388,8 @@ WITH checks AS ( -- PATIENT (OLIDS_MASKED) SELECT 'PATIENT', 'gender_concept_id', COUNT(DISTINCT base.gender_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.gender_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.gender_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.gender_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -398,8 +400,8 @@ WITH checks AS ( -- PATIENT_ADDRESS (OLIDS_MASKED) SELECT 'PATIENT_ADDRESS', 'address_type_concept_id', COUNT(DISTINCT base.address_type_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.address_type_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.address_type_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.address_type_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id @@ -410,8 +412,8 @@ WITH checks AS ( -- PATIENT_CONTACT (OLIDS_MASKED) SELECT 'PATIENT_CONTACT', 'contact_type_concept_id', COUNT(DISTINCT base.contact_type_concept_id), COUNT(*), - COUNT(DISTINCT CASE WHEN cm.source_code_id IS NULL THEN base.contact_type_concept_id END), - SUM(CASE WHEN cm.source_code_id IS NULL THEN 1 ELSE 0 END) + COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.contact_type_concept_id END), + SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.contact_type_concept_id = cm.source_code_id LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id diff --git a/OLIDS/Testing/data-quality/test_data_freshness.sql b/OLIDS/Testing/data-quality/test_data_freshness.sql index 7129e87..cdabd21 100644 --- a/OLIDS/Testing/data-quality/test_data_freshness.sql +++ b/OLIDS/Testing/data-quality/test_data_freshness.sql @@ -20,6 +20,10 @@ - metric_value = % of orgs with fresh data - total_orgs, fresh_orgs, stale_orgs, min/max/avg days (shown with --verbose) + Coverage: + The 8 tables below are all OLIDS tables that have both + record_owner_organisation_code and date_recorded columns. + To add a table: Add a UNION ALL block selecting table_name, org_code, MAX(date_recorded), and DATEDIFF from any table with record_owner_organisation_code and diff --git a/OLIDS/Testing/data-quality/test_referential_integrity.sql b/OLIDS/Testing/data-quality/test_referential_integrity.sql index b723e72..6c55863 100644 --- a/OLIDS/Testing/data-quality/test_referential_integrity.sql +++ b/OLIDS/Testing/data-quality/test_referential_integrity.sql @@ -38,6 +38,17 @@ WITH fk_checks AS ( UNION ALL + -- ALLERGY_INTOLERANCE -> PERSON + SELECT 'ALLERGY_INTOLERANCE', 'person_id', 'PERSON', + COUNT(DISTINCT c.person_id), + SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), + SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c + LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id + + UNION ALL + -- ALLERGY_INTOLERANCE -> ENCOUNTER SELECT 'ALLERGY_INTOLERANCE', 'encounter_id', 'ENCOUNTER', COUNT(DISTINCT c.encounter_id), @@ -126,6 +137,17 @@ WITH fk_checks AS ( UNION ALL + -- DIAGNOSTIC_ORDER -> PERSON + SELECT 'DIAGNOSTIC_ORDER', 'person_id', 'PERSON', + COUNT(DISTINCT c.person_id), + SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), + SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c + LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id + + UNION ALL + -- DIAGNOSTIC_ORDER -> ENCOUNTER SELECT 'DIAGNOSTIC_ORDER', 'encounter_id', 'ENCOUNTER', COUNT(DISTINCT c.encounter_id), @@ -170,6 +192,17 @@ WITH fk_checks AS ( UNION ALL + -- ENCOUNTER -> PERSON + SELECT 'ENCOUNTER', 'person_id', 'PERSON', + COUNT(DISTINCT c.person_id), + SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), + SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.ENCOUNTER c + LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id + + UNION ALL + -- ENCOUNTER -> PRACTITIONER SELECT 'ENCOUNTER', 'practitioner_id', 'PRACTITIONER', COUNT(DISTINCT c.practitioner_id), @@ -225,6 +258,17 @@ WITH fk_checks AS ( UNION ALL + -- EPISODE_OF_CARE -> PERSON + SELECT 'EPISODE_OF_CARE', 'person_id', 'PERSON', + COUNT(DISTINCT c.person_id), + SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), + SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.EPISODE_OF_CARE c + LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id + + UNION ALL + -- EPISODE_OF_CARE -> ORGANISATION SELECT 'EPISODE_OF_CARE', 'organisation_id', 'ORGANISATION', COUNT(DISTINCT c.organisation_id), @@ -291,6 +335,17 @@ WITH fk_checks AS ( UNION ALL + -- MEDICATION_ORDER -> PERSON + SELECT 'MEDICATION_ORDER', 'person_id', 'PERSON', + COUNT(DISTINCT c.person_id), + SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), + SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_ORDER c + LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id + + UNION ALL + -- MEDICATION_ORDER -> MEDICATION_STATEMENT SELECT 'MEDICATION_ORDER', 'medication_statement_id', 'MEDICATION_STATEMENT', COUNT(DISTINCT c.medication_statement_id), @@ -390,6 +445,17 @@ WITH fk_checks AS ( UNION ALL + -- MEDICATION_STATEMENT -> PERSON + SELECT 'MEDICATION_STATEMENT', 'person_id', 'PERSON', + COUNT(DISTINCT c.person_id), + SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), + SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.MEDICATION_STATEMENT c + LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id + + UNION ALL + -- MEDICATION_STATEMENT -> ORGANISATION SELECT 'MEDICATION_STATEMENT', 'organisation_id', 'ORGANISATION', COUNT(DISTINCT c.organisation_id), @@ -478,6 +544,17 @@ WITH fk_checks AS ( UNION ALL + -- OBSERVATION -> PERSON + SELECT 'OBSERVATION', 'person_id', 'PERSON', + COUNT(DISTINCT c.person_id), + SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), + SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.OBSERVATION c + LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id + + UNION ALL + -- OBSERVATION -> ENCOUNTER SELECT 'OBSERVATION', 'encounter_id', 'ENCOUNTER', COUNT(DISTINCT c.encounter_id), @@ -555,6 +632,28 @@ WITH fk_checks AS ( UNION ALL + -- PATIENT_PERSON -> PATIENT + SELECT 'PATIENT_PERSON', 'patient_id', 'PATIENT', + COUNT(DISTINCT c.patient_id), + SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), + SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.PATIENT_PERSON c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + + UNION ALL + + -- PATIENT_PERSON -> PERSON + SELECT 'PATIENT_PERSON', 'person_id', 'PERSON', + COUNT(DISTINCT c.person_id), + SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), + COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), + SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) + FROM OLIDS_COMMON.PATIENT_PERSON c + LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id + + UNION ALL + -- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE -> PATIENT SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'patient_id', 'PATIENT', COUNT(DISTINCT c.patient_id), @@ -768,15 +867,17 @@ SELECT child_table AS table_name, fk_column || ' -> ' || parent_table || '.id' AS test_subject, CASE + WHEN total_rows_with_fk = 0 THEN 'WARN' WHEN orphaned_fk = 0 THEN 'PASS' ELSE 'FAIL' END AS status, - ROUND(100.0 * (total_distinct_fk - orphaned_fk) / NULLIF(total_distinct_fk, 0), 2) AS metric_value, + CASE WHEN total_rows_with_fk = 0 THEN NULL + ELSE ROUND(100.0 * (total_distinct_fk - orphaned_fk) / NULLIF(total_distinct_fk, 0), 2) + END AS metric_value, 100.0 AS threshold, total_distinct_fk, total_rows_with_fk, orphaned_fk, orphaned_rows FROM fk_checks -WHERE total_rows_with_fk > 0 ORDER BY status DESC, metric_value ASC, child_table, fk_column; diff --git a/OLIDS/Testing/data-quality/test_registration_pds.sql b/OLIDS/Testing/data-quality/test_registration_pds.sql index 9025cac..07d0f1d 100644 --- a/OLIDS/Testing/data-quality/test_registration_pds.sql +++ b/OLIDS/Testing/data-quality/test_registration_pds.sql @@ -32,12 +32,26 @@ failing due to a handful of patients causing a high % diff. Configuration: - - snapshot_date: defaults to last day of previous month - - PDS tables: in "Data_Store_Registries"."pds" (change if your ICB differs) + - snapshot_date: auto-derived from EPISODE_OF_CARE freshness, snapped + to the most recent month-end (PDS updates at month-ends) + + PDS tables: + This test reads from "Data_Store_Registries"."pds" which is the standard + PDS location for most London ICBs. If your ICB stores PDS data elsewhere, + search for "Data_Store_Registries" in this file and replace all occurrences. */ --- Last day of the previous complete calendar month -SET snapshot_date = LAST_DAY(DATEADD(MONTH, -1, CURRENT_DATE)); +-- Snapshot date: the most recent month-end that OLIDS data covers. +-- PDS updates at month-ends, so we snap to a month boundary for accurate comparison. +-- Derived from MAX(date_recorded) in EPISODE_OF_CARE, rolled back to the last +-- complete month-end on or before that date. +SET snapshot_date = ( + SELECT LAST_DAY(DATEADD(MONTH, -1, DATEADD(DAY, 1, + MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END) + ))) + FROM OLIDS_COMMON.EPISODE_OF_CARE + WHERE record_owner_organisation_code IS NOT NULL +); -- Practice codes derived from EPISODE_OF_CARE (only practices with actual data) WITH icb_practices AS ( @@ -93,12 +107,14 @@ episode_type_regular AS ( SELECT source_code_id FROM OLIDS_TERMINOLOGY.CONCEPT_MAP WHERE source_code = 'Regular' + LIMIT 1 ), episode_status_left AS ( SELECT source_code_id FROM OLIDS_TERMINOLOGY.CONCEPT_MAP WHERE source_code = 'Left' + LIMIT 1 ), -- Step 5: Filter to active, valid registration episodes as of the snapshot date diff --git a/OLIDS/Testing/investigations/investigate_column_completeness.sql b/OLIDS/Testing/investigations/investigate_column_completeness.sql index c3bb24b..9a61a19 100644 --- a/OLIDS/Testing/investigations/investigate_column_completeness.sql +++ b/OLIDS/Testing/investigations/investigate_column_completeness.sql @@ -6,6 +6,8 @@ Shows NULL counts and rates for every checked column, ordered by null rate descending to highlight problem areas. Includes total_rows so you can gauge table size. + + Thresholds: 0.0% PKs, 0.5% core FKs, 1.0% dates, 5.0% concept fields */ USE DATABASE "Data_Store_OLIDS_Clinical_Validation"; -- Replace with your ICB's OLIDS database name @@ -13,15 +15,19 @@ USE DATABASE "Data_Store_OLIDS_Clinical_Validation"; -- Replace with your ICB's WITH checks AS ( -- PATIENT (OLIDS_MASKED) SELECT 'PATIENT' AS table_name, 'id' AS column_name, 0.0 AS threshold, COUNT(*) AS total_rows, SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) AS null_count FROM OLIDS_MASKED.PATIENT - UNION ALL SELECT 'PATIENT', 'sk_patient_id', 1.0, COUNT(*), SUM(CASE WHEN sk_patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'sk_patient_id', 0.5, COUNT(*), SUM(CASE WHEN sk_patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT UNION ALL SELECT 'PATIENT', 'birth_year', 1.0, COUNT(*), SUM(CASE WHEN birth_year IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT UNION ALL SELECT 'PATIENT', 'birth_month', 1.0, COUNT(*), SUM(CASE WHEN birth_month IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT - UNION ALL SELECT 'PATIENT', 'gender_concept_id', 1.0, COUNT(*), SUM(CASE WHEN gender_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'gender_concept_id', 5.0, COUNT(*), SUM(CASE WHEN gender_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT UNION ALL SELECT 'PATIENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + -- PERSON (OLIDS_MASKED) + UNION ALL SELECT 'PERSON', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PERSON + UNION ALL SELECT 'PERSON', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PERSON + -- PATIENT_ADDRESS (OLIDS_MASKED) UNION ALL SELECT 'PATIENT_ADDRESS', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS - UNION ALL SELECT 'PATIENT_ADDRESS', 'address_type_concept_id', 1.0, COUNT(*), SUM(CASE WHEN address_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS + UNION ALL SELECT 'PATIENT_ADDRESS', 'address_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN address_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS UNION ALL SELECT 'PATIENT_ADDRESS', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS -- PATIENT_CONTACT (OLIDS_MASKED) @@ -32,13 +38,18 @@ WITH checks AS ( UNION ALL SELECT 'PATIENT_UPRN', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_UPRN UNION ALL SELECT 'PATIENT_UPRN', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_UPRN + -- PATIENT_PERSON (OLIDS_COMMON) + UNION ALL SELECT 'PATIENT_PERSON', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_PERSON + UNION ALL SELECT 'PATIENT_PERSON', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_PERSON + -- EPISODE_OF_CARE (OLIDS_COMMON) UNION ALL SELECT 'EPISODE_OF_CARE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE - UNION ALL SELECT 'EPISODE_OF_CARE', 'patient_id', 1.0, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE UNION ALL SELECT 'EPISODE_OF_CARE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_of_care_start_date', 1.0, COUNT(*), SUM(CASE WHEN episode_of_care_start_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE - UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_type_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN episode_type_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE - UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_status_source_concept_id', 1.0, COUNT(*), SUM(CASE WHEN episode_status_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_type_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_type_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_status_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_status_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE ) SELECT diff --git a/OLIDS/Testing/investigations/investigate_concept_mapping.sql b/OLIDS/Testing/investigations/investigate_concept_mapping.sql index 2ec58f2..c3ea970 100644 --- a/OLIDS/Testing/investigations/investigate_concept_mapping.sql +++ b/OLIDS/Testing/investigations/investigate_concept_mapping.sql @@ -4,7 +4,8 @@ Set the USE DATABASE below to your ICB's OLIDS database. For each concept field that has unmapped values, lists the distinct - unmapped concept IDs with their row counts. + unmapped concept IDs with their row counts. Checks the full chain: + concept_id -> CONCEPT_MAP.source_code_id -> CONCEPT_MAP.target_code_id -> CONCEPT.id */ USE DATABASE "Data_Store_OLIDS_Clinical_Validation"; -- Replace with your ICB's OLIDS database name @@ -12,113 +13,140 @@ USE DATABASE "Data_Store_OLIDS_Clinical_Validation"; -- Replace with your ICB's -- Unmapped concepts per table/field with row counts WITH unmapped AS ( SELECT 'OBSERVATION' AS table_name, 'observation_source_concept_id' AS concept_field, - base.observation_source_concept_id AS concept_id, COUNT(*) AS row_count + base.observation_source_concept_id AS concept_id, COUNT(*) AS row_count, + CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END AS reason FROM OLIDS_COMMON.OBSERVATION base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.observation_source_concept_id = cm.source_code_id - WHERE base.observation_source_concept_id IS NOT NULL AND cm.source_code_id IS NULL - GROUP BY base.observation_source_concept_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.observation_source_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) + GROUP BY base.observation_source_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END UNION ALL SELECT 'OBSERVATION', 'result_value_units_concept_id', - base.result_value_units_concept_id, COUNT(*) + base.result_value_units_concept_id, COUNT(*), + CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END FROM OLIDS_COMMON.OBSERVATION base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.result_value_units_concept_id = cm.source_code_id - WHERE base.result_value_units_concept_id IS NOT NULL AND cm.source_code_id IS NULL - GROUP BY base.result_value_units_concept_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.result_value_units_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) + GROUP BY base.result_value_units_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END UNION ALL SELECT 'MEDICATION_STATEMENT', 'medication_statement_source_concept_id', - base.medication_statement_source_concept_id, COUNT(*) + base.medication_statement_source_concept_id, COUNT(*), + CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END FROM OLIDS_COMMON.MEDICATION_STATEMENT base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.medication_statement_source_concept_id = cm.source_code_id - WHERE base.medication_statement_source_concept_id IS NOT NULL AND cm.source_code_id IS NULL - GROUP BY base.medication_statement_source_concept_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.medication_statement_source_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) + GROUP BY base.medication_statement_source_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END UNION ALL SELECT 'MEDICATION_STATEMENT', 'authorisation_type_concept_id', - base.authorisation_type_concept_id, COUNT(*) + base.authorisation_type_concept_id, COUNT(*), + CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END FROM OLIDS_COMMON.MEDICATION_STATEMENT base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.authorisation_type_concept_id = cm.source_code_id - WHERE base.authorisation_type_concept_id IS NOT NULL AND cm.source_code_id IS NULL - GROUP BY base.authorisation_type_concept_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.authorisation_type_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) + GROUP BY base.authorisation_type_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END UNION ALL SELECT 'MEDICATION_ORDER', 'medication_order_source_concept_id', - base.medication_order_source_concept_id, COUNT(*) + base.medication_order_source_concept_id, COUNT(*), + CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END FROM OLIDS_COMMON.MEDICATION_ORDER base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.medication_order_source_concept_id = cm.source_code_id - WHERE base.medication_order_source_concept_id IS NOT NULL AND cm.source_code_id IS NULL - GROUP BY base.medication_order_source_concept_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.medication_order_source_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) + GROUP BY base.medication_order_source_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'result_value_units_concept_id', - base.result_value_units_concept_id, COUNT(*) + base.result_value_units_concept_id, COUNT(*), + CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END FROM OLIDS_COMMON.DIAGNOSTIC_ORDER base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.result_value_units_concept_id = cm.source_code_id - WHERE base.result_value_units_concept_id IS NOT NULL AND cm.source_code_id IS NULL - GROUP BY base.result_value_units_concept_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.result_value_units_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) + GROUP BY base.result_value_units_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END UNION ALL SELECT 'PROCEDURE_REQUEST', 'procedure_request_source_concept_id', - base.procedure_request_source_concept_id, COUNT(*) + base.procedure_request_source_concept_id, COUNT(*), + CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END FROM OLIDS_COMMON.PROCEDURE_REQUEST base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.procedure_request_source_concept_id = cm.source_code_id - WHERE base.procedure_request_source_concept_id IS NOT NULL AND cm.source_code_id IS NULL - GROUP BY base.procedure_request_source_concept_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.procedure_request_source_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) + GROUP BY base.procedure_request_source_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END UNION ALL SELECT 'PROCEDURE_REQUEST', 'status_concept_id', - base.status_concept_id, COUNT(*) + base.status_concept_id, COUNT(*), + CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END FROM OLIDS_COMMON.PROCEDURE_REQUEST base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.status_concept_id = cm.source_code_id - WHERE base.status_concept_id IS NOT NULL AND cm.source_code_id IS NULL - GROUP BY base.status_concept_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.status_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) + GROUP BY base.status_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_priority_concept_id', - base.referral_request_priority_concept_id, COUNT(*) + base.referral_request_priority_concept_id, COUNT(*), + CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END FROM OLIDS_COMMON.REFERRAL_REQUEST base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_priority_concept_id = cm.source_code_id - WHERE base.referral_request_priority_concept_id IS NOT NULL AND cm.source_code_id IS NULL - GROUP BY base.referral_request_priority_concept_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.referral_request_priority_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) + GROUP BY base.referral_request_priority_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_type_concept_id', - base.referral_request_type_concept_id, COUNT(*) + base.referral_request_type_concept_id, COUNT(*), + CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END FROM OLIDS_COMMON.REFERRAL_REQUEST base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_type_concept_id = cm.source_code_id - WHERE base.referral_request_type_concept_id IS NOT NULL AND cm.source_code_id IS NULL - GROUP BY base.referral_request_type_concept_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.referral_request_type_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) + GROUP BY base.referral_request_type_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END UNION ALL SELECT 'ENCOUNTER', 'encounter_source_concept_id', - base.encounter_source_concept_id, COUNT(*) + base.encounter_source_concept_id, COUNT(*), + CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END FROM OLIDS_COMMON.ENCOUNTER base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.encounter_source_concept_id = cm.source_code_id - WHERE base.encounter_source_concept_id IS NOT NULL AND cm.source_code_id IS NULL - GROUP BY base.encounter_source_concept_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.encounter_source_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) + GROUP BY base.encounter_source_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'allergy_intolerance_source_concept_id', - base.allergy_intolerance_source_concept_id, COUNT(*) + base.allergy_intolerance_source_concept_id, COUNT(*), + CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END FROM OLIDS_COMMON.ALLERGY_INTOLERANCE base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.allergy_intolerance_source_concept_id = cm.source_code_id - WHERE base.allergy_intolerance_source_concept_id IS NOT NULL AND cm.source_code_id IS NULL - GROUP BY base.allergy_intolerance_source_concept_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.allergy_intolerance_source_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) + GROUP BY base.allergy_intolerance_source_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END UNION ALL SELECT 'APPOINTMENT', 'booking_method_concept_id', - base.booking_method_concept_id, COUNT(*) + base.booking_method_concept_id, COUNT(*), + CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END FROM OLIDS_COMMON.APPOINTMENT base LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.booking_method_concept_id = cm.source_code_id - WHERE base.booking_method_concept_id IS NOT NULL AND cm.source_code_id IS NULL - GROUP BY base.booking_method_concept_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + WHERE base.booking_method_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) + GROUP BY base.booking_method_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END ) SELECT table_name, concept_field, concept_id, - row_count + row_count, + reason FROM unmapped ORDER BY table_name, concept_field, row_count DESC; diff --git a/OLIDS/Testing/investigations/investigate_referential_integrity.sql b/OLIDS/Testing/investigations/investigate_referential_integrity.sql index bc3f8c3..92938c4 100644 --- a/OLIDS/Testing/investigations/investigate_referential_integrity.sql +++ b/OLIDS/Testing/investigations/investigate_referential_integrity.sql @@ -99,4 +99,54 @@ LEFT JOIN OLIDS_COMMON.SCHEDULE p ON c.schedule_id = p.id WHERE c.schedule_id IS NOT NULL AND p.id IS NULL GROUP BY c.schedule_id +UNION ALL + +-- ENCOUNTER -> PERSON +SELECT 'ENCOUNTER', 'person_id', 'PERSON', + c.person_id, COUNT(*) +FROM OLIDS_COMMON.ENCOUNTER c +LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id +WHERE c.person_id IS NOT NULL AND p.id IS NULL +GROUP BY c.person_id + +UNION ALL + +-- OBSERVATION -> PERSON +SELECT 'OBSERVATION', 'person_id', 'PERSON', + c.person_id, COUNT(*) +FROM OLIDS_COMMON.OBSERVATION c +LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id +WHERE c.person_id IS NOT NULL AND p.id IS NULL +GROUP BY c.person_id + +UNION ALL + +-- EPISODE_OF_CARE -> PERSON +SELECT 'EPISODE_OF_CARE', 'person_id', 'PERSON', + c.person_id, COUNT(*) +FROM OLIDS_COMMON.EPISODE_OF_CARE c +LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id +WHERE c.person_id IS NOT NULL AND p.id IS NULL +GROUP BY c.person_id + +UNION ALL + +-- PATIENT_PERSON -> PATIENT +SELECT 'PATIENT_PERSON', 'patient_id', 'PATIENT', + c.patient_id, COUNT(*) +FROM OLIDS_COMMON.PATIENT_PERSON c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +WHERE c.patient_id IS NOT NULL AND p.id IS NULL +GROUP BY c.patient_id + +UNION ALL + +-- PATIENT_PERSON -> PERSON +SELECT 'PATIENT_PERSON', 'person_id', 'PERSON', + c.person_id, COUNT(*) +FROM OLIDS_COMMON.PATIENT_PERSON c +LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id +WHERE c.person_id IS NOT NULL AND p.id IS NULL +GROUP BY c.person_id + ORDER BY child_table, fk_column, row_count DESC; diff --git a/OLIDS/Testing/investigations/investigate_registration_pds.sql b/OLIDS/Testing/investigations/investigate_registration_pds.sql index 4a2a9da..c81994c 100644 --- a/OLIDS/Testing/investigations/investigate_registration_pds.sql +++ b/OLIDS/Testing/investigations/investigate_registration_pds.sql @@ -10,7 +10,14 @@ USE DATABASE "Data_Store_OLIDS_Clinical_Validation"; -- Replace with your ICB's OLIDS database name -SET snapshot_date = LAST_DAY(DATEADD(MONTH, -1, CURRENT_DATE)); +-- Most recent month-end that OLIDS data covers (PDS updates at month-ends) +SET snapshot_date = ( + SELECT LAST_DAY(DATEADD(MONTH, -1, DATEADD(DAY, 1, + MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END) + ))) + FROM OLIDS_COMMON.EPISODE_OF_CARE + WHERE record_owner_organisation_code IS NOT NULL +); -- Practice codes derived from EPISODE_OF_CARE (only practices with actual data) WITH icb_practices AS ( @@ -50,11 +57,11 @@ patient_to_person AS ( ), episode_type_regular AS ( - SELECT source_code_id FROM OLIDS_TERMINOLOGY.CONCEPT_MAP WHERE source_code = 'Regular' + SELECT source_code_id FROM OLIDS_TERMINOLOGY.CONCEPT_MAP WHERE source_code = 'Regular' LIMIT 1 ), episode_status_left AS ( - SELECT source_code_id FROM OLIDS_TERMINOLOGY.CONCEPT_MAP WHERE source_code = 'Left' + SELECT source_code_id FROM OLIDS_TERMINOLOGY.CONCEPT_MAP WHERE source_code = 'Left' LIMIT 1 ), filtered_episodes AS ( diff --git a/OLIDS/Testing/run_tests.py b/OLIDS/Testing/run_tests.py index c6161a0..821407b 100644 --- a/OLIDS/Testing/run_tests.py +++ b/OLIDS/Testing/run_tests.py @@ -115,15 +115,31 @@ def execute_test(conn, sql_file: Path, database: str) -> list: if USE_SNOWPARK: # Execute each statement; collect results from the last one - for stmt in statements[:-1]: - conn.sql(stmt).collect() + for i, stmt in enumerate(statements[:-1]): + try: + conn.sql(stmt).collect() + except Exception as e: + if i == 0 and 'USE' in stmt.upper(): + raise RuntimeError( + f"Failed to set database '{database}'. " + f"Check SNOWFLAKE_DATABASE in .env is correct and your role has access." + ) from e + raise df = conn.sql(statements[-1]).to_pandas() return df.to_dict('records') else: cursor = conn.cursor() try: - for stmt in statements: - cursor.execute(stmt) + for i, stmt in enumerate(statements): + try: + cursor.execute(stmt) + except Exception as e: + if i == 0 and 'USE' in stmt.upper(): + raise RuntimeError( + f"Failed to set database '{database}'. " + f"Check SNOWFLAKE_DATABASE in .env is correct and your role has access." + ) from e + raise columns = [desc[0] for desc in cursor.description] if cursor.description else [] rows = cursor.fetchall() return [dict(zip(columns, row)) for row in rows] diff --git a/OLIDS/Testing/setup.ps1 b/OLIDS/Testing/setup.ps1 index 9a3ff73..960f374 100644 --- a/OLIDS/Testing/setup.ps1 +++ b/OLIDS/Testing/setup.ps1 @@ -117,7 +117,7 @@ Write-Host "" Write-Host "Installing Python dependencies..." -ForegroundColor Cyan Push-Location $PSScriptRoot try { - uv lock --upgrade + uv lock uv sync Write-Host "Dependencies installed." -ForegroundColor Green } finally { From 5911edea5bea480cbaf841f53d527614b078163a Mon Sep 17 00:00:00 2001 From: EddieDavison92 <143042680+EddieDavison92@users.noreply.github.com> Date: Wed, 11 Feb 2026 23:14:44 +0000 Subject: [PATCH 04/15] fix: expand investigation scripts to match full test scope Column completeness: 7 tables -> 22 tables (~90 checks). Referential integrity: 15 FK checks -> 55 FK checks. Both investigation scripts now cover every table/relationship their corresponding tests check. --- .../investigate_column_completeness.sql | 134 ++++ .../investigate_referential_integrity.sql | 705 ++++++++++++++++-- 2 files changed, 796 insertions(+), 43 deletions(-) diff --git a/OLIDS/Testing/investigations/investigate_column_completeness.sql b/OLIDS/Testing/investigations/investigate_column_completeness.sql index 9a61a19..07a4c8e 100644 --- a/OLIDS/Testing/investigations/investigate_column_completeness.sql +++ b/OLIDS/Testing/investigations/investigate_column_completeness.sql @@ -32,6 +32,7 @@ WITH checks AS ( -- PATIENT_CONTACT (OLIDS_MASKED) UNION ALL SELECT 'PATIENT_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT + UNION ALL SELECT 'PATIENT_CONTACT', 'contact_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT UNION ALL SELECT 'PATIENT_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT -- PATIENT_UPRN (OLIDS_MASKED) @@ -50,6 +51,139 @@ WITH checks AS ( UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_of_care_start_date', 1.0, COUNT(*), SUM(CASE WHEN episode_of_care_start_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_type_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_type_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_status_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_status_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + + -- OBSERVATION (OLIDS_COMMON) + UNION ALL SELECT 'OBSERVATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'observation_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN observation_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'result_value_units_concept_id', 5.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'episodicity_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + + -- MEDICATION_STATEMENT (OLIDS_COMMON) + UNION ALL SELECT 'MEDICATION_STATEMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'medication_statement_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN medication_statement_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'authorisation_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN authorisation_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + + -- MEDICATION_ORDER (OLIDS_COMMON) + UNION ALL SELECT 'MEDICATION_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'medication_order_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN medication_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + + -- DIAGNOSTIC_ORDER (OLIDS_COMMON) + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'diagnostic_order_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN diagnostic_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'result_value_units_concept_id', 5.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'episodicity_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + + -- ENCOUNTER (OLIDS_COMMON) + UNION ALL SELECT 'ENCOUNTER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'encounter_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN encounter_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + + -- ALLERGY_INTOLERANCE (OLIDS_COMMON) + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'allergy_intolerance_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN allergy_intolerance_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + + -- PROCEDURE_REQUEST (OLIDS_COMMON) + UNION ALL SELECT 'PROCEDURE_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'procedure_request_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN procedure_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'status_concept_id', 5.0, COUNT(*), SUM(CASE WHEN status_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + + -- REFERRAL_REQUEST (OLIDS_COMMON) + UNION ALL SELECT 'REFERRAL_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_priority_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_priority_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_specialty_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_specialty_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + + -- LOCATION_CONTACT (OLIDS_COMMON) + UNION ALL SELECT 'LOCATION_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT + UNION ALL SELECT 'LOCATION_CONTACT', 'contact_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT + UNION ALL SELECT 'LOCATION_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT + + -- APPOINTMENT (OLIDS_COMMON) + UNION ALL SELECT 'APPOINTMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'appointment_status_concept_id', 5.0, COUNT(*), SUM(CASE WHEN appointment_status_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'booking_method_concept_id', 5.0, COUNT(*), SUM(CASE WHEN booking_method_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'contact_mode_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_mode_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + + -- APPOINTMENT_PRACTITIONER (OLIDS_COMMON) + UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER + UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER + + -- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE (OLIDS_COMMON) + UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE + UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE + + -- LOCATION (OLIDS_COMMON) + UNION ALL SELECT 'LOCATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION + UNION ALL SELECT 'LOCATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION + + -- FLAG (OLIDS_COMMON) + UNION ALL SELECT 'FLAG', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.FLAG + UNION ALL SELECT 'FLAG', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.FLAG + + -- ORGANISATION (OLIDS_COMMON) + UNION ALL SELECT 'ORGANISATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ORGANISATION + UNION ALL SELECT 'ORGANISATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ORGANISATION + + -- PRACTITIONER (OLIDS_COMMON) + UNION ALL SELECT 'PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER + UNION ALL SELECT 'PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER + + -- PRACTITIONER_IN_ROLE (OLIDS_COMMON) + UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE + UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE + + -- SCHEDULE (OLIDS_COMMON) + UNION ALL SELECT 'SCHEDULE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE + UNION ALL SELECT 'SCHEDULE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE + + -- SCHEDULE_PRACTITIONER (OLIDS_COMMON) + UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER + UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER + + -- CONCEPT (OLIDS_TERMINOLOGY) + UNION ALL SELECT 'CONCEPT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT + UNION ALL SELECT 'CONCEPT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT + + -- CONCEPT_MAP (OLIDS_TERMINOLOGY) + UNION ALL SELECT 'CONCEPT_MAP', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT_MAP + UNION ALL SELECT 'CONCEPT_MAP', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT_MAP ) SELECT diff --git a/OLIDS/Testing/investigations/investigate_referential_integrity.sql b/OLIDS/Testing/investigations/investigate_referential_integrity.sql index 92938c4..6f354b7 100644 --- a/OLIDS/Testing/investigations/investigate_referential_integrity.sql +++ b/OLIDS/Testing/investigations/investigate_referential_integrity.sql @@ -3,74 +3,213 @@ Run: Execute directly in Snowsight or VS Code Snowflake extension. Set the USE DATABASE below to your ICB's OLIDS database. - For the most common FK failures, shows orphaned FK values + For each FK relationship, shows orphaned FK values with their row counts. Helps identify whether orphans are systematic (few IDs, many rows) or scattered. - Add more FK checks as needed following the same pattern. */ USE DATABASE "Data_Store_OLIDS_Clinical_Validation"; -- Replace with your ICB's OLIDS database name --- ENCOUNTER -> PATIENT: orphaned patient_ids -SELECT 'ENCOUNTER' AS child_table, 'patient_id' AS fk_column, 'PATIENT' AS parent_table, +-- ALLERGY_INTOLERANCE -> PATIENT +SELECT 'ALLERGY_INTOLERANCE' AS child_table, 'patient_id' AS fk_column, 'PATIENT' AS parent_table, c.patient_id AS orphaned_value, COUNT(*) AS row_count -FROM OLIDS_COMMON.ENCOUNTER c +FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id UNION ALL --- OBSERVATION -> PATIENT -SELECT 'OBSERVATION', 'patient_id', 'PATIENT', - c.patient_id, COUNT(*) -FROM OLIDS_COMMON.OBSERVATION c -LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id -WHERE c.patient_id IS NOT NULL AND p.id IS NULL -GROUP BY c.patient_id +-- ALLERGY_INTOLERANCE -> PERSON +SELECT 'ALLERGY_INTOLERANCE', 'person_id', 'PERSON', + c.person_id, COUNT(*) +FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c +LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id +WHERE c.person_id IS NOT NULL AND p.id IS NULL +GROUP BY c.person_id UNION ALL --- OBSERVATION -> ENCOUNTER -SELECT 'OBSERVATION', 'encounter_id', 'ENCOUNTER', +-- ALLERGY_INTOLERANCE -> ENCOUNTER +SELECT 'ALLERGY_INTOLERANCE', 'encounter_id', 'ENCOUNTER', c.encounter_id, COUNT(*) -FROM OLIDS_COMMON.OBSERVATION c +FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id WHERE c.encounter_id IS NOT NULL AND p.id IS NULL GROUP BY c.encounter_id UNION ALL --- MEDICATION_ORDER -> PATIENT -SELECT 'MEDICATION_ORDER', 'patient_id', 'PATIENT', +-- ALLERGY_INTOLERANCE -> PRACTITIONER +SELECT 'ALLERGY_INTOLERANCE', 'practitioner_id', 'PRACTITIONER', + c.practitioner_id, COUNT(*) +FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL +GROUP BY c.practitioner_id + +UNION ALL + +-- APPOINTMENT -> PATIENT +SELECT 'APPOINTMENT', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_ORDER c +FROM OLIDS_COMMON.APPOINTMENT c LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id UNION ALL --- MEDICATION_ORDER -> ENCOUNTER -SELECT 'MEDICATION_ORDER', 'encounter_id', 'ENCOUNTER', +-- APPOINTMENT -> PRACTITIONER_IN_ROLE +SELECT 'APPOINTMENT', 'practitioner_in_role_id', 'PRACTITIONER_IN_ROLE', + c.practitioner_in_role_id, COUNT(*) +FROM OLIDS_COMMON.APPOINTMENT c +LEFT JOIN OLIDS_COMMON.PRACTITIONER_IN_ROLE p ON c.practitioner_in_role_id = p.id +WHERE c.practitioner_in_role_id IS NOT NULL AND p.id IS NULL +GROUP BY c.practitioner_in_role_id + +UNION ALL + +-- APPOINTMENT -> SCHEDULE +SELECT 'APPOINTMENT', 'schedule_id', 'SCHEDULE', + c.schedule_id, COUNT(*) +FROM OLIDS_COMMON.APPOINTMENT c +LEFT JOIN OLIDS_COMMON.SCHEDULE p ON c.schedule_id = p.id +WHERE c.schedule_id IS NOT NULL AND p.id IS NULL +GROUP BY c.schedule_id + +UNION ALL + +-- APPOINTMENT_PRACTITIONER -> APPOINTMENT +SELECT 'APPOINTMENT_PRACTITIONER', 'appointment_id', 'APPOINTMENT', + c.appointment_id, COUNT(*) +FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER c +LEFT JOIN OLIDS_COMMON.APPOINTMENT p ON c.appointment_id = p.id +WHERE c.appointment_id IS NOT NULL AND p.id IS NULL +GROUP BY c.appointment_id + +UNION ALL + +-- APPOINTMENT_PRACTITIONER -> PRACTITIONER +SELECT 'APPOINTMENT_PRACTITIONER', 'practitioner_id', 'PRACTITIONER', + c.practitioner_id, COUNT(*) +FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL +GROUP BY c.practitioner_id + +UNION ALL + +-- DIAGNOSTIC_ORDER -> PATIENT +SELECT 'DIAGNOSTIC_ORDER', 'patient_id', 'PATIENT', + c.patient_id, COUNT(*) +FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +WHERE c.patient_id IS NOT NULL AND p.id IS NULL +GROUP BY c.patient_id + +UNION ALL + +-- DIAGNOSTIC_ORDER -> PERSON +SELECT 'DIAGNOSTIC_ORDER', 'person_id', 'PERSON', + c.person_id, COUNT(*) +FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c +LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id +WHERE c.person_id IS NOT NULL AND p.id IS NULL +GROUP BY c.person_id + +UNION ALL + +-- DIAGNOSTIC_ORDER -> ENCOUNTER +SELECT 'DIAGNOSTIC_ORDER', 'encounter_id', 'ENCOUNTER', c.encounter_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_ORDER c +FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id WHERE c.encounter_id IS NOT NULL AND p.id IS NULL GROUP BY c.encounter_id UNION ALL --- MEDICATION_STATEMENT -> PATIENT -SELECT 'MEDICATION_STATEMENT', 'patient_id', 'PATIENT', +-- DIAGNOSTIC_ORDER -> PRACTITIONER +SELECT 'DIAGNOSTIC_ORDER', 'practitioner_id', 'PRACTITIONER', + c.practitioner_id, COUNT(*) +FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL +GROUP BY c.practitioner_id + +UNION ALL + +-- DIAGNOSTIC_ORDER -> OBSERVATION (parent) +SELECT 'DIAGNOSTIC_ORDER', 'parent_observation_id', 'OBSERVATION', + c.parent_observation_id, COUNT(*) +FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c +LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.parent_observation_id = p.id +WHERE c.parent_observation_id IS NOT NULL AND p.id IS NULL +GROUP BY c.parent_observation_id + +UNION ALL + +-- ENCOUNTER -> PATIENT +SELECT 'ENCOUNTER', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_STATEMENT c +FROM OLIDS_COMMON.ENCOUNTER c LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id UNION ALL +-- ENCOUNTER -> PERSON +SELECT 'ENCOUNTER', 'person_id', 'PERSON', + c.person_id, COUNT(*) +FROM OLIDS_COMMON.ENCOUNTER c +LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id +WHERE c.person_id IS NOT NULL AND p.id IS NULL +GROUP BY c.person_id + +UNION ALL + +-- ENCOUNTER -> PRACTITIONER +SELECT 'ENCOUNTER', 'practitioner_id', 'PRACTITIONER', + c.practitioner_id, COUNT(*) +FROM OLIDS_COMMON.ENCOUNTER c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL +GROUP BY c.practitioner_id + +UNION ALL + +-- ENCOUNTER -> EPISODE_OF_CARE +SELECT 'ENCOUNTER', 'episode_of_care_id', 'EPISODE_OF_CARE', + c.episode_of_care_id, COUNT(*) +FROM OLIDS_COMMON.ENCOUNTER c +LEFT JOIN OLIDS_COMMON.EPISODE_OF_CARE p ON c.episode_of_care_id = p.id +WHERE c.episode_of_care_id IS NOT NULL AND p.id IS NULL +GROUP BY c.episode_of_care_id + +UNION ALL + +-- ENCOUNTER -> APPOINTMENT +SELECT 'ENCOUNTER', 'appointment_id', 'APPOINTMENT', + c.appointment_id, COUNT(*) +FROM OLIDS_COMMON.ENCOUNTER c +LEFT JOIN OLIDS_COMMON.APPOINTMENT p ON c.appointment_id = p.id +WHERE c.appointment_id IS NOT NULL AND p.id IS NULL +GROUP BY c.appointment_id + +UNION ALL + +-- ENCOUNTER -> ORGANISATION (service provider) +SELECT 'ENCOUNTER', 'service_provider_organisation_id', 'ORGANISATION', + c.service_provider_organisation_id, COUNT(*) +FROM OLIDS_COMMON.ENCOUNTER c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.service_provider_organisation_id = p.id +WHERE c.service_provider_organisation_id IS NOT NULL AND p.id IS NULL +GROUP BY c.service_provider_organisation_id + +UNION ALL + -- EPISODE_OF_CARE -> PATIENT SELECT 'EPISODE_OF_CARE', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) @@ -81,56 +220,346 @@ GROUP BY c.patient_id UNION ALL --- APPOINTMENT -> PATIENT -SELECT 'APPOINTMENT', 'patient_id', 'PATIENT', +-- EPISODE_OF_CARE -> PERSON +SELECT 'EPISODE_OF_CARE', 'person_id', 'PERSON', + c.person_id, COUNT(*) +FROM OLIDS_COMMON.EPISODE_OF_CARE c +LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id +WHERE c.person_id IS NOT NULL AND p.id IS NULL +GROUP BY c.person_id + +UNION ALL + +-- EPISODE_OF_CARE -> ORGANISATION +SELECT 'EPISODE_OF_CARE', 'organisation_id', 'ORGANISATION', + c.organisation_id, COUNT(*) +FROM OLIDS_COMMON.EPISODE_OF_CARE c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id +WHERE c.organisation_id IS NOT NULL AND p.id IS NULL +GROUP BY c.organisation_id + +UNION ALL + +-- EPISODE_OF_CARE -> PRACTITIONER (care manager) +SELECT 'EPISODE_OF_CARE', 'care_manager_practitioner_id', 'PRACTITIONER', + c.care_manager_practitioner_id, COUNT(*) +FROM OLIDS_COMMON.EPISODE_OF_CARE c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.care_manager_practitioner_id = p.id +WHERE c.care_manager_practitioner_id IS NOT NULL AND p.id IS NULL +GROUP BY c.care_manager_practitioner_id + +UNION ALL + +-- FLAG -> PATIENT +SELECT 'FLAG', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM OLIDS_COMMON.APPOINTMENT c +FROM OLIDS_COMMON.FLAG c LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id UNION ALL --- SCHEDULE_PRACTITIONER -> SCHEDULE -SELECT 'SCHEDULE_PRACTITIONER', 'schedule_id', 'SCHEDULE', - c.schedule_id, COUNT(*) -FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER c -LEFT JOIN OLIDS_COMMON.SCHEDULE p ON c.schedule_id = p.id -WHERE c.schedule_id IS NOT NULL AND p.id IS NULL -GROUP BY c.schedule_id +-- LOCATION -> ORGANISATION (managing) +SELECT 'LOCATION', 'managing_organisation_id', 'ORGANISATION', + c.managing_organisation_id, COUNT(*) +FROM OLIDS_COMMON.LOCATION c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.managing_organisation_id = p.id +WHERE c.managing_organisation_id IS NOT NULL AND p.id IS NULL +GROUP BY c.managing_organisation_id UNION ALL --- ENCOUNTER -> PERSON -SELECT 'ENCOUNTER', 'person_id', 'PERSON', +-- LOCATION_CONTACT -> LOCATION +SELECT 'LOCATION_CONTACT', 'location_id', 'LOCATION', + c.location_id, COUNT(*) +FROM OLIDS_COMMON.LOCATION_CONTACT c +LEFT JOIN OLIDS_COMMON.LOCATION p ON c.location_id = p.id +WHERE c.location_id IS NOT NULL AND p.id IS NULL +GROUP BY c.location_id + +UNION ALL + +-- MEDICATION_ORDER -> PATIENT +SELECT 'MEDICATION_ORDER', 'patient_id', 'PATIENT', + c.patient_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_ORDER c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +WHERE c.patient_id IS NOT NULL AND p.id IS NULL +GROUP BY c.patient_id + +UNION ALL + +-- MEDICATION_ORDER -> PERSON +SELECT 'MEDICATION_ORDER', 'person_id', 'PERSON', c.person_id, COUNT(*) -FROM OLIDS_COMMON.ENCOUNTER c +FROM OLIDS_COMMON.MEDICATION_ORDER c LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id WHERE c.person_id IS NOT NULL AND p.id IS NULL GROUP BY c.person_id UNION ALL --- OBSERVATION -> PERSON -SELECT 'OBSERVATION', 'person_id', 'PERSON', +-- MEDICATION_ORDER -> MEDICATION_STATEMENT +SELECT 'MEDICATION_ORDER', 'medication_statement_id', 'MEDICATION_STATEMENT', + c.medication_statement_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_ORDER c +LEFT JOIN OLIDS_COMMON.MEDICATION_STATEMENT p ON c.medication_statement_id = p.id +WHERE c.medication_statement_id IS NOT NULL AND p.id IS NULL +GROUP BY c.medication_statement_id + +UNION ALL + +-- MEDICATION_ORDER -> ORGANISATION +SELECT 'MEDICATION_ORDER', 'organisation_id', 'ORGANISATION', + c.organisation_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_ORDER c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id +WHERE c.organisation_id IS NOT NULL AND p.id IS NULL +GROUP BY c.organisation_id + +UNION ALL + +-- MEDICATION_ORDER -> ENCOUNTER +SELECT 'MEDICATION_ORDER', 'encounter_id', 'ENCOUNTER', + c.encounter_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_ORDER c +LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id +WHERE c.encounter_id IS NOT NULL AND p.id IS NULL +GROUP BY c.encounter_id + +UNION ALL + +-- MEDICATION_ORDER -> PRACTITIONER +SELECT 'MEDICATION_ORDER', 'practitioner_id', 'PRACTITIONER', + c.practitioner_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_ORDER c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL +GROUP BY c.practitioner_id + +UNION ALL + +-- MEDICATION_ORDER -> OBSERVATION +SELECT 'MEDICATION_ORDER', 'observation_id', 'OBSERVATION', + c.observation_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_ORDER c +LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.observation_id = p.id +WHERE c.observation_id IS NOT NULL AND p.id IS NULL +GROUP BY c.observation_id + +UNION ALL + +-- MEDICATION_ORDER -> ALLERGY_INTOLERANCE +SELECT 'MEDICATION_ORDER', 'allergy_intolerance_id', 'ALLERGY_INTOLERANCE', + c.allergy_intolerance_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_ORDER c +LEFT JOIN OLIDS_COMMON.ALLERGY_INTOLERANCE p ON c.allergy_intolerance_id = p.id +WHERE c.allergy_intolerance_id IS NOT NULL AND p.id IS NULL +GROUP BY c.allergy_intolerance_id + +UNION ALL + +-- MEDICATION_ORDER -> DIAGNOSTIC_ORDER +SELECT 'MEDICATION_ORDER', 'diagnostic_order_id', 'DIAGNOSTIC_ORDER', + c.diagnostic_order_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_ORDER c +LEFT JOIN OLIDS_COMMON.DIAGNOSTIC_ORDER p ON c.diagnostic_order_id = p.id +WHERE c.diagnostic_order_id IS NOT NULL AND p.id IS NULL +GROUP BY c.diagnostic_order_id + +UNION ALL + +-- MEDICATION_ORDER -> REFERRAL_REQUEST +SELECT 'MEDICATION_ORDER', 'referral_request_id', 'REFERRAL_REQUEST', + c.referral_request_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_ORDER c +LEFT JOIN OLIDS_COMMON.REFERRAL_REQUEST p ON c.referral_request_id = p.id +WHERE c.referral_request_id IS NOT NULL AND p.id IS NULL +GROUP BY c.referral_request_id + +UNION ALL + +-- MEDICATION_STATEMENT -> PATIENT +SELECT 'MEDICATION_STATEMENT', 'patient_id', 'PATIENT', + c.patient_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_STATEMENT c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +WHERE c.patient_id IS NOT NULL AND p.id IS NULL +GROUP BY c.patient_id + +UNION ALL + +-- MEDICATION_STATEMENT -> PERSON +SELECT 'MEDICATION_STATEMENT', 'person_id', 'PERSON', c.person_id, COUNT(*) -FROM OLIDS_COMMON.OBSERVATION c +FROM OLIDS_COMMON.MEDICATION_STATEMENT c LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id WHERE c.person_id IS NOT NULL AND p.id IS NULL GROUP BY c.person_id UNION ALL --- EPISODE_OF_CARE -> PERSON -SELECT 'EPISODE_OF_CARE', 'person_id', 'PERSON', +-- MEDICATION_STATEMENT -> ORGANISATION +SELECT 'MEDICATION_STATEMENT', 'organisation_id', 'ORGANISATION', + c.organisation_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_STATEMENT c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id +WHERE c.organisation_id IS NOT NULL AND p.id IS NULL +GROUP BY c.organisation_id + +UNION ALL + +-- MEDICATION_STATEMENT -> ENCOUNTER +SELECT 'MEDICATION_STATEMENT', 'encounter_id', 'ENCOUNTER', + c.encounter_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_STATEMENT c +LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id +WHERE c.encounter_id IS NOT NULL AND p.id IS NULL +GROUP BY c.encounter_id + +UNION ALL + +-- MEDICATION_STATEMENT -> PRACTITIONER +SELECT 'MEDICATION_STATEMENT', 'practitioner_id', 'PRACTITIONER', + c.practitioner_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_STATEMENT c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL +GROUP BY c.practitioner_id + +UNION ALL + +-- MEDICATION_STATEMENT -> OBSERVATION +SELECT 'MEDICATION_STATEMENT', 'observation_id', 'OBSERVATION', + c.observation_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_STATEMENT c +LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.observation_id = p.id +WHERE c.observation_id IS NOT NULL AND p.id IS NULL +GROUP BY c.observation_id + +UNION ALL + +-- MEDICATION_STATEMENT -> ALLERGY_INTOLERANCE +SELECT 'MEDICATION_STATEMENT', 'allergy_intolerance_id', 'ALLERGY_INTOLERANCE', + c.allergy_intolerance_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_STATEMENT c +LEFT JOIN OLIDS_COMMON.ALLERGY_INTOLERANCE p ON c.allergy_intolerance_id = p.id +WHERE c.allergy_intolerance_id IS NOT NULL AND p.id IS NULL +GROUP BY c.allergy_intolerance_id + +UNION ALL + +-- MEDICATION_STATEMENT -> DIAGNOSTIC_ORDER +SELECT 'MEDICATION_STATEMENT', 'diagnostic_order_id', 'DIAGNOSTIC_ORDER', + c.diagnostic_order_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_STATEMENT c +LEFT JOIN OLIDS_COMMON.DIAGNOSTIC_ORDER p ON c.diagnostic_order_id = p.id +WHERE c.diagnostic_order_id IS NOT NULL AND p.id IS NULL +GROUP BY c.diagnostic_order_id + +UNION ALL + +-- MEDICATION_STATEMENT -> REFERRAL_REQUEST +SELECT 'MEDICATION_STATEMENT', 'referral_request_id', 'REFERRAL_REQUEST', + c.referral_request_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_STATEMENT c +LEFT JOIN OLIDS_COMMON.REFERRAL_REQUEST p ON c.referral_request_id = p.id +WHERE c.referral_request_id IS NOT NULL AND p.id IS NULL +GROUP BY c.referral_request_id + +UNION ALL + +-- OBSERVATION -> PATIENT +SELECT 'OBSERVATION', 'patient_id', 'PATIENT', + c.patient_id, COUNT(*) +FROM OLIDS_COMMON.OBSERVATION c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +WHERE c.patient_id IS NOT NULL AND p.id IS NULL +GROUP BY c.patient_id + +UNION ALL + +-- OBSERVATION -> PERSON +SELECT 'OBSERVATION', 'person_id', 'PERSON', c.person_id, COUNT(*) -FROM OLIDS_COMMON.EPISODE_OF_CARE c +FROM OLIDS_COMMON.OBSERVATION c LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id WHERE c.person_id IS NOT NULL AND p.id IS NULL GROUP BY c.person_id UNION ALL +-- OBSERVATION -> ENCOUNTER +SELECT 'OBSERVATION', 'encounter_id', 'ENCOUNTER', + c.encounter_id, COUNT(*) +FROM OLIDS_COMMON.OBSERVATION c +LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id +WHERE c.encounter_id IS NOT NULL AND p.id IS NULL +GROUP BY c.encounter_id + +UNION ALL + +-- OBSERVATION -> PRACTITIONER +SELECT 'OBSERVATION', 'practitioner_id', 'PRACTITIONER', + c.practitioner_id, COUNT(*) +FROM OLIDS_COMMON.OBSERVATION c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL +GROUP BY c.practitioner_id + +UNION ALL + +-- OBSERVATION -> OBSERVATION (parent) +SELECT 'OBSERVATION', 'parent_observation_id', 'OBSERVATION', + c.parent_observation_id, COUNT(*) +FROM OLIDS_COMMON.OBSERVATION c +LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.parent_observation_id = p.id +WHERE c.parent_observation_id IS NOT NULL AND p.id IS NULL +GROUP BY c.parent_observation_id + +UNION ALL + +-- ORGANISATION -> ORGANISATION (parent) +SELECT 'ORGANISATION', 'parent_organisation_id', 'ORGANISATION', + c.parent_organisation_id, COUNT(*) +FROM OLIDS_COMMON.ORGANISATION c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.parent_organisation_id = p.id +WHERE c.parent_organisation_id IS NOT NULL AND p.id IS NULL +GROUP BY c.parent_organisation_id + +UNION ALL + +-- PATIENT -> ORGANISATION (registered practice) +SELECT 'PATIENT', 'registered_practice_id', 'ORGANISATION', + c.registered_practice_id, COUNT(*) +FROM OLIDS_MASKED.PATIENT c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.registered_practice_id = p.id +WHERE c.registered_practice_id IS NOT NULL AND p.id IS NULL +GROUP BY c.registered_practice_id + +UNION ALL + +-- PATIENT_ADDRESS -> PATIENT +SELECT 'PATIENT_ADDRESS', 'patient_id', 'PATIENT', + c.patient_id, COUNT(*) +FROM OLIDS_MASKED.PATIENT_ADDRESS c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +WHERE c.patient_id IS NOT NULL AND p.id IS NULL +GROUP BY c.patient_id + +UNION ALL + +-- PATIENT_CONTACT -> PATIENT +SELECT 'PATIENT_CONTACT', 'patient_id', 'PATIENT', + c.patient_id, COUNT(*) +FROM OLIDS_MASKED.PATIENT_CONTACT c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +WHERE c.patient_id IS NOT NULL AND p.id IS NULL +GROUP BY c.patient_id + +UNION ALL + -- PATIENT_PERSON -> PATIENT SELECT 'PATIENT_PERSON', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) @@ -149,4 +578,194 @@ LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id WHERE c.person_id IS NOT NULL AND p.id IS NULL GROUP BY c.person_id +UNION ALL + +-- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE -> PATIENT +SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'patient_id', 'PATIENT', + c.patient_id, COUNT(*) +FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +WHERE c.patient_id IS NOT NULL AND p.id IS NULL +GROUP BY c.patient_id + +UNION ALL + +-- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE -> ORGANISATION +SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'organisation_id', 'ORGANISATION', + c.organisation_id, COUNT(*) +FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id +WHERE c.organisation_id IS NOT NULL AND p.id IS NULL +GROUP BY c.organisation_id + +UNION ALL + +-- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE -> PRACTITIONER +SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'practitioner_id', 'PRACTITIONER', + c.practitioner_id, COUNT(*) +FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL +GROUP BY c.practitioner_id + +UNION ALL + +-- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE -> EPISODE_OF_CARE +SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'episode_of_care_id', 'EPISODE_OF_CARE', + c.episode_of_care_id, COUNT(*) +FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c +LEFT JOIN OLIDS_COMMON.EPISODE_OF_CARE p ON c.episode_of_care_id = p.id +WHERE c.episode_of_care_id IS NOT NULL AND p.id IS NULL +GROUP BY c.episode_of_care_id + +UNION ALL + +-- PRACTITIONER_IN_ROLE -> PRACTITIONER +SELECT 'PRACTITIONER_IN_ROLE', 'practitioner_id', 'PRACTITIONER', + c.practitioner_id, COUNT(*) +FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL +GROUP BY c.practitioner_id + +UNION ALL + +-- PRACTITIONER_IN_ROLE -> ORGANISATION +SELECT 'PRACTITIONER_IN_ROLE', 'organisation_id', 'ORGANISATION', + c.organisation_id, COUNT(*) +FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id +WHERE c.organisation_id IS NOT NULL AND p.id IS NULL +GROUP BY c.organisation_id + +UNION ALL + +-- PROCEDURE_REQUEST -> PATIENT +SELECT 'PROCEDURE_REQUEST', 'patient_id', 'PATIENT', + c.patient_id, COUNT(*) +FROM OLIDS_COMMON.PROCEDURE_REQUEST c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +WHERE c.patient_id IS NOT NULL AND p.id IS NULL +GROUP BY c.patient_id + +UNION ALL + +-- PROCEDURE_REQUEST -> ENCOUNTER +SELECT 'PROCEDURE_REQUEST', 'encounter_id', 'ENCOUNTER', + c.encounter_id, COUNT(*) +FROM OLIDS_COMMON.PROCEDURE_REQUEST c +LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id +WHERE c.encounter_id IS NOT NULL AND p.id IS NULL +GROUP BY c.encounter_id + +UNION ALL + +-- PROCEDURE_REQUEST -> PRACTITIONER +SELECT 'PROCEDURE_REQUEST', 'practitioner_id', 'PRACTITIONER', + c.practitioner_id, COUNT(*) +FROM OLIDS_COMMON.PROCEDURE_REQUEST c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL +GROUP BY c.practitioner_id + +UNION ALL + +-- REFERRAL_REQUEST -> PATIENT +SELECT 'REFERRAL_REQUEST', 'patient_id', 'PATIENT', + c.patient_id, COUNT(*) +FROM OLIDS_COMMON.REFERRAL_REQUEST c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +WHERE c.patient_id IS NOT NULL AND p.id IS NULL +GROUP BY c.patient_id + +UNION ALL + +-- REFERRAL_REQUEST -> ENCOUNTER +SELECT 'REFERRAL_REQUEST', 'encounter_id', 'ENCOUNTER', + c.encounter_id, COUNT(*) +FROM OLIDS_COMMON.REFERRAL_REQUEST c +LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id +WHERE c.encounter_id IS NOT NULL AND p.id IS NULL +GROUP BY c.encounter_id + +UNION ALL + +-- REFERRAL_REQUEST -> PRACTITIONER +SELECT 'REFERRAL_REQUEST', 'practitioner_id', 'PRACTITIONER', + c.practitioner_id, COUNT(*) +FROM OLIDS_COMMON.REFERRAL_REQUEST c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL +GROUP BY c.practitioner_id + +UNION ALL + +-- REFERRAL_REQUEST -> ORGANISATION +SELECT 'REFERRAL_REQUEST', 'organisation_id', 'ORGANISATION', + c.organisation_id, COUNT(*) +FROM OLIDS_COMMON.REFERRAL_REQUEST c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id +WHERE c.organisation_id IS NOT NULL AND p.id IS NULL +GROUP BY c.organisation_id + +UNION ALL + +-- REFERRAL_REQUEST -> ORGANISATION (requester) +SELECT 'REFERRAL_REQUEST', 'requester_organisation_id', 'ORGANISATION', + c.requester_organisation_id, COUNT(*) +FROM OLIDS_COMMON.REFERRAL_REQUEST c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.requester_organisation_id = p.id +WHERE c.requester_organisation_id IS NOT NULL AND p.id IS NULL +GROUP BY c.requester_organisation_id + +UNION ALL + +-- REFERRAL_REQUEST -> ORGANISATION (recipient) +SELECT 'REFERRAL_REQUEST', 'recipient_organisation_id', 'ORGANISATION', + c.recipient_organisation_id, COUNT(*) +FROM OLIDS_COMMON.REFERRAL_REQUEST c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.recipient_organisation_id = p.id +WHERE c.recipient_organisation_id IS NOT NULL AND p.id IS NULL +GROUP BY c.recipient_organisation_id + +UNION ALL + +-- SCHEDULE -> LOCATION +SELECT 'SCHEDULE', 'location_id', 'LOCATION', + c.location_id, COUNT(*) +FROM OLIDS_COMMON.SCHEDULE c +LEFT JOIN OLIDS_COMMON.LOCATION p ON c.location_id = p.id +WHERE c.location_id IS NOT NULL AND p.id IS NULL +GROUP BY c.location_id + +UNION ALL + +-- SCHEDULE -> PRACTITIONER +SELECT 'SCHEDULE', 'practitioner_id', 'PRACTITIONER', + c.practitioner_id, COUNT(*) +FROM OLIDS_COMMON.SCHEDULE c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL +GROUP BY c.practitioner_id + +UNION ALL + +-- SCHEDULE_PRACTITIONER -> SCHEDULE +SELECT 'SCHEDULE_PRACTITIONER', 'schedule_id', 'SCHEDULE', + c.schedule_id, COUNT(*) +FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER c +LEFT JOIN OLIDS_COMMON.SCHEDULE p ON c.schedule_id = p.id +WHERE c.schedule_id IS NOT NULL AND p.id IS NULL +GROUP BY c.schedule_id + +UNION ALL + +-- SCHEDULE_PRACTITIONER -> PRACTITIONER +SELECT 'SCHEDULE_PRACTITIONER', 'practitioner_id', 'PRACTITIONER', + c.practitioner_id, COUNT(*) +FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL +GROUP BY c.practitioner_id + ORDER BY child_table, fk_column, row_count DESC; From eb7975a28db517e9fdbc1974d2f42ab18e7337e8 Mon Sep 17 00:00:00 2001 From: EddieDavison92 <143042680+EddieDavison92@users.noreply.github.com> Date: Wed, 11 Feb 2026 23:19:59 +0000 Subject: [PATCH 05/15] fix: use lds_start_date_time for registration PDS snapshot date EPISODE_OF_CARE lacks date_recorded. Use lds_start_date_time (LDS ingestion timestamp) instead, cast to DATE with future-date guard. Fixes SQL compilation error in test_registration_pds. --- OLIDS/Testing/data-quality/test_registration_pds.sql | 6 +++--- .../Testing/investigations/investigate_registration_pds.sql | 3 ++- 2 files changed, 5 insertions(+), 4 deletions(-) diff --git a/OLIDS/Testing/data-quality/test_registration_pds.sql b/OLIDS/Testing/data-quality/test_registration_pds.sql index 07d0f1d..8295e6a 100644 --- a/OLIDS/Testing/data-quality/test_registration_pds.sql +++ b/OLIDS/Testing/data-quality/test_registration_pds.sql @@ -43,11 +43,11 @@ -- Snapshot date: the most recent month-end that OLIDS data covers. -- PDS updates at month-ends, so we snap to a month boundary for accurate comparison. --- Derived from MAX(date_recorded) in EPISODE_OF_CARE, rolled back to the last --- complete month-end on or before that date. +-- Derived from MAX(lds_start_date_time) in EPISODE_OF_CARE (the LDS ingestion timestamp), +-- rolled back to the last complete month-end on or before that date. SET snapshot_date = ( SELECT LAST_DAY(DATEADD(MONTH, -1, DATEADD(DAY, 1, - MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END) + MAX(CASE WHEN lds_start_date_time <= CURRENT_DATE THEN lds_start_date_time END)::DATE ))) FROM OLIDS_COMMON.EPISODE_OF_CARE WHERE record_owner_organisation_code IS NOT NULL diff --git a/OLIDS/Testing/investigations/investigate_registration_pds.sql b/OLIDS/Testing/investigations/investigate_registration_pds.sql index c81994c..c2edbe5 100644 --- a/OLIDS/Testing/investigations/investigate_registration_pds.sql +++ b/OLIDS/Testing/investigations/investigate_registration_pds.sql @@ -11,9 +11,10 @@ USE DATABASE "Data_Store_OLIDS_Clinical_Validation"; -- Replace with your ICB's OLIDS database name -- Most recent month-end that OLIDS data covers (PDS updates at month-ends) +-- Uses lds_start_date_time (LDS ingestion timestamp) since EPISODE_OF_CARE lacks date_recorded SET snapshot_date = ( SELECT LAST_DAY(DATEADD(MONTH, -1, DATEADD(DAY, 1, - MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END) + MAX(CASE WHEN lds_start_date_time <= CURRENT_DATE THEN lds_start_date_time END)::DATE ))) FROM OLIDS_COMMON.EPISODE_OF_CARE WHERE record_owner_organisation_code IS NOT NULL From 3d64ba2f2a320c48f5a58f6e61b2b186fd72f4a4 Mon Sep 17 00:00:00 2001 From: EddieDavison92 <143042680+EddieDavison92@users.noreply.github.com> Date: Wed, 11 Feb 2026 23:28:58 +0000 Subject: [PATCH 06/15] fix: derive PDS snapshot from episode_of_care_start_date Use MAX(episode_of_care_start_date) to snap to the most recent month-end the data covers. Revert LIMIT 1 on concept CTEs which was filtering out all registrations. Improves strictest match from 92/174 to 118/174 practices. --- OLIDS/Testing/data-quality/test_registration_pds.sql | 11 ++++------- .../investigations/investigate_registration_pds.sql | 11 ++++++----- 2 files changed, 10 insertions(+), 12 deletions(-) diff --git a/OLIDS/Testing/data-quality/test_registration_pds.sql b/OLIDS/Testing/data-quality/test_registration_pds.sql index 8295e6a..581e87f 100644 --- a/OLIDS/Testing/data-quality/test_registration_pds.sql +++ b/OLIDS/Testing/data-quality/test_registration_pds.sql @@ -32,8 +32,8 @@ failing due to a handful of patients causing a high % diff. Configuration: - - snapshot_date: auto-derived from EPISODE_OF_CARE freshness, snapped - to the most recent month-end (PDS updates at month-ends) + - snapshot_date: last day of the previous complete calendar month + (PDS updates at month-ends) PDS tables: This test reads from "Data_Store_Registries"."pds" which is the standard @@ -43,11 +43,10 @@ -- Snapshot date: the most recent month-end that OLIDS data covers. -- PDS updates at month-ends, so we snap to a month boundary for accurate comparison. --- Derived from MAX(lds_start_date_time) in EPISODE_OF_CARE (the LDS ingestion timestamp), --- rolled back to the last complete month-end on or before that date. +-- Uses MAX(episode_of_care_start_date) as the freshness indicator. Future dates excluded. SET snapshot_date = ( SELECT LAST_DAY(DATEADD(MONTH, -1, DATEADD(DAY, 1, - MAX(CASE WHEN lds_start_date_time <= CURRENT_DATE THEN lds_start_date_time END)::DATE + MAX(CASE WHEN episode_of_care_start_date <= CURRENT_DATE THEN episode_of_care_start_date END)::DATE ))) FROM OLIDS_COMMON.EPISODE_OF_CARE WHERE record_owner_organisation_code IS NOT NULL @@ -107,14 +106,12 @@ episode_type_regular AS ( SELECT source_code_id FROM OLIDS_TERMINOLOGY.CONCEPT_MAP WHERE source_code = 'Regular' - LIMIT 1 ), episode_status_left AS ( SELECT source_code_id FROM OLIDS_TERMINOLOGY.CONCEPT_MAP WHERE source_code = 'Left' - LIMIT 1 ), -- Step 5: Filter to active, valid registration episodes as of the snapshot date diff --git a/OLIDS/Testing/investigations/investigate_registration_pds.sql b/OLIDS/Testing/investigations/investigate_registration_pds.sql index c2edbe5..1dc75bc 100644 --- a/OLIDS/Testing/investigations/investigate_registration_pds.sql +++ b/OLIDS/Testing/investigations/investigate_registration_pds.sql @@ -10,11 +10,12 @@ USE DATABASE "Data_Store_OLIDS_Clinical_Validation"; -- Replace with your ICB's OLIDS database name --- Most recent month-end that OLIDS data covers (PDS updates at month-ends) --- Uses lds_start_date_time (LDS ingestion timestamp) since EPISODE_OF_CARE lacks date_recorded +-- Snapshot date: the most recent month-end that OLIDS data covers. +-- PDS updates at month-ends, so we snap to a month boundary for accurate comparison. +-- Uses MAX(episode_of_care_start_date) as the freshness indicator. Future dates excluded. SET snapshot_date = ( SELECT LAST_DAY(DATEADD(MONTH, -1, DATEADD(DAY, 1, - MAX(CASE WHEN lds_start_date_time <= CURRENT_DATE THEN lds_start_date_time END)::DATE + MAX(CASE WHEN episode_of_care_start_date <= CURRENT_DATE THEN episode_of_care_start_date END)::DATE ))) FROM OLIDS_COMMON.EPISODE_OF_CARE WHERE record_owner_organisation_code IS NOT NULL @@ -58,11 +59,11 @@ patient_to_person AS ( ), episode_type_regular AS ( - SELECT source_code_id FROM OLIDS_TERMINOLOGY.CONCEPT_MAP WHERE source_code = 'Regular' LIMIT 1 + SELECT source_code_id FROM OLIDS_TERMINOLOGY.CONCEPT_MAP WHERE source_code = 'Regular' ), episode_status_left AS ( - SELECT source_code_id FROM OLIDS_TERMINOLOGY.CONCEPT_MAP WHERE source_code = 'Left' LIMIT 1 + SELECT source_code_id FROM OLIDS_TERMINOLOGY.CONCEPT_MAP WHERE source_code = 'Left' ), filtered_episodes AS ( From 95988b553c8ea3071b3c741b701865e8ef5fda16 Mon Sep 17 00:00:00 2001 From: EddieDavison92 <143042680+EddieDavison92@users.noreply.github.com> Date: Thu, 12 Feb 2026 13:47:01 +0000 Subject: [PATCH 07/15] fix: write .env as UTF-8 without BOM in setup.ps1 PowerShell 5.x's -Encoding UTF8 adds a byte-order mark which corrupts the first key for python-dotenv, causing SNOWFLAKE_ACCOUNT to be unreadable. --- OLIDS/Testing/setup.ps1 | 8 +++++--- 1 file changed, 5 insertions(+), 3 deletions(-) diff --git a/OLIDS/Testing/setup.ps1 b/OLIDS/Testing/setup.ps1 index 960f374..bbdaafc 100644 --- a/OLIDS/Testing/setup.ps1 +++ b/OLIDS/Testing/setup.ps1 @@ -99,14 +99,16 @@ if ($needsSetup -and -not (Test-Path $envFile)) { Write-Host " The ICB-specific OLIDS database (e.g. Data_Store_OLIDS_Alpha)." -ForegroundColor DarkGray $database = Read-Host " SNOWFLAKE_DATABASE" - # Write .env - @" + # Write .env (UTF-8 without BOM — PS 5.x's -Encoding UTF8 adds a BOM + # which corrupts the first key for python-dotenv) + $content = @" SNOWFLAKE_ACCOUNT=$account SNOWFLAKE_USER=$user SNOWFLAKE_WAREHOUSE=$warehouse SNOWFLAKE_ROLE=$role SNOWFLAKE_DATABASE=$database -"@ | Set-Content -Path $envFile -Encoding UTF8 +"@ + [System.IO.File]::WriteAllText($envFile, $content) Write-Host "" Write-Host "Credentials saved to $envFile" -ForegroundColor Green From 9c242cb41cb714062e4eccabdcc6466e9e8786de Mon Sep 17 00:00:00 2001 From: EddieDavison92 <143042680+EddieDavison92@users.noreply.github.com> Date: Fri, 13 Feb 2026 10:50:05 +0000 Subject: [PATCH 08/15] feat: add macOS setup script and use SET variables for schema names - Add setup.sh (macOS/Linux equivalent of setup.ps1) - Convert all SQL files to use SET variables + IDENTIFIER() for schema references instead of hardcoded schema prefixes - Update apply_schema_map() to also replace quoted schema names in SET statements so the runner can override them with detected values - Update README with macOS setup instructions and schema variable docs --- OLIDS/Testing/README.md | 23 +- .../data-quality/test_column_completeness.sql | 239 ++++++------- .../data-quality/test_concept_mapping.sql | 212 ++++++------ .../data-quality/test_data_freshness.sql | 20 +- .../test_referential_integrity.sql | 308 ++++++++--------- .../data-quality/test_registration_pds.sql | 18 +- .../investigate_column_completeness.sql | 241 +++++++------- .../investigate_concept_mapping.sql | 87 ++--- .../investigate_data_freshness.sql | 25 +- .../investigate_referential_integrity.sql | 313 +++++++++--------- .../investigate_registration_pds.sql | 23 +- OLIDS/Testing/run_tests.py | 209 +++++++++++- OLIDS/Testing/setup.sh | 120 +++++++ 13 files changed, 1099 insertions(+), 739 deletions(-) create mode 100644 OLIDS/Testing/setup.sh diff --git a/OLIDS/Testing/README.md b/OLIDS/Testing/README.md index 36b6317..42b37c7 100644 --- a/OLIDS/Testing/README.md +++ b/OLIDS/Testing/README.md @@ -1,16 +1,26 @@ # OLIDS Data Quality Tests -SQL-based data quality tests for OLIDS, run against Snowflake. Portable across London ICBs — each ICB sets their own database name via `.env` and the runner injects `USE DATABASE` before each test. +SQL-based data quality tests for OLIDS, run against Snowflake. Portable across London ICBs — each ICB sets their own database name via `.env` and the runner auto-detects schema names at startup. ## Setup ```powershell +# Windows cd OLIDS/Testing .\setup.ps1 ``` +```bash +# macOS / Linux +cd OLIDS/Testing +chmod +x setup.sh +./setup.sh +``` + This installs [uv](https://docs.astral.sh/uv/), prompts for Snowflake credentials, writes `.env`, and runs `uv sync`. +> **Snowflake private link**: If your organisation connects via private link, use the format `..privatelink` as your Snowflake account identifier (e.g. `us96268.uk-south.privatelink`). + ## Running Tests All commands assume you're in the `OLIDS/Testing` directory. @@ -24,6 +34,9 @@ uv run run_tests.py --test test_column_completeness # Show passing results and extra columns uv run run_tests.py --verbose + +# Run an investigation script (or any SQL file) with schema auto-detection +uv run run_tests.py --run investigations/investigate_column_completeness.sql ``` ## Tests @@ -79,12 +92,16 @@ Use `UNION ALL` to return multiple checks from one file. Any extra columns beyon Other notes: - Use `SET var = value;` and `$var` for Snowflake session variables (e.g. thresholds) -- Use schema-qualified names (`OLIDS_COMMON.TABLE`) without the database prefix — the runner injects `USE DATABASE` +- Schema names are configured via SET variables at the top of each file (`schema_masked`, `schema_common`, `schema_terminology`). Reference tables with `IDENTIFIER($schema_common || '.TABLE')`. The runner auto-detects schemas at startup and overwrites the SET values (e.g. `OLIDS_MASKED` → `OLIDS_PCD`). For Snowsight, change the SET values manually. - Avoid semicolons inside comments or string literals — the runner naively splits on `;` to execute statements individually ## Investigating Failures -The `investigations/` folder has companion scripts for each test. These return row-level detail to help diagnose failures. Run them directly in Snowsight or the VS Code Snowflake extension — each file has a `USE DATABASE` line at the top to fill in. +The `investigations/` folder has companion scripts for each test. These return row-level detail to help diagnose failures. Run them through the runner with `--run` (handles schema detection and database context automatically), or directly in Snowsight (set the `USE DATABASE` and `SET schema_*` variables at the top of each file to match your ICB). + +```bash +uv run run_tests.py --run investigations/investigate_referential_integrity.sql +``` | File | What it shows | |---|---| diff --git a/OLIDS/Testing/data-quality/test_column_completeness.sql b/OLIDS/Testing/data-quality/test_column_completeness.sql index b056428..d36a1b4 100644 --- a/OLIDS/Testing/data-quality/test_column_completeness.sql +++ b/OLIDS/Testing/data-quality/test_column_completeness.sql @@ -24,182 +24,187 @@ Add a UNION ALL SELECT row with (table_name, column_name, threshold, COUNT(*), SUM(...)) Example: UNION ALL SELECT 'MY_TABLE', 'my_column', 1.0, COUNT(*), - SUM(CASE WHEN my_column IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MY_TABLE + SUM(CASE WHEN my_column IS NULL THEN 1 ELSE 0 END) + FROM IDENTIFIER($schema_common || '.MY_TABLE') */ +SET schema_masked = 'OLIDS_MASKED'; -- Change if your ICB uses a different name (e.g. OLIDS_PCD) +SET schema_common = 'OLIDS_COMMON'; +SET schema_terminology = 'OLIDS_TERMINOLOGY'; + WITH checks AS ( -- Each row: table, column, max allowed NULL %, total rows, NULL count -- PATIENT (OLIDS_MASKED) - SELECT 'PATIENT' AS table_name, 'id' AS column_name, 0.0 AS threshold, COUNT(*) AS total_rows, SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) AS null_count FROM OLIDS_MASKED.PATIENT - UNION ALL SELECT 'PATIENT', 'sk_patient_id', 0.5, COUNT(*), SUM(CASE WHEN sk_patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT - UNION ALL SELECT 'PATIENT', 'birth_year', 1.0, COUNT(*), SUM(CASE WHEN birth_year IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT - UNION ALL SELECT 'PATIENT', 'birth_month', 1.0, COUNT(*), SUM(CASE WHEN birth_month IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT - UNION ALL SELECT 'PATIENT', 'gender_concept_id', 5.0, COUNT(*), SUM(CASE WHEN gender_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT - UNION ALL SELECT 'PATIENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + SELECT 'PATIENT' AS table_name, 'id' AS column_name, 0.0 AS threshold, COUNT(*) AS total_rows, SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) AS null_count FROM IDENTIFIER($schema_masked || '.PATIENT') + UNION ALL SELECT 'PATIENT', 'sk_patient_id', 0.5, COUNT(*), SUM(CASE WHEN sk_patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT') + UNION ALL SELECT 'PATIENT', 'birth_year', 1.0, COUNT(*), SUM(CASE WHEN birth_year IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT') + UNION ALL SELECT 'PATIENT', 'birth_month', 1.0, COUNT(*), SUM(CASE WHEN birth_month IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT') + UNION ALL SELECT 'PATIENT', 'gender_concept_id', 5.0, COUNT(*), SUM(CASE WHEN gender_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT') + UNION ALL SELECT 'PATIENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT') -- PERSON (OLIDS_MASKED) - UNION ALL SELECT 'PERSON', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PERSON - UNION ALL SELECT 'PERSON', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PERSON + UNION ALL SELECT 'PERSON', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PERSON') + UNION ALL SELECT 'PERSON', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PERSON') -- PATIENT_ADDRESS (OLIDS_MASKED) - UNION ALL SELECT 'PATIENT_ADDRESS', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS - UNION ALL SELECT 'PATIENT_ADDRESS', 'address_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN address_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS - UNION ALL SELECT 'PATIENT_ADDRESS', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS + UNION ALL SELECT 'PATIENT_ADDRESS', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_ADDRESS') + UNION ALL SELECT 'PATIENT_ADDRESS', 'address_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN address_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_ADDRESS') + UNION ALL SELECT 'PATIENT_ADDRESS', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_ADDRESS') -- PATIENT_CONTACT (OLIDS_MASKED) - UNION ALL SELECT 'PATIENT_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT - UNION ALL SELECT 'PATIENT_CONTACT', 'contact_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT - UNION ALL SELECT 'PATIENT_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT + UNION ALL SELECT 'PATIENT_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_CONTACT') + UNION ALL SELECT 'PATIENT_CONTACT', 'contact_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_CONTACT') + UNION ALL SELECT 'PATIENT_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_CONTACT') -- PATIENT_UPRN (OLIDS_MASKED) - UNION ALL SELECT 'PATIENT_UPRN', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_UPRN - UNION ALL SELECT 'PATIENT_UPRN', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_UPRN + UNION ALL SELECT 'PATIENT_UPRN', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_UPRN') + UNION ALL SELECT 'PATIENT_UPRN', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_UPRN') -- PATIENT_PERSON (OLIDS_COMMON) - UNION ALL SELECT 'PATIENT_PERSON', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_PERSON - UNION ALL SELECT 'PATIENT_PERSON', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_PERSON + UNION ALL SELECT 'PATIENT_PERSON', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PATIENT_PERSON') + UNION ALL SELECT 'PATIENT_PERSON', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PATIENT_PERSON') -- EPISODE_OF_CARE (OLIDS_COMMON) - UNION ALL SELECT 'EPISODE_OF_CARE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE - UNION ALL SELECT 'EPISODE_OF_CARE', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE - UNION ALL SELECT 'EPISODE_OF_CARE', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE - UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_of_care_start_date', 1.0, COUNT(*), SUM(CASE WHEN episode_of_care_start_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE - UNION ALL SELECT 'EPISODE_OF_CARE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE - UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_type_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_type_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE - UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_status_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_status_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') + UNION ALL SELECT 'EPISODE_OF_CARE', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') + UNION ALL SELECT 'EPISODE_OF_CARE', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_of_care_start_date', 1.0, COUNT(*), SUM(CASE WHEN episode_of_care_start_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') + UNION ALL SELECT 'EPISODE_OF_CARE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_type_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_type_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_status_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_status_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') -- OBSERVATION (OLIDS_COMMON) - UNION ALL SELECT 'OBSERVATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'observation_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN observation_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'result_value_units_concept_id', 5.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'episodicity_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') + UNION ALL SELECT 'OBSERVATION', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') + UNION ALL SELECT 'OBSERVATION', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') + UNION ALL SELECT 'OBSERVATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') + UNION ALL SELECT 'OBSERVATION', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') + UNION ALL SELECT 'OBSERVATION', 'observation_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN observation_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') + UNION ALL SELECT 'OBSERVATION', 'result_value_units_concept_id', 5.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') + UNION ALL SELECT 'OBSERVATION', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') + UNION ALL SELECT 'OBSERVATION', 'episodicity_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') -- MEDICATION_STATEMENT (OLIDS_COMMON) - UNION ALL SELECT 'MEDICATION_STATEMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT - UNION ALL SELECT 'MEDICATION_STATEMENT', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT - UNION ALL SELECT 'MEDICATION_STATEMENT', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT - UNION ALL SELECT 'MEDICATION_STATEMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT - UNION ALL SELECT 'MEDICATION_STATEMENT', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT - UNION ALL SELECT 'MEDICATION_STATEMENT', 'medication_statement_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN medication_statement_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT - UNION ALL SELECT 'MEDICATION_STATEMENT', 'authorisation_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN authorisation_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT - UNION ALL SELECT 'MEDICATION_STATEMENT', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') + UNION ALL SELECT 'MEDICATION_STATEMENT', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') + UNION ALL SELECT 'MEDICATION_STATEMENT', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') + UNION ALL SELECT 'MEDICATION_STATEMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') + UNION ALL SELECT 'MEDICATION_STATEMENT', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') + UNION ALL SELECT 'MEDICATION_STATEMENT', 'medication_statement_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN medication_statement_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') + UNION ALL SELECT 'MEDICATION_STATEMENT', 'authorisation_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN authorisation_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') + UNION ALL SELECT 'MEDICATION_STATEMENT', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') -- MEDICATION_ORDER (OLIDS_COMMON) - UNION ALL SELECT 'MEDICATION_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER - UNION ALL SELECT 'MEDICATION_ORDER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER - UNION ALL SELECT 'MEDICATION_ORDER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER - UNION ALL SELECT 'MEDICATION_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER - UNION ALL SELECT 'MEDICATION_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER - UNION ALL SELECT 'MEDICATION_ORDER', 'medication_order_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN medication_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER - UNION ALL SELECT 'MEDICATION_ORDER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') + UNION ALL SELECT 'MEDICATION_ORDER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') + UNION ALL SELECT 'MEDICATION_ORDER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') + UNION ALL SELECT 'MEDICATION_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') + UNION ALL SELECT 'MEDICATION_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') + UNION ALL SELECT 'MEDICATION_ORDER', 'medication_order_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN medication_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') + UNION ALL SELECT 'MEDICATION_ORDER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') -- DIAGNOSTIC_ORDER (OLIDS_COMMON) - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'diagnostic_order_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN diagnostic_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'result_value_units_concept_id', 5.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'episodicity_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'diagnostic_order_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN diagnostic_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'result_value_units_concept_id', 5.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'episodicity_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') -- ENCOUNTER (OLIDS_COMMON) - UNION ALL SELECT 'ENCOUNTER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER - UNION ALL SELECT 'ENCOUNTER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER - UNION ALL SELECT 'ENCOUNTER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER - UNION ALL SELECT 'ENCOUNTER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER - UNION ALL SELECT 'ENCOUNTER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER - UNION ALL SELECT 'ENCOUNTER', 'encounter_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN encounter_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER - UNION ALL SELECT 'ENCOUNTER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') + UNION ALL SELECT 'ENCOUNTER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') + UNION ALL SELECT 'ENCOUNTER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') + UNION ALL SELECT 'ENCOUNTER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') + UNION ALL SELECT 'ENCOUNTER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') + UNION ALL SELECT 'ENCOUNTER', 'encounter_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN encounter_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') + UNION ALL SELECT 'ENCOUNTER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') -- ALLERGY_INTOLERANCE (OLIDS_COMMON) - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'allergy_intolerance_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN allergy_intolerance_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'allergy_intolerance_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN allergy_intolerance_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') -- PROCEDURE_REQUEST (OLIDS_COMMON) - UNION ALL SELECT 'PROCEDURE_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST - UNION ALL SELECT 'PROCEDURE_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST - UNION ALL SELECT 'PROCEDURE_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST - UNION ALL SELECT 'PROCEDURE_REQUEST', 'procedure_request_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN procedure_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST - UNION ALL SELECT 'PROCEDURE_REQUEST', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST - UNION ALL SELECT 'PROCEDURE_REQUEST', 'status_concept_id', 5.0, COUNT(*), SUM(CASE WHEN status_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') + UNION ALL SELECT 'PROCEDURE_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') + UNION ALL SELECT 'PROCEDURE_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') + UNION ALL SELECT 'PROCEDURE_REQUEST', 'procedure_request_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN procedure_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') + UNION ALL SELECT 'PROCEDURE_REQUEST', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') + UNION ALL SELECT 'PROCEDURE_REQUEST', 'status_concept_id', 5.0, COUNT(*), SUM(CASE WHEN status_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') -- REFERRAL_REQUEST (OLIDS_COMMON) - UNION ALL SELECT 'REFERRAL_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST - UNION ALL SELECT 'REFERRAL_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST - UNION ALL SELECT 'REFERRAL_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST - UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST - UNION ALL SELECT 'REFERRAL_REQUEST', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST - UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_priority_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_priority_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST - UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST - UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_specialty_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_specialty_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') + UNION ALL SELECT 'REFERRAL_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') + UNION ALL SELECT 'REFERRAL_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') + UNION ALL SELECT 'REFERRAL_REQUEST', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_priority_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_priority_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_specialty_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_specialty_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') -- LOCATION_CONTACT (OLIDS_COMMON) - UNION ALL SELECT 'LOCATION_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT - UNION ALL SELECT 'LOCATION_CONTACT', 'contact_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT - UNION ALL SELECT 'LOCATION_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT + UNION ALL SELECT 'LOCATION_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.LOCATION_CONTACT') + UNION ALL SELECT 'LOCATION_CONTACT', 'contact_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.LOCATION_CONTACT') + UNION ALL SELECT 'LOCATION_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.LOCATION_CONTACT') -- APPOINTMENT (OLIDS_COMMON) - UNION ALL SELECT 'APPOINTMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT - UNION ALL SELECT 'APPOINTMENT', 'appointment_status_concept_id', 5.0, COUNT(*), SUM(CASE WHEN appointment_status_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT - UNION ALL SELECT 'APPOINTMENT', 'booking_method_concept_id', 5.0, COUNT(*), SUM(CASE WHEN booking_method_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT - UNION ALL SELECT 'APPOINTMENT', 'contact_mode_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_mode_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT - UNION ALL SELECT 'APPOINTMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT') + UNION ALL SELECT 'APPOINTMENT', 'appointment_status_concept_id', 5.0, COUNT(*), SUM(CASE WHEN appointment_status_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT') + UNION ALL SELECT 'APPOINTMENT', 'booking_method_concept_id', 5.0, COUNT(*), SUM(CASE WHEN booking_method_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT') + UNION ALL SELECT 'APPOINTMENT', 'contact_mode_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_mode_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT') + UNION ALL SELECT 'APPOINTMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT') -- APPOINTMENT_PRACTITIONER (OLIDS_COMMON) - UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER - UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER + UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT_PRACTITIONER') + UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT_PRACTITIONER') -- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE (OLIDS_COMMON) - UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE - UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE + UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') + UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') -- LOCATION (OLIDS_COMMON) - UNION ALL SELECT 'LOCATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION - UNION ALL SELECT 'LOCATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION + UNION ALL SELECT 'LOCATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.LOCATION') + UNION ALL SELECT 'LOCATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.LOCATION') -- FLAG (OLIDS_COMMON) - UNION ALL SELECT 'FLAG', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.FLAG - UNION ALL SELECT 'FLAG', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.FLAG + UNION ALL SELECT 'FLAG', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.FLAG') + UNION ALL SELECT 'FLAG', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.FLAG') -- ORGANISATION (OLIDS_COMMON) - UNION ALL SELECT 'ORGANISATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ORGANISATION - UNION ALL SELECT 'ORGANISATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ORGANISATION + UNION ALL SELECT 'ORGANISATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ORGANISATION') + UNION ALL SELECT 'ORGANISATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ORGANISATION') -- PRACTITIONER (OLIDS_COMMON) - UNION ALL SELECT 'PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER - UNION ALL SELECT 'PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER + UNION ALL SELECT 'PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PRACTITIONER') + UNION ALL SELECT 'PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PRACTITIONER') -- PRACTITIONER_IN_ROLE (OLIDS_COMMON) - UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE - UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE + UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PRACTITIONER_IN_ROLE') + UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PRACTITIONER_IN_ROLE') -- SCHEDULE (OLIDS_COMMON) - UNION ALL SELECT 'SCHEDULE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE - UNION ALL SELECT 'SCHEDULE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE + UNION ALL SELECT 'SCHEDULE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.SCHEDULE') + UNION ALL SELECT 'SCHEDULE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.SCHEDULE') -- SCHEDULE_PRACTITIONER (OLIDS_COMMON) - UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER - UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER + UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.SCHEDULE_PRACTITIONER') + UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.SCHEDULE_PRACTITIONER') -- CONCEPT (OLIDS_TERMINOLOGY) - UNION ALL SELECT 'CONCEPT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT - UNION ALL SELECT 'CONCEPT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT + UNION ALL SELECT 'CONCEPT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_terminology || '.CONCEPT') + UNION ALL SELECT 'CONCEPT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_terminology || '.CONCEPT') -- CONCEPT_MAP (OLIDS_TERMINOLOGY) - UNION ALL SELECT 'CONCEPT_MAP', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT_MAP - UNION ALL SELECT 'CONCEPT_MAP', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT_MAP + UNION ALL SELECT 'CONCEPT_MAP', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_terminology || '.CONCEPT_MAP') + UNION ALL SELECT 'CONCEPT_MAP', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_terminology || '.CONCEPT_MAP') ) -- Compute completeness % and compare against threshold diff --git a/OLIDS/Testing/data-quality/test_concept_mapping.sql b/OLIDS/Testing/data-quality/test_concept_mapping.sql index 84c0f85..cfb858a 100644 --- a/OLIDS/Testing/data-quality/test_concept_mapping.sql +++ b/OLIDS/Testing/data-quality/test_concept_mapping.sql @@ -24,10 +24,14 @@ To add a check: Add a UNION ALL block joining your table's concept column through CONCEPT_MAP and CONCEPT. Follow the pattern below: - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base. = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base. = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id */ +SET schema_masked = 'OLIDS_MASKED'; -- Change if your ICB uses a different name (e.g. OLIDS_PCD) +SET schema_common = 'OLIDS_COMMON'; +SET schema_terminology = 'OLIDS_TERMINOLOGY'; + WITH checks AS ( -- Each block: LEFT JOIN concept column through CONCEPT_MAP -> CONCEPT, -- count distinct values and how many fail to map. @@ -38,9 +42,9 @@ WITH checks AS ( COUNT(*) AS total_rows, COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.observation_source_concept_id END) AS unmapped_concepts, SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) AS unmapped_rows - FROM OLIDS_COMMON.OBSERVATION base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.observation_source_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.OBSERVATION') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.observation_source_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.observation_source_concept_id IS NOT NULL UNION ALL @@ -49,9 +53,9 @@ WITH checks AS ( COUNT(DISTINCT base.result_value_units_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.result_value_units_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.OBSERVATION base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.result_value_units_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.OBSERVATION') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.result_value_units_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.result_value_units_concept_id IS NOT NULL UNION ALL @@ -60,9 +64,9 @@ WITH checks AS ( COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.OBSERVATION base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.OBSERVATION') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.date_precision_concept_id IS NOT NULL UNION ALL @@ -71,9 +75,9 @@ WITH checks AS ( COUNT(DISTINCT base.episodicity_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.episodicity_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.OBSERVATION base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.episodicity_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.OBSERVATION') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.episodicity_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.episodicity_concept_id IS NOT NULL UNION ALL @@ -83,9 +87,9 @@ WITH checks AS ( COUNT(DISTINCT base.medication_statement_source_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.medication_statement_source_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_STATEMENT base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.medication_statement_source_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.medication_statement_source_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.medication_statement_source_concept_id IS NOT NULL UNION ALL @@ -94,9 +98,9 @@ WITH checks AS ( COUNT(DISTINCT base.authorisation_type_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.authorisation_type_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_STATEMENT base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.authorisation_type_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.authorisation_type_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.authorisation_type_concept_id IS NOT NULL UNION ALL @@ -105,9 +109,9 @@ WITH checks AS ( COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_STATEMENT base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.date_precision_concept_id IS NOT NULL UNION ALL @@ -117,9 +121,9 @@ WITH checks AS ( COUNT(DISTINCT base.medication_order_source_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.medication_order_source_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_ORDER base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.medication_order_source_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.medication_order_source_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.medication_order_source_concept_id IS NOT NULL UNION ALL @@ -128,9 +132,9 @@ WITH checks AS ( COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_ORDER base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.date_precision_concept_id IS NOT NULL UNION ALL @@ -140,9 +144,9 @@ WITH checks AS ( COUNT(DISTINCT base.diagnostic_order_source_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.diagnostic_order_source_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.DIAGNOSTIC_ORDER base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.diagnostic_order_source_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.diagnostic_order_source_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.diagnostic_order_source_concept_id IS NOT NULL UNION ALL @@ -151,9 +155,9 @@ WITH checks AS ( COUNT(DISTINCT base.result_value_units_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.result_value_units_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.DIAGNOSTIC_ORDER base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.result_value_units_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.result_value_units_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.result_value_units_concept_id IS NOT NULL UNION ALL @@ -162,9 +166,9 @@ WITH checks AS ( COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.DIAGNOSTIC_ORDER base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.date_precision_concept_id IS NOT NULL UNION ALL @@ -173,9 +177,9 @@ WITH checks AS ( COUNT(DISTINCT base.episodicity_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.episodicity_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.DIAGNOSTIC_ORDER base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.episodicity_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.episodicity_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.episodicity_concept_id IS NOT NULL UNION ALL @@ -185,9 +189,9 @@ WITH checks AS ( COUNT(DISTINCT base.procedure_request_source_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.procedure_request_source_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.PROCEDURE_REQUEST base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.procedure_request_source_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.procedure_request_source_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.procedure_request_source_concept_id IS NOT NULL UNION ALL @@ -196,9 +200,9 @@ WITH checks AS ( COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.PROCEDURE_REQUEST base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.date_precision_concept_id IS NOT NULL UNION ALL @@ -207,9 +211,9 @@ WITH checks AS ( COUNT(DISTINCT base.status_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.status_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.PROCEDURE_REQUEST base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.status_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.status_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.status_concept_id IS NOT NULL UNION ALL @@ -219,9 +223,9 @@ WITH checks AS ( COUNT(DISTINCT base.referral_request_source_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.referral_request_source_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.REFERRAL_REQUEST base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_source_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.referral_request_source_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.referral_request_source_concept_id IS NOT NULL UNION ALL @@ -230,9 +234,9 @@ WITH checks AS ( COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.REFERRAL_REQUEST base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.date_precision_concept_id IS NOT NULL UNION ALL @@ -241,9 +245,9 @@ WITH checks AS ( COUNT(DISTINCT base.referral_request_priority_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.referral_request_priority_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.REFERRAL_REQUEST base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_priority_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.referral_request_priority_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.referral_request_priority_concept_id IS NOT NULL UNION ALL @@ -252,9 +256,9 @@ WITH checks AS ( COUNT(DISTINCT base.referral_request_type_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.referral_request_type_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.REFERRAL_REQUEST base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_type_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.referral_request_type_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.referral_request_type_concept_id IS NOT NULL UNION ALL @@ -263,9 +267,9 @@ WITH checks AS ( COUNT(DISTINCT base.referral_request_specialty_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.referral_request_specialty_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.REFERRAL_REQUEST base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_specialty_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.referral_request_specialty_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.referral_request_specialty_concept_id IS NOT NULL UNION ALL @@ -275,9 +279,9 @@ WITH checks AS ( COUNT(DISTINCT base.allergy_intolerance_source_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.allergy_intolerance_source_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.ALLERGY_INTOLERANCE base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.allergy_intolerance_source_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.allergy_intolerance_source_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.allergy_intolerance_source_concept_id IS NOT NULL UNION ALL @@ -286,9 +290,9 @@ WITH checks AS ( COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.ALLERGY_INTOLERANCE base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.date_precision_concept_id IS NOT NULL UNION ALL @@ -298,9 +302,9 @@ WITH checks AS ( COUNT(DISTINCT base.encounter_source_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.encounter_source_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.ENCOUNTER base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.encounter_source_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.ENCOUNTER') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.encounter_source_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.encounter_source_concept_id IS NOT NULL UNION ALL @@ -309,9 +313,9 @@ WITH checks AS ( COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.ENCOUNTER base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.ENCOUNTER') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.date_precision_concept_id IS NOT NULL UNION ALL @@ -321,9 +325,9 @@ WITH checks AS ( COUNT(DISTINCT base.episode_type_source_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.episode_type_source_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.EPISODE_OF_CARE base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.episode_type_source_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.episode_type_source_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.episode_type_source_concept_id IS NOT NULL UNION ALL @@ -332,9 +336,9 @@ WITH checks AS ( COUNT(DISTINCT base.episode_status_source_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.episode_status_source_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.EPISODE_OF_CARE base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.episode_status_source_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.episode_status_source_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.episode_status_source_concept_id IS NOT NULL UNION ALL @@ -344,9 +348,9 @@ WITH checks AS ( COUNT(DISTINCT base.contact_type_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.contact_type_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.LOCATION_CONTACT base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.contact_type_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.LOCATION_CONTACT') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.contact_type_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.contact_type_concept_id IS NOT NULL UNION ALL @@ -356,9 +360,9 @@ WITH checks AS ( COUNT(DISTINCT base.appointment_status_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.appointment_status_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.APPOINTMENT base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.appointment_status_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.APPOINTMENT') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.appointment_status_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.appointment_status_concept_id IS NOT NULL UNION ALL @@ -367,9 +371,9 @@ WITH checks AS ( COUNT(DISTINCT base.booking_method_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.booking_method_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.APPOINTMENT base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.booking_method_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.APPOINTMENT') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.booking_method_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.booking_method_concept_id IS NOT NULL UNION ALL @@ -378,9 +382,9 @@ WITH checks AS ( COUNT(DISTINCT base.contact_mode_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.contact_mode_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.APPOINTMENT base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.contact_mode_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.APPOINTMENT') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.contact_mode_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.contact_mode_concept_id IS NOT NULL UNION ALL @@ -390,9 +394,9 @@ WITH checks AS ( COUNT(DISTINCT base.gender_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.gender_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_MASKED.PATIENT base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.gender_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_masked || '.PATIENT') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.gender_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.gender_concept_id IS NOT NULL UNION ALL @@ -402,9 +406,9 @@ WITH checks AS ( COUNT(DISTINCT base.address_type_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.address_type_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_MASKED.PATIENT_ADDRESS base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.address_type_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_masked || '.PATIENT_ADDRESS') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.address_type_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.address_type_concept_id IS NOT NULL UNION ALL @@ -414,9 +418,9 @@ WITH checks AS ( COUNT(DISTINCT base.contact_type_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.contact_type_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM OLIDS_MASKED.PATIENT_CONTACT base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.contact_type_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_masked || '.PATIENT_CONTACT') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.contact_type_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.contact_type_concept_id IS NOT NULL ) diff --git a/OLIDS/Testing/data-quality/test_data_freshness.sql b/OLIDS/Testing/data-quality/test_data_freshness.sql index cdabd21..029ae77 100644 --- a/OLIDS/Testing/data-quality/test_data_freshness.sql +++ b/OLIDS/Testing/data-quality/test_data_freshness.sql @@ -30,6 +30,10 @@ date_recorded columns. */ +SET schema_masked = 'OLIDS_MASKED'; -- Change if your ICB uses a different name (e.g. OLIDS_PCD) +SET schema_common = 'OLIDS_COMMON'; +SET schema_terminology = 'OLIDS_TERMINOLOGY'; + SET freshness_days = 5; SET pass_threshold_pct = 90.0; @@ -39,7 +43,7 @@ WITH org_freshness AS ( SELECT 'OBSERVATION' AS table_name, record_owner_organisation_code AS org_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END) AS max_date_recorded, DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) AS days_since_last - FROM OLIDS_COMMON.OBSERVATION WHERE record_owner_organisation_code IS NOT NULL + FROM IDENTIFIER($schema_common || '.OBSERVATION') WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL @@ -48,7 +52,7 @@ WITH org_freshness AS ( SELECT 'ENCOUNTER', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM OLIDS_COMMON.ENCOUNTER WHERE record_owner_organisation_code IS NOT NULL + FROM IDENTIFIER($schema_common || '.ENCOUNTER') WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL @@ -57,7 +61,7 @@ WITH org_freshness AS ( SELECT 'MEDICATION_ORDER', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM OLIDS_COMMON.MEDICATION_ORDER WHERE record_owner_organisation_code IS NOT NULL + FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL @@ -66,7 +70,7 @@ WITH org_freshness AS ( SELECT 'MEDICATION_STATEMENT', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM OLIDS_COMMON.MEDICATION_STATEMENT WHERE record_owner_organisation_code IS NOT NULL + FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL @@ -75,7 +79,7 @@ WITH org_freshness AS ( SELECT 'DIAGNOSTIC_ORDER', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM OLIDS_COMMON.DIAGNOSTIC_ORDER WHERE record_owner_organisation_code IS NOT NULL + FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL @@ -84,7 +88,7 @@ WITH org_freshness AS ( SELECT 'ALLERGY_INTOLERANCE', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM OLIDS_COMMON.ALLERGY_INTOLERANCE WHERE record_owner_organisation_code IS NOT NULL + FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL @@ -93,7 +97,7 @@ WITH org_freshness AS ( SELECT 'PROCEDURE_REQUEST', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM OLIDS_COMMON.PROCEDURE_REQUEST WHERE record_owner_organisation_code IS NOT NULL + FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL @@ -102,7 +106,7 @@ WITH org_freshness AS ( SELECT 'REFERRAL_REQUEST', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM OLIDS_COMMON.REFERRAL_REQUEST WHERE record_owner_organisation_code IS NOT NULL + FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code ), diff --git a/OLIDS/Testing/data-quality/test_referential_integrity.sql b/OLIDS/Testing/data-quality/test_referential_integrity.sql index 6c55863..6442d32 100644 --- a/OLIDS/Testing/data-quality/test_referential_integrity.sql +++ b/OLIDS/Testing/data-quality/test_referential_integrity.sql @@ -23,6 +23,10 @@ Use aliases 'c' (child) and 'p' (parent). Follow the pattern below. */ +SET schema_masked = 'OLIDS_MASKED'; -- Change if your ICB uses a different name (e.g. OLIDS_PCD) +SET schema_common = 'OLIDS_COMMON'; +SET schema_terminology = 'OLIDS_TERMINOLOGY'; + WITH fk_checks AS ( -- Each block: LEFT JOIN child.fk_column to parent.id, count orphaned values. -- Uses 'c' for child table and 'p' for parent table throughout. @@ -33,8 +37,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END) AS total_rows_with_fk, COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END) AS orphaned_fk, SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) AS orphaned_rows - FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c - LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') c + LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id UNION ALL @@ -44,8 +48,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c - LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id + FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') c + LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id UNION ALL @@ -55,8 +59,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.encounter_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN c.encounter_id END), SUM(CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c - LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id + FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') c + LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id UNION ALL @@ -66,8 +70,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c - LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') c + LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id UNION ALL @@ -77,8 +81,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.APPOINTMENT c - LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + FROM IDENTIFIER($schema_common || '.APPOINTMENT') c + LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id UNION ALL @@ -88,8 +92,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_in_role_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_in_role_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_in_role_id END), SUM(CASE WHEN c.practitioner_in_role_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.APPOINTMENT c - LEFT JOIN OLIDS_COMMON.PRACTITIONER_IN_ROLE p ON c.practitioner_in_role_id = p.id + FROM IDENTIFIER($schema_common || '.APPOINTMENT') c + LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER_IN_ROLE') p ON c.practitioner_in_role_id = p.id UNION ALL @@ -99,8 +103,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.schedule_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.schedule_id IS NOT NULL AND p.id IS NULL THEN c.schedule_id END), SUM(CASE WHEN c.schedule_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.APPOINTMENT c - LEFT JOIN OLIDS_COMMON.SCHEDULE p ON c.schedule_id = p.id + FROM IDENTIFIER($schema_common || '.APPOINTMENT') c + LEFT JOIN IDENTIFIER($schema_common || '.SCHEDULE') p ON c.schedule_id = p.id UNION ALL @@ -110,8 +114,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.appointment_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.appointment_id IS NOT NULL AND p.id IS NULL THEN c.appointment_id END), SUM(CASE WHEN c.appointment_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER c - LEFT JOIN OLIDS_COMMON.APPOINTMENT p ON c.appointment_id = p.id + FROM IDENTIFIER($schema_common || '.APPOINTMENT_PRACTITIONER') c + LEFT JOIN IDENTIFIER($schema_common || '.APPOINTMENT') p ON c.appointment_id = p.id UNION ALL @@ -121,8 +125,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER c - LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + FROM IDENTIFIER($schema_common || '.APPOINTMENT_PRACTITIONER') c + LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id UNION ALL @@ -132,8 +136,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c - LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') c + LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id UNION ALL @@ -143,8 +147,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c - LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id + FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') c + LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id UNION ALL @@ -154,8 +158,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.encounter_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN c.encounter_id END), SUM(CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c - LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id + FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') c + LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id UNION ALL @@ -165,8 +169,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c - LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') c + LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id UNION ALL @@ -176,8 +180,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.parent_observation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.parent_observation_id IS NOT NULL AND p.id IS NULL THEN c.parent_observation_id END), SUM(CASE WHEN c.parent_observation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c - LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.parent_observation_id = p.id + FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') c + LEFT JOIN IDENTIFIER($schema_common || '.OBSERVATION') p ON c.parent_observation_id = p.id UNION ALL @@ -187,8 +191,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.ENCOUNTER c - LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + FROM IDENTIFIER($schema_common || '.ENCOUNTER') c + LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id UNION ALL @@ -198,8 +202,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.ENCOUNTER c - LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id + FROM IDENTIFIER($schema_common || '.ENCOUNTER') c + LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id UNION ALL @@ -209,8 +213,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.ENCOUNTER c - LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + FROM IDENTIFIER($schema_common || '.ENCOUNTER') c + LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id UNION ALL @@ -220,8 +224,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.episode_of_care_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.episode_of_care_id IS NOT NULL AND p.id IS NULL THEN c.episode_of_care_id END), SUM(CASE WHEN c.episode_of_care_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.ENCOUNTER c - LEFT JOIN OLIDS_COMMON.EPISODE_OF_CARE p ON c.episode_of_care_id = p.id + FROM IDENTIFIER($schema_common || '.ENCOUNTER') c + LEFT JOIN IDENTIFIER($schema_common || '.EPISODE_OF_CARE') p ON c.episode_of_care_id = p.id UNION ALL @@ -231,8 +235,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.appointment_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.appointment_id IS NOT NULL AND p.id IS NULL THEN c.appointment_id END), SUM(CASE WHEN c.appointment_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.ENCOUNTER c - LEFT JOIN OLIDS_COMMON.APPOINTMENT p ON c.appointment_id = p.id + FROM IDENTIFIER($schema_common || '.ENCOUNTER') c + LEFT JOIN IDENTIFIER($schema_common || '.APPOINTMENT') p ON c.appointment_id = p.id UNION ALL @@ -242,8 +246,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.service_provider_organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.service_provider_organisation_id IS NOT NULL AND p.id IS NULL THEN c.service_provider_organisation_id END), SUM(CASE WHEN c.service_provider_organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.ENCOUNTER c - LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.service_provider_organisation_id = p.id + FROM IDENTIFIER($schema_common || '.ENCOUNTER') c + LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.service_provider_organisation_id = p.id UNION ALL @@ -253,8 +257,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.EPISODE_OF_CARE c - LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') c + LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id UNION ALL @@ -264,8 +268,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.EPISODE_OF_CARE c - LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id + FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') c + LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id UNION ALL @@ -275,8 +279,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN c.organisation_id END), SUM(CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.EPISODE_OF_CARE c - LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id + FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') c + LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id UNION ALL @@ -286,8 +290,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.care_manager_practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.care_manager_practitioner_id IS NOT NULL AND p.id IS NULL THEN c.care_manager_practitioner_id END), SUM(CASE WHEN c.care_manager_practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.EPISODE_OF_CARE c - LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.care_manager_practitioner_id = p.id + FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') c + LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.care_manager_practitioner_id = p.id UNION ALL @@ -297,8 +301,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.FLAG c - LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + FROM IDENTIFIER($schema_common || '.FLAG') c + LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id UNION ALL @@ -308,8 +312,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.managing_organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.managing_organisation_id IS NOT NULL AND p.id IS NULL THEN c.managing_organisation_id END), SUM(CASE WHEN c.managing_organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.LOCATION c - LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.managing_organisation_id = p.id + FROM IDENTIFIER($schema_common || '.LOCATION') c + LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.managing_organisation_id = p.id UNION ALL @@ -319,8 +323,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.location_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.location_id IS NOT NULL AND p.id IS NULL THEN c.location_id END), SUM(CASE WHEN c.location_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.LOCATION_CONTACT c - LEFT JOIN OLIDS_COMMON.LOCATION p ON c.location_id = p.id + FROM IDENTIFIER($schema_common || '.LOCATION_CONTACT') c + LEFT JOIN IDENTIFIER($schema_common || '.LOCATION') p ON c.location_id = p.id UNION ALL @@ -330,8 +334,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_ORDER c - LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c + LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id UNION ALL @@ -341,8 +345,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_ORDER c - LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id + FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c + LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id UNION ALL @@ -352,8 +356,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.medication_statement_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.medication_statement_id IS NOT NULL AND p.id IS NULL THEN c.medication_statement_id END), SUM(CASE WHEN c.medication_statement_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_ORDER c - LEFT JOIN OLIDS_COMMON.MEDICATION_STATEMENT p ON c.medication_statement_id = p.id + FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c + LEFT JOIN IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') p ON c.medication_statement_id = p.id UNION ALL @@ -363,8 +367,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN c.organisation_id END), SUM(CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_ORDER c - LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id + FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c + LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id UNION ALL @@ -374,8 +378,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.encounter_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN c.encounter_id END), SUM(CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_ORDER c - LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id + FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c + LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id UNION ALL @@ -385,8 +389,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_ORDER c - LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c + LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id UNION ALL @@ -396,8 +400,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.observation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.observation_id IS NOT NULL AND p.id IS NULL THEN c.observation_id END), SUM(CASE WHEN c.observation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_ORDER c - LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.observation_id = p.id + FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c + LEFT JOIN IDENTIFIER($schema_common || '.OBSERVATION') p ON c.observation_id = p.id UNION ALL @@ -407,8 +411,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.allergy_intolerance_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.allergy_intolerance_id IS NOT NULL AND p.id IS NULL THEN c.allergy_intolerance_id END), SUM(CASE WHEN c.allergy_intolerance_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_ORDER c - LEFT JOIN OLIDS_COMMON.ALLERGY_INTOLERANCE p ON c.allergy_intolerance_id = p.id + FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c + LEFT JOIN IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') p ON c.allergy_intolerance_id = p.id UNION ALL @@ -418,8 +422,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.diagnostic_order_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.diagnostic_order_id IS NOT NULL AND p.id IS NULL THEN c.diagnostic_order_id END), SUM(CASE WHEN c.diagnostic_order_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_ORDER c - LEFT JOIN OLIDS_COMMON.DIAGNOSTIC_ORDER p ON c.diagnostic_order_id = p.id + FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c + LEFT JOIN IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') p ON c.diagnostic_order_id = p.id UNION ALL @@ -429,8 +433,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.referral_request_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.referral_request_id IS NOT NULL AND p.id IS NULL THEN c.referral_request_id END), SUM(CASE WHEN c.referral_request_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_ORDER c - LEFT JOIN OLIDS_COMMON.REFERRAL_REQUEST p ON c.referral_request_id = p.id + FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c + LEFT JOIN IDENTIFIER($schema_common || '.REFERRAL_REQUEST') p ON c.referral_request_id = p.id UNION ALL @@ -440,8 +444,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_STATEMENT c - LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c + LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id UNION ALL @@ -451,8 +455,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_STATEMENT c - LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id + FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c + LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id UNION ALL @@ -462,8 +466,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN c.organisation_id END), SUM(CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_STATEMENT c - LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id + FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c + LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id UNION ALL @@ -473,8 +477,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.encounter_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN c.encounter_id END), SUM(CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_STATEMENT c - LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id + FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c + LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id UNION ALL @@ -484,8 +488,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_STATEMENT c - LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c + LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id UNION ALL @@ -495,8 +499,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.observation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.observation_id IS NOT NULL AND p.id IS NULL THEN c.observation_id END), SUM(CASE WHEN c.observation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_STATEMENT c - LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.observation_id = p.id + FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c + LEFT JOIN IDENTIFIER($schema_common || '.OBSERVATION') p ON c.observation_id = p.id UNION ALL @@ -506,8 +510,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.allergy_intolerance_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.allergy_intolerance_id IS NOT NULL AND p.id IS NULL THEN c.allergy_intolerance_id END), SUM(CASE WHEN c.allergy_intolerance_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_STATEMENT c - LEFT JOIN OLIDS_COMMON.ALLERGY_INTOLERANCE p ON c.allergy_intolerance_id = p.id + FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c + LEFT JOIN IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') p ON c.allergy_intolerance_id = p.id UNION ALL @@ -517,8 +521,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.diagnostic_order_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.diagnostic_order_id IS NOT NULL AND p.id IS NULL THEN c.diagnostic_order_id END), SUM(CASE WHEN c.diagnostic_order_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_STATEMENT c - LEFT JOIN OLIDS_COMMON.DIAGNOSTIC_ORDER p ON c.diagnostic_order_id = p.id + FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c + LEFT JOIN IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') p ON c.diagnostic_order_id = p.id UNION ALL @@ -528,8 +532,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.referral_request_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.referral_request_id IS NOT NULL AND p.id IS NULL THEN c.referral_request_id END), SUM(CASE WHEN c.referral_request_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.MEDICATION_STATEMENT c - LEFT JOIN OLIDS_COMMON.REFERRAL_REQUEST p ON c.referral_request_id = p.id + FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c + LEFT JOIN IDENTIFIER($schema_common || '.REFERRAL_REQUEST') p ON c.referral_request_id = p.id UNION ALL @@ -539,8 +543,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.OBSERVATION c - LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + FROM IDENTIFIER($schema_common || '.OBSERVATION') c + LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id UNION ALL @@ -550,8 +554,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.OBSERVATION c - LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id + FROM IDENTIFIER($schema_common || '.OBSERVATION') c + LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id UNION ALL @@ -561,8 +565,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.encounter_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN c.encounter_id END), SUM(CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.OBSERVATION c - LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id + FROM IDENTIFIER($schema_common || '.OBSERVATION') c + LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id UNION ALL @@ -572,8 +576,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.OBSERVATION c - LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + FROM IDENTIFIER($schema_common || '.OBSERVATION') c + LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id UNION ALL @@ -583,8 +587,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.parent_observation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.parent_observation_id IS NOT NULL AND p.id IS NULL THEN c.parent_observation_id END), SUM(CASE WHEN c.parent_observation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.OBSERVATION c - LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.parent_observation_id = p.id + FROM IDENTIFIER($schema_common || '.OBSERVATION') c + LEFT JOIN IDENTIFIER($schema_common || '.OBSERVATION') p ON c.parent_observation_id = p.id UNION ALL @@ -594,8 +598,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.parent_organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.parent_organisation_id IS NOT NULL AND p.id IS NULL THEN c.parent_organisation_id END), SUM(CASE WHEN c.parent_organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.ORGANISATION c - LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.parent_organisation_id = p.id + FROM IDENTIFIER($schema_common || '.ORGANISATION') c + LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.parent_organisation_id = p.id UNION ALL @@ -605,8 +609,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.registered_practice_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.registered_practice_id IS NOT NULL AND p.id IS NULL THEN c.registered_practice_id END), SUM(CASE WHEN c.registered_practice_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_MASKED.PATIENT c - LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.registered_practice_id = p.id + FROM IDENTIFIER($schema_masked || '.PATIENT') c + LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.registered_practice_id = p.id UNION ALL @@ -616,8 +620,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_MASKED.PATIENT_ADDRESS c - LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + FROM IDENTIFIER($schema_masked || '.PATIENT_ADDRESS') c + LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id UNION ALL @@ -627,8 +631,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_MASKED.PATIENT_CONTACT c - LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + FROM IDENTIFIER($schema_masked || '.PATIENT_CONTACT') c + LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id UNION ALL @@ -638,8 +642,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.PATIENT_PERSON c - LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + FROM IDENTIFIER($schema_common || '.PATIENT_PERSON') c + LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id UNION ALL @@ -649,8 +653,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.PATIENT_PERSON c - LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id + FROM IDENTIFIER($schema_common || '.PATIENT_PERSON') c + LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id UNION ALL @@ -660,8 +664,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c - LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') c + LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id UNION ALL @@ -671,8 +675,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN c.organisation_id END), SUM(CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c - LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id + FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') c + LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id UNION ALL @@ -682,8 +686,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c - LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') c + LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id UNION ALL @@ -693,8 +697,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.episode_of_care_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.episode_of_care_id IS NOT NULL AND p.id IS NULL THEN c.episode_of_care_id END), SUM(CASE WHEN c.episode_of_care_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c - LEFT JOIN OLIDS_COMMON.EPISODE_OF_CARE p ON c.episode_of_care_id = p.id + FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') c + LEFT JOIN IDENTIFIER($schema_common || '.EPISODE_OF_CARE') p ON c.episode_of_care_id = p.id UNION ALL @@ -704,8 +708,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE c - LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + FROM IDENTIFIER($schema_common || '.PRACTITIONER_IN_ROLE') c + LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id UNION ALL @@ -715,8 +719,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN c.organisation_id END), SUM(CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE c - LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id + FROM IDENTIFIER($schema_common || '.PRACTITIONER_IN_ROLE') c + LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id UNION ALL @@ -726,8 +730,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.PROCEDURE_REQUEST c - LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') c + LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id UNION ALL @@ -737,8 +741,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.encounter_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN c.encounter_id END), SUM(CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.PROCEDURE_REQUEST c - LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id + FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') c + LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id UNION ALL @@ -748,8 +752,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.PROCEDURE_REQUEST c - LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') c + LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id UNION ALL @@ -759,8 +763,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.REFERRAL_REQUEST c - LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id + FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c + LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id UNION ALL @@ -770,8 +774,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.encounter_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN c.encounter_id END), SUM(CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.REFERRAL_REQUEST c - LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id + FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c + LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id UNION ALL @@ -781,8 +785,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.REFERRAL_REQUEST c - LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c + LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id UNION ALL @@ -792,8 +796,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN c.organisation_id END), SUM(CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.REFERRAL_REQUEST c - LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id + FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c + LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id UNION ALL @@ -803,8 +807,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.requester_organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.requester_organisation_id IS NOT NULL AND p.id IS NULL THEN c.requester_organisation_id END), SUM(CASE WHEN c.requester_organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.REFERRAL_REQUEST c - LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.requester_organisation_id = p.id + FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c + LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.requester_organisation_id = p.id UNION ALL @@ -814,8 +818,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.recipient_organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.recipient_organisation_id IS NOT NULL AND p.id IS NULL THEN c.recipient_organisation_id END), SUM(CASE WHEN c.recipient_organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.REFERRAL_REQUEST c - LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.recipient_organisation_id = p.id + FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c + LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.recipient_organisation_id = p.id UNION ALL @@ -825,8 +829,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.location_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.location_id IS NOT NULL AND p.id IS NULL THEN c.location_id END), SUM(CASE WHEN c.location_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.SCHEDULE c - LEFT JOIN OLIDS_COMMON.LOCATION p ON c.location_id = p.id + FROM IDENTIFIER($schema_common || '.SCHEDULE') c + LEFT JOIN IDENTIFIER($schema_common || '.LOCATION') p ON c.location_id = p.id UNION ALL @@ -836,8 +840,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.SCHEDULE c - LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + FROM IDENTIFIER($schema_common || '.SCHEDULE') c + LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id UNION ALL @@ -847,8 +851,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.schedule_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.schedule_id IS NOT NULL AND p.id IS NULL THEN c.schedule_id END), SUM(CASE WHEN c.schedule_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER c - LEFT JOIN OLIDS_COMMON.SCHEDULE p ON c.schedule_id = p.id + FROM IDENTIFIER($schema_common || '.SCHEDULE_PRACTITIONER') c + LEFT JOIN IDENTIFIER($schema_common || '.SCHEDULE') p ON c.schedule_id = p.id UNION ALL @@ -858,8 +862,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER c - LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id + FROM IDENTIFIER($schema_common || '.SCHEDULE_PRACTITIONER') c + LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id ) SELECT diff --git a/OLIDS/Testing/data-quality/test_registration_pds.sql b/OLIDS/Testing/data-quality/test_registration_pds.sql index 581e87f..7d3f6e7 100644 --- a/OLIDS/Testing/data-quality/test_registration_pds.sql +++ b/OLIDS/Testing/data-quality/test_registration_pds.sql @@ -41,6 +41,10 @@ search for "Data_Store_Registries" in this file and replace all occurrences. */ +SET schema_masked = 'OLIDS_MASKED'; -- Change if your ICB uses a different name (e.g. OLIDS_PCD) +SET schema_common = 'OLIDS_COMMON'; +SET schema_terminology = 'OLIDS_TERMINOLOGY'; + -- Snapshot date: the most recent month-end that OLIDS data covers. -- PDS updates at month-ends, so we snap to a month boundary for accurate comparison. -- Uses MAX(episode_of_care_start_date) as the freshness indicator. Future dates excluded. @@ -48,14 +52,14 @@ SET snapshot_date = ( SELECT LAST_DAY(DATEADD(MONTH, -1, DATEADD(DAY, 1, MAX(CASE WHEN episode_of_care_start_date <= CURRENT_DATE THEN episode_of_care_start_date END)::DATE ))) - FROM OLIDS_COMMON.EPISODE_OF_CARE + FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') WHERE record_owner_organisation_code IS NOT NULL ); -- Practice codes derived from EPISODE_OF_CARE (only practices with actual data) WITH icb_practices AS ( SELECT DISTINCT record_owner_organisation_code AS practice_code - FROM OLIDS_COMMON.EPISODE_OF_CARE + FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') WHERE record_owner_organisation_code IS NOT NULL ), @@ -66,7 +70,7 @@ eligible_patients AS ( sk_patient_id, death_year, death_month - FROM OLIDS_MASKED.PATIENT + FROM IDENTIFIER($schema_masked || '.PATIENT') WHERE sk_patient_id IS NOT NULL AND is_spine_sensitive = FALSE AND is_confidential = FALSE @@ -97,20 +101,20 @@ patient_death_dates AS ( -- Step 3: Map patient_id to person_id (OLIDS deduplicates by person, not patient) patient_to_person AS ( SELECT patient_id, person_id - FROM OLIDS_COMMON.PATIENT_PERSON + FROM IDENTIFIER($schema_common || '.PATIENT_PERSON') WHERE patient_id IS NOT NULL AND person_id IS NOT NULL ), -- Step 4: Look up concept IDs for 'Regular' episode type and 'Left' status episode_type_regular AS ( SELECT source_code_id - FROM OLIDS_TERMINOLOGY.CONCEPT_MAP + FROM IDENTIFIER($schema_terminology || '.CONCEPT_MAP') WHERE source_code = 'Regular' ), episode_status_left AS ( SELECT source_code_id - FROM OLIDS_TERMINOLOGY.CONCEPT_MAP + FROM IDENTIFIER($schema_terminology || '.CONCEPT_MAP') WHERE source_code = 'Left' ), @@ -122,7 +126,7 @@ filtered_episodes AS ( eoc.record_owner_organisation_code AS practice_code, eoc.organisation_id, eoc.episode_of_care_start_date - FROM OLIDS_COMMON.EPISODE_OF_CARE eoc + FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') eoc INNER JOIN patient_death_dates pdd ON eoc.patient_id = pdd.patient_id INNER JOIN patient_to_person ptp ON eoc.patient_id = ptp.patient_id INNER JOIN episode_type_regular etr ON eoc.episode_type_source_concept_id = etr.source_code_id diff --git a/OLIDS/Testing/investigations/investigate_column_completeness.sql b/OLIDS/Testing/investigations/investigate_column_completeness.sql index 07a4c8e..78fe8e1 100644 --- a/OLIDS/Testing/investigations/investigate_column_completeness.sql +++ b/OLIDS/Testing/investigations/investigate_column_completeness.sql @@ -1,7 +1,8 @@ /* Investigation: Column Completeness - Run: Execute directly in Snowsight or VS Code Snowflake extension. - Set the USE DATABASE below to your ICB's OLIDS database. + Run: uv run run_tests.py --run investigations/investigate_column_completeness.sql + Or execute directly in Snowsight — set the USE DATABASE and schema + variables below to match your ICB. Shows NULL counts and rates for every checked column, ordered by null rate descending to highlight problem areas. @@ -12,178 +13,182 @@ USE DATABASE "Data_Store_OLIDS_Clinical_Validation"; -- Replace with your ICB's OLIDS database name +SET schema_masked = 'OLIDS_MASKED'; -- Change if your ICB uses a different name (e.g. OLIDS_PCD) +SET schema_common = 'OLIDS_COMMON'; +SET schema_terminology = 'OLIDS_TERMINOLOGY'; + WITH checks AS ( -- PATIENT (OLIDS_MASKED) - SELECT 'PATIENT' AS table_name, 'id' AS column_name, 0.0 AS threshold, COUNT(*) AS total_rows, SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) AS null_count FROM OLIDS_MASKED.PATIENT - UNION ALL SELECT 'PATIENT', 'sk_patient_id', 0.5, COUNT(*), SUM(CASE WHEN sk_patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT - UNION ALL SELECT 'PATIENT', 'birth_year', 1.0, COUNT(*), SUM(CASE WHEN birth_year IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT - UNION ALL SELECT 'PATIENT', 'birth_month', 1.0, COUNT(*), SUM(CASE WHEN birth_month IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT - UNION ALL SELECT 'PATIENT', 'gender_concept_id', 5.0, COUNT(*), SUM(CASE WHEN gender_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT - UNION ALL SELECT 'PATIENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + SELECT 'PATIENT' AS table_name, 'id' AS column_name, 0.0 AS threshold, COUNT(*) AS total_rows, SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) AS null_count FROM IDENTIFIER($schema_masked || '.PATIENT') + UNION ALL SELECT 'PATIENT', 'sk_patient_id', 0.5, COUNT(*), SUM(CASE WHEN sk_patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT') + UNION ALL SELECT 'PATIENT', 'birth_year', 1.0, COUNT(*), SUM(CASE WHEN birth_year IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT') + UNION ALL SELECT 'PATIENT', 'birth_month', 1.0, COUNT(*), SUM(CASE WHEN birth_month IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT') + UNION ALL SELECT 'PATIENT', 'gender_concept_id', 5.0, COUNT(*), SUM(CASE WHEN gender_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT') + UNION ALL SELECT 'PATIENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT') -- PERSON (OLIDS_MASKED) - UNION ALL SELECT 'PERSON', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PERSON - UNION ALL SELECT 'PERSON', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PERSON + UNION ALL SELECT 'PERSON', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PERSON') + UNION ALL SELECT 'PERSON', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PERSON') -- PATIENT_ADDRESS (OLIDS_MASKED) - UNION ALL SELECT 'PATIENT_ADDRESS', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS - UNION ALL SELECT 'PATIENT_ADDRESS', 'address_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN address_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS - UNION ALL SELECT 'PATIENT_ADDRESS', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS + UNION ALL SELECT 'PATIENT_ADDRESS', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_ADDRESS') + UNION ALL SELECT 'PATIENT_ADDRESS', 'address_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN address_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_ADDRESS') + UNION ALL SELECT 'PATIENT_ADDRESS', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_ADDRESS') -- PATIENT_CONTACT (OLIDS_MASKED) - UNION ALL SELECT 'PATIENT_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT - UNION ALL SELECT 'PATIENT_CONTACT', 'contact_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT - UNION ALL SELECT 'PATIENT_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT + UNION ALL SELECT 'PATIENT_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_CONTACT') + UNION ALL SELECT 'PATIENT_CONTACT', 'contact_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_CONTACT') + UNION ALL SELECT 'PATIENT_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_CONTACT') -- PATIENT_UPRN (OLIDS_MASKED) - UNION ALL SELECT 'PATIENT_UPRN', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_UPRN - UNION ALL SELECT 'PATIENT_UPRN', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_UPRN + UNION ALL SELECT 'PATIENT_UPRN', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_UPRN') + UNION ALL SELECT 'PATIENT_UPRN', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_UPRN') -- PATIENT_PERSON (OLIDS_COMMON) - UNION ALL SELECT 'PATIENT_PERSON', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_PERSON - UNION ALL SELECT 'PATIENT_PERSON', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_PERSON + UNION ALL SELECT 'PATIENT_PERSON', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PATIENT_PERSON') + UNION ALL SELECT 'PATIENT_PERSON', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PATIENT_PERSON') -- EPISODE_OF_CARE (OLIDS_COMMON) - UNION ALL SELECT 'EPISODE_OF_CARE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE - UNION ALL SELECT 'EPISODE_OF_CARE', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE - UNION ALL SELECT 'EPISODE_OF_CARE', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE - UNION ALL SELECT 'EPISODE_OF_CARE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE - UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_of_care_start_date', 1.0, COUNT(*), SUM(CASE WHEN episode_of_care_start_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE - UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_type_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_type_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE - UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_status_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_status_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') + UNION ALL SELECT 'EPISODE_OF_CARE', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') + UNION ALL SELECT 'EPISODE_OF_CARE', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') + UNION ALL SELECT 'EPISODE_OF_CARE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_of_care_start_date', 1.0, COUNT(*), SUM(CASE WHEN episode_of_care_start_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_type_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_type_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_status_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_status_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') -- OBSERVATION (OLIDS_COMMON) - UNION ALL SELECT 'OBSERVATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'observation_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN observation_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'result_value_units_concept_id', 5.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION - UNION ALL SELECT 'OBSERVATION', 'episodicity_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') + UNION ALL SELECT 'OBSERVATION', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') + UNION ALL SELECT 'OBSERVATION', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') + UNION ALL SELECT 'OBSERVATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') + UNION ALL SELECT 'OBSERVATION', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') + UNION ALL SELECT 'OBSERVATION', 'observation_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN observation_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') + UNION ALL SELECT 'OBSERVATION', 'result_value_units_concept_id', 5.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') + UNION ALL SELECT 'OBSERVATION', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') + UNION ALL SELECT 'OBSERVATION', 'episodicity_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') -- MEDICATION_STATEMENT (OLIDS_COMMON) - UNION ALL SELECT 'MEDICATION_STATEMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT - UNION ALL SELECT 'MEDICATION_STATEMENT', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT - UNION ALL SELECT 'MEDICATION_STATEMENT', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT - UNION ALL SELECT 'MEDICATION_STATEMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT - UNION ALL SELECT 'MEDICATION_STATEMENT', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT - UNION ALL SELECT 'MEDICATION_STATEMENT', 'medication_statement_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN medication_statement_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT - UNION ALL SELECT 'MEDICATION_STATEMENT', 'authorisation_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN authorisation_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT - UNION ALL SELECT 'MEDICATION_STATEMENT', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') + UNION ALL SELECT 'MEDICATION_STATEMENT', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') + UNION ALL SELECT 'MEDICATION_STATEMENT', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') + UNION ALL SELECT 'MEDICATION_STATEMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') + UNION ALL SELECT 'MEDICATION_STATEMENT', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') + UNION ALL SELECT 'MEDICATION_STATEMENT', 'medication_statement_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN medication_statement_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') + UNION ALL SELECT 'MEDICATION_STATEMENT', 'authorisation_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN authorisation_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') + UNION ALL SELECT 'MEDICATION_STATEMENT', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') -- MEDICATION_ORDER (OLIDS_COMMON) - UNION ALL SELECT 'MEDICATION_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER - UNION ALL SELECT 'MEDICATION_ORDER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER - UNION ALL SELECT 'MEDICATION_ORDER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER - UNION ALL SELECT 'MEDICATION_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER - UNION ALL SELECT 'MEDICATION_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER - UNION ALL SELECT 'MEDICATION_ORDER', 'medication_order_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN medication_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER - UNION ALL SELECT 'MEDICATION_ORDER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') + UNION ALL SELECT 'MEDICATION_ORDER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') + UNION ALL SELECT 'MEDICATION_ORDER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') + UNION ALL SELECT 'MEDICATION_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') + UNION ALL SELECT 'MEDICATION_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') + UNION ALL SELECT 'MEDICATION_ORDER', 'medication_order_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN medication_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') + UNION ALL SELECT 'MEDICATION_ORDER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') -- DIAGNOSTIC_ORDER (OLIDS_COMMON) - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'diagnostic_order_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN diagnostic_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'result_value_units_concept_id', 5.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'episodicity_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'diagnostic_order_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN diagnostic_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'result_value_units_concept_id', 5.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'episodicity_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') -- ENCOUNTER (OLIDS_COMMON) - UNION ALL SELECT 'ENCOUNTER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER - UNION ALL SELECT 'ENCOUNTER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER - UNION ALL SELECT 'ENCOUNTER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER - UNION ALL SELECT 'ENCOUNTER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER - UNION ALL SELECT 'ENCOUNTER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER - UNION ALL SELECT 'ENCOUNTER', 'encounter_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN encounter_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER - UNION ALL SELECT 'ENCOUNTER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') + UNION ALL SELECT 'ENCOUNTER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') + UNION ALL SELECT 'ENCOUNTER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') + UNION ALL SELECT 'ENCOUNTER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') + UNION ALL SELECT 'ENCOUNTER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') + UNION ALL SELECT 'ENCOUNTER', 'encounter_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN encounter_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') + UNION ALL SELECT 'ENCOUNTER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') -- ALLERGY_INTOLERANCE (OLIDS_COMMON) - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'allergy_intolerance_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN allergy_intolerance_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'allergy_intolerance_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN allergy_intolerance_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') -- PROCEDURE_REQUEST (OLIDS_COMMON) - UNION ALL SELECT 'PROCEDURE_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST - UNION ALL SELECT 'PROCEDURE_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST - UNION ALL SELECT 'PROCEDURE_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST - UNION ALL SELECT 'PROCEDURE_REQUEST', 'procedure_request_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN procedure_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST - UNION ALL SELECT 'PROCEDURE_REQUEST', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST - UNION ALL SELECT 'PROCEDURE_REQUEST', 'status_concept_id', 5.0, COUNT(*), SUM(CASE WHEN status_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') + UNION ALL SELECT 'PROCEDURE_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') + UNION ALL SELECT 'PROCEDURE_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') + UNION ALL SELECT 'PROCEDURE_REQUEST', 'procedure_request_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN procedure_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') + UNION ALL SELECT 'PROCEDURE_REQUEST', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') + UNION ALL SELECT 'PROCEDURE_REQUEST', 'status_concept_id', 5.0, COUNT(*), SUM(CASE WHEN status_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') -- REFERRAL_REQUEST (OLIDS_COMMON) - UNION ALL SELECT 'REFERRAL_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST - UNION ALL SELECT 'REFERRAL_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST - UNION ALL SELECT 'REFERRAL_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST - UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST - UNION ALL SELECT 'REFERRAL_REQUEST', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST - UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_priority_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_priority_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST - UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST - UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_specialty_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_specialty_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') + UNION ALL SELECT 'REFERRAL_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') + UNION ALL SELECT 'REFERRAL_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') + UNION ALL SELECT 'REFERRAL_REQUEST', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_priority_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_priority_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_specialty_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_specialty_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') -- LOCATION_CONTACT (OLIDS_COMMON) - UNION ALL SELECT 'LOCATION_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT - UNION ALL SELECT 'LOCATION_CONTACT', 'contact_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT - UNION ALL SELECT 'LOCATION_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT + UNION ALL SELECT 'LOCATION_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.LOCATION_CONTACT') + UNION ALL SELECT 'LOCATION_CONTACT', 'contact_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.LOCATION_CONTACT') + UNION ALL SELECT 'LOCATION_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.LOCATION_CONTACT') -- APPOINTMENT (OLIDS_COMMON) - UNION ALL SELECT 'APPOINTMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT - UNION ALL SELECT 'APPOINTMENT', 'appointment_status_concept_id', 5.0, COUNT(*), SUM(CASE WHEN appointment_status_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT - UNION ALL SELECT 'APPOINTMENT', 'booking_method_concept_id', 5.0, COUNT(*), SUM(CASE WHEN booking_method_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT - UNION ALL SELECT 'APPOINTMENT', 'contact_mode_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_mode_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT - UNION ALL SELECT 'APPOINTMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT') + UNION ALL SELECT 'APPOINTMENT', 'appointment_status_concept_id', 5.0, COUNT(*), SUM(CASE WHEN appointment_status_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT') + UNION ALL SELECT 'APPOINTMENT', 'booking_method_concept_id', 5.0, COUNT(*), SUM(CASE WHEN booking_method_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT') + UNION ALL SELECT 'APPOINTMENT', 'contact_mode_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_mode_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT') + UNION ALL SELECT 'APPOINTMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT') -- APPOINTMENT_PRACTITIONER (OLIDS_COMMON) - UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER - UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER + UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT_PRACTITIONER') + UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT_PRACTITIONER') -- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE (OLIDS_COMMON) - UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE - UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE + UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') + UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') -- LOCATION (OLIDS_COMMON) - UNION ALL SELECT 'LOCATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION - UNION ALL SELECT 'LOCATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION + UNION ALL SELECT 'LOCATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.LOCATION') + UNION ALL SELECT 'LOCATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.LOCATION') -- FLAG (OLIDS_COMMON) - UNION ALL SELECT 'FLAG', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.FLAG - UNION ALL SELECT 'FLAG', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.FLAG + UNION ALL SELECT 'FLAG', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.FLAG') + UNION ALL SELECT 'FLAG', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.FLAG') -- ORGANISATION (OLIDS_COMMON) - UNION ALL SELECT 'ORGANISATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ORGANISATION - UNION ALL SELECT 'ORGANISATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ORGANISATION + UNION ALL SELECT 'ORGANISATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ORGANISATION') + UNION ALL SELECT 'ORGANISATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ORGANISATION') -- PRACTITIONER (OLIDS_COMMON) - UNION ALL SELECT 'PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER - UNION ALL SELECT 'PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER + UNION ALL SELECT 'PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PRACTITIONER') + UNION ALL SELECT 'PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PRACTITIONER') -- PRACTITIONER_IN_ROLE (OLIDS_COMMON) - UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE - UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE + UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PRACTITIONER_IN_ROLE') + UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PRACTITIONER_IN_ROLE') -- SCHEDULE (OLIDS_COMMON) - UNION ALL SELECT 'SCHEDULE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE - UNION ALL SELECT 'SCHEDULE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE + UNION ALL SELECT 'SCHEDULE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.SCHEDULE') + UNION ALL SELECT 'SCHEDULE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.SCHEDULE') -- SCHEDULE_PRACTITIONER (OLIDS_COMMON) - UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER - UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER + UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.SCHEDULE_PRACTITIONER') + UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.SCHEDULE_PRACTITIONER') -- CONCEPT (OLIDS_TERMINOLOGY) - UNION ALL SELECT 'CONCEPT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT - UNION ALL SELECT 'CONCEPT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT + UNION ALL SELECT 'CONCEPT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_terminology || '.CONCEPT') + UNION ALL SELECT 'CONCEPT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_terminology || '.CONCEPT') -- CONCEPT_MAP (OLIDS_TERMINOLOGY) - UNION ALL SELECT 'CONCEPT_MAP', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT_MAP - UNION ALL SELECT 'CONCEPT_MAP', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT_MAP + UNION ALL SELECT 'CONCEPT_MAP', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_terminology || '.CONCEPT_MAP') + UNION ALL SELECT 'CONCEPT_MAP', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_terminology || '.CONCEPT_MAP') ) SELECT diff --git a/OLIDS/Testing/investigations/investigate_concept_mapping.sql b/OLIDS/Testing/investigations/investigate_concept_mapping.sql index c3ea970..e1ff800 100644 --- a/OLIDS/Testing/investigations/investigate_concept_mapping.sql +++ b/OLIDS/Testing/investigations/investigate_concept_mapping.sql @@ -1,7 +1,8 @@ /* Investigation: Concept Mapping - Run: Execute directly in Snowsight or VS Code Snowflake extension. - Set the USE DATABASE below to your ICB's OLIDS database. + Run: uv run run_tests.py --run investigations/investigate_concept_mapping.sql + Or execute directly in Snowsight — set the USE DATABASE and schema + variables below to match your ICB. For each concept field that has unmapped values, lists the distinct unmapped concept IDs with their row counts. Checks the full chain: @@ -10,14 +11,18 @@ USE DATABASE "Data_Store_OLIDS_Clinical_Validation"; -- Replace with your ICB's OLIDS database name +SET schema_masked = 'OLIDS_MASKED'; -- Change if your ICB uses a different name (e.g. OLIDS_PCD) +SET schema_common = 'OLIDS_COMMON'; +SET schema_terminology = 'OLIDS_TERMINOLOGY'; + -- Unmapped concepts per table/field with row counts WITH unmapped AS ( SELECT 'OBSERVATION' AS table_name, 'observation_source_concept_id' AS concept_field, base.observation_source_concept_id AS concept_id, COUNT(*) AS row_count, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END AS reason - FROM OLIDS_COMMON.OBSERVATION base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.observation_source_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.OBSERVATION') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.observation_source_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.observation_source_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.observation_source_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -25,9 +30,9 @@ WITH unmapped AS ( SELECT 'OBSERVATION', 'result_value_units_concept_id', base.result_value_units_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM OLIDS_COMMON.OBSERVATION base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.result_value_units_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.OBSERVATION') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.result_value_units_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.result_value_units_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.result_value_units_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -35,9 +40,9 @@ WITH unmapped AS ( SELECT 'MEDICATION_STATEMENT', 'medication_statement_source_concept_id', base.medication_statement_source_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM OLIDS_COMMON.MEDICATION_STATEMENT base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.medication_statement_source_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.medication_statement_source_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.medication_statement_source_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.medication_statement_source_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -45,9 +50,9 @@ WITH unmapped AS ( SELECT 'MEDICATION_STATEMENT', 'authorisation_type_concept_id', base.authorisation_type_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM OLIDS_COMMON.MEDICATION_STATEMENT base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.authorisation_type_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.authorisation_type_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.authorisation_type_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.authorisation_type_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -55,9 +60,9 @@ WITH unmapped AS ( SELECT 'MEDICATION_ORDER', 'medication_order_source_concept_id', base.medication_order_source_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM OLIDS_COMMON.MEDICATION_ORDER base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.medication_order_source_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.medication_order_source_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.medication_order_source_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.medication_order_source_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -65,9 +70,9 @@ WITH unmapped AS ( SELECT 'DIAGNOSTIC_ORDER', 'result_value_units_concept_id', base.result_value_units_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM OLIDS_COMMON.DIAGNOSTIC_ORDER base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.result_value_units_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.result_value_units_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.result_value_units_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.result_value_units_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -75,9 +80,9 @@ WITH unmapped AS ( SELECT 'PROCEDURE_REQUEST', 'procedure_request_source_concept_id', base.procedure_request_source_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM OLIDS_COMMON.PROCEDURE_REQUEST base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.procedure_request_source_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.procedure_request_source_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.procedure_request_source_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.procedure_request_source_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -85,9 +90,9 @@ WITH unmapped AS ( SELECT 'PROCEDURE_REQUEST', 'status_concept_id', base.status_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM OLIDS_COMMON.PROCEDURE_REQUEST base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.status_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.status_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.status_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.status_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -95,9 +100,9 @@ WITH unmapped AS ( SELECT 'REFERRAL_REQUEST', 'referral_request_priority_concept_id', base.referral_request_priority_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM OLIDS_COMMON.REFERRAL_REQUEST base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_priority_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.referral_request_priority_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.referral_request_priority_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.referral_request_priority_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -105,9 +110,9 @@ WITH unmapped AS ( SELECT 'REFERRAL_REQUEST', 'referral_request_type_concept_id', base.referral_request_type_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM OLIDS_COMMON.REFERRAL_REQUEST base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_type_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.referral_request_type_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.referral_request_type_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.referral_request_type_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -115,9 +120,9 @@ WITH unmapped AS ( SELECT 'ENCOUNTER', 'encounter_source_concept_id', base.encounter_source_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM OLIDS_COMMON.ENCOUNTER base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.encounter_source_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.ENCOUNTER') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.encounter_source_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.encounter_source_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.encounter_source_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -125,9 +130,9 @@ WITH unmapped AS ( SELECT 'ALLERGY_INTOLERANCE', 'allergy_intolerance_source_concept_id', base.allergy_intolerance_source_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM OLIDS_COMMON.ALLERGY_INTOLERANCE base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.allergy_intolerance_source_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.allergy_intolerance_source_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.allergy_intolerance_source_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.allergy_intolerance_source_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -135,9 +140,9 @@ WITH unmapped AS ( SELECT 'APPOINTMENT', 'booking_method_concept_id', base.booking_method_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM OLIDS_COMMON.APPOINTMENT base - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.booking_method_concept_id = cm.source_code_id - LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id + FROM IDENTIFIER($schema_common || '.APPOINTMENT') base + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.booking_method_concept_id = cm.source_code_id + LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id WHERE base.booking_method_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.booking_method_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END ) diff --git a/OLIDS/Testing/investigations/investigate_data_freshness.sql b/OLIDS/Testing/investigations/investigate_data_freshness.sql index dd9896a..8e2d78d 100644 --- a/OLIDS/Testing/investigations/investigate_data_freshness.sql +++ b/OLIDS/Testing/investigations/investigate_data_freshness.sql @@ -1,7 +1,8 @@ /* Investigation: Data Freshness - Run: Execute directly in Snowsight or VS Code Snowflake extension. - Set the USE DATABASE below to your ICB's OLIDS database. + Run: uv run run_tests.py --run investigations/investigate_data_freshness.sql + Or execute directly in Snowsight — set the USE DATABASE and schema + variables below to match your ICB. Shows per-org, per-table freshness: last date_recorded and days since. Ordered by stalest first to identify which orgs are behind. @@ -9,62 +10,66 @@ USE DATABASE "Data_Store_OLIDS_Clinical_Validation"; -- Replace with your ICB's OLIDS database name +SET schema_masked = 'OLIDS_MASKED'; -- Change if your ICB uses a different name (e.g. OLIDS_PCD) +SET schema_common = 'OLIDS_COMMON'; +SET schema_terminology = 'OLIDS_TERMINOLOGY'; + SET freshness_days = 5; WITH org_freshness AS ( SELECT 'OBSERVATION' AS table_name, record_owner_organisation_code AS org_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END) AS last_date_recorded, DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) AS days_since - FROM OLIDS_COMMON.OBSERVATION WHERE record_owner_organisation_code IS NOT NULL + FROM IDENTIFIER($schema_common || '.OBSERVATION') WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL SELECT 'ENCOUNTER', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM OLIDS_COMMON.ENCOUNTER WHERE record_owner_organisation_code IS NOT NULL + FROM IDENTIFIER($schema_common || '.ENCOUNTER') WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL SELECT 'MEDICATION_ORDER', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM OLIDS_COMMON.MEDICATION_ORDER WHERE record_owner_organisation_code IS NOT NULL + FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL SELECT 'MEDICATION_STATEMENT', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM OLIDS_COMMON.MEDICATION_STATEMENT WHERE record_owner_organisation_code IS NOT NULL + FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL SELECT 'DIAGNOSTIC_ORDER', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM OLIDS_COMMON.DIAGNOSTIC_ORDER WHERE record_owner_organisation_code IS NOT NULL + FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL SELECT 'ALLERGY_INTOLERANCE', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM OLIDS_COMMON.ALLERGY_INTOLERANCE WHERE record_owner_organisation_code IS NOT NULL + FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL SELECT 'PROCEDURE_REQUEST', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM OLIDS_COMMON.PROCEDURE_REQUEST WHERE record_owner_organisation_code IS NOT NULL + FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL SELECT 'REFERRAL_REQUEST', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM OLIDS_COMMON.REFERRAL_REQUEST WHERE record_owner_organisation_code IS NOT NULL + FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code ) diff --git a/OLIDS/Testing/investigations/investigate_referential_integrity.sql b/OLIDS/Testing/investigations/investigate_referential_integrity.sql index 6f354b7..ac5f033 100644 --- a/OLIDS/Testing/investigations/investigate_referential_integrity.sql +++ b/OLIDS/Testing/investigations/investigate_referential_integrity.sql @@ -1,7 +1,8 @@ /* Investigation: Referential Integrity - Run: Execute directly in Snowsight or VS Code Snowflake extension. - Set the USE DATABASE below to your ICB's OLIDS database. + Run: uv run run_tests.py --run investigations/investigate_referential_integrity.sql + Or execute directly in Snowsight — set the USE DATABASE and schema + variables below to match your ICB. For each FK relationship, shows orphaned FK values with their row counts. Helps identify whether orphans are @@ -10,11 +11,15 @@ USE DATABASE "Data_Store_OLIDS_Clinical_Validation"; -- Replace with your ICB's OLIDS database name +SET schema_masked = 'OLIDS_MASKED'; -- Change if your ICB uses a different name (e.g. OLIDS_PCD) +SET schema_common = 'OLIDS_COMMON'; +SET schema_terminology = 'OLIDS_TERMINOLOGY'; + -- ALLERGY_INTOLERANCE -> PATIENT SELECT 'ALLERGY_INTOLERANCE' AS child_table, 'patient_id' AS fk_column, 'PATIENT' AS parent_table, c.patient_id AS orphaned_value, COUNT(*) AS row_count -FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c -LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') c +LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -23,8 +28,8 @@ UNION ALL -- ALLERGY_INTOLERANCE -> PERSON SELECT 'ALLERGY_INTOLERANCE', 'person_id', 'PERSON', c.person_id, COUNT(*) -FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c -LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id +FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') c +LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id WHERE c.person_id IS NOT NULL AND p.id IS NULL GROUP BY c.person_id @@ -33,8 +38,8 @@ UNION ALL -- ALLERGY_INTOLERANCE -> ENCOUNTER SELECT 'ALLERGY_INTOLERANCE', 'encounter_id', 'ENCOUNTER', c.encounter_id, COUNT(*) -FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c -LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id +FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') c +LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id WHERE c.encounter_id IS NOT NULL AND p.id IS NULL GROUP BY c.encounter_id @@ -43,8 +48,8 @@ UNION ALL -- ALLERGY_INTOLERANCE -> PRACTITIONER SELECT 'ALLERGY_INTOLERANCE', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c -LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') c +LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -53,8 +58,8 @@ UNION ALL -- APPOINTMENT -> PATIENT SELECT 'APPOINTMENT', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM OLIDS_COMMON.APPOINTMENT c -LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +FROM IDENTIFIER($schema_common || '.APPOINTMENT') c +LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -63,8 +68,8 @@ UNION ALL -- APPOINTMENT -> PRACTITIONER_IN_ROLE SELECT 'APPOINTMENT', 'practitioner_in_role_id', 'PRACTITIONER_IN_ROLE', c.practitioner_in_role_id, COUNT(*) -FROM OLIDS_COMMON.APPOINTMENT c -LEFT JOIN OLIDS_COMMON.PRACTITIONER_IN_ROLE p ON c.practitioner_in_role_id = p.id +FROM IDENTIFIER($schema_common || '.APPOINTMENT') c +LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER_IN_ROLE') p ON c.practitioner_in_role_id = p.id WHERE c.practitioner_in_role_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_in_role_id @@ -73,8 +78,8 @@ UNION ALL -- APPOINTMENT -> SCHEDULE SELECT 'APPOINTMENT', 'schedule_id', 'SCHEDULE', c.schedule_id, COUNT(*) -FROM OLIDS_COMMON.APPOINTMENT c -LEFT JOIN OLIDS_COMMON.SCHEDULE p ON c.schedule_id = p.id +FROM IDENTIFIER($schema_common || '.APPOINTMENT') c +LEFT JOIN IDENTIFIER($schema_common || '.SCHEDULE') p ON c.schedule_id = p.id WHERE c.schedule_id IS NOT NULL AND p.id IS NULL GROUP BY c.schedule_id @@ -83,8 +88,8 @@ UNION ALL -- APPOINTMENT_PRACTITIONER -> APPOINTMENT SELECT 'APPOINTMENT_PRACTITIONER', 'appointment_id', 'APPOINTMENT', c.appointment_id, COUNT(*) -FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER c -LEFT JOIN OLIDS_COMMON.APPOINTMENT p ON c.appointment_id = p.id +FROM IDENTIFIER($schema_common || '.APPOINTMENT_PRACTITIONER') c +LEFT JOIN IDENTIFIER($schema_common || '.APPOINTMENT') p ON c.appointment_id = p.id WHERE c.appointment_id IS NOT NULL AND p.id IS NULL GROUP BY c.appointment_id @@ -93,8 +98,8 @@ UNION ALL -- APPOINTMENT_PRACTITIONER -> PRACTITIONER SELECT 'APPOINTMENT_PRACTITIONER', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER c -LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +FROM IDENTIFIER($schema_common || '.APPOINTMENT_PRACTITIONER') c +LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -103,8 +108,8 @@ UNION ALL -- DIAGNOSTIC_ORDER -> PATIENT SELECT 'DIAGNOSTIC_ORDER', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c -LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') c +LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -113,8 +118,8 @@ UNION ALL -- DIAGNOSTIC_ORDER -> PERSON SELECT 'DIAGNOSTIC_ORDER', 'person_id', 'PERSON', c.person_id, COUNT(*) -FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c -LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id +FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') c +LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id WHERE c.person_id IS NOT NULL AND p.id IS NULL GROUP BY c.person_id @@ -123,8 +128,8 @@ UNION ALL -- DIAGNOSTIC_ORDER -> ENCOUNTER SELECT 'DIAGNOSTIC_ORDER', 'encounter_id', 'ENCOUNTER', c.encounter_id, COUNT(*) -FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c -LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id +FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') c +LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id WHERE c.encounter_id IS NOT NULL AND p.id IS NULL GROUP BY c.encounter_id @@ -133,8 +138,8 @@ UNION ALL -- DIAGNOSTIC_ORDER -> PRACTITIONER SELECT 'DIAGNOSTIC_ORDER', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c -LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') c +LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -143,8 +148,8 @@ UNION ALL -- DIAGNOSTIC_ORDER -> OBSERVATION (parent) SELECT 'DIAGNOSTIC_ORDER', 'parent_observation_id', 'OBSERVATION', c.parent_observation_id, COUNT(*) -FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c -LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.parent_observation_id = p.id +FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') c +LEFT JOIN IDENTIFIER($schema_common || '.OBSERVATION') p ON c.parent_observation_id = p.id WHERE c.parent_observation_id IS NOT NULL AND p.id IS NULL GROUP BY c.parent_observation_id @@ -153,8 +158,8 @@ UNION ALL -- ENCOUNTER -> PATIENT SELECT 'ENCOUNTER', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM OLIDS_COMMON.ENCOUNTER c -LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +FROM IDENTIFIER($schema_common || '.ENCOUNTER') c +LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -163,8 +168,8 @@ UNION ALL -- ENCOUNTER -> PERSON SELECT 'ENCOUNTER', 'person_id', 'PERSON', c.person_id, COUNT(*) -FROM OLIDS_COMMON.ENCOUNTER c -LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id +FROM IDENTIFIER($schema_common || '.ENCOUNTER') c +LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id WHERE c.person_id IS NOT NULL AND p.id IS NULL GROUP BY c.person_id @@ -173,8 +178,8 @@ UNION ALL -- ENCOUNTER -> PRACTITIONER SELECT 'ENCOUNTER', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM OLIDS_COMMON.ENCOUNTER c -LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +FROM IDENTIFIER($schema_common || '.ENCOUNTER') c +LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -183,8 +188,8 @@ UNION ALL -- ENCOUNTER -> EPISODE_OF_CARE SELECT 'ENCOUNTER', 'episode_of_care_id', 'EPISODE_OF_CARE', c.episode_of_care_id, COUNT(*) -FROM OLIDS_COMMON.ENCOUNTER c -LEFT JOIN OLIDS_COMMON.EPISODE_OF_CARE p ON c.episode_of_care_id = p.id +FROM IDENTIFIER($schema_common || '.ENCOUNTER') c +LEFT JOIN IDENTIFIER($schema_common || '.EPISODE_OF_CARE') p ON c.episode_of_care_id = p.id WHERE c.episode_of_care_id IS NOT NULL AND p.id IS NULL GROUP BY c.episode_of_care_id @@ -193,8 +198,8 @@ UNION ALL -- ENCOUNTER -> APPOINTMENT SELECT 'ENCOUNTER', 'appointment_id', 'APPOINTMENT', c.appointment_id, COUNT(*) -FROM OLIDS_COMMON.ENCOUNTER c -LEFT JOIN OLIDS_COMMON.APPOINTMENT p ON c.appointment_id = p.id +FROM IDENTIFIER($schema_common || '.ENCOUNTER') c +LEFT JOIN IDENTIFIER($schema_common || '.APPOINTMENT') p ON c.appointment_id = p.id WHERE c.appointment_id IS NOT NULL AND p.id IS NULL GROUP BY c.appointment_id @@ -203,8 +208,8 @@ UNION ALL -- ENCOUNTER -> ORGANISATION (service provider) SELECT 'ENCOUNTER', 'service_provider_organisation_id', 'ORGANISATION', c.service_provider_organisation_id, COUNT(*) -FROM OLIDS_COMMON.ENCOUNTER c -LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.service_provider_organisation_id = p.id +FROM IDENTIFIER($schema_common || '.ENCOUNTER') c +LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.service_provider_organisation_id = p.id WHERE c.service_provider_organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.service_provider_organisation_id @@ -213,8 +218,8 @@ UNION ALL -- EPISODE_OF_CARE -> PATIENT SELECT 'EPISODE_OF_CARE', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM OLIDS_COMMON.EPISODE_OF_CARE c -LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') c +LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -223,8 +228,8 @@ UNION ALL -- EPISODE_OF_CARE -> PERSON SELECT 'EPISODE_OF_CARE', 'person_id', 'PERSON', c.person_id, COUNT(*) -FROM OLIDS_COMMON.EPISODE_OF_CARE c -LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id +FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') c +LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id WHERE c.person_id IS NOT NULL AND p.id IS NULL GROUP BY c.person_id @@ -233,8 +238,8 @@ UNION ALL -- EPISODE_OF_CARE -> ORGANISATION SELECT 'EPISODE_OF_CARE', 'organisation_id', 'ORGANISATION', c.organisation_id, COUNT(*) -FROM OLIDS_COMMON.EPISODE_OF_CARE c -LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id +FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') c +LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id WHERE c.organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.organisation_id @@ -243,8 +248,8 @@ UNION ALL -- EPISODE_OF_CARE -> PRACTITIONER (care manager) SELECT 'EPISODE_OF_CARE', 'care_manager_practitioner_id', 'PRACTITIONER', c.care_manager_practitioner_id, COUNT(*) -FROM OLIDS_COMMON.EPISODE_OF_CARE c -LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.care_manager_practitioner_id = p.id +FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') c +LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.care_manager_practitioner_id = p.id WHERE c.care_manager_practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.care_manager_practitioner_id @@ -253,8 +258,8 @@ UNION ALL -- FLAG -> PATIENT SELECT 'FLAG', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM OLIDS_COMMON.FLAG c -LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +FROM IDENTIFIER($schema_common || '.FLAG') c +LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -263,8 +268,8 @@ UNION ALL -- LOCATION -> ORGANISATION (managing) SELECT 'LOCATION', 'managing_organisation_id', 'ORGANISATION', c.managing_organisation_id, COUNT(*) -FROM OLIDS_COMMON.LOCATION c -LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.managing_organisation_id = p.id +FROM IDENTIFIER($schema_common || '.LOCATION') c +LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.managing_organisation_id = p.id WHERE c.managing_organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.managing_organisation_id @@ -273,8 +278,8 @@ UNION ALL -- LOCATION_CONTACT -> LOCATION SELECT 'LOCATION_CONTACT', 'location_id', 'LOCATION', c.location_id, COUNT(*) -FROM OLIDS_COMMON.LOCATION_CONTACT c -LEFT JOIN OLIDS_COMMON.LOCATION p ON c.location_id = p.id +FROM IDENTIFIER($schema_common || '.LOCATION_CONTACT') c +LEFT JOIN IDENTIFIER($schema_common || '.LOCATION') p ON c.location_id = p.id WHERE c.location_id IS NOT NULL AND p.id IS NULL GROUP BY c.location_id @@ -283,8 +288,8 @@ UNION ALL -- MEDICATION_ORDER -> PATIENT SELECT 'MEDICATION_ORDER', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_ORDER c -LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c +LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -293,8 +298,8 @@ UNION ALL -- MEDICATION_ORDER -> PERSON SELECT 'MEDICATION_ORDER', 'person_id', 'PERSON', c.person_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_ORDER c -LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id +FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c +LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id WHERE c.person_id IS NOT NULL AND p.id IS NULL GROUP BY c.person_id @@ -303,8 +308,8 @@ UNION ALL -- MEDICATION_ORDER -> MEDICATION_STATEMENT SELECT 'MEDICATION_ORDER', 'medication_statement_id', 'MEDICATION_STATEMENT', c.medication_statement_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_ORDER c -LEFT JOIN OLIDS_COMMON.MEDICATION_STATEMENT p ON c.medication_statement_id = p.id +FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c +LEFT JOIN IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') p ON c.medication_statement_id = p.id WHERE c.medication_statement_id IS NOT NULL AND p.id IS NULL GROUP BY c.medication_statement_id @@ -313,8 +318,8 @@ UNION ALL -- MEDICATION_ORDER -> ORGANISATION SELECT 'MEDICATION_ORDER', 'organisation_id', 'ORGANISATION', c.organisation_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_ORDER c -LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id +FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c +LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id WHERE c.organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.organisation_id @@ -323,8 +328,8 @@ UNION ALL -- MEDICATION_ORDER -> ENCOUNTER SELECT 'MEDICATION_ORDER', 'encounter_id', 'ENCOUNTER', c.encounter_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_ORDER c -LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id +FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c +LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id WHERE c.encounter_id IS NOT NULL AND p.id IS NULL GROUP BY c.encounter_id @@ -333,8 +338,8 @@ UNION ALL -- MEDICATION_ORDER -> PRACTITIONER SELECT 'MEDICATION_ORDER', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_ORDER c -LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c +LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -343,8 +348,8 @@ UNION ALL -- MEDICATION_ORDER -> OBSERVATION SELECT 'MEDICATION_ORDER', 'observation_id', 'OBSERVATION', c.observation_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_ORDER c -LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.observation_id = p.id +FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c +LEFT JOIN IDENTIFIER($schema_common || '.OBSERVATION') p ON c.observation_id = p.id WHERE c.observation_id IS NOT NULL AND p.id IS NULL GROUP BY c.observation_id @@ -353,8 +358,8 @@ UNION ALL -- MEDICATION_ORDER -> ALLERGY_INTOLERANCE SELECT 'MEDICATION_ORDER', 'allergy_intolerance_id', 'ALLERGY_INTOLERANCE', c.allergy_intolerance_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_ORDER c -LEFT JOIN OLIDS_COMMON.ALLERGY_INTOLERANCE p ON c.allergy_intolerance_id = p.id +FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c +LEFT JOIN IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') p ON c.allergy_intolerance_id = p.id WHERE c.allergy_intolerance_id IS NOT NULL AND p.id IS NULL GROUP BY c.allergy_intolerance_id @@ -363,8 +368,8 @@ UNION ALL -- MEDICATION_ORDER -> DIAGNOSTIC_ORDER SELECT 'MEDICATION_ORDER', 'diagnostic_order_id', 'DIAGNOSTIC_ORDER', c.diagnostic_order_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_ORDER c -LEFT JOIN OLIDS_COMMON.DIAGNOSTIC_ORDER p ON c.diagnostic_order_id = p.id +FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c +LEFT JOIN IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') p ON c.diagnostic_order_id = p.id WHERE c.diagnostic_order_id IS NOT NULL AND p.id IS NULL GROUP BY c.diagnostic_order_id @@ -373,8 +378,8 @@ UNION ALL -- MEDICATION_ORDER -> REFERRAL_REQUEST SELECT 'MEDICATION_ORDER', 'referral_request_id', 'REFERRAL_REQUEST', c.referral_request_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_ORDER c -LEFT JOIN OLIDS_COMMON.REFERRAL_REQUEST p ON c.referral_request_id = p.id +FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c +LEFT JOIN IDENTIFIER($schema_common || '.REFERRAL_REQUEST') p ON c.referral_request_id = p.id WHERE c.referral_request_id IS NOT NULL AND p.id IS NULL GROUP BY c.referral_request_id @@ -383,8 +388,8 @@ UNION ALL -- MEDICATION_STATEMENT -> PATIENT SELECT 'MEDICATION_STATEMENT', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_STATEMENT c -LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c +LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -393,8 +398,8 @@ UNION ALL -- MEDICATION_STATEMENT -> PERSON SELECT 'MEDICATION_STATEMENT', 'person_id', 'PERSON', c.person_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_STATEMENT c -LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id +FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c +LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id WHERE c.person_id IS NOT NULL AND p.id IS NULL GROUP BY c.person_id @@ -403,8 +408,8 @@ UNION ALL -- MEDICATION_STATEMENT -> ORGANISATION SELECT 'MEDICATION_STATEMENT', 'organisation_id', 'ORGANISATION', c.organisation_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_STATEMENT c -LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id +FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c +LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id WHERE c.organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.organisation_id @@ -413,8 +418,8 @@ UNION ALL -- MEDICATION_STATEMENT -> ENCOUNTER SELECT 'MEDICATION_STATEMENT', 'encounter_id', 'ENCOUNTER', c.encounter_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_STATEMENT c -LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id +FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c +LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id WHERE c.encounter_id IS NOT NULL AND p.id IS NULL GROUP BY c.encounter_id @@ -423,8 +428,8 @@ UNION ALL -- MEDICATION_STATEMENT -> PRACTITIONER SELECT 'MEDICATION_STATEMENT', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_STATEMENT c -LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c +LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -433,8 +438,8 @@ UNION ALL -- MEDICATION_STATEMENT -> OBSERVATION SELECT 'MEDICATION_STATEMENT', 'observation_id', 'OBSERVATION', c.observation_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_STATEMENT c -LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.observation_id = p.id +FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c +LEFT JOIN IDENTIFIER($schema_common || '.OBSERVATION') p ON c.observation_id = p.id WHERE c.observation_id IS NOT NULL AND p.id IS NULL GROUP BY c.observation_id @@ -443,8 +448,8 @@ UNION ALL -- MEDICATION_STATEMENT -> ALLERGY_INTOLERANCE SELECT 'MEDICATION_STATEMENT', 'allergy_intolerance_id', 'ALLERGY_INTOLERANCE', c.allergy_intolerance_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_STATEMENT c -LEFT JOIN OLIDS_COMMON.ALLERGY_INTOLERANCE p ON c.allergy_intolerance_id = p.id +FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c +LEFT JOIN IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') p ON c.allergy_intolerance_id = p.id WHERE c.allergy_intolerance_id IS NOT NULL AND p.id IS NULL GROUP BY c.allergy_intolerance_id @@ -453,8 +458,8 @@ UNION ALL -- MEDICATION_STATEMENT -> DIAGNOSTIC_ORDER SELECT 'MEDICATION_STATEMENT', 'diagnostic_order_id', 'DIAGNOSTIC_ORDER', c.diagnostic_order_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_STATEMENT c -LEFT JOIN OLIDS_COMMON.DIAGNOSTIC_ORDER p ON c.diagnostic_order_id = p.id +FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c +LEFT JOIN IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') p ON c.diagnostic_order_id = p.id WHERE c.diagnostic_order_id IS NOT NULL AND p.id IS NULL GROUP BY c.diagnostic_order_id @@ -463,8 +468,8 @@ UNION ALL -- MEDICATION_STATEMENT -> REFERRAL_REQUEST SELECT 'MEDICATION_STATEMENT', 'referral_request_id', 'REFERRAL_REQUEST', c.referral_request_id, COUNT(*) -FROM OLIDS_COMMON.MEDICATION_STATEMENT c -LEFT JOIN OLIDS_COMMON.REFERRAL_REQUEST p ON c.referral_request_id = p.id +FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c +LEFT JOIN IDENTIFIER($schema_common || '.REFERRAL_REQUEST') p ON c.referral_request_id = p.id WHERE c.referral_request_id IS NOT NULL AND p.id IS NULL GROUP BY c.referral_request_id @@ -473,8 +478,8 @@ UNION ALL -- OBSERVATION -> PATIENT SELECT 'OBSERVATION', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM OLIDS_COMMON.OBSERVATION c -LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +FROM IDENTIFIER($schema_common || '.OBSERVATION') c +LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -483,8 +488,8 @@ UNION ALL -- OBSERVATION -> PERSON SELECT 'OBSERVATION', 'person_id', 'PERSON', c.person_id, COUNT(*) -FROM OLIDS_COMMON.OBSERVATION c -LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id +FROM IDENTIFIER($schema_common || '.OBSERVATION') c +LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id WHERE c.person_id IS NOT NULL AND p.id IS NULL GROUP BY c.person_id @@ -493,8 +498,8 @@ UNION ALL -- OBSERVATION -> ENCOUNTER SELECT 'OBSERVATION', 'encounter_id', 'ENCOUNTER', c.encounter_id, COUNT(*) -FROM OLIDS_COMMON.OBSERVATION c -LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id +FROM IDENTIFIER($schema_common || '.OBSERVATION') c +LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id WHERE c.encounter_id IS NOT NULL AND p.id IS NULL GROUP BY c.encounter_id @@ -503,8 +508,8 @@ UNION ALL -- OBSERVATION -> PRACTITIONER SELECT 'OBSERVATION', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM OLIDS_COMMON.OBSERVATION c -LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +FROM IDENTIFIER($schema_common || '.OBSERVATION') c +LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -513,8 +518,8 @@ UNION ALL -- OBSERVATION -> OBSERVATION (parent) SELECT 'OBSERVATION', 'parent_observation_id', 'OBSERVATION', c.parent_observation_id, COUNT(*) -FROM OLIDS_COMMON.OBSERVATION c -LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.parent_observation_id = p.id +FROM IDENTIFIER($schema_common || '.OBSERVATION') c +LEFT JOIN IDENTIFIER($schema_common || '.OBSERVATION') p ON c.parent_observation_id = p.id WHERE c.parent_observation_id IS NOT NULL AND p.id IS NULL GROUP BY c.parent_observation_id @@ -523,8 +528,8 @@ UNION ALL -- ORGANISATION -> ORGANISATION (parent) SELECT 'ORGANISATION', 'parent_organisation_id', 'ORGANISATION', c.parent_organisation_id, COUNT(*) -FROM OLIDS_COMMON.ORGANISATION c -LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.parent_organisation_id = p.id +FROM IDENTIFIER($schema_common || '.ORGANISATION') c +LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.parent_organisation_id = p.id WHERE c.parent_organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.parent_organisation_id @@ -533,8 +538,8 @@ UNION ALL -- PATIENT -> ORGANISATION (registered practice) SELECT 'PATIENT', 'registered_practice_id', 'ORGANISATION', c.registered_practice_id, COUNT(*) -FROM OLIDS_MASKED.PATIENT c -LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.registered_practice_id = p.id +FROM IDENTIFIER($schema_masked || '.PATIENT') c +LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.registered_practice_id = p.id WHERE c.registered_practice_id IS NOT NULL AND p.id IS NULL GROUP BY c.registered_practice_id @@ -543,8 +548,8 @@ UNION ALL -- PATIENT_ADDRESS -> PATIENT SELECT 'PATIENT_ADDRESS', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM OLIDS_MASKED.PATIENT_ADDRESS c -LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +FROM IDENTIFIER($schema_masked || '.PATIENT_ADDRESS') c +LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -553,8 +558,8 @@ UNION ALL -- PATIENT_CONTACT -> PATIENT SELECT 'PATIENT_CONTACT', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM OLIDS_MASKED.PATIENT_CONTACT c -LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +FROM IDENTIFIER($schema_masked || '.PATIENT_CONTACT') c +LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -563,8 +568,8 @@ UNION ALL -- PATIENT_PERSON -> PATIENT SELECT 'PATIENT_PERSON', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM OLIDS_COMMON.PATIENT_PERSON c -LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +FROM IDENTIFIER($schema_common || '.PATIENT_PERSON') c +LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -573,8 +578,8 @@ UNION ALL -- PATIENT_PERSON -> PERSON SELECT 'PATIENT_PERSON', 'person_id', 'PERSON', c.person_id, COUNT(*) -FROM OLIDS_COMMON.PATIENT_PERSON c -LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id +FROM IDENTIFIER($schema_common || '.PATIENT_PERSON') c +LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id WHERE c.person_id IS NOT NULL AND p.id IS NULL GROUP BY c.person_id @@ -583,8 +588,8 @@ UNION ALL -- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE -> PATIENT SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c -LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') c +LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -593,8 +598,8 @@ UNION ALL -- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE -> ORGANISATION SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'organisation_id', 'ORGANISATION', c.organisation_id, COUNT(*) -FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c -LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id +FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') c +LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id WHERE c.organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.organisation_id @@ -603,8 +608,8 @@ UNION ALL -- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE -> PRACTITIONER SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c -LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') c +LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -613,8 +618,8 @@ UNION ALL -- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE -> EPISODE_OF_CARE SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'episode_of_care_id', 'EPISODE_OF_CARE', c.episode_of_care_id, COUNT(*) -FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c -LEFT JOIN OLIDS_COMMON.EPISODE_OF_CARE p ON c.episode_of_care_id = p.id +FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') c +LEFT JOIN IDENTIFIER($schema_common || '.EPISODE_OF_CARE') p ON c.episode_of_care_id = p.id WHERE c.episode_of_care_id IS NOT NULL AND p.id IS NULL GROUP BY c.episode_of_care_id @@ -623,8 +628,8 @@ UNION ALL -- PRACTITIONER_IN_ROLE -> PRACTITIONER SELECT 'PRACTITIONER_IN_ROLE', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE c -LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +FROM IDENTIFIER($schema_common || '.PRACTITIONER_IN_ROLE') c +LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -633,8 +638,8 @@ UNION ALL -- PRACTITIONER_IN_ROLE -> ORGANISATION SELECT 'PRACTITIONER_IN_ROLE', 'organisation_id', 'ORGANISATION', c.organisation_id, COUNT(*) -FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE c -LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id +FROM IDENTIFIER($schema_common || '.PRACTITIONER_IN_ROLE') c +LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id WHERE c.organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.organisation_id @@ -643,8 +648,8 @@ UNION ALL -- PROCEDURE_REQUEST -> PATIENT SELECT 'PROCEDURE_REQUEST', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM OLIDS_COMMON.PROCEDURE_REQUEST c -LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') c +LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -653,8 +658,8 @@ UNION ALL -- PROCEDURE_REQUEST -> ENCOUNTER SELECT 'PROCEDURE_REQUEST', 'encounter_id', 'ENCOUNTER', c.encounter_id, COUNT(*) -FROM OLIDS_COMMON.PROCEDURE_REQUEST c -LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id +FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') c +LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id WHERE c.encounter_id IS NOT NULL AND p.id IS NULL GROUP BY c.encounter_id @@ -663,8 +668,8 @@ UNION ALL -- PROCEDURE_REQUEST -> PRACTITIONER SELECT 'PROCEDURE_REQUEST', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM OLIDS_COMMON.PROCEDURE_REQUEST c -LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') c +LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -673,8 +678,8 @@ UNION ALL -- REFERRAL_REQUEST -> PATIENT SELECT 'REFERRAL_REQUEST', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM OLIDS_COMMON.REFERRAL_REQUEST c -LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id +FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c +LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -683,8 +688,8 @@ UNION ALL -- REFERRAL_REQUEST -> ENCOUNTER SELECT 'REFERRAL_REQUEST', 'encounter_id', 'ENCOUNTER', c.encounter_id, COUNT(*) -FROM OLIDS_COMMON.REFERRAL_REQUEST c -LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id +FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c +LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id WHERE c.encounter_id IS NOT NULL AND p.id IS NULL GROUP BY c.encounter_id @@ -693,8 +698,8 @@ UNION ALL -- REFERRAL_REQUEST -> PRACTITIONER SELECT 'REFERRAL_REQUEST', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM OLIDS_COMMON.REFERRAL_REQUEST c -LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c +LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -703,8 +708,8 @@ UNION ALL -- REFERRAL_REQUEST -> ORGANISATION SELECT 'REFERRAL_REQUEST', 'organisation_id', 'ORGANISATION', c.organisation_id, COUNT(*) -FROM OLIDS_COMMON.REFERRAL_REQUEST c -LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id +FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c +LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id WHERE c.organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.organisation_id @@ -713,8 +718,8 @@ UNION ALL -- REFERRAL_REQUEST -> ORGANISATION (requester) SELECT 'REFERRAL_REQUEST', 'requester_organisation_id', 'ORGANISATION', c.requester_organisation_id, COUNT(*) -FROM OLIDS_COMMON.REFERRAL_REQUEST c -LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.requester_organisation_id = p.id +FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c +LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.requester_organisation_id = p.id WHERE c.requester_organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.requester_organisation_id @@ -723,8 +728,8 @@ UNION ALL -- REFERRAL_REQUEST -> ORGANISATION (recipient) SELECT 'REFERRAL_REQUEST', 'recipient_organisation_id', 'ORGANISATION', c.recipient_organisation_id, COUNT(*) -FROM OLIDS_COMMON.REFERRAL_REQUEST c -LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.recipient_organisation_id = p.id +FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c +LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.recipient_organisation_id = p.id WHERE c.recipient_organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.recipient_organisation_id @@ -733,8 +738,8 @@ UNION ALL -- SCHEDULE -> LOCATION SELECT 'SCHEDULE', 'location_id', 'LOCATION', c.location_id, COUNT(*) -FROM OLIDS_COMMON.SCHEDULE c -LEFT JOIN OLIDS_COMMON.LOCATION p ON c.location_id = p.id +FROM IDENTIFIER($schema_common || '.SCHEDULE') c +LEFT JOIN IDENTIFIER($schema_common || '.LOCATION') p ON c.location_id = p.id WHERE c.location_id IS NOT NULL AND p.id IS NULL GROUP BY c.location_id @@ -743,8 +748,8 @@ UNION ALL -- SCHEDULE -> PRACTITIONER SELECT 'SCHEDULE', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM OLIDS_COMMON.SCHEDULE c -LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +FROM IDENTIFIER($schema_common || '.SCHEDULE') c +LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -753,8 +758,8 @@ UNION ALL -- SCHEDULE_PRACTITIONER -> SCHEDULE SELECT 'SCHEDULE_PRACTITIONER', 'schedule_id', 'SCHEDULE', c.schedule_id, COUNT(*) -FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER c -LEFT JOIN OLIDS_COMMON.SCHEDULE p ON c.schedule_id = p.id +FROM IDENTIFIER($schema_common || '.SCHEDULE_PRACTITIONER') c +LEFT JOIN IDENTIFIER($schema_common || '.SCHEDULE') p ON c.schedule_id = p.id WHERE c.schedule_id IS NOT NULL AND p.id IS NULL GROUP BY c.schedule_id @@ -763,8 +768,8 @@ UNION ALL -- SCHEDULE_PRACTITIONER -> PRACTITIONER SELECT 'SCHEDULE_PRACTITIONER', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER c -LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id +FROM IDENTIFIER($schema_common || '.SCHEDULE_PRACTITIONER') c +LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id diff --git a/OLIDS/Testing/investigations/investigate_registration_pds.sql b/OLIDS/Testing/investigations/investigate_registration_pds.sql index 1dc75bc..01184f8 100644 --- a/OLIDS/Testing/investigations/investigate_registration_pds.sql +++ b/OLIDS/Testing/investigations/investigate_registration_pds.sql @@ -1,7 +1,8 @@ /* Investigation: Registration PDS Comparison - Run: Execute directly in Snowsight or VS Code Snowflake extension. - Set the USE DATABASE below to your ICB's OLIDS database. + Run: uv run run_tests.py --run investigations/investigate_registration_pds.sql + Or execute directly in Snowsight — set the USE DATABASE and schema + variables below to match your ICB. Shows per-practice comparison of OLIDS vs PDS registration counts. Reuses the same methodology as test_registration_pds.sql. @@ -10,6 +11,10 @@ USE DATABASE "Data_Store_OLIDS_Clinical_Validation"; -- Replace with your ICB's OLIDS database name +SET schema_masked = 'OLIDS_MASKED'; -- Change if your ICB uses a different name (e.g. OLIDS_PCD) +SET schema_common = 'OLIDS_COMMON'; +SET schema_terminology = 'OLIDS_TERMINOLOGY'; + -- Snapshot date: the most recent month-end that OLIDS data covers. -- PDS updates at month-ends, so we snap to a month boundary for accurate comparison. -- Uses MAX(episode_of_care_start_date) as the freshness indicator. Future dates excluded. @@ -17,20 +22,20 @@ SET snapshot_date = ( SELECT LAST_DAY(DATEADD(MONTH, -1, DATEADD(DAY, 1, MAX(CASE WHEN episode_of_care_start_date <= CURRENT_DATE THEN episode_of_care_start_date END)::DATE ))) - FROM OLIDS_COMMON.EPISODE_OF_CARE + FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') WHERE record_owner_organisation_code IS NOT NULL ); -- Practice codes derived from EPISODE_OF_CARE (only practices with actual data) WITH icb_practices AS ( SELECT DISTINCT record_owner_organisation_code AS practice_code - FROM OLIDS_COMMON.EPISODE_OF_CARE + FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') WHERE record_owner_organisation_code IS NOT NULL ), eligible_patients AS ( SELECT id AS patient_id, sk_patient_id, death_year, death_month - FROM OLIDS_MASKED.PATIENT + FROM IDENTIFIER($schema_masked || '.PATIENT') WHERE sk_patient_id IS NOT NULL AND is_spine_sensitive = FALSE AND is_confidential = FALSE @@ -54,23 +59,23 @@ patient_death_dates AS ( patient_to_person AS ( SELECT patient_id, person_id - FROM OLIDS_COMMON.PATIENT_PERSON + FROM IDENTIFIER($schema_common || '.PATIENT_PERSON') WHERE patient_id IS NOT NULL AND person_id IS NOT NULL ), episode_type_regular AS ( - SELECT source_code_id FROM OLIDS_TERMINOLOGY.CONCEPT_MAP WHERE source_code = 'Regular' + SELECT source_code_id FROM IDENTIFIER($schema_terminology || '.CONCEPT_MAP') WHERE source_code = 'Regular' ), episode_status_left AS ( - SELECT source_code_id FROM OLIDS_TERMINOLOGY.CONCEPT_MAP WHERE source_code = 'Left' + SELECT source_code_id FROM IDENTIFIER($schema_terminology || '.CONCEPT_MAP') WHERE source_code = 'Left' ), filtered_episodes AS ( SELECT eoc.id AS episode_id, ptp.person_id, eoc.record_owner_organisation_code AS practice_code, eoc.organisation_id, eoc.episode_of_care_start_date - FROM OLIDS_COMMON.EPISODE_OF_CARE eoc + FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') eoc INNER JOIN patient_death_dates pdd ON eoc.patient_id = pdd.patient_id INNER JOIN patient_to_person ptp ON eoc.patient_id = ptp.patient_id INNER JOIN episode_type_regular etr ON eoc.episode_type_source_concept_id = etr.source_code_id diff --git a/OLIDS/Testing/run_tests.py b/OLIDS/Testing/run_tests.py index 821407b..3ebc6c6 100644 --- a/OLIDS/Testing/run_tests.py +++ b/OLIDS/Testing/run_tests.py @@ -4,11 +4,14 @@ Discovers and executes test_*.sql files against Snowflake. Database context is set from SNOWFLAKE_DATABASE in .env. +Schema names (OLIDS_MASKED, OLIDS_COMMON, OLIDS_TERMINOLOGY) are +auto-detected from INFORMATION_SCHEMA and remapped at runtime. Usage: uv run run_tests.py uv run run_tests.py --test test_data_freshness uv run run_tests.py --verbose + uv run run_tests.py --run investigations/investigate_column_completeness.sql """ import os @@ -52,7 +55,7 @@ def validate_config(): missing.append(var) if missing: print(f"ERROR: Missing environment variables: {', '.join(missing)}") - print("Run setup.ps1 or copy .env.example to .env and fill in your credentials.") + print("Run setup.ps1 (Windows) or setup.sh (macOS/Linux), or copy .env.example to .env.") sys.exit(1) @@ -88,6 +91,94 @@ def discover_tests(test_dir: Path, specific_test: str = None) -> list: return tests +# Known tables per default schema. Used to auto-detect actual schema names +# by querying INFORMATION_SCHEMA. All tables in a group must resolve to the +# same actual schema; detection fails if they don't. +SCHEMA_TABLES = { + 'OLIDS_MASKED': [ + 'PATIENT', 'PERSON', 'PATIENT_ADDRESS', 'PATIENT_CONTACT', 'PATIENT_UPRN', + ], + 'OLIDS_COMMON': [ + 'ALLERGY_INTOLERANCE', 'APPOINTMENT', 'APPOINTMENT_PRACTITIONER', + 'DIAGNOSTIC_ORDER', 'ENCOUNTER', 'EPISODE_OF_CARE', 'FLAG', 'LOCATION', + 'LOCATION_CONTACT', 'MEDICATION_ORDER', 'MEDICATION_STATEMENT', + 'OBSERVATION', 'ORGANISATION', 'PATIENT_PERSON', + 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'PRACTITIONER', + 'PRACTITIONER_IN_ROLE', 'PROCEDURE_REQUEST', 'REFERRAL_REQUEST', + 'SCHEDULE', 'SCHEDULE_PRACTITIONER', + ], + 'OLIDS_TERMINOLOGY': [ + 'CONCEPT', 'CONCEPT_MAP', + ], +} + + +def detect_schemas(conn, database: str) -> dict: + """Auto-detect schema names by querying INFORMATION_SCHEMA for known tables. + + Returns a map from default name to actual name, e.g. + {'OLIDS_MASKED': 'OLIDS_PCD', 'OLIDS_COMMON': 'OLIDS_COMMON', ...} + """ + # Reverse map: table name -> default schema + table_to_default = {} + for default_schema, tables in SCHEMA_TABLES.items(): + for table in tables: + table_to_default[table] = default_schema + + all_tables = list(table_to_default.keys()) + placeholders = ','.join(f"'{t}'" for t in all_tables) + query = ( + f"SELECT TABLE_SCHEMA, TABLE_NAME " + f"FROM INFORMATION_SCHEMA.TABLES " + f"WHERE TABLE_NAME IN ({placeholders})" + ) + + if USE_SNOWPARK: + rows = conn.sql(query).collect() + results = [(r['TABLE_SCHEMA'], r['TABLE_NAME']) for r in rows] + else: + cursor = conn.cursor() + try: + cursor.execute(query) + results = cursor.fetchall() + finally: + cursor.close() + + # For each default schema, collect the actual schema(s) its tables appear in + default_to_actuals = {ds: set() for ds in SCHEMA_TABLES} + for schema, table in results: + default = table_to_default.get(table) + if default: + default_to_actuals[default].add(schema) + + schema_map = {} + for default_name, actual_schemas in default_to_actuals.items(): + if not actual_schemas: + print(f"ERROR: No tables found for schema '{default_name}' in database '{database}'.") + print(f" Expected tables: {', '.join(SCHEMA_TABLES[default_name][:5])}...") + sys.exit(1) + if len(actual_schemas) > 1: + print(f"ERROR: Tables for '{default_name}' found in multiple schemas: " + f"{', '.join(sorted(actual_schemas))}") + sys.exit(1) + schema_map[default_name] = actual_schemas.pop() + + return schema_map + + +def apply_schema_map(sql: str, schema_map: dict) -> str: + """Replace default schema names in SQL with the detected actual names. + + Handles both direct references (OLIDS_MASKED.TABLE in test files) and + SET variable values ('OLIDS_MASKED' in investigation files). + """ + for default_name, actual_name in schema_map.items(): + if default_name != actual_name: + sql = sql.replace(f'{default_name}.', f'{actual_name}.') + sql = sql.replace(f"'{default_name}'", f"'{actual_name}'") + return sql + + def split_statements(sql: str) -> list: """Split SQL into individual statements, skipping empty/comment-only ones.""" statements = [] @@ -103,13 +194,24 @@ def split_statements(sql: str) -> list: return statements -def execute_test(conn, sql_file: Path, database: str) -> list: - """Execute USE DATABASE then the test SQL, returning result rows as dicts.""" +def execute_sql(conn, sql_file: Path, database: str, schema_map: dict = None) -> list: + """Execute USE DATABASE then the SQL file, returning result rows as dicts. + + Strips any USE DATABASE statements from the file (the runner controls database + context via .env), and applies schema name remapping before execution. + """ preamble = f'USE DATABASE "{database}"' sql = sql_file.read_text(encoding='utf-8') + if schema_map: + sql = apply_schema_map(sql, schema_map) full_sql = preamble + ';\n' + sql statements = split_statements(full_sql) + # Strip USE DATABASE/SCHEMA statements from the file; the preamble handles context + statements = [statements[0]] + [ + s for s in statements[1:] + if not s.strip().upper().startswith(('USE DATABASE', 'USE SCHEMA')) + ] if not statements: return [] @@ -159,6 +261,26 @@ def _extra_columns(row: dict) -> dict: return {k: v for k, v in row.items() if k not in STANDARD_COLUMNS} +def print_query_results(results: list): + """Print query results as a formatted table (for --run mode).""" + if not results: + print("No results returned.") + return + columns = list(results[0].keys()) + col_widths = {} + for col in columns: + values = [str(r.get(col, '')) for r in results] + col_widths[col] = min(max(len(col), max((len(v) for v in values), default=0)), 40) + header = ' | '.join(col.ljust(col_widths[col])[:col_widths[col]] for col in columns) + separator = '-+-'.join('-' * col_widths[col] for col in columns) + print(header) + print(separator) + for r in results: + row = ' | '.join(str(r.get(col, '')).ljust(col_widths[col])[:col_widths[col]] for col in columns) + print(row) + print(f"\n{len(results)} row(s)") + + def print_results(all_results: dict, durations: dict = None, verbose: bool = False): """Print formatted test results to console.""" total_tests = 0 @@ -253,26 +375,39 @@ def main(): parser.add_argument('--dir', '-d', default='data-quality', help='Test subdirectory (default: data-quality)') parser.add_argument('--test', '-t', help='Run specific test file only') + parser.add_argument('--run', '-r', help='Execute any SQL file with schema replacement and print results') parser.add_argument('--verbose', '-v', action='store_true', help='Show detailed output') args = parser.parse_args() validate_config() - # Find tests - test_dir = Path(__file__).parent / args.dir - if not test_dir.exists(): - print(f"ERROR: Test directory not found: {test_dir}") - sys.exit(1) + run_file = None + if args.run: + run_path = Path(args.run) + if not run_path.is_absolute(): + run_path = Path(__file__).parent / run_path + if not run_path.exists(): + print(f"ERROR: SQL file not found: {args.run}") + sys.exit(1) + run_file = run_path + + # Find tests (skip when using --run) + tests = [] + if not run_file: + test_dir = Path(__file__).parent / args.dir + if not test_dir.exists(): + print(f"ERROR: Test directory not found: {test_dir}") + sys.exit(1) - tests = discover_tests(test_dir, args.test) + tests = discover_tests(test_dir, args.test) - if not tests: - print(f"No test files found (test_*.sql) in {test_dir}") - sys.exit(1) + if not tests: + print(f"No test files found (test_*.sql) in {test_dir}") + sys.exit(1) - print(f"Found {len(tests)} test file(s)") - for t in tests: - print(f" - {t.name}") + print(f"Found {len(tests)} test file(s)") + for t in tests: + print(f" - {t.name}") # Connect to Snowflake print("\nConnecting to Snowflake...") @@ -283,6 +418,48 @@ def main(): print(f"ERROR: Failed to connect: {e}") sys.exit(1) + # Detect schema names + print("\nDetecting schemas...") + try: + use_db_stmt = f'USE DATABASE "{DATABASE}"' + if USE_SNOWPARK: + conn.sql(use_db_stmt).collect() + else: + cursor = conn.cursor() + try: + cursor.execute(use_db_stmt) + finally: + cursor.close() + except Exception as e: + print(f"ERROR: Failed to set database '{DATABASE}': {e}") + print("Check SNOWFLAKE_DATABASE in .env is correct and your role has access.") + conn.close() + sys.exit(1) + + schema_map = detect_schemas(conn, DATABASE) + remapped = {k: v for k, v in schema_map.items() if k != v} + if remapped: + print("Schema mapping:") + for default, actual in schema_map.items(): + label = f" (remapped from {default})" if default != actual else "" + print(f" {actual}{label}") + else: + print(f"Schemas: {', '.join(schema_map.values())}") + + # --run mode: execute a single SQL file and print results + if run_file: + print(f"\nExecuting: {run_file.name}...") + try: + results = execute_sql(conn, run_file, DATABASE, schema_map) + print() + print_query_results(results) + except Exception as e: + print(f"ERROR: {e}") + sys.exit(1) + finally: + conn.close() + sys.exit(0) + # Execute tests all_results = {} all_durations = {} @@ -292,7 +469,7 @@ def main(): print(f"\nExecuting: {test_file.name}...") test_start = time.time() try: - results = execute_test(conn, test_file, DATABASE) + results = execute_sql(conn, test_file, DATABASE, schema_map) duration = time.time() - test_start all_results[test_file.name] = results all_durations[test_file.name] = duration diff --git a/OLIDS/Testing/setup.sh b/OLIDS/Testing/setup.sh new file mode 100644 index 0000000..2e98e8d --- /dev/null +++ b/OLIDS/Testing/setup.sh @@ -0,0 +1,120 @@ +#!/usr/bin/env bash +# +# Sets up the OLIDS testing environment. +# Installs uv (if needed), creates a .env file with Snowflake credentials, +# and installs Python dependencies. + +set -euo pipefail + +SCRIPT_DIR="$(cd "$(dirname "${BASH_SOURCE[0]}")" && pwd)" + +echo "" +echo "OLIDS Testing - Setup" +echo "=====================" +echo "" + +# --- Step 1: Check for uv --- +if ! command -v uv &>/dev/null; then + echo "uv not found on PATH. Installing..." + curl -LsSf https://astral.sh/uv/install.sh | sh + + # Source the env file uv's installer creates + if [ -f "$HOME/.local/bin/env" ]; then + source "$HOME/.local/bin/env" + fi + export PATH="$HOME/.local/bin:$PATH" + + if ! command -v uv &>/dev/null; then + echo "ERROR: uv installation succeeded but is still not on PATH." + echo "Close and reopen your terminal, then run this script again." + exit 1 + fi + echo "uv installed successfully." +else + echo "uv found: $(uv --version)" +fi + +# --- Step 2: Snowflake credentials --- +ENV_FILE="$SCRIPT_DIR/.env" +NEEDS_SETUP=true + +if [ -f "$ENV_FILE" ]; then + echo "" + echo "Existing Snowflake configuration found:" + for key in SNOWFLAKE_ACCOUNT SNOWFLAKE_USER SNOWFLAKE_WAREHOUSE SNOWFLAKE_ROLE SNOWFLAKE_DATABASE; do + val=$(grep "^${key}=" "$ENV_FILE" 2>/dev/null | cut -d= -f2- || true) + if [ -n "$val" ]; then + echo " $key = $val" + fi + done + echo "" + read -rp "Keep these settings? (Y/n) " change + if [ "$change" = "n" ] || [ "$change" = "N" ]; then + rm "$ENV_FILE" + else + echo "Keeping existing credentials." + NEEDS_SETUP=false + fi +fi + +if $NEEDS_SETUP && [ ! -f "$ENV_FILE" ]; then + echo "" + echo "Snowflake Connection Setup" + echo "--------------------------" + echo "" + + echo "Account identifier" + echo " In Snowflake (https://app.snowflake.com/), click your profile (bottom-left)" + echo " and copy the 'Account identifier' value from Account Details." + echo " Format: XXXXXXX-XXX (e.g. ATKJNCU-NCL)" + read -rp " SNOWFLAKE_ACCOUNT: " account + + echo "" + echo "Username (your Snowflake login, usually your NHS email)" + read -rp " SNOWFLAKE_USER: " user + + echo "" + echo "Warehouse name" + echo " The compute warehouse to run queries against." + read -rp " SNOWFLAKE_WAREHOUSE: " warehouse + + echo "" + echo "Role name" + echo " Your Snowflake role with read access to the OLIDS schemas." + read -rp " SNOWFLAKE_ROLE: " role + + echo "" + echo "Database name" + echo " The ICB-specific OLIDS database (e.g. Data_Store_OLIDS_Alpha)." + read -rp " SNOWFLAKE_DATABASE: " database + + cat > "$ENV_FILE" < Date: Fri, 13 Feb 2026 10:50:22 +0000 Subject: [PATCH 09/15] docs: add prerequisites section to README --- OLIDS/Testing/README.md | 7 +++++++ 1 file changed, 7 insertions(+) diff --git a/OLIDS/Testing/README.md b/OLIDS/Testing/README.md index 42b37c7..7ea39e7 100644 --- a/OLIDS/Testing/README.md +++ b/OLIDS/Testing/README.md @@ -2,6 +2,13 @@ SQL-based data quality tests for OLIDS, run against Snowflake. Portable across London ICBs — each ICB sets their own database name via `.env` and the runner auto-detects schema names at startup. +## Prerequisites + +- **Git** — to clone the repository +- **A web browser** — for Snowflake SSO login (opens automatically on first run) + +Python and all dependencies are installed automatically by the setup script via [uv](https://docs.astral.sh/uv/). + ## Setup ```powershell From cdfcb40062ae602db9d87eab702d31ec962dbb6b Mon Sep 17 00:00:00 2001 From: EddieDavison92 <143042680+EddieDavison92@users.noreply.github.com> Date: Fri, 13 Feb 2026 10:51:32 +0000 Subject: [PATCH 10/15] docs: add git install instructions to prerequisites --- OLIDS/Testing/README.md | 3 +++ 1 file changed, 3 insertions(+) diff --git a/OLIDS/Testing/README.md b/OLIDS/Testing/README.md index 7ea39e7..67e294b 100644 --- a/OLIDS/Testing/README.md +++ b/OLIDS/Testing/README.md @@ -5,6 +5,9 @@ SQL-based data quality tests for OLIDS, run against Snowflake. Portable across L ## Prerequisites - **Git** — to clone the repository + - Windows: download from [git-scm.com/downloads/win](https://git-scm.com/downloads/win) + - macOS: run `xcode-select --install` or download from [git-scm.com/downloads/mac](https://git-scm.com/downloads/mac) + - Linux: `sudo apt install git` (Debian/Ubuntu) or `sudo dnf install git` (Fedora) - **A web browser** — for Snowflake SSO login (opens automatically on first run) Python and all dependencies are installed automatically by the setup script via [uv](https://docs.astral.sh/uv/). From 647ad7c678e79e89d5b3c314ef2e21f971d0b1d6 Mon Sep 17 00:00:00 2001 From: EddieDavison92 <143042680+EddieDavison92@users.noreply.github.com> Date: Fri, 13 Feb 2026 10:59:24 +0000 Subject: [PATCH 11/15] fix: revert IDENTIFIER() to plain schema.table references Snowflake's IDENTIFIER() doesn't support expressions like $var || '.TABLE'. Reverted all SQL files to use plain OLIDS_X.TABLE references. SET variables remain as defaults that the runner overrides via string replacement at runtime. Also removed Linux references from README. --- OLIDS/Testing/README.md | 7 +- .../data-quality/test_column_completeness.sql | 234 +++++++------- .../data-quality/test_concept_mapping.sql | 208 ++++++------ .../data-quality/test_data_freshness.sql | 16 +- .../test_referential_integrity.sql | 304 +++++++++--------- .../data-quality/test_registration_pds.sql | 14 +- .../investigate_column_completeness.sql | 232 ++++++------- .../investigate_concept_mapping.sql | 78 ++--- .../investigate_data_freshness.sql | 16 +- .../investigate_referential_integrity.sql | 304 +++++++++--------- .../investigate_registration_pds.sql | 14 +- OLIDS/Testing/run_tests.py | 2 +- 12 files changed, 714 insertions(+), 715 deletions(-) diff --git a/OLIDS/Testing/README.md b/OLIDS/Testing/README.md index 67e294b..efb62e0 100644 --- a/OLIDS/Testing/README.md +++ b/OLIDS/Testing/README.md @@ -7,7 +7,6 @@ SQL-based data quality tests for OLIDS, run against Snowflake. Portable across L - **Git** — to clone the repository - Windows: download from [git-scm.com/downloads/win](https://git-scm.com/downloads/win) - macOS: run `xcode-select --install` or download from [git-scm.com/downloads/mac](https://git-scm.com/downloads/mac) - - Linux: `sudo apt install git` (Debian/Ubuntu) or `sudo dnf install git` (Fedora) - **A web browser** — for Snowflake SSO login (opens automatically on first run) Python and all dependencies are installed automatically by the setup script via [uv](https://docs.astral.sh/uv/). @@ -21,7 +20,7 @@ cd OLIDS/Testing ``` ```bash -# macOS / Linux +# macOS cd OLIDS/Testing chmod +x setup.sh ./setup.sh @@ -102,12 +101,12 @@ Use `UNION ALL` to return multiple checks from one file. Any extra columns beyon Other notes: - Use `SET var = value;` and `$var` for Snowflake session variables (e.g. thresholds) -- Schema names are configured via SET variables at the top of each file (`schema_masked`, `schema_common`, `schema_terminology`). Reference tables with `IDENTIFIER($schema_common || '.TABLE')`. The runner auto-detects schemas at startup and overwrites the SET values (e.g. `OLIDS_MASKED` → `OLIDS_PCD`). For Snowsight, change the SET values manually. +- Schema names are declared as SET variables at the top of each file (`schema_masked`, `schema_common`, `schema_terminology`). The runner auto-detects actual schema names at startup and replaces them in the SQL before execution (e.g. `OLIDS_MASKED` → `OLIDS_PCD`). For Snowsight, find-replace the schema prefixes to match your ICB. - Avoid semicolons inside comments or string literals — the runner naively splits on `;` to execute statements individually ## Investigating Failures -The `investigations/` folder has companion scripts for each test. These return row-level detail to help diagnose failures. Run them through the runner with `--run` (handles schema detection and database context automatically), or directly in Snowsight (set the `USE DATABASE` and `SET schema_*` variables at the top of each file to match your ICB). +The `investigations/` folder has companion scripts for each test. These return row-level detail to help diagnose failures. Run them through the runner with `--run` (handles schema detection and database context automatically), or directly in Snowsight (set the `USE DATABASE` and find-replace the schema prefixes at the top of each file to match your ICB). ```bash uv run run_tests.py --run investigations/investigate_referential_integrity.sql diff --git a/OLIDS/Testing/data-quality/test_column_completeness.sql b/OLIDS/Testing/data-quality/test_column_completeness.sql index d36a1b4..25a007a 100644 --- a/OLIDS/Testing/data-quality/test_column_completeness.sql +++ b/OLIDS/Testing/data-quality/test_column_completeness.sql @@ -25,7 +25,7 @@ Example: UNION ALL SELECT 'MY_TABLE', 'my_column', 1.0, COUNT(*), SUM(CASE WHEN my_column IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MY_TABLE') + FROM OLIDS_COMMON.MY_TABLE */ SET schema_masked = 'OLIDS_MASKED'; -- Change if your ICB uses a different name (e.g. OLIDS_PCD) @@ -35,176 +35,176 @@ SET schema_terminology = 'OLIDS_TERMINOLOGY'; WITH checks AS ( -- Each row: table, column, max allowed NULL %, total rows, NULL count -- PATIENT (OLIDS_MASKED) - SELECT 'PATIENT' AS table_name, 'id' AS column_name, 0.0 AS threshold, COUNT(*) AS total_rows, SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) AS null_count FROM IDENTIFIER($schema_masked || '.PATIENT') - UNION ALL SELECT 'PATIENT', 'sk_patient_id', 0.5, COUNT(*), SUM(CASE WHEN sk_patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT') - UNION ALL SELECT 'PATIENT', 'birth_year', 1.0, COUNT(*), SUM(CASE WHEN birth_year IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT') - UNION ALL SELECT 'PATIENT', 'birth_month', 1.0, COUNT(*), SUM(CASE WHEN birth_month IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT') - UNION ALL SELECT 'PATIENT', 'gender_concept_id', 5.0, COUNT(*), SUM(CASE WHEN gender_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT') - UNION ALL SELECT 'PATIENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT') + SELECT 'PATIENT' AS table_name, 'id' AS column_name, 0.0 AS threshold, COUNT(*) AS total_rows, SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) AS null_count FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'sk_patient_id', 0.5, COUNT(*), SUM(CASE WHEN sk_patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'birth_year', 1.0, COUNT(*), SUM(CASE WHEN birth_year IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'birth_month', 1.0, COUNT(*), SUM(CASE WHEN birth_month IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'gender_concept_id', 5.0, COUNT(*), SUM(CASE WHEN gender_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT -- PERSON (OLIDS_MASKED) - UNION ALL SELECT 'PERSON', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PERSON') - UNION ALL SELECT 'PERSON', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PERSON') + UNION ALL SELECT 'PERSON', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PERSON + UNION ALL SELECT 'PERSON', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PERSON -- PATIENT_ADDRESS (OLIDS_MASKED) - UNION ALL SELECT 'PATIENT_ADDRESS', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_ADDRESS') - UNION ALL SELECT 'PATIENT_ADDRESS', 'address_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN address_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_ADDRESS') - UNION ALL SELECT 'PATIENT_ADDRESS', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_ADDRESS') + UNION ALL SELECT 'PATIENT_ADDRESS', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS + UNION ALL SELECT 'PATIENT_ADDRESS', 'address_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN address_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS + UNION ALL SELECT 'PATIENT_ADDRESS', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS -- PATIENT_CONTACT (OLIDS_MASKED) - UNION ALL SELECT 'PATIENT_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_CONTACT') - UNION ALL SELECT 'PATIENT_CONTACT', 'contact_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_CONTACT') - UNION ALL SELECT 'PATIENT_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_CONTACT') + UNION ALL SELECT 'PATIENT_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT + UNION ALL SELECT 'PATIENT_CONTACT', 'contact_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT + UNION ALL SELECT 'PATIENT_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT -- PATIENT_UPRN (OLIDS_MASKED) - UNION ALL SELECT 'PATIENT_UPRN', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_UPRN') - UNION ALL SELECT 'PATIENT_UPRN', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_UPRN') + UNION ALL SELECT 'PATIENT_UPRN', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_UPRN + UNION ALL SELECT 'PATIENT_UPRN', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_UPRN -- PATIENT_PERSON (OLIDS_COMMON) - UNION ALL SELECT 'PATIENT_PERSON', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PATIENT_PERSON') - UNION ALL SELECT 'PATIENT_PERSON', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PATIENT_PERSON') + UNION ALL SELECT 'PATIENT_PERSON', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_PERSON + UNION ALL SELECT 'PATIENT_PERSON', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_PERSON -- EPISODE_OF_CARE (OLIDS_COMMON) - UNION ALL SELECT 'EPISODE_OF_CARE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') - UNION ALL SELECT 'EPISODE_OF_CARE', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') - UNION ALL SELECT 'EPISODE_OF_CARE', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') - UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_of_care_start_date', 1.0, COUNT(*), SUM(CASE WHEN episode_of_care_start_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') - UNION ALL SELECT 'EPISODE_OF_CARE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') - UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_type_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_type_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') - UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_status_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_status_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') + UNION ALL SELECT 'EPISODE_OF_CARE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_of_care_start_date', 1.0, COUNT(*), SUM(CASE WHEN episode_of_care_start_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_type_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_type_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_status_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_status_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE -- OBSERVATION (OLIDS_COMMON) - UNION ALL SELECT 'OBSERVATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') - UNION ALL SELECT 'OBSERVATION', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') - UNION ALL SELECT 'OBSERVATION', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') - UNION ALL SELECT 'OBSERVATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') - UNION ALL SELECT 'OBSERVATION', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') - UNION ALL SELECT 'OBSERVATION', 'observation_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN observation_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') - UNION ALL SELECT 'OBSERVATION', 'result_value_units_concept_id', 5.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') - UNION ALL SELECT 'OBSERVATION', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') - UNION ALL SELECT 'OBSERVATION', 'episodicity_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') + UNION ALL SELECT 'OBSERVATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'observation_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN observation_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'result_value_units_concept_id', 5.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'episodicity_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION -- MEDICATION_STATEMENT (OLIDS_COMMON) - UNION ALL SELECT 'MEDICATION_STATEMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') - UNION ALL SELECT 'MEDICATION_STATEMENT', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') - UNION ALL SELECT 'MEDICATION_STATEMENT', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') - UNION ALL SELECT 'MEDICATION_STATEMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') - UNION ALL SELECT 'MEDICATION_STATEMENT', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') - UNION ALL SELECT 'MEDICATION_STATEMENT', 'medication_statement_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN medication_statement_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') - UNION ALL SELECT 'MEDICATION_STATEMENT', 'authorisation_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN authorisation_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') - UNION ALL SELECT 'MEDICATION_STATEMENT', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') + UNION ALL SELECT 'MEDICATION_STATEMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'medication_statement_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN medication_statement_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'authorisation_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN authorisation_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT -- MEDICATION_ORDER (OLIDS_COMMON) - UNION ALL SELECT 'MEDICATION_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') - UNION ALL SELECT 'MEDICATION_ORDER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') - UNION ALL SELECT 'MEDICATION_ORDER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') - UNION ALL SELECT 'MEDICATION_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') - UNION ALL SELECT 'MEDICATION_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') - UNION ALL SELECT 'MEDICATION_ORDER', 'medication_order_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN medication_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') - UNION ALL SELECT 'MEDICATION_ORDER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') + UNION ALL SELECT 'MEDICATION_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'medication_order_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN medication_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER -- DIAGNOSTIC_ORDER (OLIDS_COMMON) - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'diagnostic_order_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN diagnostic_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'result_value_units_concept_id', 5.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'episodicity_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'diagnostic_order_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN diagnostic_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'result_value_units_concept_id', 5.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'episodicity_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER -- ENCOUNTER (OLIDS_COMMON) - UNION ALL SELECT 'ENCOUNTER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') - UNION ALL SELECT 'ENCOUNTER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') - UNION ALL SELECT 'ENCOUNTER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') - UNION ALL SELECT 'ENCOUNTER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') - UNION ALL SELECT 'ENCOUNTER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') - UNION ALL SELECT 'ENCOUNTER', 'encounter_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN encounter_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') - UNION ALL SELECT 'ENCOUNTER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') + UNION ALL SELECT 'ENCOUNTER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'encounter_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN encounter_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER -- ALLERGY_INTOLERANCE (OLIDS_COMMON) - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'allergy_intolerance_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN allergy_intolerance_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'allergy_intolerance_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN allergy_intolerance_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE -- PROCEDURE_REQUEST (OLIDS_COMMON) - UNION ALL SELECT 'PROCEDURE_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') - UNION ALL SELECT 'PROCEDURE_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') - UNION ALL SELECT 'PROCEDURE_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') - UNION ALL SELECT 'PROCEDURE_REQUEST', 'procedure_request_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN procedure_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') - UNION ALL SELECT 'PROCEDURE_REQUEST', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') - UNION ALL SELECT 'PROCEDURE_REQUEST', 'status_concept_id', 5.0, COUNT(*), SUM(CASE WHEN status_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') + UNION ALL SELECT 'PROCEDURE_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'procedure_request_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN procedure_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'status_concept_id', 5.0, COUNT(*), SUM(CASE WHEN status_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST -- REFERRAL_REQUEST (OLIDS_COMMON) - UNION ALL SELECT 'REFERRAL_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') - UNION ALL SELECT 'REFERRAL_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') - UNION ALL SELECT 'REFERRAL_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') - UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') - UNION ALL SELECT 'REFERRAL_REQUEST', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') - UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_priority_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_priority_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') - UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') - UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_specialty_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_specialty_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') + UNION ALL SELECT 'REFERRAL_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_priority_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_priority_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_specialty_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_specialty_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST -- LOCATION_CONTACT (OLIDS_COMMON) - UNION ALL SELECT 'LOCATION_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.LOCATION_CONTACT') - UNION ALL SELECT 'LOCATION_CONTACT', 'contact_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.LOCATION_CONTACT') - UNION ALL SELECT 'LOCATION_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.LOCATION_CONTACT') + UNION ALL SELECT 'LOCATION_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT + UNION ALL SELECT 'LOCATION_CONTACT', 'contact_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT + UNION ALL SELECT 'LOCATION_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT -- APPOINTMENT (OLIDS_COMMON) - UNION ALL SELECT 'APPOINTMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT') - UNION ALL SELECT 'APPOINTMENT', 'appointment_status_concept_id', 5.0, COUNT(*), SUM(CASE WHEN appointment_status_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT') - UNION ALL SELECT 'APPOINTMENT', 'booking_method_concept_id', 5.0, COUNT(*), SUM(CASE WHEN booking_method_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT') - UNION ALL SELECT 'APPOINTMENT', 'contact_mode_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_mode_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT') - UNION ALL SELECT 'APPOINTMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT') + UNION ALL SELECT 'APPOINTMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'appointment_status_concept_id', 5.0, COUNT(*), SUM(CASE WHEN appointment_status_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'booking_method_concept_id', 5.0, COUNT(*), SUM(CASE WHEN booking_method_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'contact_mode_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_mode_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT -- APPOINTMENT_PRACTITIONER (OLIDS_COMMON) - UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT_PRACTITIONER') - UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT_PRACTITIONER') + UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER + UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER -- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE (OLIDS_COMMON) - UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') - UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') + UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE + UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE -- LOCATION (OLIDS_COMMON) - UNION ALL SELECT 'LOCATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.LOCATION') - UNION ALL SELECT 'LOCATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.LOCATION') + UNION ALL SELECT 'LOCATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION + UNION ALL SELECT 'LOCATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION -- FLAG (OLIDS_COMMON) - UNION ALL SELECT 'FLAG', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.FLAG') - UNION ALL SELECT 'FLAG', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.FLAG') + UNION ALL SELECT 'FLAG', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.FLAG + UNION ALL SELECT 'FLAG', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.FLAG -- ORGANISATION (OLIDS_COMMON) - UNION ALL SELECT 'ORGANISATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ORGANISATION') - UNION ALL SELECT 'ORGANISATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ORGANISATION') + UNION ALL SELECT 'ORGANISATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ORGANISATION + UNION ALL SELECT 'ORGANISATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ORGANISATION -- PRACTITIONER (OLIDS_COMMON) - UNION ALL SELECT 'PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PRACTITIONER') - UNION ALL SELECT 'PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PRACTITIONER') + UNION ALL SELECT 'PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER + UNION ALL SELECT 'PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER -- PRACTITIONER_IN_ROLE (OLIDS_COMMON) - UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PRACTITIONER_IN_ROLE') - UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PRACTITIONER_IN_ROLE') + UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE + UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE -- SCHEDULE (OLIDS_COMMON) - UNION ALL SELECT 'SCHEDULE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.SCHEDULE') - UNION ALL SELECT 'SCHEDULE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.SCHEDULE') + UNION ALL SELECT 'SCHEDULE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE + UNION ALL SELECT 'SCHEDULE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE -- SCHEDULE_PRACTITIONER (OLIDS_COMMON) - UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.SCHEDULE_PRACTITIONER') - UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.SCHEDULE_PRACTITIONER') + UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER + UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER -- CONCEPT (OLIDS_TERMINOLOGY) - UNION ALL SELECT 'CONCEPT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_terminology || '.CONCEPT') - UNION ALL SELECT 'CONCEPT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_terminology || '.CONCEPT') + UNION ALL SELECT 'CONCEPT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT + UNION ALL SELECT 'CONCEPT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT -- CONCEPT_MAP (OLIDS_TERMINOLOGY) - UNION ALL SELECT 'CONCEPT_MAP', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_terminology || '.CONCEPT_MAP') - UNION ALL SELECT 'CONCEPT_MAP', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_terminology || '.CONCEPT_MAP') + UNION ALL SELECT 'CONCEPT_MAP', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT_MAP + UNION ALL SELECT 'CONCEPT_MAP', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT_MAP ) -- Compute completeness % and compare against threshold diff --git a/OLIDS/Testing/data-quality/test_concept_mapping.sql b/OLIDS/Testing/data-quality/test_concept_mapping.sql index cfb858a..fc484b1 100644 --- a/OLIDS/Testing/data-quality/test_concept_mapping.sql +++ b/OLIDS/Testing/data-quality/test_concept_mapping.sql @@ -24,8 +24,8 @@ To add a check: Add a UNION ALL block joining your table's concept column through CONCEPT_MAP and CONCEPT. Follow the pattern below: - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base. = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base. = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id */ SET schema_masked = 'OLIDS_MASKED'; -- Change if your ICB uses a different name (e.g. OLIDS_PCD) @@ -42,9 +42,9 @@ WITH checks AS ( COUNT(*) AS total_rows, COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.observation_source_concept_id END) AS unmapped_concepts, SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) AS unmapped_rows - FROM IDENTIFIER($schema_common || '.OBSERVATION') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.observation_source_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.OBSERVATION base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.observation_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.observation_source_concept_id IS NOT NULL UNION ALL @@ -53,9 +53,9 @@ WITH checks AS ( COUNT(DISTINCT base.result_value_units_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.result_value_units_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.OBSERVATION') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.result_value_units_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.OBSERVATION base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.result_value_units_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.result_value_units_concept_id IS NOT NULL UNION ALL @@ -64,9 +64,9 @@ WITH checks AS ( COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.OBSERVATION') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.date_precision_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.OBSERVATION base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.date_precision_concept_id IS NOT NULL UNION ALL @@ -75,9 +75,9 @@ WITH checks AS ( COUNT(DISTINCT base.episodicity_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.episodicity_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.OBSERVATION') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.episodicity_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.OBSERVATION base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.episodicity_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.episodicity_concept_id IS NOT NULL UNION ALL @@ -87,9 +87,9 @@ WITH checks AS ( COUNT(DISTINCT base.medication_statement_source_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.medication_statement_source_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.medication_statement_source_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.MEDICATION_STATEMENT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.medication_statement_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.medication_statement_source_concept_id IS NOT NULL UNION ALL @@ -98,9 +98,9 @@ WITH checks AS ( COUNT(DISTINCT base.authorisation_type_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.authorisation_type_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.authorisation_type_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.MEDICATION_STATEMENT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.authorisation_type_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.authorisation_type_concept_id IS NOT NULL UNION ALL @@ -109,9 +109,9 @@ WITH checks AS ( COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.date_precision_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.MEDICATION_STATEMENT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.date_precision_concept_id IS NOT NULL UNION ALL @@ -121,9 +121,9 @@ WITH checks AS ( COUNT(DISTINCT base.medication_order_source_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.medication_order_source_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.medication_order_source_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.MEDICATION_ORDER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.medication_order_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.medication_order_source_concept_id IS NOT NULL UNION ALL @@ -132,9 +132,9 @@ WITH checks AS ( COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.date_precision_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.MEDICATION_ORDER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.date_precision_concept_id IS NOT NULL UNION ALL @@ -144,9 +144,9 @@ WITH checks AS ( COUNT(DISTINCT base.diagnostic_order_source_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.diagnostic_order_source_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.diagnostic_order_source_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.diagnostic_order_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.diagnostic_order_source_concept_id IS NOT NULL UNION ALL @@ -155,9 +155,9 @@ WITH checks AS ( COUNT(DISTINCT base.result_value_units_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.result_value_units_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.result_value_units_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.result_value_units_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.result_value_units_concept_id IS NOT NULL UNION ALL @@ -166,9 +166,9 @@ WITH checks AS ( COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.date_precision_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.date_precision_concept_id IS NOT NULL UNION ALL @@ -177,9 +177,9 @@ WITH checks AS ( COUNT(DISTINCT base.episodicity_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.episodicity_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.episodicity_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.episodicity_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.episodicity_concept_id IS NOT NULL UNION ALL @@ -189,9 +189,9 @@ WITH checks AS ( COUNT(DISTINCT base.procedure_request_source_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.procedure_request_source_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.procedure_request_source_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.PROCEDURE_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.procedure_request_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.procedure_request_source_concept_id IS NOT NULL UNION ALL @@ -200,9 +200,9 @@ WITH checks AS ( COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.date_precision_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.PROCEDURE_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.date_precision_concept_id IS NOT NULL UNION ALL @@ -211,9 +211,9 @@ WITH checks AS ( COUNT(DISTINCT base.status_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.status_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.status_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.PROCEDURE_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.status_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.status_concept_id IS NOT NULL UNION ALL @@ -223,9 +223,9 @@ WITH checks AS ( COUNT(DISTINCT base.referral_request_source_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.referral_request_source_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.referral_request_source_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.REFERRAL_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.referral_request_source_concept_id IS NOT NULL UNION ALL @@ -234,9 +234,9 @@ WITH checks AS ( COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.date_precision_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.REFERRAL_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.date_precision_concept_id IS NOT NULL UNION ALL @@ -245,9 +245,9 @@ WITH checks AS ( COUNT(DISTINCT base.referral_request_priority_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.referral_request_priority_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.referral_request_priority_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.REFERRAL_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_priority_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.referral_request_priority_concept_id IS NOT NULL UNION ALL @@ -256,9 +256,9 @@ WITH checks AS ( COUNT(DISTINCT base.referral_request_type_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.referral_request_type_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.referral_request_type_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.REFERRAL_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_type_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.referral_request_type_concept_id IS NOT NULL UNION ALL @@ -267,9 +267,9 @@ WITH checks AS ( COUNT(DISTINCT base.referral_request_specialty_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.referral_request_specialty_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.referral_request_specialty_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.REFERRAL_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_specialty_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.referral_request_specialty_concept_id IS NOT NULL UNION ALL @@ -279,9 +279,9 @@ WITH checks AS ( COUNT(DISTINCT base.allergy_intolerance_source_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.allergy_intolerance_source_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.allergy_intolerance_source_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.ALLERGY_INTOLERANCE base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.allergy_intolerance_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.allergy_intolerance_source_concept_id IS NOT NULL UNION ALL @@ -290,9 +290,9 @@ WITH checks AS ( COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.date_precision_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.ALLERGY_INTOLERANCE base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.date_precision_concept_id IS NOT NULL UNION ALL @@ -302,9 +302,9 @@ WITH checks AS ( COUNT(DISTINCT base.encounter_source_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.encounter_source_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.ENCOUNTER') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.encounter_source_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.ENCOUNTER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.encounter_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.encounter_source_concept_id IS NOT NULL UNION ALL @@ -313,9 +313,9 @@ WITH checks AS ( COUNT(DISTINCT base.date_precision_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.date_precision_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.ENCOUNTER') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.date_precision_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.ENCOUNTER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.date_precision_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.date_precision_concept_id IS NOT NULL UNION ALL @@ -325,9 +325,9 @@ WITH checks AS ( COUNT(DISTINCT base.episode_type_source_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.episode_type_source_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.episode_type_source_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.EPISODE_OF_CARE base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.episode_type_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.episode_type_source_concept_id IS NOT NULL UNION ALL @@ -336,9 +336,9 @@ WITH checks AS ( COUNT(DISTINCT base.episode_status_source_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.episode_status_source_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.episode_status_source_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.EPISODE_OF_CARE base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.episode_status_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.episode_status_source_concept_id IS NOT NULL UNION ALL @@ -348,9 +348,9 @@ WITH checks AS ( COUNT(DISTINCT base.contact_type_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.contact_type_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.LOCATION_CONTACT') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.contact_type_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.LOCATION_CONTACT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.contact_type_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.contact_type_concept_id IS NOT NULL UNION ALL @@ -360,9 +360,9 @@ WITH checks AS ( COUNT(DISTINCT base.appointment_status_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.appointment_status_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.APPOINTMENT') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.appointment_status_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.APPOINTMENT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.appointment_status_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.appointment_status_concept_id IS NOT NULL UNION ALL @@ -371,9 +371,9 @@ WITH checks AS ( COUNT(DISTINCT base.booking_method_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.booking_method_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.APPOINTMENT') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.booking_method_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.APPOINTMENT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.booking_method_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.booking_method_concept_id IS NOT NULL UNION ALL @@ -382,9 +382,9 @@ WITH checks AS ( COUNT(DISTINCT base.contact_mode_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.contact_mode_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.APPOINTMENT') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.contact_mode_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.APPOINTMENT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.contact_mode_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.contact_mode_concept_id IS NOT NULL UNION ALL @@ -394,9 +394,9 @@ WITH checks AS ( COUNT(DISTINCT base.gender_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.gender_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_masked || '.PATIENT') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.gender_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_MASKED.PATIENT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.gender_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.gender_concept_id IS NOT NULL UNION ALL @@ -406,9 +406,9 @@ WITH checks AS ( COUNT(DISTINCT base.address_type_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.address_type_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_masked || '.PATIENT_ADDRESS') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.address_type_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_MASKED.PATIENT_ADDRESS base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.address_type_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.address_type_concept_id IS NOT NULL UNION ALL @@ -418,9 +418,9 @@ WITH checks AS ( COUNT(DISTINCT base.contact_type_concept_id), COUNT(*), COUNT(DISTINCT CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN base.contact_type_concept_id END), SUM(CASE WHEN (cm.source_code_id IS NULL OR c.id IS NULL) THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_masked || '.PATIENT_CONTACT') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.contact_type_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_MASKED.PATIENT_CONTACT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.contact_type_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.contact_type_concept_id IS NOT NULL ) diff --git a/OLIDS/Testing/data-quality/test_data_freshness.sql b/OLIDS/Testing/data-quality/test_data_freshness.sql index 029ae77..83da38f 100644 --- a/OLIDS/Testing/data-quality/test_data_freshness.sql +++ b/OLIDS/Testing/data-quality/test_data_freshness.sql @@ -43,7 +43,7 @@ WITH org_freshness AS ( SELECT 'OBSERVATION' AS table_name, record_owner_organisation_code AS org_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END) AS max_date_recorded, DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) AS days_since_last - FROM IDENTIFIER($schema_common || '.OBSERVATION') WHERE record_owner_organisation_code IS NOT NULL + FROM OLIDS_COMMON.OBSERVATION WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL @@ -52,7 +52,7 @@ WITH org_freshness AS ( SELECT 'ENCOUNTER', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM IDENTIFIER($schema_common || '.ENCOUNTER') WHERE record_owner_organisation_code IS NOT NULL + FROM OLIDS_COMMON.ENCOUNTER WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL @@ -61,7 +61,7 @@ WITH org_freshness AS ( SELECT 'MEDICATION_ORDER', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') WHERE record_owner_organisation_code IS NOT NULL + FROM OLIDS_COMMON.MEDICATION_ORDER WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL @@ -70,7 +70,7 @@ WITH org_freshness AS ( SELECT 'MEDICATION_STATEMENT', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') WHERE record_owner_organisation_code IS NOT NULL + FROM OLIDS_COMMON.MEDICATION_STATEMENT WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL @@ -79,7 +79,7 @@ WITH org_freshness AS ( SELECT 'DIAGNOSTIC_ORDER', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') WHERE record_owner_organisation_code IS NOT NULL + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL @@ -88,7 +88,7 @@ WITH org_freshness AS ( SELECT 'ALLERGY_INTOLERANCE', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') WHERE record_owner_organisation_code IS NOT NULL + FROM OLIDS_COMMON.ALLERGY_INTOLERANCE WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL @@ -97,7 +97,7 @@ WITH org_freshness AS ( SELECT 'PROCEDURE_REQUEST', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') WHERE record_owner_organisation_code IS NOT NULL + FROM OLIDS_COMMON.PROCEDURE_REQUEST WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL @@ -106,7 +106,7 @@ WITH org_freshness AS ( SELECT 'REFERRAL_REQUEST', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') WHERE record_owner_organisation_code IS NOT NULL + FROM OLIDS_COMMON.REFERRAL_REQUEST WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code ), diff --git a/OLIDS/Testing/data-quality/test_referential_integrity.sql b/OLIDS/Testing/data-quality/test_referential_integrity.sql index 6442d32..e60e9b5 100644 --- a/OLIDS/Testing/data-quality/test_referential_integrity.sql +++ b/OLIDS/Testing/data-quality/test_referential_integrity.sql @@ -37,8 +37,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END) AS total_rows_with_fk, COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END) AS orphaned_fk, SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) AS orphaned_rows - FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') c - LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id + FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id UNION ALL @@ -48,8 +48,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') c - LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id + FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c + LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id UNION ALL @@ -59,8 +59,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.encounter_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN c.encounter_id END), SUM(CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') c - LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id + FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c + LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id UNION ALL @@ -70,8 +70,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') c - LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id + FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id UNION ALL @@ -81,8 +81,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.APPOINTMENT') c - LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id + FROM OLIDS_COMMON.APPOINTMENT c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id UNION ALL @@ -92,8 +92,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_in_role_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_in_role_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_in_role_id END), SUM(CASE WHEN c.practitioner_in_role_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.APPOINTMENT') c - LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER_IN_ROLE') p ON c.practitioner_in_role_id = p.id + FROM OLIDS_COMMON.APPOINTMENT c + LEFT JOIN OLIDS_COMMON.PRACTITIONER_IN_ROLE p ON c.practitioner_in_role_id = p.id UNION ALL @@ -103,8 +103,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.schedule_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.schedule_id IS NOT NULL AND p.id IS NULL THEN c.schedule_id END), SUM(CASE WHEN c.schedule_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.APPOINTMENT') c - LEFT JOIN IDENTIFIER($schema_common || '.SCHEDULE') p ON c.schedule_id = p.id + FROM OLIDS_COMMON.APPOINTMENT c + LEFT JOIN OLIDS_COMMON.SCHEDULE p ON c.schedule_id = p.id UNION ALL @@ -114,8 +114,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.appointment_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.appointment_id IS NOT NULL AND p.id IS NULL THEN c.appointment_id END), SUM(CASE WHEN c.appointment_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.APPOINTMENT_PRACTITIONER') c - LEFT JOIN IDENTIFIER($schema_common || '.APPOINTMENT') p ON c.appointment_id = p.id + FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER c + LEFT JOIN OLIDS_COMMON.APPOINTMENT p ON c.appointment_id = p.id UNION ALL @@ -125,8 +125,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.APPOINTMENT_PRACTITIONER') c - LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id + FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id UNION ALL @@ -136,8 +136,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') c - LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id UNION ALL @@ -147,8 +147,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') c - LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c + LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id UNION ALL @@ -158,8 +158,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.encounter_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN c.encounter_id END), SUM(CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') c - LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c + LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id UNION ALL @@ -169,8 +169,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') c - LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id UNION ALL @@ -180,8 +180,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.parent_observation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.parent_observation_id IS NOT NULL AND p.id IS NULL THEN c.parent_observation_id END), SUM(CASE WHEN c.parent_observation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') c - LEFT JOIN IDENTIFIER($schema_common || '.OBSERVATION') p ON c.parent_observation_id = p.id + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c + LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.parent_observation_id = p.id UNION ALL @@ -191,8 +191,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.ENCOUNTER') c - LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id + FROM OLIDS_COMMON.ENCOUNTER c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id UNION ALL @@ -202,8 +202,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.ENCOUNTER') c - LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id + FROM OLIDS_COMMON.ENCOUNTER c + LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id UNION ALL @@ -213,8 +213,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.ENCOUNTER') c - LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id + FROM OLIDS_COMMON.ENCOUNTER c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id UNION ALL @@ -224,8 +224,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.episode_of_care_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.episode_of_care_id IS NOT NULL AND p.id IS NULL THEN c.episode_of_care_id END), SUM(CASE WHEN c.episode_of_care_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.ENCOUNTER') c - LEFT JOIN IDENTIFIER($schema_common || '.EPISODE_OF_CARE') p ON c.episode_of_care_id = p.id + FROM OLIDS_COMMON.ENCOUNTER c + LEFT JOIN OLIDS_COMMON.EPISODE_OF_CARE p ON c.episode_of_care_id = p.id UNION ALL @@ -235,8 +235,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.appointment_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.appointment_id IS NOT NULL AND p.id IS NULL THEN c.appointment_id END), SUM(CASE WHEN c.appointment_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.ENCOUNTER') c - LEFT JOIN IDENTIFIER($schema_common || '.APPOINTMENT') p ON c.appointment_id = p.id + FROM OLIDS_COMMON.ENCOUNTER c + LEFT JOIN OLIDS_COMMON.APPOINTMENT p ON c.appointment_id = p.id UNION ALL @@ -246,8 +246,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.service_provider_organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.service_provider_organisation_id IS NOT NULL AND p.id IS NULL THEN c.service_provider_organisation_id END), SUM(CASE WHEN c.service_provider_organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.ENCOUNTER') c - LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.service_provider_organisation_id = p.id + FROM OLIDS_COMMON.ENCOUNTER c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.service_provider_organisation_id = p.id UNION ALL @@ -257,8 +257,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') c - LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id + FROM OLIDS_COMMON.EPISODE_OF_CARE c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id UNION ALL @@ -268,8 +268,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') c - LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id + FROM OLIDS_COMMON.EPISODE_OF_CARE c + LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id UNION ALL @@ -279,8 +279,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN c.organisation_id END), SUM(CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') c - LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id + FROM OLIDS_COMMON.EPISODE_OF_CARE c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id UNION ALL @@ -290,8 +290,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.care_manager_practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.care_manager_practitioner_id IS NOT NULL AND p.id IS NULL THEN c.care_manager_practitioner_id END), SUM(CASE WHEN c.care_manager_practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') c - LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.care_manager_practitioner_id = p.id + FROM OLIDS_COMMON.EPISODE_OF_CARE c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.care_manager_practitioner_id = p.id UNION ALL @@ -301,8 +301,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.FLAG') c - LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id + FROM OLIDS_COMMON.FLAG c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id UNION ALL @@ -312,8 +312,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.managing_organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.managing_organisation_id IS NOT NULL AND p.id IS NULL THEN c.managing_organisation_id END), SUM(CASE WHEN c.managing_organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.LOCATION') c - LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.managing_organisation_id = p.id + FROM OLIDS_COMMON.LOCATION c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.managing_organisation_id = p.id UNION ALL @@ -323,8 +323,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.location_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.location_id IS NOT NULL AND p.id IS NULL THEN c.location_id END), SUM(CASE WHEN c.location_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.LOCATION_CONTACT') c - LEFT JOIN IDENTIFIER($schema_common || '.LOCATION') p ON c.location_id = p.id + FROM OLIDS_COMMON.LOCATION_CONTACT c + LEFT JOIN OLIDS_COMMON.LOCATION p ON c.location_id = p.id UNION ALL @@ -334,8 +334,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c - LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id + FROM OLIDS_COMMON.MEDICATION_ORDER c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id UNION ALL @@ -345,8 +345,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c - LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id + FROM OLIDS_COMMON.MEDICATION_ORDER c + LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id UNION ALL @@ -356,8 +356,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.medication_statement_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.medication_statement_id IS NOT NULL AND p.id IS NULL THEN c.medication_statement_id END), SUM(CASE WHEN c.medication_statement_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c - LEFT JOIN IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') p ON c.medication_statement_id = p.id + FROM OLIDS_COMMON.MEDICATION_ORDER c + LEFT JOIN OLIDS_COMMON.MEDICATION_STATEMENT p ON c.medication_statement_id = p.id UNION ALL @@ -367,8 +367,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN c.organisation_id END), SUM(CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c - LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id + FROM OLIDS_COMMON.MEDICATION_ORDER c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id UNION ALL @@ -378,8 +378,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.encounter_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN c.encounter_id END), SUM(CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c - LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id + FROM OLIDS_COMMON.MEDICATION_ORDER c + LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id UNION ALL @@ -389,8 +389,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c - LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id + FROM OLIDS_COMMON.MEDICATION_ORDER c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id UNION ALL @@ -400,8 +400,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.observation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.observation_id IS NOT NULL AND p.id IS NULL THEN c.observation_id END), SUM(CASE WHEN c.observation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c - LEFT JOIN IDENTIFIER($schema_common || '.OBSERVATION') p ON c.observation_id = p.id + FROM OLIDS_COMMON.MEDICATION_ORDER c + LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.observation_id = p.id UNION ALL @@ -411,8 +411,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.allergy_intolerance_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.allergy_intolerance_id IS NOT NULL AND p.id IS NULL THEN c.allergy_intolerance_id END), SUM(CASE WHEN c.allergy_intolerance_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c - LEFT JOIN IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') p ON c.allergy_intolerance_id = p.id + FROM OLIDS_COMMON.MEDICATION_ORDER c + LEFT JOIN OLIDS_COMMON.ALLERGY_INTOLERANCE p ON c.allergy_intolerance_id = p.id UNION ALL @@ -422,8 +422,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.diagnostic_order_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.diagnostic_order_id IS NOT NULL AND p.id IS NULL THEN c.diagnostic_order_id END), SUM(CASE WHEN c.diagnostic_order_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c - LEFT JOIN IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') p ON c.diagnostic_order_id = p.id + FROM OLIDS_COMMON.MEDICATION_ORDER c + LEFT JOIN OLIDS_COMMON.DIAGNOSTIC_ORDER p ON c.diagnostic_order_id = p.id UNION ALL @@ -433,8 +433,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.referral_request_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.referral_request_id IS NOT NULL AND p.id IS NULL THEN c.referral_request_id END), SUM(CASE WHEN c.referral_request_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c - LEFT JOIN IDENTIFIER($schema_common || '.REFERRAL_REQUEST') p ON c.referral_request_id = p.id + FROM OLIDS_COMMON.MEDICATION_ORDER c + LEFT JOIN OLIDS_COMMON.REFERRAL_REQUEST p ON c.referral_request_id = p.id UNION ALL @@ -444,8 +444,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c - LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id + FROM OLIDS_COMMON.MEDICATION_STATEMENT c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id UNION ALL @@ -455,8 +455,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c - LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id + FROM OLIDS_COMMON.MEDICATION_STATEMENT c + LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id UNION ALL @@ -466,8 +466,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN c.organisation_id END), SUM(CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c - LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id + FROM OLIDS_COMMON.MEDICATION_STATEMENT c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id UNION ALL @@ -477,8 +477,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.encounter_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN c.encounter_id END), SUM(CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c - LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id + FROM OLIDS_COMMON.MEDICATION_STATEMENT c + LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id UNION ALL @@ -488,8 +488,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c - LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id + FROM OLIDS_COMMON.MEDICATION_STATEMENT c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id UNION ALL @@ -499,8 +499,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.observation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.observation_id IS NOT NULL AND p.id IS NULL THEN c.observation_id END), SUM(CASE WHEN c.observation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c - LEFT JOIN IDENTIFIER($schema_common || '.OBSERVATION') p ON c.observation_id = p.id + FROM OLIDS_COMMON.MEDICATION_STATEMENT c + LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.observation_id = p.id UNION ALL @@ -510,8 +510,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.allergy_intolerance_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.allergy_intolerance_id IS NOT NULL AND p.id IS NULL THEN c.allergy_intolerance_id END), SUM(CASE WHEN c.allergy_intolerance_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c - LEFT JOIN IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') p ON c.allergy_intolerance_id = p.id + FROM OLIDS_COMMON.MEDICATION_STATEMENT c + LEFT JOIN OLIDS_COMMON.ALLERGY_INTOLERANCE p ON c.allergy_intolerance_id = p.id UNION ALL @@ -521,8 +521,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.diagnostic_order_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.diagnostic_order_id IS NOT NULL AND p.id IS NULL THEN c.diagnostic_order_id END), SUM(CASE WHEN c.diagnostic_order_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c - LEFT JOIN IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') p ON c.diagnostic_order_id = p.id + FROM OLIDS_COMMON.MEDICATION_STATEMENT c + LEFT JOIN OLIDS_COMMON.DIAGNOSTIC_ORDER p ON c.diagnostic_order_id = p.id UNION ALL @@ -532,8 +532,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.referral_request_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.referral_request_id IS NOT NULL AND p.id IS NULL THEN c.referral_request_id END), SUM(CASE WHEN c.referral_request_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c - LEFT JOIN IDENTIFIER($schema_common || '.REFERRAL_REQUEST') p ON c.referral_request_id = p.id + FROM OLIDS_COMMON.MEDICATION_STATEMENT c + LEFT JOIN OLIDS_COMMON.REFERRAL_REQUEST p ON c.referral_request_id = p.id UNION ALL @@ -543,8 +543,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.OBSERVATION') c - LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id + FROM OLIDS_COMMON.OBSERVATION c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id UNION ALL @@ -554,8 +554,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.OBSERVATION') c - LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id + FROM OLIDS_COMMON.OBSERVATION c + LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id UNION ALL @@ -565,8 +565,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.encounter_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN c.encounter_id END), SUM(CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.OBSERVATION') c - LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id + FROM OLIDS_COMMON.OBSERVATION c + LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id UNION ALL @@ -576,8 +576,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.OBSERVATION') c - LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id + FROM OLIDS_COMMON.OBSERVATION c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id UNION ALL @@ -587,8 +587,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.parent_observation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.parent_observation_id IS NOT NULL AND p.id IS NULL THEN c.parent_observation_id END), SUM(CASE WHEN c.parent_observation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.OBSERVATION') c - LEFT JOIN IDENTIFIER($schema_common || '.OBSERVATION') p ON c.parent_observation_id = p.id + FROM OLIDS_COMMON.OBSERVATION c + LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.parent_observation_id = p.id UNION ALL @@ -598,8 +598,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.parent_organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.parent_organisation_id IS NOT NULL AND p.id IS NULL THEN c.parent_organisation_id END), SUM(CASE WHEN c.parent_organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.ORGANISATION') c - LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.parent_organisation_id = p.id + FROM OLIDS_COMMON.ORGANISATION c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.parent_organisation_id = p.id UNION ALL @@ -609,8 +609,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.registered_practice_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.registered_practice_id IS NOT NULL AND p.id IS NULL THEN c.registered_practice_id END), SUM(CASE WHEN c.registered_practice_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_masked || '.PATIENT') c - LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.registered_practice_id = p.id + FROM OLIDS_MASKED.PATIENT c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.registered_practice_id = p.id UNION ALL @@ -620,8 +620,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_masked || '.PATIENT_ADDRESS') c - LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id + FROM OLIDS_MASKED.PATIENT_ADDRESS c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id UNION ALL @@ -631,8 +631,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_masked || '.PATIENT_CONTACT') c - LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id + FROM OLIDS_MASKED.PATIENT_CONTACT c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id UNION ALL @@ -642,8 +642,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.PATIENT_PERSON') c - LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id + FROM OLIDS_COMMON.PATIENT_PERSON c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id UNION ALL @@ -653,8 +653,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.person_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN c.person_id END), SUM(CASE WHEN c.person_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.PATIENT_PERSON') c - LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id + FROM OLIDS_COMMON.PATIENT_PERSON c + LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id UNION ALL @@ -664,8 +664,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') c - LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id + FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id UNION ALL @@ -675,8 +675,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN c.organisation_id END), SUM(CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') c - LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id + FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id UNION ALL @@ -686,8 +686,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') c - LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id + FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id UNION ALL @@ -697,8 +697,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.episode_of_care_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.episode_of_care_id IS NOT NULL AND p.id IS NULL THEN c.episode_of_care_id END), SUM(CASE WHEN c.episode_of_care_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') c - LEFT JOIN IDENTIFIER($schema_common || '.EPISODE_OF_CARE') p ON c.episode_of_care_id = p.id + FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c + LEFT JOIN OLIDS_COMMON.EPISODE_OF_CARE p ON c.episode_of_care_id = p.id UNION ALL @@ -708,8 +708,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.PRACTITIONER_IN_ROLE') c - LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id + FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id UNION ALL @@ -719,8 +719,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN c.organisation_id END), SUM(CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.PRACTITIONER_IN_ROLE') c - LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id + FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id UNION ALL @@ -730,8 +730,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') c - LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id + FROM OLIDS_COMMON.PROCEDURE_REQUEST c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id UNION ALL @@ -741,8 +741,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.encounter_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN c.encounter_id END), SUM(CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') c - LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id + FROM OLIDS_COMMON.PROCEDURE_REQUEST c + LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id UNION ALL @@ -752,8 +752,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') c - LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id + FROM OLIDS_COMMON.PROCEDURE_REQUEST c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id UNION ALL @@ -763,8 +763,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.patient_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN c.patient_id END), SUM(CASE WHEN c.patient_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c - LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id + FROM OLIDS_COMMON.REFERRAL_REQUEST c + LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id UNION ALL @@ -774,8 +774,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.encounter_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN c.encounter_id END), SUM(CASE WHEN c.encounter_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c - LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id + FROM OLIDS_COMMON.REFERRAL_REQUEST c + LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id UNION ALL @@ -785,8 +785,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c - LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id + FROM OLIDS_COMMON.REFERRAL_REQUEST c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id UNION ALL @@ -796,8 +796,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN c.organisation_id END), SUM(CASE WHEN c.organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c - LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id + FROM OLIDS_COMMON.REFERRAL_REQUEST c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id UNION ALL @@ -807,8 +807,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.requester_organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.requester_organisation_id IS NOT NULL AND p.id IS NULL THEN c.requester_organisation_id END), SUM(CASE WHEN c.requester_organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c - LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.requester_organisation_id = p.id + FROM OLIDS_COMMON.REFERRAL_REQUEST c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.requester_organisation_id = p.id UNION ALL @@ -818,8 +818,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.recipient_organisation_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.recipient_organisation_id IS NOT NULL AND p.id IS NULL THEN c.recipient_organisation_id END), SUM(CASE WHEN c.recipient_organisation_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c - LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.recipient_organisation_id = p.id + FROM OLIDS_COMMON.REFERRAL_REQUEST c + LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.recipient_organisation_id = p.id UNION ALL @@ -829,8 +829,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.location_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.location_id IS NOT NULL AND p.id IS NULL THEN c.location_id END), SUM(CASE WHEN c.location_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.SCHEDULE') c - LEFT JOIN IDENTIFIER($schema_common || '.LOCATION') p ON c.location_id = p.id + FROM OLIDS_COMMON.SCHEDULE c + LEFT JOIN OLIDS_COMMON.LOCATION p ON c.location_id = p.id UNION ALL @@ -840,8 +840,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.SCHEDULE') c - LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id + FROM OLIDS_COMMON.SCHEDULE c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id UNION ALL @@ -851,8 +851,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.schedule_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.schedule_id IS NOT NULL AND p.id IS NULL THEN c.schedule_id END), SUM(CASE WHEN c.schedule_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.SCHEDULE_PRACTITIONER') c - LEFT JOIN IDENTIFIER($schema_common || '.SCHEDULE') p ON c.schedule_id = p.id + FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER c + LEFT JOIN OLIDS_COMMON.SCHEDULE p ON c.schedule_id = p.id UNION ALL @@ -862,8 +862,8 @@ WITH fk_checks AS ( SUM(CASE WHEN c.practitioner_id IS NOT NULL THEN 1 ELSE 0 END), COUNT(DISTINCT CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN c.practitioner_id END), SUM(CASE WHEN c.practitioner_id IS NOT NULL AND p.id IS NULL THEN 1 ELSE 0 END) - FROM IDENTIFIER($schema_common || '.SCHEDULE_PRACTITIONER') c - LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id + FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER c + LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id ) SELECT diff --git a/OLIDS/Testing/data-quality/test_registration_pds.sql b/OLIDS/Testing/data-quality/test_registration_pds.sql index 7d3f6e7..83e3dff 100644 --- a/OLIDS/Testing/data-quality/test_registration_pds.sql +++ b/OLIDS/Testing/data-quality/test_registration_pds.sql @@ -52,14 +52,14 @@ SET snapshot_date = ( SELECT LAST_DAY(DATEADD(MONTH, -1, DATEADD(DAY, 1, MAX(CASE WHEN episode_of_care_start_date <= CURRENT_DATE THEN episode_of_care_start_date END)::DATE ))) - FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') + FROM OLIDS_COMMON.EPISODE_OF_CARE WHERE record_owner_organisation_code IS NOT NULL ); -- Practice codes derived from EPISODE_OF_CARE (only practices with actual data) WITH icb_practices AS ( SELECT DISTINCT record_owner_organisation_code AS practice_code - FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') + FROM OLIDS_COMMON.EPISODE_OF_CARE WHERE record_owner_organisation_code IS NOT NULL ), @@ -70,7 +70,7 @@ eligible_patients AS ( sk_patient_id, death_year, death_month - FROM IDENTIFIER($schema_masked || '.PATIENT') + FROM OLIDS_MASKED.PATIENT WHERE sk_patient_id IS NOT NULL AND is_spine_sensitive = FALSE AND is_confidential = FALSE @@ -101,20 +101,20 @@ patient_death_dates AS ( -- Step 3: Map patient_id to person_id (OLIDS deduplicates by person, not patient) patient_to_person AS ( SELECT patient_id, person_id - FROM IDENTIFIER($schema_common || '.PATIENT_PERSON') + FROM OLIDS_COMMON.PATIENT_PERSON WHERE patient_id IS NOT NULL AND person_id IS NOT NULL ), -- Step 4: Look up concept IDs for 'Regular' episode type and 'Left' status episode_type_regular AS ( SELECT source_code_id - FROM IDENTIFIER($schema_terminology || '.CONCEPT_MAP') + FROM OLIDS_TERMINOLOGY.CONCEPT_MAP WHERE source_code = 'Regular' ), episode_status_left AS ( SELECT source_code_id - FROM IDENTIFIER($schema_terminology || '.CONCEPT_MAP') + FROM OLIDS_TERMINOLOGY.CONCEPT_MAP WHERE source_code = 'Left' ), @@ -126,7 +126,7 @@ filtered_episodes AS ( eoc.record_owner_organisation_code AS practice_code, eoc.organisation_id, eoc.episode_of_care_start_date - FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') eoc + FROM OLIDS_COMMON.EPISODE_OF_CARE eoc INNER JOIN patient_death_dates pdd ON eoc.patient_id = pdd.patient_id INNER JOIN patient_to_person ptp ON eoc.patient_id = ptp.patient_id INNER JOIN episode_type_regular etr ON eoc.episode_type_source_concept_id = etr.source_code_id diff --git a/OLIDS/Testing/investigations/investigate_column_completeness.sql b/OLIDS/Testing/investigations/investigate_column_completeness.sql index 78fe8e1..41765f9 100644 --- a/OLIDS/Testing/investigations/investigate_column_completeness.sql +++ b/OLIDS/Testing/investigations/investigate_column_completeness.sql @@ -19,176 +19,176 @@ SET schema_terminology = 'OLIDS_TERMINOLOGY'; WITH checks AS ( -- PATIENT (OLIDS_MASKED) - SELECT 'PATIENT' AS table_name, 'id' AS column_name, 0.0 AS threshold, COUNT(*) AS total_rows, SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) AS null_count FROM IDENTIFIER($schema_masked || '.PATIENT') - UNION ALL SELECT 'PATIENT', 'sk_patient_id', 0.5, COUNT(*), SUM(CASE WHEN sk_patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT') - UNION ALL SELECT 'PATIENT', 'birth_year', 1.0, COUNT(*), SUM(CASE WHEN birth_year IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT') - UNION ALL SELECT 'PATIENT', 'birth_month', 1.0, COUNT(*), SUM(CASE WHEN birth_month IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT') - UNION ALL SELECT 'PATIENT', 'gender_concept_id', 5.0, COUNT(*), SUM(CASE WHEN gender_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT') - UNION ALL SELECT 'PATIENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT') + SELECT 'PATIENT' AS table_name, 'id' AS column_name, 0.0 AS threshold, COUNT(*) AS total_rows, SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) AS null_count FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'sk_patient_id', 0.5, COUNT(*), SUM(CASE WHEN sk_patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'birth_year', 1.0, COUNT(*), SUM(CASE WHEN birth_year IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'birth_month', 1.0, COUNT(*), SUM(CASE WHEN birth_month IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'gender_concept_id', 5.0, COUNT(*), SUM(CASE WHEN gender_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT -- PERSON (OLIDS_MASKED) - UNION ALL SELECT 'PERSON', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PERSON') - UNION ALL SELECT 'PERSON', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PERSON') + UNION ALL SELECT 'PERSON', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PERSON + UNION ALL SELECT 'PERSON', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PERSON -- PATIENT_ADDRESS (OLIDS_MASKED) - UNION ALL SELECT 'PATIENT_ADDRESS', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_ADDRESS') - UNION ALL SELECT 'PATIENT_ADDRESS', 'address_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN address_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_ADDRESS') - UNION ALL SELECT 'PATIENT_ADDRESS', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_ADDRESS') + UNION ALL SELECT 'PATIENT_ADDRESS', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS + UNION ALL SELECT 'PATIENT_ADDRESS', 'address_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN address_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS + UNION ALL SELECT 'PATIENT_ADDRESS', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_ADDRESS -- PATIENT_CONTACT (OLIDS_MASKED) - UNION ALL SELECT 'PATIENT_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_CONTACT') - UNION ALL SELECT 'PATIENT_CONTACT', 'contact_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_CONTACT') - UNION ALL SELECT 'PATIENT_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_CONTACT') + UNION ALL SELECT 'PATIENT_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT + UNION ALL SELECT 'PATIENT_CONTACT', 'contact_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT + UNION ALL SELECT 'PATIENT_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_CONTACT -- PATIENT_UPRN (OLIDS_MASKED) - UNION ALL SELECT 'PATIENT_UPRN', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_UPRN') - UNION ALL SELECT 'PATIENT_UPRN', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_masked || '.PATIENT_UPRN') + UNION ALL SELECT 'PATIENT_UPRN', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_UPRN + UNION ALL SELECT 'PATIENT_UPRN', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT_UPRN -- PATIENT_PERSON (OLIDS_COMMON) - UNION ALL SELECT 'PATIENT_PERSON', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PATIENT_PERSON') - UNION ALL SELECT 'PATIENT_PERSON', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PATIENT_PERSON') + UNION ALL SELECT 'PATIENT_PERSON', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_PERSON + UNION ALL SELECT 'PATIENT_PERSON', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_PERSON -- EPISODE_OF_CARE (OLIDS_COMMON) - UNION ALL SELECT 'EPISODE_OF_CARE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') - UNION ALL SELECT 'EPISODE_OF_CARE', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') - UNION ALL SELECT 'EPISODE_OF_CARE', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') - UNION ALL SELECT 'EPISODE_OF_CARE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') - UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_of_care_start_date', 1.0, COUNT(*), SUM(CASE WHEN episode_of_care_start_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') - UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_type_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_type_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') - UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_status_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_status_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') + UNION ALL SELECT 'EPISODE_OF_CARE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_of_care_start_date', 1.0, COUNT(*), SUM(CASE WHEN episode_of_care_start_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_type_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_type_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'episode_status_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episode_status_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.EPISODE_OF_CARE -- OBSERVATION (OLIDS_COMMON) - UNION ALL SELECT 'OBSERVATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') - UNION ALL SELECT 'OBSERVATION', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') - UNION ALL SELECT 'OBSERVATION', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') - UNION ALL SELECT 'OBSERVATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') - UNION ALL SELECT 'OBSERVATION', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') - UNION ALL SELECT 'OBSERVATION', 'observation_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN observation_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') - UNION ALL SELECT 'OBSERVATION', 'result_value_units_concept_id', 5.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') - UNION ALL SELECT 'OBSERVATION', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') - UNION ALL SELECT 'OBSERVATION', 'episodicity_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.OBSERVATION') + UNION ALL SELECT 'OBSERVATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'observation_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN observation_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'result_value_units_concept_id', 5.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'episodicity_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.OBSERVATION -- MEDICATION_STATEMENT (OLIDS_COMMON) - UNION ALL SELECT 'MEDICATION_STATEMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') - UNION ALL SELECT 'MEDICATION_STATEMENT', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') - UNION ALL SELECT 'MEDICATION_STATEMENT', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') - UNION ALL SELECT 'MEDICATION_STATEMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') - UNION ALL SELECT 'MEDICATION_STATEMENT', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') - UNION ALL SELECT 'MEDICATION_STATEMENT', 'medication_statement_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN medication_statement_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') - UNION ALL SELECT 'MEDICATION_STATEMENT', 'authorisation_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN authorisation_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') - UNION ALL SELECT 'MEDICATION_STATEMENT', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') + UNION ALL SELECT 'MEDICATION_STATEMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'medication_statement_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN medication_statement_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'authorisation_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN authorisation_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_STATEMENT -- MEDICATION_ORDER (OLIDS_COMMON) - UNION ALL SELECT 'MEDICATION_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') - UNION ALL SELECT 'MEDICATION_ORDER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') - UNION ALL SELECT 'MEDICATION_ORDER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') - UNION ALL SELECT 'MEDICATION_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') - UNION ALL SELECT 'MEDICATION_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') - UNION ALL SELECT 'MEDICATION_ORDER', 'medication_order_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN medication_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') - UNION ALL SELECT 'MEDICATION_ORDER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') + UNION ALL SELECT 'MEDICATION_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'medication_order_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN medication_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.MEDICATION_ORDER -- DIAGNOSTIC_ORDER (OLIDS_COMMON) - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'diagnostic_order_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN diagnostic_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'result_value_units_concept_id', 5.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') - UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'episodicity_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'diagnostic_order_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN diagnostic_order_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'result_value_units_concept_id', 5.0, COUNT(*), SUM(CASE WHEN result_value_units_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'episodicity_concept_id', 5.0, COUNT(*), SUM(CASE WHEN episodicity_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER -- ENCOUNTER (OLIDS_COMMON) - UNION ALL SELECT 'ENCOUNTER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') - UNION ALL SELECT 'ENCOUNTER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') - UNION ALL SELECT 'ENCOUNTER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') - UNION ALL SELECT 'ENCOUNTER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') - UNION ALL SELECT 'ENCOUNTER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') - UNION ALL SELECT 'ENCOUNTER', 'encounter_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN encounter_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') - UNION ALL SELECT 'ENCOUNTER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ENCOUNTER') + UNION ALL SELECT 'ENCOUNTER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'encounter_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN encounter_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ENCOUNTER -- ALLERGY_INTOLERANCE (OLIDS_COMMON) - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'allergy_intolerance_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN allergy_intolerance_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') - UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'patient_id', 0.5, COUNT(*), SUM(CASE WHEN patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'person_id', 0.5, COUNT(*), SUM(CASE WHEN person_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'allergy_intolerance_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN allergy_intolerance_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE -- PROCEDURE_REQUEST (OLIDS_COMMON) - UNION ALL SELECT 'PROCEDURE_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') - UNION ALL SELECT 'PROCEDURE_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') - UNION ALL SELECT 'PROCEDURE_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') - UNION ALL SELECT 'PROCEDURE_REQUEST', 'procedure_request_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN procedure_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') - UNION ALL SELECT 'PROCEDURE_REQUEST', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') - UNION ALL SELECT 'PROCEDURE_REQUEST', 'status_concept_id', 5.0, COUNT(*), SUM(CASE WHEN status_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') + UNION ALL SELECT 'PROCEDURE_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'procedure_request_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN procedure_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'status_concept_id', 5.0, COUNT(*), SUM(CASE WHEN status_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PROCEDURE_REQUEST -- REFERRAL_REQUEST (OLIDS_COMMON) - UNION ALL SELECT 'REFERRAL_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') - UNION ALL SELECT 'REFERRAL_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') - UNION ALL SELECT 'REFERRAL_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') - UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') - UNION ALL SELECT 'REFERRAL_REQUEST', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') - UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_priority_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_priority_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') - UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') - UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_specialty_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_specialty_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') + UNION ALL SELECT 'REFERRAL_REQUEST', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'clinical_effective_date', 1.0, COUNT(*), SUM(CASE WHEN clinical_effective_date IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_source_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_source_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'date_precision_concept_id', 5.0, COUNT(*), SUM(CASE WHEN date_precision_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_priority_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_priority_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'referral_request_specialty_concept_id', 5.0, COUNT(*), SUM(CASE WHEN referral_request_specialty_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.REFERRAL_REQUEST -- LOCATION_CONTACT (OLIDS_COMMON) - UNION ALL SELECT 'LOCATION_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.LOCATION_CONTACT') - UNION ALL SELECT 'LOCATION_CONTACT', 'contact_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.LOCATION_CONTACT') - UNION ALL SELECT 'LOCATION_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.LOCATION_CONTACT') + UNION ALL SELECT 'LOCATION_CONTACT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT + UNION ALL SELECT 'LOCATION_CONTACT', 'contact_type_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_type_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT + UNION ALL SELECT 'LOCATION_CONTACT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION_CONTACT -- APPOINTMENT (OLIDS_COMMON) - UNION ALL SELECT 'APPOINTMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT') - UNION ALL SELECT 'APPOINTMENT', 'appointment_status_concept_id', 5.0, COUNT(*), SUM(CASE WHEN appointment_status_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT') - UNION ALL SELECT 'APPOINTMENT', 'booking_method_concept_id', 5.0, COUNT(*), SUM(CASE WHEN booking_method_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT') - UNION ALL SELECT 'APPOINTMENT', 'contact_mode_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_mode_concept_id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT') - UNION ALL SELECT 'APPOINTMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT') + UNION ALL SELECT 'APPOINTMENT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'appointment_status_concept_id', 5.0, COUNT(*), SUM(CASE WHEN appointment_status_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'booking_method_concept_id', 5.0, COUNT(*), SUM(CASE WHEN booking_method_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'contact_mode_concept_id', 5.0, COUNT(*), SUM(CASE WHEN contact_mode_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT -- APPOINTMENT_PRACTITIONER (OLIDS_COMMON) - UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT_PRACTITIONER') - UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.APPOINTMENT_PRACTITIONER') + UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER + UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER -- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE (OLIDS_COMMON) - UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') - UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') + UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE + UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE -- LOCATION (OLIDS_COMMON) - UNION ALL SELECT 'LOCATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.LOCATION') - UNION ALL SELECT 'LOCATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.LOCATION') + UNION ALL SELECT 'LOCATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION + UNION ALL SELECT 'LOCATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.LOCATION -- FLAG (OLIDS_COMMON) - UNION ALL SELECT 'FLAG', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.FLAG') - UNION ALL SELECT 'FLAG', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.FLAG') + UNION ALL SELECT 'FLAG', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.FLAG + UNION ALL SELECT 'FLAG', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.FLAG -- ORGANISATION (OLIDS_COMMON) - UNION ALL SELECT 'ORGANISATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ORGANISATION') - UNION ALL SELECT 'ORGANISATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.ORGANISATION') + UNION ALL SELECT 'ORGANISATION', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ORGANISATION + UNION ALL SELECT 'ORGANISATION', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.ORGANISATION -- PRACTITIONER (OLIDS_COMMON) - UNION ALL SELECT 'PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PRACTITIONER') - UNION ALL SELECT 'PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PRACTITIONER') + UNION ALL SELECT 'PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER + UNION ALL SELECT 'PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER -- PRACTITIONER_IN_ROLE (OLIDS_COMMON) - UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PRACTITIONER_IN_ROLE') - UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.PRACTITIONER_IN_ROLE') + UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE + UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE -- SCHEDULE (OLIDS_COMMON) - UNION ALL SELECT 'SCHEDULE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.SCHEDULE') - UNION ALL SELECT 'SCHEDULE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.SCHEDULE') + UNION ALL SELECT 'SCHEDULE', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE + UNION ALL SELECT 'SCHEDULE', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE -- SCHEDULE_PRACTITIONER (OLIDS_COMMON) - UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.SCHEDULE_PRACTITIONER') - UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_common || '.SCHEDULE_PRACTITIONER') + UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER + UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER -- CONCEPT (OLIDS_TERMINOLOGY) - UNION ALL SELECT 'CONCEPT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_terminology || '.CONCEPT') - UNION ALL SELECT 'CONCEPT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_terminology || '.CONCEPT') + UNION ALL SELECT 'CONCEPT', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT + UNION ALL SELECT 'CONCEPT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT -- CONCEPT_MAP (OLIDS_TERMINOLOGY) - UNION ALL SELECT 'CONCEPT_MAP', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_terminology || '.CONCEPT_MAP') - UNION ALL SELECT 'CONCEPT_MAP', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM IDENTIFIER($schema_terminology || '.CONCEPT_MAP') + UNION ALL SELECT 'CONCEPT_MAP', 'id', 0.0, COUNT(*), SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT_MAP + UNION ALL SELECT 'CONCEPT_MAP', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_TERMINOLOGY.CONCEPT_MAP ) SELECT diff --git a/OLIDS/Testing/investigations/investigate_concept_mapping.sql b/OLIDS/Testing/investigations/investigate_concept_mapping.sql index e1ff800..8aa1960 100644 --- a/OLIDS/Testing/investigations/investigate_concept_mapping.sql +++ b/OLIDS/Testing/investigations/investigate_concept_mapping.sql @@ -20,9 +20,9 @@ WITH unmapped AS ( SELECT 'OBSERVATION' AS table_name, 'observation_source_concept_id' AS concept_field, base.observation_source_concept_id AS concept_id, COUNT(*) AS row_count, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END AS reason - FROM IDENTIFIER($schema_common || '.OBSERVATION') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.observation_source_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.OBSERVATION base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.observation_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.observation_source_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.observation_source_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -30,9 +30,9 @@ WITH unmapped AS ( SELECT 'OBSERVATION', 'result_value_units_concept_id', base.result_value_units_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM IDENTIFIER($schema_common || '.OBSERVATION') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.result_value_units_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.OBSERVATION base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.result_value_units_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.result_value_units_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.result_value_units_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -40,9 +40,9 @@ WITH unmapped AS ( SELECT 'MEDICATION_STATEMENT', 'medication_statement_source_concept_id', base.medication_statement_source_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.medication_statement_source_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.MEDICATION_STATEMENT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.medication_statement_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.medication_statement_source_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.medication_statement_source_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -50,9 +50,9 @@ WITH unmapped AS ( SELECT 'MEDICATION_STATEMENT', 'authorisation_type_concept_id', base.authorisation_type_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.authorisation_type_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.MEDICATION_STATEMENT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.authorisation_type_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.authorisation_type_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.authorisation_type_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -60,9 +60,9 @@ WITH unmapped AS ( SELECT 'MEDICATION_ORDER', 'medication_order_source_concept_id', base.medication_order_source_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.medication_order_source_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.MEDICATION_ORDER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.medication_order_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.medication_order_source_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.medication_order_source_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -70,9 +70,9 @@ WITH unmapped AS ( SELECT 'DIAGNOSTIC_ORDER', 'result_value_units_concept_id', base.result_value_units_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.result_value_units_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.result_value_units_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.result_value_units_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.result_value_units_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -80,9 +80,9 @@ WITH unmapped AS ( SELECT 'PROCEDURE_REQUEST', 'procedure_request_source_concept_id', base.procedure_request_source_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.procedure_request_source_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.PROCEDURE_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.procedure_request_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.procedure_request_source_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.procedure_request_source_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -90,9 +90,9 @@ WITH unmapped AS ( SELECT 'PROCEDURE_REQUEST', 'status_concept_id', base.status_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.status_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.PROCEDURE_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.status_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.status_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.status_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -100,9 +100,9 @@ WITH unmapped AS ( SELECT 'REFERRAL_REQUEST', 'referral_request_priority_concept_id', base.referral_request_priority_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.referral_request_priority_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.REFERRAL_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_priority_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.referral_request_priority_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.referral_request_priority_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -110,9 +110,9 @@ WITH unmapped AS ( SELECT 'REFERRAL_REQUEST', 'referral_request_type_concept_id', base.referral_request_type_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.referral_request_type_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.REFERRAL_REQUEST base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.referral_request_type_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.referral_request_type_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.referral_request_type_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -120,9 +120,9 @@ WITH unmapped AS ( SELECT 'ENCOUNTER', 'encounter_source_concept_id', base.encounter_source_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM IDENTIFIER($schema_common || '.ENCOUNTER') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.encounter_source_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.ENCOUNTER base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.encounter_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.encounter_source_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.encounter_source_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -130,9 +130,9 @@ WITH unmapped AS ( SELECT 'ALLERGY_INTOLERANCE', 'allergy_intolerance_source_concept_id', base.allergy_intolerance_source_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.allergy_intolerance_source_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.ALLERGY_INTOLERANCE base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.allergy_intolerance_source_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.allergy_intolerance_source_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.allergy_intolerance_source_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END @@ -140,9 +140,9 @@ WITH unmapped AS ( SELECT 'APPOINTMENT', 'booking_method_concept_id', base.booking_method_concept_id, COUNT(*), CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END - FROM IDENTIFIER($schema_common || '.APPOINTMENT') base - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT_MAP') cm ON base.booking_method_concept_id = cm.source_code_id - LEFT JOIN IDENTIFIER($schema_terminology || '.CONCEPT') c ON cm.target_code_id = c.id + FROM OLIDS_COMMON.APPOINTMENT base + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT_MAP cm ON base.booking_method_concept_id = cm.source_code_id + LEFT JOIN OLIDS_TERMINOLOGY.CONCEPT c ON cm.target_code_id = c.id WHERE base.booking_method_concept_id IS NOT NULL AND (cm.source_code_id IS NULL OR c.id IS NULL) GROUP BY base.booking_method_concept_id, CASE WHEN cm.source_code_id IS NULL THEN 'NOT IN CONCEPT_MAP' ELSE 'TARGET CONCEPT MISSING' END ) diff --git a/OLIDS/Testing/investigations/investigate_data_freshness.sql b/OLIDS/Testing/investigations/investigate_data_freshness.sql index 8e2d78d..ebdd27a 100644 --- a/OLIDS/Testing/investigations/investigate_data_freshness.sql +++ b/OLIDS/Testing/investigations/investigate_data_freshness.sql @@ -20,56 +20,56 @@ WITH org_freshness AS ( SELECT 'OBSERVATION' AS table_name, record_owner_organisation_code AS org_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END) AS last_date_recorded, DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) AS days_since - FROM IDENTIFIER($schema_common || '.OBSERVATION') WHERE record_owner_organisation_code IS NOT NULL + FROM OLIDS_COMMON.OBSERVATION WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL SELECT 'ENCOUNTER', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM IDENTIFIER($schema_common || '.ENCOUNTER') WHERE record_owner_organisation_code IS NOT NULL + FROM OLIDS_COMMON.ENCOUNTER WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL SELECT 'MEDICATION_ORDER', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') WHERE record_owner_organisation_code IS NOT NULL + FROM OLIDS_COMMON.MEDICATION_ORDER WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL SELECT 'MEDICATION_STATEMENT', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') WHERE record_owner_organisation_code IS NOT NULL + FROM OLIDS_COMMON.MEDICATION_STATEMENT WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL SELECT 'DIAGNOSTIC_ORDER', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') WHERE record_owner_organisation_code IS NOT NULL + FROM OLIDS_COMMON.DIAGNOSTIC_ORDER WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL SELECT 'ALLERGY_INTOLERANCE', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') WHERE record_owner_organisation_code IS NOT NULL + FROM OLIDS_COMMON.ALLERGY_INTOLERANCE WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL SELECT 'PROCEDURE_REQUEST', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') WHERE record_owner_organisation_code IS NOT NULL + FROM OLIDS_COMMON.PROCEDURE_REQUEST WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code UNION ALL SELECT 'REFERRAL_REQUEST', record_owner_organisation_code, MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), DATEDIFF('day', MAX(CASE WHEN date_recorded <= CURRENT_DATE THEN date_recorded END), CURRENT_DATE) - FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') WHERE record_owner_organisation_code IS NOT NULL + FROM OLIDS_COMMON.REFERRAL_REQUEST WHERE record_owner_organisation_code IS NOT NULL GROUP BY record_owner_organisation_code ) diff --git a/OLIDS/Testing/investigations/investigate_referential_integrity.sql b/OLIDS/Testing/investigations/investigate_referential_integrity.sql index ac5f033..e715420 100644 --- a/OLIDS/Testing/investigations/investigate_referential_integrity.sql +++ b/OLIDS/Testing/investigations/investigate_referential_integrity.sql @@ -18,8 +18,8 @@ SET schema_terminology = 'OLIDS_TERMINOLOGY'; -- ALLERGY_INTOLERANCE -> PATIENT SELECT 'ALLERGY_INTOLERANCE' AS child_table, 'patient_id' AS fk_column, 'PATIENT' AS parent_table, c.patient_id AS orphaned_value, COUNT(*) AS row_count -FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') c -LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id +FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -28,8 +28,8 @@ UNION ALL -- ALLERGY_INTOLERANCE -> PERSON SELECT 'ALLERGY_INTOLERANCE', 'person_id', 'PERSON', c.person_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') c -LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id +FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c +LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id WHERE c.person_id IS NOT NULL AND p.id IS NULL GROUP BY c.person_id @@ -38,8 +38,8 @@ UNION ALL -- ALLERGY_INTOLERANCE -> ENCOUNTER SELECT 'ALLERGY_INTOLERANCE', 'encounter_id', 'ENCOUNTER', c.encounter_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') c -LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id +FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c +LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id WHERE c.encounter_id IS NOT NULL AND p.id IS NULL GROUP BY c.encounter_id @@ -48,8 +48,8 @@ UNION ALL -- ALLERGY_INTOLERANCE -> PRACTITIONER SELECT 'ALLERGY_INTOLERANCE', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') c -LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id +FROM OLIDS_COMMON.ALLERGY_INTOLERANCE c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -58,8 +58,8 @@ UNION ALL -- APPOINTMENT -> PATIENT SELECT 'APPOINTMENT', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.APPOINTMENT') c -LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id +FROM OLIDS_COMMON.APPOINTMENT c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -68,8 +68,8 @@ UNION ALL -- APPOINTMENT -> PRACTITIONER_IN_ROLE SELECT 'APPOINTMENT', 'practitioner_in_role_id', 'PRACTITIONER_IN_ROLE', c.practitioner_in_role_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.APPOINTMENT') c -LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER_IN_ROLE') p ON c.practitioner_in_role_id = p.id +FROM OLIDS_COMMON.APPOINTMENT c +LEFT JOIN OLIDS_COMMON.PRACTITIONER_IN_ROLE p ON c.practitioner_in_role_id = p.id WHERE c.practitioner_in_role_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_in_role_id @@ -78,8 +78,8 @@ UNION ALL -- APPOINTMENT -> SCHEDULE SELECT 'APPOINTMENT', 'schedule_id', 'SCHEDULE', c.schedule_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.APPOINTMENT') c -LEFT JOIN IDENTIFIER($schema_common || '.SCHEDULE') p ON c.schedule_id = p.id +FROM OLIDS_COMMON.APPOINTMENT c +LEFT JOIN OLIDS_COMMON.SCHEDULE p ON c.schedule_id = p.id WHERE c.schedule_id IS NOT NULL AND p.id IS NULL GROUP BY c.schedule_id @@ -88,8 +88,8 @@ UNION ALL -- APPOINTMENT_PRACTITIONER -> APPOINTMENT SELECT 'APPOINTMENT_PRACTITIONER', 'appointment_id', 'APPOINTMENT', c.appointment_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.APPOINTMENT_PRACTITIONER') c -LEFT JOIN IDENTIFIER($schema_common || '.APPOINTMENT') p ON c.appointment_id = p.id +FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER c +LEFT JOIN OLIDS_COMMON.APPOINTMENT p ON c.appointment_id = p.id WHERE c.appointment_id IS NOT NULL AND p.id IS NULL GROUP BY c.appointment_id @@ -98,8 +98,8 @@ UNION ALL -- APPOINTMENT_PRACTITIONER -> PRACTITIONER SELECT 'APPOINTMENT_PRACTITIONER', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.APPOINTMENT_PRACTITIONER') c -LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id +FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -108,8 +108,8 @@ UNION ALL -- DIAGNOSTIC_ORDER -> PATIENT SELECT 'DIAGNOSTIC_ORDER', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') c -LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id +FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -118,8 +118,8 @@ UNION ALL -- DIAGNOSTIC_ORDER -> PERSON SELECT 'DIAGNOSTIC_ORDER', 'person_id', 'PERSON', c.person_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') c -LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id +FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c +LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id WHERE c.person_id IS NOT NULL AND p.id IS NULL GROUP BY c.person_id @@ -128,8 +128,8 @@ UNION ALL -- DIAGNOSTIC_ORDER -> ENCOUNTER SELECT 'DIAGNOSTIC_ORDER', 'encounter_id', 'ENCOUNTER', c.encounter_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') c -LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id +FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c +LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id WHERE c.encounter_id IS NOT NULL AND p.id IS NULL GROUP BY c.encounter_id @@ -138,8 +138,8 @@ UNION ALL -- DIAGNOSTIC_ORDER -> PRACTITIONER SELECT 'DIAGNOSTIC_ORDER', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') c -LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id +FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -148,8 +148,8 @@ UNION ALL -- DIAGNOSTIC_ORDER -> OBSERVATION (parent) SELECT 'DIAGNOSTIC_ORDER', 'parent_observation_id', 'OBSERVATION', c.parent_observation_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') c -LEFT JOIN IDENTIFIER($schema_common || '.OBSERVATION') p ON c.parent_observation_id = p.id +FROM OLIDS_COMMON.DIAGNOSTIC_ORDER c +LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.parent_observation_id = p.id WHERE c.parent_observation_id IS NOT NULL AND p.id IS NULL GROUP BY c.parent_observation_id @@ -158,8 +158,8 @@ UNION ALL -- ENCOUNTER -> PATIENT SELECT 'ENCOUNTER', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.ENCOUNTER') c -LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id +FROM OLIDS_COMMON.ENCOUNTER c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -168,8 +168,8 @@ UNION ALL -- ENCOUNTER -> PERSON SELECT 'ENCOUNTER', 'person_id', 'PERSON', c.person_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.ENCOUNTER') c -LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id +FROM OLIDS_COMMON.ENCOUNTER c +LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id WHERE c.person_id IS NOT NULL AND p.id IS NULL GROUP BY c.person_id @@ -178,8 +178,8 @@ UNION ALL -- ENCOUNTER -> PRACTITIONER SELECT 'ENCOUNTER', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.ENCOUNTER') c -LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id +FROM OLIDS_COMMON.ENCOUNTER c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -188,8 +188,8 @@ UNION ALL -- ENCOUNTER -> EPISODE_OF_CARE SELECT 'ENCOUNTER', 'episode_of_care_id', 'EPISODE_OF_CARE', c.episode_of_care_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.ENCOUNTER') c -LEFT JOIN IDENTIFIER($schema_common || '.EPISODE_OF_CARE') p ON c.episode_of_care_id = p.id +FROM OLIDS_COMMON.ENCOUNTER c +LEFT JOIN OLIDS_COMMON.EPISODE_OF_CARE p ON c.episode_of_care_id = p.id WHERE c.episode_of_care_id IS NOT NULL AND p.id IS NULL GROUP BY c.episode_of_care_id @@ -198,8 +198,8 @@ UNION ALL -- ENCOUNTER -> APPOINTMENT SELECT 'ENCOUNTER', 'appointment_id', 'APPOINTMENT', c.appointment_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.ENCOUNTER') c -LEFT JOIN IDENTIFIER($schema_common || '.APPOINTMENT') p ON c.appointment_id = p.id +FROM OLIDS_COMMON.ENCOUNTER c +LEFT JOIN OLIDS_COMMON.APPOINTMENT p ON c.appointment_id = p.id WHERE c.appointment_id IS NOT NULL AND p.id IS NULL GROUP BY c.appointment_id @@ -208,8 +208,8 @@ UNION ALL -- ENCOUNTER -> ORGANISATION (service provider) SELECT 'ENCOUNTER', 'service_provider_organisation_id', 'ORGANISATION', c.service_provider_organisation_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.ENCOUNTER') c -LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.service_provider_organisation_id = p.id +FROM OLIDS_COMMON.ENCOUNTER c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.service_provider_organisation_id = p.id WHERE c.service_provider_organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.service_provider_organisation_id @@ -218,8 +218,8 @@ UNION ALL -- EPISODE_OF_CARE -> PATIENT SELECT 'EPISODE_OF_CARE', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') c -LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id +FROM OLIDS_COMMON.EPISODE_OF_CARE c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -228,8 +228,8 @@ UNION ALL -- EPISODE_OF_CARE -> PERSON SELECT 'EPISODE_OF_CARE', 'person_id', 'PERSON', c.person_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') c -LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id +FROM OLIDS_COMMON.EPISODE_OF_CARE c +LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id WHERE c.person_id IS NOT NULL AND p.id IS NULL GROUP BY c.person_id @@ -238,8 +238,8 @@ UNION ALL -- EPISODE_OF_CARE -> ORGANISATION SELECT 'EPISODE_OF_CARE', 'organisation_id', 'ORGANISATION', c.organisation_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') c -LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id +FROM OLIDS_COMMON.EPISODE_OF_CARE c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id WHERE c.organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.organisation_id @@ -248,8 +248,8 @@ UNION ALL -- EPISODE_OF_CARE -> PRACTITIONER (care manager) SELECT 'EPISODE_OF_CARE', 'care_manager_practitioner_id', 'PRACTITIONER', c.care_manager_practitioner_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') c -LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.care_manager_practitioner_id = p.id +FROM OLIDS_COMMON.EPISODE_OF_CARE c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.care_manager_practitioner_id = p.id WHERE c.care_manager_practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.care_manager_practitioner_id @@ -258,8 +258,8 @@ UNION ALL -- FLAG -> PATIENT SELECT 'FLAG', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.FLAG') c -LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id +FROM OLIDS_COMMON.FLAG c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -268,8 +268,8 @@ UNION ALL -- LOCATION -> ORGANISATION (managing) SELECT 'LOCATION', 'managing_organisation_id', 'ORGANISATION', c.managing_organisation_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.LOCATION') c -LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.managing_organisation_id = p.id +FROM OLIDS_COMMON.LOCATION c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.managing_organisation_id = p.id WHERE c.managing_organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.managing_organisation_id @@ -278,8 +278,8 @@ UNION ALL -- LOCATION_CONTACT -> LOCATION SELECT 'LOCATION_CONTACT', 'location_id', 'LOCATION', c.location_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.LOCATION_CONTACT') c -LEFT JOIN IDENTIFIER($schema_common || '.LOCATION') p ON c.location_id = p.id +FROM OLIDS_COMMON.LOCATION_CONTACT c +LEFT JOIN OLIDS_COMMON.LOCATION p ON c.location_id = p.id WHERE c.location_id IS NOT NULL AND p.id IS NULL GROUP BY c.location_id @@ -288,8 +288,8 @@ UNION ALL -- MEDICATION_ORDER -> PATIENT SELECT 'MEDICATION_ORDER', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c -LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id +FROM OLIDS_COMMON.MEDICATION_ORDER c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -298,8 +298,8 @@ UNION ALL -- MEDICATION_ORDER -> PERSON SELECT 'MEDICATION_ORDER', 'person_id', 'PERSON', c.person_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c -LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id +FROM OLIDS_COMMON.MEDICATION_ORDER c +LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id WHERE c.person_id IS NOT NULL AND p.id IS NULL GROUP BY c.person_id @@ -308,8 +308,8 @@ UNION ALL -- MEDICATION_ORDER -> MEDICATION_STATEMENT SELECT 'MEDICATION_ORDER', 'medication_statement_id', 'MEDICATION_STATEMENT', c.medication_statement_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c -LEFT JOIN IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') p ON c.medication_statement_id = p.id +FROM OLIDS_COMMON.MEDICATION_ORDER c +LEFT JOIN OLIDS_COMMON.MEDICATION_STATEMENT p ON c.medication_statement_id = p.id WHERE c.medication_statement_id IS NOT NULL AND p.id IS NULL GROUP BY c.medication_statement_id @@ -318,8 +318,8 @@ UNION ALL -- MEDICATION_ORDER -> ORGANISATION SELECT 'MEDICATION_ORDER', 'organisation_id', 'ORGANISATION', c.organisation_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c -LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id +FROM OLIDS_COMMON.MEDICATION_ORDER c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id WHERE c.organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.organisation_id @@ -328,8 +328,8 @@ UNION ALL -- MEDICATION_ORDER -> ENCOUNTER SELECT 'MEDICATION_ORDER', 'encounter_id', 'ENCOUNTER', c.encounter_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c -LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id +FROM OLIDS_COMMON.MEDICATION_ORDER c +LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id WHERE c.encounter_id IS NOT NULL AND p.id IS NULL GROUP BY c.encounter_id @@ -338,8 +338,8 @@ UNION ALL -- MEDICATION_ORDER -> PRACTITIONER SELECT 'MEDICATION_ORDER', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c -LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id +FROM OLIDS_COMMON.MEDICATION_ORDER c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -348,8 +348,8 @@ UNION ALL -- MEDICATION_ORDER -> OBSERVATION SELECT 'MEDICATION_ORDER', 'observation_id', 'OBSERVATION', c.observation_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c -LEFT JOIN IDENTIFIER($schema_common || '.OBSERVATION') p ON c.observation_id = p.id +FROM OLIDS_COMMON.MEDICATION_ORDER c +LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.observation_id = p.id WHERE c.observation_id IS NOT NULL AND p.id IS NULL GROUP BY c.observation_id @@ -358,8 +358,8 @@ UNION ALL -- MEDICATION_ORDER -> ALLERGY_INTOLERANCE SELECT 'MEDICATION_ORDER', 'allergy_intolerance_id', 'ALLERGY_INTOLERANCE', c.allergy_intolerance_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c -LEFT JOIN IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') p ON c.allergy_intolerance_id = p.id +FROM OLIDS_COMMON.MEDICATION_ORDER c +LEFT JOIN OLIDS_COMMON.ALLERGY_INTOLERANCE p ON c.allergy_intolerance_id = p.id WHERE c.allergy_intolerance_id IS NOT NULL AND p.id IS NULL GROUP BY c.allergy_intolerance_id @@ -368,8 +368,8 @@ UNION ALL -- MEDICATION_ORDER -> DIAGNOSTIC_ORDER SELECT 'MEDICATION_ORDER', 'diagnostic_order_id', 'DIAGNOSTIC_ORDER', c.diagnostic_order_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c -LEFT JOIN IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') p ON c.diagnostic_order_id = p.id +FROM OLIDS_COMMON.MEDICATION_ORDER c +LEFT JOIN OLIDS_COMMON.DIAGNOSTIC_ORDER p ON c.diagnostic_order_id = p.id WHERE c.diagnostic_order_id IS NOT NULL AND p.id IS NULL GROUP BY c.diagnostic_order_id @@ -378,8 +378,8 @@ UNION ALL -- MEDICATION_ORDER -> REFERRAL_REQUEST SELECT 'MEDICATION_ORDER', 'referral_request_id', 'REFERRAL_REQUEST', c.referral_request_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.MEDICATION_ORDER') c -LEFT JOIN IDENTIFIER($schema_common || '.REFERRAL_REQUEST') p ON c.referral_request_id = p.id +FROM OLIDS_COMMON.MEDICATION_ORDER c +LEFT JOIN OLIDS_COMMON.REFERRAL_REQUEST p ON c.referral_request_id = p.id WHERE c.referral_request_id IS NOT NULL AND p.id IS NULL GROUP BY c.referral_request_id @@ -388,8 +388,8 @@ UNION ALL -- MEDICATION_STATEMENT -> PATIENT SELECT 'MEDICATION_STATEMENT', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c -LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id +FROM OLIDS_COMMON.MEDICATION_STATEMENT c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -398,8 +398,8 @@ UNION ALL -- MEDICATION_STATEMENT -> PERSON SELECT 'MEDICATION_STATEMENT', 'person_id', 'PERSON', c.person_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c -LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id +FROM OLIDS_COMMON.MEDICATION_STATEMENT c +LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id WHERE c.person_id IS NOT NULL AND p.id IS NULL GROUP BY c.person_id @@ -408,8 +408,8 @@ UNION ALL -- MEDICATION_STATEMENT -> ORGANISATION SELECT 'MEDICATION_STATEMENT', 'organisation_id', 'ORGANISATION', c.organisation_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c -LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id +FROM OLIDS_COMMON.MEDICATION_STATEMENT c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id WHERE c.organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.organisation_id @@ -418,8 +418,8 @@ UNION ALL -- MEDICATION_STATEMENT -> ENCOUNTER SELECT 'MEDICATION_STATEMENT', 'encounter_id', 'ENCOUNTER', c.encounter_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c -LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id +FROM OLIDS_COMMON.MEDICATION_STATEMENT c +LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id WHERE c.encounter_id IS NOT NULL AND p.id IS NULL GROUP BY c.encounter_id @@ -428,8 +428,8 @@ UNION ALL -- MEDICATION_STATEMENT -> PRACTITIONER SELECT 'MEDICATION_STATEMENT', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c -LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id +FROM OLIDS_COMMON.MEDICATION_STATEMENT c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -438,8 +438,8 @@ UNION ALL -- MEDICATION_STATEMENT -> OBSERVATION SELECT 'MEDICATION_STATEMENT', 'observation_id', 'OBSERVATION', c.observation_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c -LEFT JOIN IDENTIFIER($schema_common || '.OBSERVATION') p ON c.observation_id = p.id +FROM OLIDS_COMMON.MEDICATION_STATEMENT c +LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.observation_id = p.id WHERE c.observation_id IS NOT NULL AND p.id IS NULL GROUP BY c.observation_id @@ -448,8 +448,8 @@ UNION ALL -- MEDICATION_STATEMENT -> ALLERGY_INTOLERANCE SELECT 'MEDICATION_STATEMENT', 'allergy_intolerance_id', 'ALLERGY_INTOLERANCE', c.allergy_intolerance_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c -LEFT JOIN IDENTIFIER($schema_common || '.ALLERGY_INTOLERANCE') p ON c.allergy_intolerance_id = p.id +FROM OLIDS_COMMON.MEDICATION_STATEMENT c +LEFT JOIN OLIDS_COMMON.ALLERGY_INTOLERANCE p ON c.allergy_intolerance_id = p.id WHERE c.allergy_intolerance_id IS NOT NULL AND p.id IS NULL GROUP BY c.allergy_intolerance_id @@ -458,8 +458,8 @@ UNION ALL -- MEDICATION_STATEMENT -> DIAGNOSTIC_ORDER SELECT 'MEDICATION_STATEMENT', 'diagnostic_order_id', 'DIAGNOSTIC_ORDER', c.diagnostic_order_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c -LEFT JOIN IDENTIFIER($schema_common || '.DIAGNOSTIC_ORDER') p ON c.diagnostic_order_id = p.id +FROM OLIDS_COMMON.MEDICATION_STATEMENT c +LEFT JOIN OLIDS_COMMON.DIAGNOSTIC_ORDER p ON c.diagnostic_order_id = p.id WHERE c.diagnostic_order_id IS NOT NULL AND p.id IS NULL GROUP BY c.diagnostic_order_id @@ -468,8 +468,8 @@ UNION ALL -- MEDICATION_STATEMENT -> REFERRAL_REQUEST SELECT 'MEDICATION_STATEMENT', 'referral_request_id', 'REFERRAL_REQUEST', c.referral_request_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.MEDICATION_STATEMENT') c -LEFT JOIN IDENTIFIER($schema_common || '.REFERRAL_REQUEST') p ON c.referral_request_id = p.id +FROM OLIDS_COMMON.MEDICATION_STATEMENT c +LEFT JOIN OLIDS_COMMON.REFERRAL_REQUEST p ON c.referral_request_id = p.id WHERE c.referral_request_id IS NOT NULL AND p.id IS NULL GROUP BY c.referral_request_id @@ -478,8 +478,8 @@ UNION ALL -- OBSERVATION -> PATIENT SELECT 'OBSERVATION', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.OBSERVATION') c -LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id +FROM OLIDS_COMMON.OBSERVATION c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -488,8 +488,8 @@ UNION ALL -- OBSERVATION -> PERSON SELECT 'OBSERVATION', 'person_id', 'PERSON', c.person_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.OBSERVATION') c -LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id +FROM OLIDS_COMMON.OBSERVATION c +LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id WHERE c.person_id IS NOT NULL AND p.id IS NULL GROUP BY c.person_id @@ -498,8 +498,8 @@ UNION ALL -- OBSERVATION -> ENCOUNTER SELECT 'OBSERVATION', 'encounter_id', 'ENCOUNTER', c.encounter_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.OBSERVATION') c -LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id +FROM OLIDS_COMMON.OBSERVATION c +LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id WHERE c.encounter_id IS NOT NULL AND p.id IS NULL GROUP BY c.encounter_id @@ -508,8 +508,8 @@ UNION ALL -- OBSERVATION -> PRACTITIONER SELECT 'OBSERVATION', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.OBSERVATION') c -LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id +FROM OLIDS_COMMON.OBSERVATION c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -518,8 +518,8 @@ UNION ALL -- OBSERVATION -> OBSERVATION (parent) SELECT 'OBSERVATION', 'parent_observation_id', 'OBSERVATION', c.parent_observation_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.OBSERVATION') c -LEFT JOIN IDENTIFIER($schema_common || '.OBSERVATION') p ON c.parent_observation_id = p.id +FROM OLIDS_COMMON.OBSERVATION c +LEFT JOIN OLIDS_COMMON.OBSERVATION p ON c.parent_observation_id = p.id WHERE c.parent_observation_id IS NOT NULL AND p.id IS NULL GROUP BY c.parent_observation_id @@ -528,8 +528,8 @@ UNION ALL -- ORGANISATION -> ORGANISATION (parent) SELECT 'ORGANISATION', 'parent_organisation_id', 'ORGANISATION', c.parent_organisation_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.ORGANISATION') c -LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.parent_organisation_id = p.id +FROM OLIDS_COMMON.ORGANISATION c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.parent_organisation_id = p.id WHERE c.parent_organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.parent_organisation_id @@ -538,8 +538,8 @@ UNION ALL -- PATIENT -> ORGANISATION (registered practice) SELECT 'PATIENT', 'registered_practice_id', 'ORGANISATION', c.registered_practice_id, COUNT(*) -FROM IDENTIFIER($schema_masked || '.PATIENT') c -LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.registered_practice_id = p.id +FROM OLIDS_MASKED.PATIENT c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.registered_practice_id = p.id WHERE c.registered_practice_id IS NOT NULL AND p.id IS NULL GROUP BY c.registered_practice_id @@ -548,8 +548,8 @@ UNION ALL -- PATIENT_ADDRESS -> PATIENT SELECT 'PATIENT_ADDRESS', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM IDENTIFIER($schema_masked || '.PATIENT_ADDRESS') c -LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id +FROM OLIDS_MASKED.PATIENT_ADDRESS c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -558,8 +558,8 @@ UNION ALL -- PATIENT_CONTACT -> PATIENT SELECT 'PATIENT_CONTACT', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM IDENTIFIER($schema_masked || '.PATIENT_CONTACT') c -LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id +FROM OLIDS_MASKED.PATIENT_CONTACT c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -568,8 +568,8 @@ UNION ALL -- PATIENT_PERSON -> PATIENT SELECT 'PATIENT_PERSON', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.PATIENT_PERSON') c -LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id +FROM OLIDS_COMMON.PATIENT_PERSON c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -578,8 +578,8 @@ UNION ALL -- PATIENT_PERSON -> PERSON SELECT 'PATIENT_PERSON', 'person_id', 'PERSON', c.person_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.PATIENT_PERSON') c -LEFT JOIN IDENTIFIER($schema_masked || '.PERSON') p ON c.person_id = p.id +FROM OLIDS_COMMON.PATIENT_PERSON c +LEFT JOIN OLIDS_MASKED.PERSON p ON c.person_id = p.id WHERE c.person_id IS NOT NULL AND p.id IS NULL GROUP BY c.person_id @@ -588,8 +588,8 @@ UNION ALL -- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE -> PATIENT SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') c -LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id +FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -598,8 +598,8 @@ UNION ALL -- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE -> ORGANISATION SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'organisation_id', 'ORGANISATION', c.organisation_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') c -LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id +FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id WHERE c.organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.organisation_id @@ -608,8 +608,8 @@ UNION ALL -- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE -> PRACTITIONER SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') c -LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id +FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -618,8 +618,8 @@ UNION ALL -- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE -> EPISODE_OF_CARE SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'episode_of_care_id', 'EPISODE_OF_CARE', c.episode_of_care_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE') c -LEFT JOIN IDENTIFIER($schema_common || '.EPISODE_OF_CARE') p ON c.episode_of_care_id = p.id +FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE c +LEFT JOIN OLIDS_COMMON.EPISODE_OF_CARE p ON c.episode_of_care_id = p.id WHERE c.episode_of_care_id IS NOT NULL AND p.id IS NULL GROUP BY c.episode_of_care_id @@ -628,8 +628,8 @@ UNION ALL -- PRACTITIONER_IN_ROLE -> PRACTITIONER SELECT 'PRACTITIONER_IN_ROLE', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.PRACTITIONER_IN_ROLE') c -LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id +FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -638,8 +638,8 @@ UNION ALL -- PRACTITIONER_IN_ROLE -> ORGANISATION SELECT 'PRACTITIONER_IN_ROLE', 'organisation_id', 'ORGANISATION', c.organisation_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.PRACTITIONER_IN_ROLE') c -LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id +FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id WHERE c.organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.organisation_id @@ -648,8 +648,8 @@ UNION ALL -- PROCEDURE_REQUEST -> PATIENT SELECT 'PROCEDURE_REQUEST', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') c -LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id +FROM OLIDS_COMMON.PROCEDURE_REQUEST c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -658,8 +658,8 @@ UNION ALL -- PROCEDURE_REQUEST -> ENCOUNTER SELECT 'PROCEDURE_REQUEST', 'encounter_id', 'ENCOUNTER', c.encounter_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') c -LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id +FROM OLIDS_COMMON.PROCEDURE_REQUEST c +LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id WHERE c.encounter_id IS NOT NULL AND p.id IS NULL GROUP BY c.encounter_id @@ -668,8 +668,8 @@ UNION ALL -- PROCEDURE_REQUEST -> PRACTITIONER SELECT 'PROCEDURE_REQUEST', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.PROCEDURE_REQUEST') c -LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id +FROM OLIDS_COMMON.PROCEDURE_REQUEST c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -678,8 +678,8 @@ UNION ALL -- REFERRAL_REQUEST -> PATIENT SELECT 'REFERRAL_REQUEST', 'patient_id', 'PATIENT', c.patient_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c -LEFT JOIN IDENTIFIER($schema_masked || '.PATIENT') p ON c.patient_id = p.id +FROM OLIDS_COMMON.REFERRAL_REQUEST c +LEFT JOIN OLIDS_MASKED.PATIENT p ON c.patient_id = p.id WHERE c.patient_id IS NOT NULL AND p.id IS NULL GROUP BY c.patient_id @@ -688,8 +688,8 @@ UNION ALL -- REFERRAL_REQUEST -> ENCOUNTER SELECT 'REFERRAL_REQUEST', 'encounter_id', 'ENCOUNTER', c.encounter_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c -LEFT JOIN IDENTIFIER($schema_common || '.ENCOUNTER') p ON c.encounter_id = p.id +FROM OLIDS_COMMON.REFERRAL_REQUEST c +LEFT JOIN OLIDS_COMMON.ENCOUNTER p ON c.encounter_id = p.id WHERE c.encounter_id IS NOT NULL AND p.id IS NULL GROUP BY c.encounter_id @@ -698,8 +698,8 @@ UNION ALL -- REFERRAL_REQUEST -> PRACTITIONER SELECT 'REFERRAL_REQUEST', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c -LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id +FROM OLIDS_COMMON.REFERRAL_REQUEST c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -708,8 +708,8 @@ UNION ALL -- REFERRAL_REQUEST -> ORGANISATION SELECT 'REFERRAL_REQUEST', 'organisation_id', 'ORGANISATION', c.organisation_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c -LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.organisation_id = p.id +FROM OLIDS_COMMON.REFERRAL_REQUEST c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.organisation_id = p.id WHERE c.organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.organisation_id @@ -718,8 +718,8 @@ UNION ALL -- REFERRAL_REQUEST -> ORGANISATION (requester) SELECT 'REFERRAL_REQUEST', 'requester_organisation_id', 'ORGANISATION', c.requester_organisation_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c -LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.requester_organisation_id = p.id +FROM OLIDS_COMMON.REFERRAL_REQUEST c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.requester_organisation_id = p.id WHERE c.requester_organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.requester_organisation_id @@ -728,8 +728,8 @@ UNION ALL -- REFERRAL_REQUEST -> ORGANISATION (recipient) SELECT 'REFERRAL_REQUEST', 'recipient_organisation_id', 'ORGANISATION', c.recipient_organisation_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.REFERRAL_REQUEST') c -LEFT JOIN IDENTIFIER($schema_common || '.ORGANISATION') p ON c.recipient_organisation_id = p.id +FROM OLIDS_COMMON.REFERRAL_REQUEST c +LEFT JOIN OLIDS_COMMON.ORGANISATION p ON c.recipient_organisation_id = p.id WHERE c.recipient_organisation_id IS NOT NULL AND p.id IS NULL GROUP BY c.recipient_organisation_id @@ -738,8 +738,8 @@ UNION ALL -- SCHEDULE -> LOCATION SELECT 'SCHEDULE', 'location_id', 'LOCATION', c.location_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.SCHEDULE') c -LEFT JOIN IDENTIFIER($schema_common || '.LOCATION') p ON c.location_id = p.id +FROM OLIDS_COMMON.SCHEDULE c +LEFT JOIN OLIDS_COMMON.LOCATION p ON c.location_id = p.id WHERE c.location_id IS NOT NULL AND p.id IS NULL GROUP BY c.location_id @@ -748,8 +748,8 @@ UNION ALL -- SCHEDULE -> PRACTITIONER SELECT 'SCHEDULE', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.SCHEDULE') c -LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id +FROM OLIDS_COMMON.SCHEDULE c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id @@ -758,8 +758,8 @@ UNION ALL -- SCHEDULE_PRACTITIONER -> SCHEDULE SELECT 'SCHEDULE_PRACTITIONER', 'schedule_id', 'SCHEDULE', c.schedule_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.SCHEDULE_PRACTITIONER') c -LEFT JOIN IDENTIFIER($schema_common || '.SCHEDULE') p ON c.schedule_id = p.id +FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER c +LEFT JOIN OLIDS_COMMON.SCHEDULE p ON c.schedule_id = p.id WHERE c.schedule_id IS NOT NULL AND p.id IS NULL GROUP BY c.schedule_id @@ -768,8 +768,8 @@ UNION ALL -- SCHEDULE_PRACTITIONER -> PRACTITIONER SELECT 'SCHEDULE_PRACTITIONER', 'practitioner_id', 'PRACTITIONER', c.practitioner_id, COUNT(*) -FROM IDENTIFIER($schema_common || '.SCHEDULE_PRACTITIONER') c -LEFT JOIN IDENTIFIER($schema_common || '.PRACTITIONER') p ON c.practitioner_id = p.id +FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER c +LEFT JOIN OLIDS_COMMON.PRACTITIONER p ON c.practitioner_id = p.id WHERE c.practitioner_id IS NOT NULL AND p.id IS NULL GROUP BY c.practitioner_id diff --git a/OLIDS/Testing/investigations/investigate_registration_pds.sql b/OLIDS/Testing/investigations/investigate_registration_pds.sql index 01184f8..867e1c9 100644 --- a/OLIDS/Testing/investigations/investigate_registration_pds.sql +++ b/OLIDS/Testing/investigations/investigate_registration_pds.sql @@ -22,20 +22,20 @@ SET snapshot_date = ( SELECT LAST_DAY(DATEADD(MONTH, -1, DATEADD(DAY, 1, MAX(CASE WHEN episode_of_care_start_date <= CURRENT_DATE THEN episode_of_care_start_date END)::DATE ))) - FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') + FROM OLIDS_COMMON.EPISODE_OF_CARE WHERE record_owner_organisation_code IS NOT NULL ); -- Practice codes derived from EPISODE_OF_CARE (only practices with actual data) WITH icb_practices AS ( SELECT DISTINCT record_owner_organisation_code AS practice_code - FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') + FROM OLIDS_COMMON.EPISODE_OF_CARE WHERE record_owner_organisation_code IS NOT NULL ), eligible_patients AS ( SELECT id AS patient_id, sk_patient_id, death_year, death_month - FROM IDENTIFIER($schema_masked || '.PATIENT') + FROM OLIDS_MASKED.PATIENT WHERE sk_patient_id IS NOT NULL AND is_spine_sensitive = FALSE AND is_confidential = FALSE @@ -59,23 +59,23 @@ patient_death_dates AS ( patient_to_person AS ( SELECT patient_id, person_id - FROM IDENTIFIER($schema_common || '.PATIENT_PERSON') + FROM OLIDS_COMMON.PATIENT_PERSON WHERE patient_id IS NOT NULL AND person_id IS NOT NULL ), episode_type_regular AS ( - SELECT source_code_id FROM IDENTIFIER($schema_terminology || '.CONCEPT_MAP') WHERE source_code = 'Regular' + SELECT source_code_id FROM OLIDS_TERMINOLOGY.CONCEPT_MAP WHERE source_code = 'Regular' ), episode_status_left AS ( - SELECT source_code_id FROM IDENTIFIER($schema_terminology || '.CONCEPT_MAP') WHERE source_code = 'Left' + SELECT source_code_id FROM OLIDS_TERMINOLOGY.CONCEPT_MAP WHERE source_code = 'Left' ), filtered_episodes AS ( SELECT eoc.id AS episode_id, ptp.person_id, eoc.record_owner_organisation_code AS practice_code, eoc.organisation_id, eoc.episode_of_care_start_date - FROM IDENTIFIER($schema_common || '.EPISODE_OF_CARE') eoc + FROM OLIDS_COMMON.EPISODE_OF_CARE eoc INNER JOIN patient_death_dates pdd ON eoc.patient_id = pdd.patient_id INNER JOIN patient_to_person ptp ON eoc.patient_id = ptp.patient_id INNER JOIN episode_type_regular etr ON eoc.episode_type_source_concept_id = etr.source_code_id diff --git a/OLIDS/Testing/run_tests.py b/OLIDS/Testing/run_tests.py index 3ebc6c6..6df14a3 100644 --- a/OLIDS/Testing/run_tests.py +++ b/OLIDS/Testing/run_tests.py @@ -55,7 +55,7 @@ def validate_config(): missing.append(var) if missing: print(f"ERROR: Missing environment variables: {', '.join(missing)}") - print("Run setup.ps1 (Windows) or setup.sh (macOS/Linux), or copy .env.example to .env.") + print("Run setup.ps1 (Windows) or setup.sh (macOS), or copy .env.example to .env.") sys.exit(1) From 37433129cf256fc75a80044adcc9a741e2c2eb39 Mon Sep 17 00:00:00 2001 From: EddieDavison92 <143042680+EddieDavison92@users.noreply.github.com> Date: Fri, 13 Feb 2026 11:03:49 +0000 Subject: [PATCH 12/15] fix: remove chmod step and simplify schema output Set execute bit on setup.sh so macOS/Linux users can run it directly. Remove chmod instruction from README. Simplify schema mapping output in run_tests.py. --- OLIDS/Testing/README.md | 3 +-- OLIDS/Testing/run_tests.py | 12 ++++-------- OLIDS/Testing/setup.sh | 0 3 files changed, 5 insertions(+), 10 deletions(-) mode change 100644 => 100755 OLIDS/Testing/setup.sh diff --git a/OLIDS/Testing/README.md b/OLIDS/Testing/README.md index efb62e0..b16bbae 100644 --- a/OLIDS/Testing/README.md +++ b/OLIDS/Testing/README.md @@ -20,9 +20,8 @@ cd OLIDS/Testing ``` ```bash -# macOS +# macOS / Linux cd OLIDS/Testing -chmod +x setup.sh ./setup.sh ``` diff --git a/OLIDS/Testing/run_tests.py b/OLIDS/Testing/run_tests.py index 6df14a3..2f5fa26 100644 --- a/OLIDS/Testing/run_tests.py +++ b/OLIDS/Testing/run_tests.py @@ -437,14 +437,10 @@ def main(): sys.exit(1) schema_map = detect_schemas(conn, DATABASE) - remapped = {k: v for k, v in schema_map.items() if k != v} - if remapped: - print("Schema mapping:") - for default, actual in schema_map.items(): - label = f" (remapped from {default})" if default != actual else "" - print(f" {actual}{label}") - else: - print(f"Schemas: {', '.join(schema_map.values())}") + print(f"Database: {DATABASE}") + for default, actual in schema_map.items(): + label = f" (remapped from {default})" if default != actual else "" + print(f" {actual}{label}") # --run mode: execute a single SQL file and print results if run_file: diff --git a/OLIDS/Testing/setup.sh b/OLIDS/Testing/setup.sh old mode 100644 new mode 100755 From 5e260c418f41afd04a69d399cf5400e45d2c41a0 Mon Sep 17 00:00:00 2001 From: Eddie Davison <143042680+EddieDavison92@users.noreply.github.com> Date: Fri, 13 Feb 2026 11:17:53 +0000 Subject: [PATCH 13/15] docs: update private link instructions in readme --- OLIDS/Testing/README.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/OLIDS/Testing/README.md b/OLIDS/Testing/README.md index b16bbae..b421c51 100644 --- a/OLIDS/Testing/README.md +++ b/OLIDS/Testing/README.md @@ -27,7 +27,7 @@ cd OLIDS/Testing This installs [uv](https://docs.astral.sh/uv/), prompts for Snowflake credentials, writes `.env`, and runs `uv sync`. -> **Snowflake private link**: If your organisation connects via private link, use the format `..privatelink` as your Snowflake account identifier (e.g. `us96268.uk-south.privatelink`). +> **Snowflake private link**: If your organisation connects via private link, use the format `..privatelink` as your Snowflake account identifier (e.g. `us12345.uk-south.privatelink`). ## Running Tests From 6584902ff2f438022b95f82c3a66cd6432916120 Mon Sep 17 00:00:00 2001 From: EddieDavison92 <143042680+EddieDavison92@users.noreply.github.com> Date: Fri, 13 Feb 2026 12:40:41 +0000 Subject: [PATCH 14/15] fix: improve uv PATH refresh on macOS after install Check both ~/.local/bin and ~/.cargo/bin for the uv binary after installation, since the install location varies by system. --- OLIDS/Testing/README.md | 2 +- OLIDS/Testing/setup.sh | 13 ++++++++----- 2 files changed, 9 insertions(+), 6 deletions(-) diff --git a/OLIDS/Testing/README.md b/OLIDS/Testing/README.md index b421c51..bb975f9 100644 --- a/OLIDS/Testing/README.md +++ b/OLIDS/Testing/README.md @@ -20,7 +20,7 @@ cd OLIDS/Testing ``` ```bash -# macOS / Linux +# macOS cd OLIDS/Testing ./setup.sh ``` diff --git a/OLIDS/Testing/setup.sh b/OLIDS/Testing/setup.sh index 2e98e8d..ff36dc6 100755 --- a/OLIDS/Testing/setup.sh +++ b/OLIDS/Testing/setup.sh @@ -18,11 +18,14 @@ if ! command -v uv &>/dev/null; then echo "uv not found on PATH. Installing..." curl -LsSf https://astral.sh/uv/install.sh | sh - # Source the env file uv's installer creates - if [ -f "$HOME/.local/bin/env" ]; then - source "$HOME/.local/bin/env" - fi - export PATH="$HOME/.local/bin:$PATH" + # uv installs to ~/.local/bin or ~/.cargo/bin depending on the system. + # Source the env file it creates and add both locations to PATH. + for env_file in "$HOME/.local/bin/env" "$HOME/.cargo/env"; do + if [ -f "$env_file" ]; then + source "$env_file" + fi + done + export PATH="$HOME/.local/bin:$HOME/.cargo/bin:$PATH" if ! command -v uv &>/dev/null; then echo "ERROR: uv installation succeeded but is still not on PATH." From 8cdd7abb936b01bc4d9e72305d5e7c3ae0ee18e4 Mon Sep 17 00:00:00 2001 From: EddieDavison92 <143042680+EddieDavison92@users.noreply.github.com> Date: Wed, 18 Feb 2026 20:30:34 +0000 Subject: [PATCH 15/15] feat: add uniqueness tests and remove MASKED-only columns MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit Add test_uniqueness.sql (94 checks across 24 tables) and companion investigate_uniqueness.sql per Owain's suggestion from PR review. Remove sk_patient_id and gender_concept_id from column completeness test — these columns only exist in OLIDS_MASKED, not OLIDS_PCD, causing failures for ICBs using PCD schemas. --- .../data-quality/test_column_completeness.sql | 6 +- .../Testing/data-quality/test_uniqueness.sql | 216 +++++++++ .../investigations/investigate_uniqueness.sql | 430 ++++++++++++++++++ 3 files changed, 649 insertions(+), 3 deletions(-) create mode 100644 OLIDS/Testing/data-quality/test_uniqueness.sql create mode 100644 OLIDS/Testing/investigations/investigate_uniqueness.sql diff --git a/OLIDS/Testing/data-quality/test_column_completeness.sql b/OLIDS/Testing/data-quality/test_column_completeness.sql index 25a007a..9f5b30c 100644 --- a/OLIDS/Testing/data-quality/test_column_completeness.sql +++ b/OLIDS/Testing/data-quality/test_column_completeness.sql @@ -9,7 +9,7 @@ total rows and NULL rows for that column in a single table scan. 2. The 'threshold' value is the max allowed NULL % for that column: - 0.0%: Primary keys (no NULLs allowed) - - 0.5%: Core foreign keys (patient_id, person_id, sk_patient_id) + - 0.5%: Core foreign keys (patient_id, person_id) - 1.0%: System/clinical dates (lds_start_date_time, clinical_effective_date) - 5.0%: Concept fields (*_concept_id) — higher tolerance for optional coding 3. The final SELECT computes the completeness % (100 - null%) and @@ -35,11 +35,11 @@ SET schema_terminology = 'OLIDS_TERMINOLOGY'; WITH checks AS ( -- Each row: table, column, max allowed NULL %, total rows, NULL count -- PATIENT (OLIDS_MASKED) + -- Note: sk_patient_id and gender_concept_id are MASKED-only columns (not in OLIDS_PCD). + -- Add those checks to an ICB-specific test directory if needed. SELECT 'PATIENT' AS table_name, 'id' AS column_name, 0.0 AS threshold, COUNT(*) AS total_rows, SUM(CASE WHEN id IS NULL THEN 1 ELSE 0 END) AS null_count FROM OLIDS_MASKED.PATIENT - UNION ALL SELECT 'PATIENT', 'sk_patient_id', 0.5, COUNT(*), SUM(CASE WHEN sk_patient_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT UNION ALL SELECT 'PATIENT', 'birth_year', 1.0, COUNT(*), SUM(CASE WHEN birth_year IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT UNION ALL SELECT 'PATIENT', 'birth_month', 1.0, COUNT(*), SUM(CASE WHEN birth_month IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT - UNION ALL SELECT 'PATIENT', 'gender_concept_id', 5.0, COUNT(*), SUM(CASE WHEN gender_concept_id IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT UNION ALL SELECT 'PATIENT', 'lds_start_date_time', 1.0, COUNT(*), SUM(CASE WHEN lds_start_date_time IS NULL THEN 1 ELSE 0 END) FROM OLIDS_MASKED.PATIENT -- PERSON (OLIDS_MASKED) diff --git a/OLIDS/Testing/data-quality/test_uniqueness.sql b/OLIDS/Testing/data-quality/test_uniqueness.sql new file mode 100644 index 0000000..d74771c --- /dev/null +++ b/OLIDS/Testing/data-quality/test_uniqueness.sql @@ -0,0 +1,216 @@ +/* + Test: Uniqueness + Run: uv run run_tests.py --test test_uniqueness + + Checks that key identifier columns contain no duplicate values. + Duplicates in these columns cause fan-out in downstream joins + and inflate row counts in derived datasets. + + How it works: + 1. The 'checks' CTE counts total rows and distinct non-NULL values + for each column. Duplicates = total_rows - distinct_count. + 2. threshold = 100% (no duplicates allowed). + 3. Empty tables return WARN. + + Columns tested per table: + - id: OLIDS record identifier + - lds_record_id: LDS ingest record ID + - lds_id: LDS entity ID + - lds_business_key: LDS business key + Note: CONCEPT and CONCEPT_MAP lack lds_record_id. + + Output: + - metric_value = uniqueness % (100 means no duplicates) + - total_rows, distinct_count, duplicate_count (shown with --verbose) +*/ + +SET schema_masked = 'OLIDS_MASKED'; -- Change if your ICB uses a different name (e.g. OLIDS_PCD) +SET schema_common = 'OLIDS_COMMON'; +SET schema_terminology = 'OLIDS_TERMINOLOGY'; + +WITH checks AS ( + -- Each row: table, column, total rows, distinct non-NULL count + -- PATIENT (OLIDS_MASKED) + SELECT 'PATIENT' AS table_name, 'id' AS column_name, COUNT(*) AS total_rows, COUNT(DISTINCT id) AS distinct_count FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_MASKED.PATIENT + UNION ALL SELECT 'PATIENT', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_MASKED.PATIENT + + -- PERSON (OLIDS_MASKED) + UNION ALL SELECT 'PERSON', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_MASKED.PERSON + UNION ALL SELECT 'PERSON', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_MASKED.PERSON + UNION ALL SELECT 'PERSON', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_MASKED.PERSON + UNION ALL SELECT 'PERSON', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_MASKED.PERSON + + -- PATIENT_ADDRESS (OLIDS_MASKED) + UNION ALL SELECT 'PATIENT_ADDRESS', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_MASKED.PATIENT_ADDRESS + UNION ALL SELECT 'PATIENT_ADDRESS', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_MASKED.PATIENT_ADDRESS + UNION ALL SELECT 'PATIENT_ADDRESS', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_MASKED.PATIENT_ADDRESS + UNION ALL SELECT 'PATIENT_ADDRESS', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_MASKED.PATIENT_ADDRESS + + -- PATIENT_CONTACT (OLIDS_MASKED) + UNION ALL SELECT 'PATIENT_CONTACT', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_MASKED.PATIENT_CONTACT + UNION ALL SELECT 'PATIENT_CONTACT', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_MASKED.PATIENT_CONTACT + UNION ALL SELECT 'PATIENT_CONTACT', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_MASKED.PATIENT_CONTACT + UNION ALL SELECT 'PATIENT_CONTACT', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_MASKED.PATIENT_CONTACT + + -- PATIENT_UPRN (OLIDS_MASKED) + UNION ALL SELECT 'PATIENT_UPRN', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_MASKED.PATIENT_UPRN + UNION ALL SELECT 'PATIENT_UPRN', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_MASKED.PATIENT_UPRN + UNION ALL SELECT 'PATIENT_UPRN', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_MASKED.PATIENT_UPRN + UNION ALL SELECT 'PATIENT_UPRN', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_MASKED.PATIENT_UPRN + + -- PATIENT_PERSON (OLIDS_COMMON) + UNION ALL SELECT 'PATIENT_PERSON', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_COMMON.PATIENT_PERSON + UNION ALL SELECT 'PATIENT_PERSON', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_COMMON.PATIENT_PERSON + UNION ALL SELECT 'PATIENT_PERSON', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_COMMON.PATIENT_PERSON + UNION ALL SELECT 'PATIENT_PERSON', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_COMMON.PATIENT_PERSON + + -- EPISODE_OF_CARE (OLIDS_COMMON) + UNION ALL SELECT 'EPISODE_OF_CARE', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_COMMON.EPISODE_OF_CARE + UNION ALL SELECT 'EPISODE_OF_CARE', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_COMMON.EPISODE_OF_CARE + + -- ENCOUNTER (OLIDS_COMMON) + UNION ALL SELECT 'ENCOUNTER', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_COMMON.ENCOUNTER + UNION ALL SELECT 'ENCOUNTER', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_COMMON.ENCOUNTER + + -- OBSERVATION (OLIDS_COMMON) + UNION ALL SELECT 'OBSERVATION', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_COMMON.OBSERVATION + UNION ALL SELECT 'OBSERVATION', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_COMMON.OBSERVATION + + -- MEDICATION_STATEMENT (OLIDS_COMMON) + UNION ALL SELECT 'MEDICATION_STATEMENT', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_COMMON.MEDICATION_STATEMENT + UNION ALL SELECT 'MEDICATION_STATEMENT', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_COMMON.MEDICATION_STATEMENT + + -- MEDICATION_ORDER (OLIDS_COMMON) + UNION ALL SELECT 'MEDICATION_ORDER', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_COMMON.MEDICATION_ORDER + UNION ALL SELECT 'MEDICATION_ORDER', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_COMMON.MEDICATION_ORDER + + -- DIAGNOSTIC_ORDER (OLIDS_COMMON) + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + UNION ALL SELECT 'DIAGNOSTIC_ORDER', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_COMMON.DIAGNOSTIC_ORDER + + -- ALLERGY_INTOLERANCE (OLIDS_COMMON) + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + UNION ALL SELECT 'ALLERGY_INTOLERANCE', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_COMMON.ALLERGY_INTOLERANCE + + -- PROCEDURE_REQUEST (OLIDS_COMMON) + UNION ALL SELECT 'PROCEDURE_REQUEST', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_COMMON.PROCEDURE_REQUEST + UNION ALL SELECT 'PROCEDURE_REQUEST', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_COMMON.PROCEDURE_REQUEST + + -- REFERRAL_REQUEST (OLIDS_COMMON) + UNION ALL SELECT 'REFERRAL_REQUEST', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_COMMON.REFERRAL_REQUEST + UNION ALL SELECT 'REFERRAL_REQUEST', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_COMMON.REFERRAL_REQUEST + + -- APPOINTMENT (OLIDS_COMMON) + UNION ALL SELECT 'APPOINTMENT', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_COMMON.APPOINTMENT + UNION ALL SELECT 'APPOINTMENT', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_COMMON.APPOINTMENT + + -- APPOINTMENT_PRACTITIONER (OLIDS_COMMON) + UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER + UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER + UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER + UNION ALL SELECT 'APPOINTMENT_PRACTITIONER', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER + + -- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE (OLIDS_COMMON) + UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE + UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE + UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE + UNION ALL SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE + + -- LOCATION (OLIDS_COMMON) + UNION ALL SELECT 'LOCATION', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_COMMON.LOCATION + UNION ALL SELECT 'LOCATION', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_COMMON.LOCATION + UNION ALL SELECT 'LOCATION', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_COMMON.LOCATION + UNION ALL SELECT 'LOCATION', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_COMMON.LOCATION + + -- LOCATION_CONTACT (OLIDS_COMMON) + UNION ALL SELECT 'LOCATION_CONTACT', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_COMMON.LOCATION_CONTACT + UNION ALL SELECT 'LOCATION_CONTACT', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_COMMON.LOCATION_CONTACT + UNION ALL SELECT 'LOCATION_CONTACT', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_COMMON.LOCATION_CONTACT + UNION ALL SELECT 'LOCATION_CONTACT', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_COMMON.LOCATION_CONTACT + + -- FLAG (OLIDS_COMMON) + UNION ALL SELECT 'FLAG', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_COMMON.FLAG + UNION ALL SELECT 'FLAG', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_COMMON.FLAG + UNION ALL SELECT 'FLAG', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_COMMON.FLAG + UNION ALL SELECT 'FLAG', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_COMMON.FLAG + + -- ORGANISATION (OLIDS_COMMON) + UNION ALL SELECT 'ORGANISATION', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_COMMON.ORGANISATION + UNION ALL SELECT 'ORGANISATION', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_COMMON.ORGANISATION + UNION ALL SELECT 'ORGANISATION', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_COMMON.ORGANISATION + UNION ALL SELECT 'ORGANISATION', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_COMMON.ORGANISATION + + -- PRACTITIONER (OLIDS_COMMON) + UNION ALL SELECT 'PRACTITIONER', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_COMMON.PRACTITIONER + UNION ALL SELECT 'PRACTITIONER', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_COMMON.PRACTITIONER + UNION ALL SELECT 'PRACTITIONER', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_COMMON.PRACTITIONER + UNION ALL SELECT 'PRACTITIONER', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_COMMON.PRACTITIONER + + -- PRACTITIONER_IN_ROLE (OLIDS_COMMON) + UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE + UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE + UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE + UNION ALL SELECT 'PRACTITIONER_IN_ROLE', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE + + -- SCHEDULE (OLIDS_COMMON) + UNION ALL SELECT 'SCHEDULE', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_COMMON.SCHEDULE + UNION ALL SELECT 'SCHEDULE', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_COMMON.SCHEDULE + UNION ALL SELECT 'SCHEDULE', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_COMMON.SCHEDULE + UNION ALL SELECT 'SCHEDULE', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_COMMON.SCHEDULE + + -- SCHEDULE_PRACTITIONER (OLIDS_COMMON) + UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER + UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'lds_record_id', COUNT(*), COUNT(DISTINCT lds_record_id) FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER + UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER + UNION ALL SELECT 'SCHEDULE_PRACTITIONER', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER + + -- CONCEPT (OLIDS_TERMINOLOGY) — no lds_record_id in this table + UNION ALL SELECT 'CONCEPT', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_TERMINOLOGY.CONCEPT + UNION ALL SELECT 'CONCEPT', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_TERMINOLOGY.CONCEPT + UNION ALL SELECT 'CONCEPT', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_TERMINOLOGY.CONCEPT + + -- CONCEPT_MAP (OLIDS_TERMINOLOGY) — no lds_record_id in this table + UNION ALL SELECT 'CONCEPT_MAP', 'id', COUNT(*), COUNT(DISTINCT id) FROM OLIDS_TERMINOLOGY.CONCEPT_MAP + UNION ALL SELECT 'CONCEPT_MAP', 'lds_id', COUNT(*), COUNT(DISTINCT lds_id) FROM OLIDS_TERMINOLOGY.CONCEPT_MAP + UNION ALL SELECT 'CONCEPT_MAP', 'lds_business_key', COUNT(*), COUNT(DISTINCT lds_business_key) FROM OLIDS_TERMINOLOGY.CONCEPT_MAP +) + +-- Compute uniqueness % and compare against threshold +SELECT + 'uniqueness' AS test_name, + table_name, + CASE WHEN total_rows = 0 THEN column_name || ' (empty table)' ELSE column_name END AS test_subject, + CASE + WHEN total_rows = 0 THEN 'WARN' + WHEN distinct_count = total_rows THEN 'PASS' + ELSE 'FAIL' + END AS status, + CASE WHEN total_rows = 0 THEN NULL ELSE ROUND(100.0 * distinct_count / total_rows, 4) END AS metric_value, + 100.0 AS threshold, + total_rows, + distinct_count, + total_rows - distinct_count AS duplicate_count +FROM checks +ORDER BY status DESC, metric_value ASC, table_name, column_name; diff --git a/OLIDS/Testing/investigations/investigate_uniqueness.sql b/OLIDS/Testing/investigations/investigate_uniqueness.sql new file mode 100644 index 0000000..3b4b85a --- /dev/null +++ b/OLIDS/Testing/investigations/investigate_uniqueness.sql @@ -0,0 +1,430 @@ +/* + Investigation: Uniqueness + Run: uv run run_tests.py --run investigations/investigate_uniqueness.sql + Or execute directly in Snowsight — set the USE DATABASE and schema + variables below to match your ICB. + + For each table/column, shows duplicate values with their occurrence + counts. Helps identify whether duplicates are systematic (few values, + many copies) or scattered. +*/ + +USE DATABASE "Data_Store_OLIDS_Clinical_Validation"; -- Replace with your ICB's OLIDS database name + +SET schema_masked = 'OLIDS_MASKED'; -- Change if your ICB uses a different name (e.g. OLIDS_PCD) +SET schema_common = 'OLIDS_COMMON'; +SET schema_terminology = 'OLIDS_TERMINOLOGY'; + +-- PATIENT +SELECT 'PATIENT' AS table_name, 'id' AS column_name, id AS duplicate_value, COUNT(*) AS occurrences +FROM OLIDS_MASKED.PATIENT GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PATIENT', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_MASKED.PATIENT GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PATIENT', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_MASKED.PATIENT GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PATIENT', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_MASKED.PATIENT GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- PERSON +SELECT 'PERSON', 'id', id, COUNT(*) +FROM OLIDS_MASKED.PERSON GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PERSON', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_MASKED.PERSON GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PERSON', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_MASKED.PERSON GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PERSON', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_MASKED.PERSON GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- PATIENT_ADDRESS +SELECT 'PATIENT_ADDRESS', 'id', id, COUNT(*) +FROM OLIDS_MASKED.PATIENT_ADDRESS GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PATIENT_ADDRESS', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_MASKED.PATIENT_ADDRESS GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PATIENT_ADDRESS', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_MASKED.PATIENT_ADDRESS GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PATIENT_ADDRESS', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_MASKED.PATIENT_ADDRESS GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- PATIENT_CONTACT +SELECT 'PATIENT_CONTACT', 'id', id, COUNT(*) +FROM OLIDS_MASKED.PATIENT_CONTACT GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PATIENT_CONTACT', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_MASKED.PATIENT_CONTACT GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PATIENT_CONTACT', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_MASKED.PATIENT_CONTACT GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PATIENT_CONTACT', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_MASKED.PATIENT_CONTACT GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- PATIENT_UPRN +SELECT 'PATIENT_UPRN', 'id', id, COUNT(*) +FROM OLIDS_MASKED.PATIENT_UPRN GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PATIENT_UPRN', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_MASKED.PATIENT_UPRN GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PATIENT_UPRN', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_MASKED.PATIENT_UPRN GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PATIENT_UPRN', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_MASKED.PATIENT_UPRN GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- PATIENT_PERSON +SELECT 'PATIENT_PERSON', 'id', id, COUNT(*) +FROM OLIDS_COMMON.PATIENT_PERSON GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PATIENT_PERSON', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_COMMON.PATIENT_PERSON GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PATIENT_PERSON', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_COMMON.PATIENT_PERSON GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PATIENT_PERSON', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_COMMON.PATIENT_PERSON GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- EPISODE_OF_CARE +SELECT 'EPISODE_OF_CARE', 'id', id, COUNT(*) +FROM OLIDS_COMMON.EPISODE_OF_CARE GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'EPISODE_OF_CARE', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_COMMON.EPISODE_OF_CARE GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'EPISODE_OF_CARE', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_COMMON.EPISODE_OF_CARE GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'EPISODE_OF_CARE', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_COMMON.EPISODE_OF_CARE GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- ENCOUNTER +SELECT 'ENCOUNTER', 'id', id, COUNT(*) +FROM OLIDS_COMMON.ENCOUNTER GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'ENCOUNTER', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_COMMON.ENCOUNTER GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'ENCOUNTER', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_COMMON.ENCOUNTER GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'ENCOUNTER', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_COMMON.ENCOUNTER GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- OBSERVATION +SELECT 'OBSERVATION', 'id', id, COUNT(*) +FROM OLIDS_COMMON.OBSERVATION GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'OBSERVATION', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_COMMON.OBSERVATION GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'OBSERVATION', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_COMMON.OBSERVATION GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'OBSERVATION', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_COMMON.OBSERVATION GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- MEDICATION_STATEMENT +SELECT 'MEDICATION_STATEMENT', 'id', id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_STATEMENT GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'MEDICATION_STATEMENT', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_STATEMENT GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'MEDICATION_STATEMENT', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_STATEMENT GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'MEDICATION_STATEMENT', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_STATEMENT GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- MEDICATION_ORDER +SELECT 'MEDICATION_ORDER', 'id', id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_ORDER GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'MEDICATION_ORDER', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_ORDER GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'MEDICATION_ORDER', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_ORDER GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'MEDICATION_ORDER', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_COMMON.MEDICATION_ORDER GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- DIAGNOSTIC_ORDER +SELECT 'DIAGNOSTIC_ORDER', 'id', id, COUNT(*) +FROM OLIDS_COMMON.DIAGNOSTIC_ORDER GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'DIAGNOSTIC_ORDER', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_COMMON.DIAGNOSTIC_ORDER GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'DIAGNOSTIC_ORDER', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_COMMON.DIAGNOSTIC_ORDER GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'DIAGNOSTIC_ORDER', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_COMMON.DIAGNOSTIC_ORDER GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- ALLERGY_INTOLERANCE +SELECT 'ALLERGY_INTOLERANCE', 'id', id, COUNT(*) +FROM OLIDS_COMMON.ALLERGY_INTOLERANCE GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'ALLERGY_INTOLERANCE', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_COMMON.ALLERGY_INTOLERANCE GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'ALLERGY_INTOLERANCE', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_COMMON.ALLERGY_INTOLERANCE GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'ALLERGY_INTOLERANCE', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_COMMON.ALLERGY_INTOLERANCE GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- PROCEDURE_REQUEST +SELECT 'PROCEDURE_REQUEST', 'id', id, COUNT(*) +FROM OLIDS_COMMON.PROCEDURE_REQUEST GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PROCEDURE_REQUEST', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_COMMON.PROCEDURE_REQUEST GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PROCEDURE_REQUEST', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_COMMON.PROCEDURE_REQUEST GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PROCEDURE_REQUEST', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_COMMON.PROCEDURE_REQUEST GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- REFERRAL_REQUEST +SELECT 'REFERRAL_REQUEST', 'id', id, COUNT(*) +FROM OLIDS_COMMON.REFERRAL_REQUEST GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'REFERRAL_REQUEST', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_COMMON.REFERRAL_REQUEST GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'REFERRAL_REQUEST', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_COMMON.REFERRAL_REQUEST GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'REFERRAL_REQUEST', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_COMMON.REFERRAL_REQUEST GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- APPOINTMENT +SELECT 'APPOINTMENT', 'id', id, COUNT(*) +FROM OLIDS_COMMON.APPOINTMENT GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'APPOINTMENT', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_COMMON.APPOINTMENT GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'APPOINTMENT', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_COMMON.APPOINTMENT GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'APPOINTMENT', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_COMMON.APPOINTMENT GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- APPOINTMENT_PRACTITIONER +SELECT 'APPOINTMENT_PRACTITIONER', 'id', id, COUNT(*) +FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'APPOINTMENT_PRACTITIONER', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'APPOINTMENT_PRACTITIONER', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'APPOINTMENT_PRACTITIONER', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_COMMON.APPOINTMENT_PRACTITIONER GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- PATIENT_REGISTERED_PRACTITIONER_IN_ROLE +SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'id', id, COUNT(*) +FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PATIENT_REGISTERED_PRACTITIONER_IN_ROLE', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_COMMON.PATIENT_REGISTERED_PRACTITIONER_IN_ROLE GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- LOCATION +SELECT 'LOCATION', 'id', id, COUNT(*) +FROM OLIDS_COMMON.LOCATION GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'LOCATION', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_COMMON.LOCATION GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'LOCATION', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_COMMON.LOCATION GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'LOCATION', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_COMMON.LOCATION GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- LOCATION_CONTACT +SELECT 'LOCATION_CONTACT', 'id', id, COUNT(*) +FROM OLIDS_COMMON.LOCATION_CONTACT GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'LOCATION_CONTACT', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_COMMON.LOCATION_CONTACT GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'LOCATION_CONTACT', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_COMMON.LOCATION_CONTACT GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'LOCATION_CONTACT', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_COMMON.LOCATION_CONTACT GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- FLAG +SELECT 'FLAG', 'id', id, COUNT(*) +FROM OLIDS_COMMON.FLAG GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'FLAG', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_COMMON.FLAG GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'FLAG', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_COMMON.FLAG GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'FLAG', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_COMMON.FLAG GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- ORGANISATION +SELECT 'ORGANISATION', 'id', id, COUNT(*) +FROM OLIDS_COMMON.ORGANISATION GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'ORGANISATION', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_COMMON.ORGANISATION GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'ORGANISATION', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_COMMON.ORGANISATION GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'ORGANISATION', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_COMMON.ORGANISATION GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- PRACTITIONER +SELECT 'PRACTITIONER', 'id', id, COUNT(*) +FROM OLIDS_COMMON.PRACTITIONER GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PRACTITIONER', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_COMMON.PRACTITIONER GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PRACTITIONER', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_COMMON.PRACTITIONER GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PRACTITIONER', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_COMMON.PRACTITIONER GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- PRACTITIONER_IN_ROLE +SELECT 'PRACTITIONER_IN_ROLE', 'id', id, COUNT(*) +FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PRACTITIONER_IN_ROLE', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PRACTITIONER_IN_ROLE', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'PRACTITIONER_IN_ROLE', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_COMMON.PRACTITIONER_IN_ROLE GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- SCHEDULE +SELECT 'SCHEDULE', 'id', id, COUNT(*) +FROM OLIDS_COMMON.SCHEDULE GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'SCHEDULE', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_COMMON.SCHEDULE GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'SCHEDULE', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_COMMON.SCHEDULE GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'SCHEDULE', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_COMMON.SCHEDULE GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- SCHEDULE_PRACTITIONER +SELECT 'SCHEDULE_PRACTITIONER', 'id', id, COUNT(*) +FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'SCHEDULE_PRACTITIONER', 'lds_record_id', lds_record_id, COUNT(*) +FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER GROUP BY lds_record_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'SCHEDULE_PRACTITIONER', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'SCHEDULE_PRACTITIONER', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_COMMON.SCHEDULE_PRACTITIONER GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- CONCEPT (no lds_record_id) +SELECT 'CONCEPT', 'id', id, COUNT(*) +FROM OLIDS_TERMINOLOGY.CONCEPT GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'CONCEPT', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_TERMINOLOGY.CONCEPT GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'CONCEPT', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_TERMINOLOGY.CONCEPT GROUP BY lds_business_key HAVING COUNT(*) > 1 + +UNION ALL + +-- CONCEPT_MAP (no lds_record_id) +SELECT 'CONCEPT_MAP', 'id', id, COUNT(*) +FROM OLIDS_TERMINOLOGY.CONCEPT_MAP GROUP BY id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'CONCEPT_MAP', 'lds_id', lds_id, COUNT(*) +FROM OLIDS_TERMINOLOGY.CONCEPT_MAP GROUP BY lds_id HAVING COUNT(*) > 1 +UNION ALL +SELECT 'CONCEPT_MAP', 'lds_business_key', lds_business_key, COUNT(*) +FROM OLIDS_TERMINOLOGY.CONCEPT_MAP GROUP BY lds_business_key HAVING COUNT(*) > 1 + +ORDER BY table_name, column_name, occurrences DESC;