Skip to content

Commit

Permalink
add staging tables
Browse files Browse the repository at this point in the history
  • Loading branch information
whitneygriffith committed Oct 29, 2021
1 parent 0ebb286 commit 7809dd2
Show file tree
Hide file tree
Showing 47 changed files with 339 additions and 214 deletions.
40 changes: 23 additions & 17 deletions sql/SPROC_move_data_to_permanent_tables.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2,24 +2,27 @@ CREATE PROCEDURE move_data_to_permanent_tables @watermark_table NVARCHAR(100)
AS
-- SET XACT_ABORT ON will cause the transaction to be uncommittable
-- when the constraint violation occurs.
SET XACT_ABORT ON;
SET XACT_ABORT ON;
BEGIN TRANSACTION move_data_to_permanent_tables
BEGIN TRY
BEGIN TRANSACTION move_data_to_permanent_tables

DECLARE @current_table_name VARCHAR(MAX);
DECLARE @staging_table_name VARCHAR(MAX);
DECLARE @log_date AS NVARCHAR(50);
DECLARE @log_message NVARCHAR(512);
SET @current_table_name = ''

-- The use of RAISERROR with the NOWAIT option shouldn't actually be emitting an exception as you might expect. It's used
-- to immediately emmit log/console messages. For additional details, see
-- https://www.mssqltips.com/sqlservertip/1660/using-the-nowait-option-with-the-sql-server-raiserror-statement/

SET @log_date = CONVERT(NVARCHAR(50),GETDATE(),121);
SET @log_message = @log_date + ' move_data_to_permanent_tables is starting execution'
RAISERROR (@log_message, 0, 1) WITH NOWAIT

SET @log_date = CONVERT(NVARCHAR(50),GETDATE(),121);
SET @log_message = @log_date + ' move_data_to_permanent_tables is removing all indexes and constraints on OMOP tables'
RAISERROR (@log_message, 0, 1) WITH NOWAIT

EXEC dbo.remove_indexes_constraints;
SET @log_date = CONVERT(NVARCHAR(50),GETDATE(),121);
SET @log_message = @log_date + ' move_data_to_permanent_tables removed all indexes and constraints on OMOP tables'
Expand All @@ -28,7 +31,7 @@ AS
DECLARE @cursor_sql VARCHAR(MAX)
SET @cursor_sql = 'DECLARE omop_tables_cursor CURSOR FOR SELECT table_name FROM ' + @watermark_table
EXEC(@cursor_sql)

SET @log_date = CONVERT(NVARCHAR(50),GETDATE(),121);
SET @log_message = @log_date + ' move_data_to_permanent_tables is moving data for tables in ' + @watermark_table
RAISERROR (@log_message, 0, 1) WITH NOWAIT
Expand Down Expand Up @@ -82,24 +85,27 @@ AS

IF (SELECT CURSOR_STATUS('global','omop_tables_cursor')) >= -1
BEGIN
DEALLOCATE omop_tables_cursor;
DEALLOCATE omop_tables_cursor;
END

-- Transaction uncommittable
IF (XACT_STATE()) = -1
SET @log_date = CONVERT(NVARCHAR(50),GETDATE(),121);
SET @log_message = @log_date + ' move_data_to_permanent_tables is rolling back transaction'
RAISERROR (@log_message, 0, 1) WITH NOWAIT
ROLLBACK TRANSACTION move_data_to_permanent_tables;

BEGIN
SET @log_date = CONVERT(NVARCHAR(50),GETDATE(),121);
SET @log_message = @log_date + ' move_data_to_permanent_tables is rolling back transaction'
RAISERROR (@log_message, 0, 1) WITH NOWAIT
ROLLBACK TRANSACTION move_data_to_permanent_tables;
THROW;
END
-- Transaction committable
IF (XACT_STATE()) = 1
SET @log_date = CONVERT(NVARCHAR(50),GETDATE(),121);
SET @log_message = @log_date + ' move_data_to_permanent_tables is committing transaction'
RAISERROR (@log_message, 0, 1) WITH NOWAIT
COMMIT TRANSACTION move_data_to_permanent_tables;

THROW;
BEGIN
SET @log_date = CONVERT(NVARCHAR(50),GETDATE(),121);
SET @log_message = @log_date + ' move_data_to_permanent_tables is committing transaction'
RAISERROR (@log_message, 0, 1) WITH NOWAIT
COMMIT TRANSACTION move_data_to_permanent_tables;
END

END CATCH;

GO
31 changes: 21 additions & 10 deletions sql/SPROC_test_move_data_to_permanent_tables.sql
Original file line number Diff line number Diff line change
Expand Up @@ -29,31 +29,42 @@ BEGIN
EXEC dbo.move_data_to_permanent_tables 'watermark_test';


DECLARE @Expected AS VARCHAR(100)
DECLARE @Actual AS VARCHAR(100)

SET @Expected = (SELECT COUNT(*) FROM expected_test_table)
SET @Actual = (SELECT COUNT(*) FROM test_table)
-- Validate test table has the same number of rows as expected table
IF (SELECT COUNT(*) FROM test_table) = (SELECT COUNT(*) FROM expected_test_table)
RAISERROR ('Equal', 0, 1) WITH NOWAIT
ELSE
RAISERROR ('Not Equal', 0, 1);
RAISERROR ('Expected and Actual Count is Equal', 0, 1) WITH NOWAIT;
ELSE
RAISERROR ('Actual Value(%s) is not Equal to expected value (%s) ', 0, 1, @Actual, @Expected) WITH NOWAIT;

-- Validate test table has the same value for col1 as expected table
SET @Expected = (SELECT col1 FROM expected_test_table)
SET @Actual = (SELECT col1 FROM test_table)
IF (SELECT col1 FROM test_table) = (SELECT col1 FROM expected_test_table)
RAISERROR ('Equal', 0, 1) WITH NOWAIT;
RAISERROR ('Actual Col 1 is Equal to Expected Col 1', 0, 1) WITH NOWAIT;
ELSE
RAISERROR ('Not Equal', 0, 1);
RAISERROR ('Actual Value(%s) is not Equal to expected value (%s) ', 0, 1, @Actual, @Expected) WITH NOWAIT;


-- Validate test table has the same value for col2 as expected table
SET @Expected = (SELECT col2 FROM expected_test_table)
SET @Actual = (SELECT col2 FROM test_table)
IF (SELECT col2 FROM test_table) = (SELECT col2 FROM expected_test_table)
RAISERROR ('Equal', 0, 1) WITH NOWAIT
RAISERROR ('Actual Col 2 is Equal to Expected Col 2', 0, 1) WITH NOWAIT;
ELSE
RAISERROR ('Not Equal', 0, 1);
RAISERROR ('Actual Value(%s) is not Equal to expected value (%s) ', 0, 1, @Actual, @Expected) WITH NOWAIT;

-- Validate test table has the same value for col3 as expected table
SET @Expected = (SELECT col3 FROM expected_test_table)
SET @Actual = (SELECT col3 FROM test_table)
IF (SELECT col3 FROM test_table) = (SELECT col3 FROM expected_test_table)
RAISERROR ('Equal', 0, 1) WITH NOWAIT
RAISERROR ('Actual Col 3 is Equal to Expected Col 3', 0, 1) WITH NOWAIT;
ELSE
RAISERROR ('Not Equal', 0, 1);

RAISERROR ('Actual Value(%s) is not Equal to expected value (%s) ', 0, 1, @Actual, @Expected) WITH NOWAIT;
DROP TABLE watermark_test;
DROP TABLE test_table;
DROP TABLE staging_test_table;
Expand Down
5 changes: 0 additions & 5 deletions sql/dacpac/dbo/Scripts/Script.PostDeployment.sql

This file was deleted.

36 changes: 20 additions & 16 deletions sql/dacpac/dbo/StoredProcedures/move_data_to_permanent_tables.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2,16 +2,19 @@ CREATE PROCEDURE move_data_to_permanent_tables @watermark_table NVARCHAR(100)
AS
-- SET XACT_ABORT ON will cause the transaction to be uncommittable
-- when the constraint violation occurs.
SET XACT_ABORT ON;
SET XACT_ABORT ON;
BEGIN TRANSACTION move_data_to_permanent_tables
BEGIN TRY
BEGIN TRANSACTION move_data_to_permanent_tables

DECLARE @current_table_name VARCHAR(MAX);
DECLARE @staging_table_name VARCHAR(MAX);
DECLARE @log_date AS NVARCHAR(50);
DECLARE @log_message NVARCHAR(512);
SET @current_table_name = ''

-- The use of RAISERROR with the NOWAIT option shouldn't actually be emitting an exception as you might expect. It's used
-- to immediately emmit log/console messages. For additional details, see
-- https://www.mssqltips.com/sqlservertip/1660/using-the-nowait-option-with-the-sql-server-raiserror-statement/

SET @log_date = CONVERT(NVARCHAR(50),GETDATE(),121);
SET @log_message = @log_date + ' move_data_to_permanent_tables is starting execution'
RAISERROR (@log_message, 0, 1) WITH NOWAIT
Expand Down Expand Up @@ -82,26 +85,27 @@ AS

IF (SELECT CURSOR_STATUS('global','omop_tables_cursor')) >= -1
BEGIN
DEALLOCATE omop_tables_cursor;
DEALLOCATE omop_tables_cursor;
END

-- Transaction uncommittable
IF (XACT_STATE()) = -1
SET @log_date = CONVERT(NVARCHAR(50),GETDATE(),121);
SET @log_message = @log_date + ' move_data_to_permanent_tables is rolling back transaction'
RAISERROR (@log_message, 0, 1) WITH NOWAIT
ROLLBACK TRANSACTION move_data_to_permanent_tables;

BEGIN
SET @log_date = CONVERT(NVARCHAR(50),GETDATE(),121);
SET @log_message = @log_date + ' move_data_to_permanent_tables is rolling back transaction'
RAISERROR (@log_message, 0, 1) WITH NOWAIT
ROLLBACK TRANSACTION move_data_to_permanent_tables;
THROW;
END
-- Transaction committable
IF (XACT_STATE()) = 1
SET @log_date = CONVERT(NVARCHAR(50),GETDATE(),121);
SET @log_message = @log_date + ' move_data_to_permanent_tables is committing transaction'
RAISERROR (@log_message, 0, 1) WITH NOWAIT
COMMIT TRANSACTION move_data_to_permanent_tables;

THROW;
BEGIN
SET @log_date = CONVERT(NVARCHAR(50),GETDATE(),121);
SET @log_message = @log_date + ' move_data_to_permanent_tables is committing transaction'
RAISERROR (@log_message, 0, 1) WITH NOWAIT
COMMIT TRANSACTION move_data_to_permanent_tables;
END

END CATCH;

GO

This file was deleted.

9 changes: 9 additions & 0 deletions sql/dacpac/dbo/Tables/metadata.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,9 @@
CREATE TABLE [dbo].[metadata] (
[metadata_concept_id] INT NOT NULL,
[metadata_type_concept_id] INT NOT NULL,
[name] VARCHAR (250) NOT NULL,
[value_as_string] VARCHAR (MAX) NULL,
[value_as_concept_id] INT NULL,
[metadata_date] DATE NULL,
[metadata_datetime] DATETIME2 (7) NULL
);
8 changes: 8 additions & 0 deletions sql/dacpac/dbo/Tables/staging_attribute_definition.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
CREATE TABLE [dbo].[staging_attribute_definition] (
[attribute_definition_id] INT NOT NULL,
[attribute_name] VARCHAR (255) NOT NULL,
[attribute_description] VARCHAR (MAX) NULL,
[attribute_type_concept_id] INT NOT NULL,
[attribute_syntax] VARCHAR (MAX) NULL,
);

4 changes: 0 additions & 4 deletions sql/dacpac/dbo/Tables/staging_care_site.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,7 +6,3 @@ CREATE TABLE [dbo].[staging_care_site] (
[care_site_source_value] VARCHAR (50) NULL,
[place_of_service_source_value] VARCHAR (50) NULL
);


GO

3 changes: 0 additions & 3 deletions sql/dacpac/dbo/Tables/staging_cdm_source.sql
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,3 @@ CREATE TABLE [dbo].[staging_cdm_source] (
[vocabulary_version] VARCHAR (20) NULL
);


GO

8 changes: 8 additions & 0 deletions sql/dacpac/dbo/Tables/staging_cohort.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
CREATE TABLE [dbo].[staging_cohort] (
[cohort_definition_id] INT NOT NULL,
[subject_id] INT NOT NULL,
[cohort_start_date] DATE NOT NULL,
[cohort_end_date] DATE NOT NULL,
);


10 changes: 10 additions & 0 deletions sql/dacpac/dbo/Tables/staging_cohort_attribute.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,10 @@
CREATE TABLE [dbo].[staging_cohort_attribute] (
[cohort_definition_id] INT NOT NULL,
[cohort_start_date] DATE NOT NULL,
[cohort_end_date] DATE NOT NULL,
[subject_id] INT NOT NULL,
[attribute_definition_id] INT NOT NULL,
[value_as_number] FLOAT (53) NULL,
[value_as_concept_id] INT NULL,
);

10 changes: 10 additions & 0 deletions sql/dacpac/dbo/Tables/staging_cohort_definition.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,10 @@
CREATE TABLE [dbo].[staging_cohort_definition] (
[cohort_definition_id] INT NOT NULL,
[cohort_definition_name] VARCHAR (255) NOT NULL,
[cohort_definition_description] VARCHAR (MAX) NULL,
[definition_type_concept_id] INT NOT NULL,
[cohort_definition_syntax] VARCHAR (MAX) NULL,
[subject_concept_id] INT NOT NULL,
[cohort_initiation_date] DATE NULL,
);

12 changes: 12 additions & 0 deletions sql/dacpac/dbo/Tables/staging_concept.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
CREATE TABLE [dbo].[staging_concept] (
[concept_id] INT NOT NULL,
[concept_name] VARCHAR (255) NOT NULL,
[domain_id] VARCHAR (20) NOT NULL,
[vocabulary_id] VARCHAR (20) NOT NULL,
[concept_class_id] VARCHAR (20) NOT NULL,
[standard_concept] VARCHAR (1) NULL,
[concept_code] VARCHAR (50) NOT NULL,
[valid_start_date] DATE NOT NULL,
[valid_end_date] DATE NOT NULL,
[invalid_reason] VARCHAR (1) NULL,
);
6 changes: 6 additions & 0 deletions sql/dacpac/dbo/Tables/staging_concept_ancestor.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,6 @@
CREATE TABLE [dbo].[staging_concept_ancestor] (
[ancestor_concept_id] INT NOT NULL,
[descendant_concept_id] INT NOT NULL,
[min_levels_of_separation] INT NOT NULL,
[max_levels_of_separation] INT NOT NULL,
);
5 changes: 5 additions & 0 deletions sql/dacpac/dbo/Tables/staging_concept_class.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
CREATE TABLE [dbo].[staging_concept_class] (
[concept_class_id] VARCHAR (20) NOT NULL,
[concept_class_name] VARCHAR (255) NOT NULL,
[concept_class_concept_id] INT NOT NULL,
);
8 changes: 8 additions & 0 deletions sql/dacpac/dbo/Tables/staging_concept_relationship.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
CREATE TABLE [dbo].[staging_concept_relationship] (
[concept_id_1] INT NOT NULL,
[concept_id_2] INT NOT NULL,
[relationship_id] VARCHAR (20) NOT NULL,
[valid_start_date] DATE NOT NULL,
[valid_end_date] DATE NOT NULL,
[invalid_reason] VARCHAR (1) NULL,
);
5 changes: 5 additions & 0 deletions sql/dacpac/dbo/Tables/staging_concept_synonym.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
CREATE TABLE [dbo].[staging_concept_synonym] (
[concept_id] INT NOT NULL,
[concept_synonym_name] VARCHAR (1000) NOT NULL,
[language_concept_id] INT NOT NULL,
);
4 changes: 0 additions & 4 deletions sql/dacpac/dbo/Tables/staging_condition_era.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,7 +6,3 @@ CREATE TABLE [dbo].[staging_condition_era] (
[condition_era_end_date] DATE NOT NULL,
[condition_occurrence_count] INT NULL
);


GO

6 changes: 1 addition & 5 deletions sql/dacpac/dbo/Tables/staging_condition_occurrence.sql
Original file line number Diff line number Diff line change
Expand Up @@ -15,8 +15,4 @@ CREATE TABLE [dbo].[staging_condition_occurrence] (
[condition_source_concept_id] INT NULL,
[condition_status_source_value] VARCHAR (50) NULL,
[condition_status_concept_id] INT NULL
);


GO

);
Loading

0 comments on commit 7809dd2

Please sign in to comment.