From d489f002a3df808888662aacadfcbdd6c6b0ad87 Mon Sep 17 00:00:00 2001 From: Rae Woong Park Date: Sun, 6 Nov 2016 23:18:54 +0900 Subject: [PATCH] Update OMOP CDM indexes required - SQL Server.sql We added some more required indexes, which were identified by running the 'Estimated Execution Plan' in the Microsoft SQL Management Studio. Some related discussions are here: http://forums.ohdsi.org/t/incremental-achilles/1847 --- ...OMOP CDM indexes required - SQL Server.sql | 175 ++++++++++++++++++ 1 file changed, 175 insertions(+) diff --git a/Sql Server/OMOP CDM indexes required - SQL Server.sql b/Sql Server/OMOP CDM indexes required - SQL Server.sql index f701dba..74efad2 100644 --- a/Sql Server/OMOP CDM indexes required - SQL Server.sql +++ b/Sql Server/OMOP CDM indexes required - SQL Server.sql @@ -185,3 +185,178 @@ CREATE INDEX idx_dose_era_concept_id ON dose_era (drug_concept_id ASC); CREATE CLUSTERED INDEX idx_condition_era_person_id ON condition_era (person_id ASC); CREATE INDEX idx_condition_era_concept_id ON condition_era (condition_concept_id ASC); +/**************************************************************************************************************************************** +***************************************************** Non Cluster Index ************************************************************** + **************************************************************************************************************************************** + **********************************/ + + /* PERSON */ + +USE [Camel_DB] +GO + CREATE NONCLUSTERED INDEX [] + ON [dbo].[PERSON] ([person_id]) + INCLUDE ([year_of_birth],[gender_concept_id] ); + GO; + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[PERSON] ([location_id]) + INCLUDE ([person_id]); + GO; + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[PERSON] ([provider_id]); + GO; + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[PERSON] ([care_site_id]); + GO; + +/* OBSERVATION */ + +USE [Camel_DB]; +GO; + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[OBSERVATION] ([provider_id]); + GO; + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[OBSERVATION] ([visit_occurrence_id]); + GO; + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[OBSERVATION] ([value_as_number],[unit_concept_id]) + INCLUDE ([observation_concept_id]); + GO; + +/* OBSERVATION_PERIOD */ + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[OBSERVATION_PERIOD] ([PERSON_ID]) + INCLUDE ([OBSERVATION_PERIOD_START_DATE]); + GO; + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[OBSERVATION_PERIOD] ([OBSERVATION_PERIOD_START_DATE],[OBSERVATION_PERIOD_END_DATE]) + INCLUDE ([PERSON_ID]); + GO; + +/* VISIT */ + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[VISIT_OCCURRENCE] ([care_site_id]); + GO; + +/* CONDITION */ + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[CONDITION_OCCURRENCE] ([provider_id]); + GO; + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[CONDITION_OCCURRENCE] ([visit_occurrence_id]); + GO; + +/* CONDITION_ERA */ + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[CONDITION_ERA] ([person_id]) + INCLUDE ([condition_concept_id],[condition_era_start_date]); + GO; + +/* PROCEDURE */ + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[PROCEDURE_OCCURRENCE] ([provider_id], [visit_occurrence_id]); + GO; + + +/* DRUG */ + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[DRUG_EXPOSURE] ([provider_id]); + GO; + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[DRUG_EXPOSURE] ([visit_occurrence_id]) + GO; + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[DRUG_EXPOSURE] ([days_supply]) + INCLUDE ([drug_concept_id]) + GO; + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[DRUG_EXPOSURE] ([refills]) + INCLUDE ([drug_concept_id]) + GO; + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[DRUG_EXPOSURE] ([quantity]) + INCLUDE ([drug_concept_id]) + GO; + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[DRUG_EXPOSURE] ([drug_concept_id]) + INCLUDE ([drug_source_value]) + GO; + +/* DRUG_ERA */ + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[DRUG_ERA] ([person_id]) + INCLUDE ([drug_concept_id],[drug_era_start_date]) + GO; + +/* MEASUREMENT */ + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[MEASUREMENT] ([person_id]) + INCLUDE ([measurement_concept_id],[measurement_date]); + GO; + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[MEASUREMENT] ([provider_id]); + GO; + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[MEASUREMENT] ([visit_occurrence_id]); + GO; + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[MEASUREMENT] ([value_as_number],[value_as_concept_id]); + GO; + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[MEASUREMENT] ([value_as_number],[unit_concept_id]) + INCLUDE ([measurement_concept_id]); + GO; + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[MEASUREMENT] ([value_as_number],[unit_concept_id],[range_low],[range_high]) + INCLUDE ([measurement_concept_id]); + GO; + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[MEASUREMENT] ([value_as_number]); + GO; + +/* PROVIDER */ + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[PROVIDER] ([care_site_id]); + GO; + +/* PAYER_PLAN_PERIOD */ + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[PAYER_PLAN_PERIOD] ([person_id]) + INCLUDE ([payer_plan_period_start_date],[payer_plan_period_end_date]); + GO; + +/* ACHILLES_results */ + + CREATE NONCLUSTERED INDEX [] + ON [dbo].[ACHILLES_results] ([count_value]); + GO;