|
| 1 | +USE [master] |
| 2 | +GO |
| 3 | + |
| 4 | +/** |
| 5 | + * TestDB |
| 6 | + */ |
| 7 | +CREATE DATABASE [TestDB] |
| 8 | +GO |
| 9 | + |
| 10 | +ALTER DATABASE [TestDB] SET RECOVERY SIMPLE |
| 11 | +GO |
| 12 | + |
| 13 | +USE [TestDB] |
| 14 | +GO |
| 15 | + |
| 16 | +SET ANSI_NULLS ON |
| 17 | +GO |
| 18 | +SET QUOTED_IDENTIFIER ON |
| 19 | +GO |
| 20 | +CREATE TABLE [dbo].[person]( |
| 21 | + [person_id] [int] NULL, |
| 22 | + [age] [int] NULL, |
| 23 | + [gender] [nvarchar](20) NULL |
| 24 | +) ON [PRIMARY] |
| 25 | +GO |
| 26 | + |
| 27 | +SET ANSI_NULLS ON |
| 28 | +GO |
| 29 | +SET QUOTED_IDENTIFIER ON |
| 30 | +GO |
| 31 | +CREATE TABLE [dbo].[visit_occurrence]( |
| 32 | + [person_id] [int] NULL, |
| 33 | + [visit_occurrence_id] [int] NULL, |
| 34 | + [visit_date] [datetime] NULL, |
| 35 | + [visit_type] [nvarchar](10) NULL |
| 36 | +) ON [PRIMARY] |
| 37 | +GO |
| 38 | + |
| 39 | +INSERT [dbo].[person] ([person_id], [age], [gender]) VALUES (1, 28, N'F') |
| 40 | +GO |
| 41 | +INSERT [dbo].[person] ([person_id], [age], [gender]) VALUES (2, 74, N'M') |
| 42 | +GO |
| 43 | +INSERT [dbo].[person] ([person_id], [age], [gender]) VALUES (3, 55, N'M') |
| 44 | +GO |
| 45 | +INSERT [dbo].[person] ([person_id], [age], [gender]) VALUES (4, 43, N'F') |
| 46 | +GO |
| 47 | +INSERT [dbo].[person] ([person_id], [age], [gender]) VALUES (5, 99, N'F') |
| 48 | +GO |
| 49 | +INSERT [dbo].[visit_occurrence] ([person_id], [visit_occurrence_id], [visit_date], [visit_type]) VALUES (1, 100, CAST(N'2020-08-14T00:00:00.000' AS DateTime), N'IP') |
| 50 | +GO |
| 51 | +INSERT [dbo].[visit_occurrence] ([person_id], [visit_occurrence_id], [visit_date], [visit_type]) VALUES (1, 101, CAST(N'2020-09-22T00:00:00.000' AS DateTime), N'OP') |
| 52 | +GO |
| 53 | +INSERT [dbo].[visit_occurrence] ([person_id], [visit_occurrence_id], [visit_date], [visit_type]) VALUES (2, 102, CAST(N'2018-06-01T00:00:00.000' AS DateTime), N'IP') |
| 54 | +GO |
| 55 | +INSERT [dbo].[visit_occurrence] ([person_id], [visit_occurrence_id], [visit_date], [visit_type]) VALUES (2, 103, CAST(N'2018-02-28T00:00:00.000' AS DateTime), N'ED') |
| 56 | +GO |
| 57 | +INSERT [dbo].[visit_occurrence] ([person_id], [visit_occurrence_id], [visit_date], [visit_type]) VALUES (3, 104, CAST(N'2015-01-01T00:00:00.000' AS DateTime), N'OP') |
| 58 | +GO |
| 59 | +INSERT [dbo].[visit_occurrence] ([person_id], [visit_occurrence_id], [visit_date], [visit_type]) VALUES (4, 105, CAST(N'2022-09-19T00:00:00.000' AS DateTime), N'OP') |
| 60 | +GO |
| 61 | +INSERT [dbo].[visit_occurrence] ([person_id], [visit_occurrence_id], [visit_date], [visit_type]) VALUES (4, 106, CAST(N'2028-01-01T00:00:00.000' AS DateTime), N'IP') |
| 62 | +GO |
| 63 | + |
| 64 | +USE [LeafDB] |
| 65 | +GO |
| 66 | + |
| 67 | + |
| 68 | +DECLARE @user NVARCHAR(20) = 'TestDB.sql' |
| 69 | +DECLARE @yes BIT = 1 |
| 70 | +DECLARE @no BIT = 0 |
| 71 | + |
| 72 | +INSERT INTO app.ConceptSqlSet (SqlSetFrom, IsEncounterBased, IsEventBased, SqlFieldDate, Created, CreatedBy, Updated, UpdatedBy) |
| 73 | +SELECT * |
| 74 | +FROM (VALUES ('dbo.person', @no, @no, NULL, GETDATE(), @user, GETDATE(), @user), |
| 75 | + ('dbo.visit_occurrence', @yes, @no, '@.visit_date', GETDATE(), @user, GETDATE(), @user) |
| 76 | + ) AS X(col1,col2,col3,col4,col5,col6,col7,col8) |
| 77 | + |
| 78 | +DECLARE @sqlset_person INT = (SELECT TOP 1 Id FROM LeafDB.app.ConceptSqlSet WHERE SqlSetFrom = 'dbo.person') |
| 79 | +DECLARE @sqlset_visit_occurrence INT = (SELECT TOP 1 Id FROM LeafDB.app.ConceptSqlSet WHERE SqlSetFrom = 'dbo.visit_occurrence') |
| 80 | + |
| 81 | +INSERT INTO app.Concept (ExternalId, ExternalParentId, [IsNumeric], IsParent, IsRoot, SqlSetId, SqlSetWhere, |
| 82 | + SqlFieldNumeric, UiDisplayName, UiDisplayText, UiDisplayUnits, UiNumericDefaultText, UiDisplayPatientCount) |
| 83 | +SELECT ExternalId = 'A' |
| 84 | + , ExternalParentId = NULL |
| 85 | + , [IsNumeric] = @no |
| 86 | + , IsParent = @yes |
| 87 | + , IsRoot = @yes |
| 88 | + , SqlSetId = @sqlset_person |
| 89 | + , SqlSetWhere = NULL |
| 90 | + , SqlFieldNumeric = NULL |
| 91 | + , UiDisplayName = 'Demographics' |
| 92 | + , UiDisplayText = 'Have demographics' |
| 93 | + , UiDisplayUnits = NULL |
| 94 | + , UiNumericDefaultText = NULL |
| 95 | + , UiDisplayPatientCount = (SELECT COUNT(*) FROM TestDB.dbo.person) |
| 96 | +UNION ALL |
| 97 | +SELECT ExternalId = 'A1' |
| 98 | + , ExternalParentId = 'A' |
| 99 | + , [IsNumeric] = @no |
| 100 | + , IsParent = @yes |
| 101 | + , IsRoot = @no |
| 102 | + , SqlSetId = @sqlset_person |
| 103 | + , SqlSetWhere = '@.gender IS NOT NULL' |
| 104 | + , SqlFieldNumeric = NULL |
| 105 | + , UiDisplayName = 'Gender' |
| 106 | + , UiDisplayText = 'Identify with a gender' |
| 107 | + , UiDisplayUnits = NULL |
| 108 | + , UiNumericDefaultText = NULL |
| 109 | + , UiDisplayPatientCount = (SELECT COUNT(*) FROM TestDB.dbo.person) |
| 110 | +UNION ALL |
| 111 | +SELECT ExternalId = 'A11' |
| 112 | + , ExternalParentId = 'A1' |
| 113 | + , [IsNumeric] = @no |
| 114 | + , IsParent = @no |
| 115 | + , IsRoot = @no |
| 116 | + , SqlSetId = @sqlset_person |
| 117 | + , SqlSetWhere = '@.gender = ''F''' |
| 118 | + , SqlFieldNumeric = NULL |
| 119 | + , UiDisplayName = 'Female' |
| 120 | + , UiDisplayText = 'Identify as Female' |
| 121 | + , UiDisplayUnits = NULL |
| 122 | + , UiNumericDefaultText = NULL |
| 123 | + , UiDisplayPatientCount = (SELECT COUNT(*) FROM TestDB.dbo.person WHERE gender = 'F') |
| 124 | +UNION ALL |
| 125 | +SELECT ExternalId = 'A12' |
| 126 | + , ExternalParentId = 'A1' |
| 127 | + , [IsNumeric] = @no |
| 128 | + , IsParent = @no |
| 129 | + , IsRoot = @no |
| 130 | + , SqlSetId = @sqlset_person |
| 131 | + , SqlSetWhere = '@.gender = ''M''' |
| 132 | + , SqlFieldNumeric = NULL |
| 133 | + , UiDisplayName = 'Male' |
| 134 | + , UiDisplayText = 'Identify as Male' |
| 135 | + , UiDisplayUnits = NULL |
| 136 | + , UiNumericDefaultText = NULL |
| 137 | + , UiDisplayPatientCount = (SELECT COUNT(*) FROM TestDB.dbo.person WHERE gender = 'M') |
| 138 | +UNION ALL |
| 139 | +SELECT ExternalId = 'A2' |
| 140 | + , ExternalParentId = 'A' |
| 141 | + , [IsNumeric] = @yes |
| 142 | + , IsParent = @no |
| 143 | + , IsRoot = @no |
| 144 | + , SqlSetId = @sqlset_person |
| 145 | + , SqlSetWhere = '@.age IS NOT NULL' |
| 146 | + , SqlFieldNumeric = '@.age' |
| 147 | + , UiDisplayName = 'Age' |
| 148 | + , UiDisplayText = 'Are currently' |
| 149 | + , UiDisplayUnits = 'years of age' |
| 150 | + , UiNumericDefaultText = 'any age' |
| 151 | + , UiDisplayPatientCount = (SELECT COUNT(*) FROM TestDB.dbo.person WHERE age IS NOT NULL) |
| 152 | +UNION ALL |
| 153 | +SELECT ExternalId = 'B' |
| 154 | + , ExternalParentId = NULL |
| 155 | + , [IsNumeric] = @no |
| 156 | + , IsParent = @yes |
| 157 | + , IsRoot = @yes |
| 158 | + , SqlSetId = @sqlset_visit_occurrence |
| 159 | + , SqlSetWhere = NULL |
| 160 | + , SqlFieldNumeric = NULL |
| 161 | + , UiDisplayName = 'Encounters' |
| 162 | + , UiDisplayText = 'Had an encounter' |
| 163 | + , UiDisplayUnits = NULL |
| 164 | + , UiNumericDefaultText = NULL |
| 165 | + , UiDisplayPatientCount = (SELECT COUNT(*) FROM TestDB.dbo.visit_occurrence) |
| 166 | +UNION ALL |
| 167 | +SELECT ExternalId = 'B1' |
| 168 | + , ExternalParentId = 'B' |
| 169 | + , [IsNumeric] = @no |
| 170 | + , IsParent = @no |
| 171 | + , IsRoot = @no |
| 172 | + , SqlSetId = @sqlset_visit_occurrence |
| 173 | + , SqlSetWhere = NULL |
| 174 | + , SqlFieldNumeric = NULL |
| 175 | + , UiDisplayName = 'Inpatient' |
| 176 | + , UiDisplayText = 'Had an Inpatient encounter' |
| 177 | + , UiDisplayUnits = NULL |
| 178 | + , UiNumericDefaultText = NULL |
| 179 | + , UiDisplayPatientCount = (SELECT COUNT(*) FROM TestDB.dbo.visit_occurrence WHERE visit_type = 'IP') |
| 180 | +UNION ALL |
| 181 | +SELECT ExternalId = 'B2' |
| 182 | + , ExternalParentId = 'B' |
| 183 | + , [IsNumeric] = @no |
| 184 | + , IsParent = @no |
| 185 | + , IsRoot = @no |
| 186 | + , SqlSetId = @sqlset_visit_occurrence |
| 187 | + , SqlSetWhere = NULL |
| 188 | + , SqlFieldNumeric = NULL |
| 189 | + , UiDisplayName = 'Outpatient' |
| 190 | + , UiDisplayText = 'Had an Outpatient encounter' |
| 191 | + , UiDisplayUnits = NULL |
| 192 | + , UiNumericDefaultText = NULL |
| 193 | + , UiDisplayPatientCount = (SELECT COUNT(*) FROM TestDB.dbo.visit_occurrence WHERE visit_type = 'OP') |
| 194 | +UNION ALL |
| 195 | +SELECT ExternalId = 'B3' |
| 196 | + , ExternalParentId = 'B' |
| 197 | + , [IsNumeric] = @no |
| 198 | + , IsParent = @no |
| 199 | + , IsRoot = @no |
| 200 | + , SqlSetId = @sqlset_visit_occurrence |
| 201 | + , SqlSetWhere = NULL |
| 202 | + , SqlFieldNumeric = NULL |
| 203 | + , UiDisplayName = 'Emergency' |
| 204 | + , UiDisplayText = 'Had an Emergency Department encounter' |
| 205 | + , UiDisplayUnits = NULL |
| 206 | + , UiNumericDefaultText = NULL |
| 207 | + , UiDisplayPatientCount = (SELECT COUNT(*) FROM TestDB.dbo.visit_occurrence WHERE visit_type = 'ED') |
| 208 | + |
| 209 | + |
| 210 | + |
| 211 | +/** |
| 212 | +* Set ParentId based on ExternalIds |
| 213 | +*/ |
| 214 | +UPDATE LeafDB.app.Concept |
| 215 | +SET ParentId = P.Id |
| 216 | +FROM LeafDB.app.Concept AS C |
| 217 | + INNER JOIN (SELECT P.Id, P.ParentId, P.ExternalId |
| 218 | + FROM LeafDB.app.Concept AS P) AS P |
| 219 | + ON C.ExternalParentID = P.ExternalID |
| 220 | +WHERE C.ParentId IS NULL |
| 221 | + |
| 222 | +/** |
| 223 | +* Set RootIds |
| 224 | +*/ |
| 225 | +; WITH roots AS |
| 226 | +( |
| 227 | + SELECT RootId = C.Id |
| 228 | + , RootUiDisplayName = C.UiDisplayName |
| 229 | + , C.IsRoot |
| 230 | + , C.Id |
| 231 | + , C.ParentId |
| 232 | + , C.UiDisplayName |
| 233 | + FROM LeafDB.app.Concept AS C |
| 234 | + WHERE C.IsRoot = 1 |
| 235 | + UNION ALL |
| 236 | + SELECT roots.RootId |
| 237 | + , roots.RootUiDisplayName |
| 238 | + , C2.IsRoot |
| 239 | + , C2.Id |
| 240 | + , C2.ParentId |
| 241 | + , C2.UiDisplayName |
| 242 | + FROM roots |
| 243 | + INNER JOIN LeafDB.app.Concept AS C2 |
| 244 | + ON C2.ParentId = roots.Id |
| 245 | +) |
| 246 | +UPDATE LeafDB.app.Concept |
| 247 | +SET RootId = roots.RootId |
| 248 | +FROM LeafDB.app.Concept AS C |
| 249 | + INNER JOIN roots |
| 250 | + ON C.Id = roots.Id |
| 251 | +WHERE C.RootId IS NULL |
0 commit comments