-
Notifications
You must be signed in to change notification settings - Fork 0
/
DW_CreationMainScript_3.4.sql
9557 lines (8097 loc) · 347 KB
/
DW_CreationMainScript_3.4.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
IF NOT EXISTS(SELECT * FROM sys.databases WHERE name = 'EdFiDW')
BEGIN
CREATE DATABASE EdFiDW
END
GO
USE EdFiDW
GO
DECLARE @dropExistingTables BIT = 1
--creating schemas if they do not exist
-------------------------------------------------------------
DECLARE @sqlCmd NVARCHAR(max);
IF NOT EXISTS (SELECT 1
FROM sys.schemas
WHERE [name] = 'Staging')
BEGIN
SET @sqlCmd = 'CREATE SCHEMA [Staging] AUTHORIZATION dbo';
EXEC sp_executesql @sqlCmd;
END
IF NOT EXISTS (SELECT 1
FROM sys.schemas
WHERE [name] = 'Raw_EdFi')
BEGIN
SET @sqlCmd = 'CREATE SCHEMA [Raw_EdFi] AUTHORIZATION dbo';
EXEC sp_executesql @sqlCmd;
END
IF NOT EXISTS (SELECT 1
FROM sys.schemas
WHERE [name] = 'Raw_LegacyDW')
BEGIN
SET @sqlCmd = 'CREATE SCHEMA [Raw_LegacyDW] AUTHORIZATION dbo';
EXEC sp_executesql @sqlCmd;
END
IF NOT EXISTS (SELECT 1
FROM sys.schemas
WHERE [name] = 'Derived')
BEGIN
SET @sqlCmd = 'CREATE SCHEMA [Derived] AUTHORIZATION dbo';
EXEC sp_executesql @sqlCmd;
END
--dropping all db objects
IF (@dropExistingTables = 1)
BEGIN
--views - dropping views first as they are schema bound
---------------------------------------------------------------
DROP VIEW IF EXISTS dbo.View_StudentAssessmentScores;
DROP VIEW IF EXISTS dbo.View_StudentAttendance_ADA;
DROP VIEW IF EXISTS dbo.View_StudentAttendanceByDay;
DROP VIEW IF EXISTS dbo.View_StudentDiscipline;
DROP VIEW IF EXISTS dbo.View_StudentCourseTranscript;
DROP VIEW IF EXISTS dbo.View_StudentCourseGrade;
DROP VIEW IF EXISTS dbo.View_StudentRoster;
--fact tables
---------------------------------------------------------------
DROP TABLE IF EXISTS dbo.FactStudentAttendanceByDay;
DROP TABLE IF EXISTS dbo.FactStudentAssessmentScore;
DROP TABLE IF EXISTS dbo.FactStudentDiscipline;
DROP TABLE IF EXISTS dbo.FactStudentCourseTranscript;
DROP TABLE IF EXISTS dbo.FactStudentCourseGrade;
--ETL Objects
---------------------------------------------------------------
--tables
DROP TABLE IF EXISTS dbo.ETL_Lineage;
DROP TABLE IF EXISTS dbo.ETL_IncrementalLoads;
DROP TABLE IF EXISTS Staging.School;
DROP TABLE IF EXISTS Staging.[Time];
DROP TABLE IF EXISTS Staging.[Staff];
DROP TABLE IF EXISTS Staging.Student;
DROP TABLE IF EXISTS Staging.AttendanceEventCategory;
DROP TABLE IF EXISTS Staging.DisciplineIncident;
DROP TABLE IF EXISTS Staging.Assessment;
DROP TABLE IF EXISTS Staging.Course;
DROP TABLE IF EXISTS Staging.GradingPeriod;
DROP TABLE IF EXISTS Staging.StudentSection;
DROP TABLE IF EXISTS Staging.StudentAttendanceByDay;
DROP TABLE IF EXISTS Staging.StudentDiscipline;
DROP TABLE IF EXISTS Staging.StudentAssessmentScore;
DROP TABLE IF EXISTS Staging.StudentCourseTranscript;
DROP TABLE IF EXISTS Staging.StudentCourseGrade;
--functions
DROP FUNCTION IF EXISTS dbo.Func_ETL_GetFullName;
DROP FUNCTION IF EXISTS dbo.Func_ETL_GetHolidayFromDate;
DROP FUNCTION IF EXISTS dbo.Func_ETL_GetSchoolYear;
DROP FUNCTION IF EXISTS dbo.Func_ETL_GetEasterHolidays;
--stored procedures
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_Lineage_GetKey];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_IncrementalLoads_GetLastLoadedDate];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_DimSchool_PopulateStaging];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_DimSchool_PopulateProduction];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_DimTime_PopulateStaging];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_DimTime_PopulateProduction];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_DimStudent_PopulateStaging];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_DimStudent_PopulateProduction];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_DimAttendanceEventCategory_PopulateStaging];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_DimAttendanceEventCategory_PopulateProduction];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_DimDisciplineIncident_PopulateStaging];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_DimDisciplineIncident_PopulateProduction];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_DimAssessment_PopulateStaging];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_DimAssessment_PopulateProduction];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_DimCourse_PopulateStaging];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_DimCourse_PopulateProduction];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_DimGradingPeriod_PopulateStaging];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_DimGradingPeriod_PopulateProduction];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_DimStudentSection_PopulateStaging];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_DimStudentSection_PopulateProduction];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_FactStudentAttendanceByDay_PopulateStaging];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_FactStudentAttendanceByDay_PopulateProduction];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_FactStudentDiscipline_PopulateStaging];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_FactStudentDiscipline_PopulateProduction];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_FactStudentAssessmentScore_PopulateStaging];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_FactStudentAssessmentScore_PopulateProduction];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_FactStudentCourseTranscript_PopulateStaging];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_FactStudentCourseTranscript_PopulateProduction];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_FactStudentCourseGrade_PopulateStaging];
DROP PROCEDURE IF EXISTS [dbo].[Proc_ETL_FactStudentCourseGrade_PopulateProduction];
--derived tables
---------------------------------------------------------------
DROP TABLE IF EXISTS Derived.StudentAttendanceByDay;
DROP TABLE IF EXISTS Derived.StudentAttendanceADA;
DROP TABLE IF EXISTS Derived.StudentAssessmentScore;
DROP TABLE IF EXISTS Derived.StaffCurrentSchools;
DROP TABLE IF EXISTS Derived.StaffCurrentGradeLevels;
DROP TABLE IF EXISTS Derived.StaffCurrentStudents;
--dim tables
---------------------------------------------------------------
DROP TABLE IF EXISTS dbo.DimCourse;
DROP TABLE IF EXISTS dbo.DimAssessment;
DROP TABLE IF EXISTS dbo.DimDisciplineIncident;
DROP TABLE IF EXISTS dbo.DimAttendanceEventCategory;
DROP TABLE IF EXISTS dbo.DimStudent;
DROP TABLE IF EXISTS dbo.DimTime;
DROP TABLE IF EXISTS dbo.DimStaff;
DROP TABLE IF EXISTS dbo.DimSchool;
DROP TABLE IF EXISTS dbo.DimGradingPeriod;
DROP TABLE IF EXISTS dbo.DimStudentSection;
END;
--********************************************************************************
--** DIMENSION TABLES **
--********************************************************************************
--school - prod
if NOT EXISTS (select 1
FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_NAME = 'DimSchool'
AND TABLE_SCHEMA = 'dbo')
BEGIN
CREATE TABLE dbo.DimSchool
(
SchoolKey int NOT NULL IDENTITY(1,1), -- surrogate
[_sourceKey] NVARCHAR(50) NOT NULL, --'Ed-Fi|Id'
DistrictSchoolCode NVARCHAR(10) NULL ,
StateSchoolCode NVARCHAR(50) NULL ,
UmbrellaSchoolCode NVARCHAR(50) NULL,
ShortNameOfInstitution NVARCHAR(500) NOT NULL,
NameOfInstitution NVARCHAR(500) NOT NULL,
SchoolCategoryType NVARCHAR(100) NOT NULL, -- elem, middle, hs, combined
SchoolCategoryType_Elementary_Indicator BIT NOT NULL,
SchoolCategoryType_Middle_Indicator BIT NOT NULL,
SchoolCategoryType_HighSchool_Indicator BIT NOT NULL,
SchoolCategoryType_Combined_Indicator BIT NOT NULL,
SchoolCategoryType_Other_Indicator BIT NOT NULL,
TitleIPartASchoolDesignationTypeCodeValue NVARCHAR(50) NOT NULL,--Not designated as a Title I Part A school
--Title I Part A Schoolwide Assistance Program Schoo
--Title I Part A Targeted Assistance School
--Title I targeted eligible school - no program
--Title I targeted school
--Title I school wide eligible - Title I targeted pr
--Title I school wide eligible school - no program
TitleIPartASchoolDesignation_Indicator BIT NOT NULL, -- True,False
OperationalStatusTypeDescriptor_CodeValue NVARCHAR(50) NOT NULL,
OperationalStatusTypeDescriptor_Description NVARCHAR(1024) NOT NULL,
BPSSchool_Indicator BIT NOT NULL,
ValidFrom DATETIME NOT NULL,
ValidTo DATETIME NOT NULL,
IsCurrent BIT NOT NULL,
IsLatest BIT NOT NULL,
LineageKey INT NOT NULL,
CONSTRAINT PK_DimSchool PRIMARY KEY (SchoolKey)
);
CREATE NONCLUSTERED INDEX DimSchool_CoveringIndex
ON dbo.DimSchool (_sourceKey, ValidFrom)
INCLUDE ( ValidTo, SchoolKey);
END;
--school - staging
if NOT EXISTS (select 1
FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_NAME = 'School'
AND TABLE_SCHEMA = 'Staging')
CREATE TABLE Staging.School
(
SchoolKey int NOT NULL IDENTITY(1,1), -- surrogate
[_sourceKey] NVARCHAR(50) NOT NULL, --'Ed-Fi|Id'
DistrictSchoolCode NVARCHAR(10) NULL ,
StateSchoolCode NVARCHAR(50) NULL ,
UmbrellaSchoolCode NVARCHAR(50) NULL,
ShortNameOfInstitution NVARCHAR(500) NOT NULL,
NameOfInstitution NVARCHAR(500) NOT NULL,
SchoolCategoryType NVARCHAR(100) NOT NULL, -- elem, middle, hs, combined
SchoolCategoryType_Elementary_Indicator BIT NOT NULL,
SchoolCategoryType_Middle_Indicator BIT NOT NULL,
SchoolCategoryType_HighSchool_Indicator BIT NOT NULL,
SchoolCategoryType_Combined_Indicator BIT NOT NULL,
SchoolCategoryType_Other_Indicator BIT NOT NULL,
TitleIPartASchoolDesignationTypeCodeValue NVARCHAR(50) NOT NULL,--Not designated as a Title I Part A school
--Title I Part A Schoolwide Assistance Program Schoo
--Title I Part A Targeted Assistance School
--Title I targeted eligible school - no program
--Title I targeted school
--Title I school wide eligible - Title I targeted pr
--Title I school wide eligible school - no program
TitleIPartASchoolDesignation_Indicator BIT NOT NULL, -- True,False
OperationalStatusTypeDescriptor_CodeValue NVARCHAR(50) NOT NULL,
OperationalStatusTypeDescriptor_Description NVARCHAR(1024) NOT NULL,
BPSSchool_Indicator BIT NOT NULL,
SchoolNameModifiedDate DATETIME NOT NULL,
SchoolOperationalStatusTypeModifiedDate DATETIME NOT NULL,
SchoolCategoryModifiedDate DATETIME NOT NULL,
SchoolTitle1StatusModifiedDate DATETIME NOT NULL,
ValidFrom DATETIME NOT NULL,
ValidTo DATETIME NOT NULL,
IsCurrent BIT NOT NULL,
CONSTRAINT PK_StagingSchool PRIMARY KEY (SchoolKey),
);
GO
--Time - prod
if NOT EXISTS (select 1
FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_NAME = 'DimTime'
AND TABLE_SCHEMA = 'dbo')
BEGIN
CREATE TABLE dbo.DimTime
(
TimeKey INT NOT NULL IDENTITY(1,1), -- ex 9/1/2019 : 20190901 -- surrogate
SchoolDate DATE NOT NULL , -- 9/1/2019
SchoolDate_MMYYYY CHAR(6) NOT NULL,
SchoolDate_Fomat1 CHAR(10) NOT NULL,
SchoolDate_Fomat2 CHAR(8) NOT NULL,
SchoolDate_Fomat3 CHAR(10) NOT NULL,
SchoolYear SMALLINT NOT NULL, -- ex: 9/1/2019 = 2020
SchoolYearDescription NVARCHAR(50) NOT NULL, -- '2019-2020 or SchoolYear 2019 - 2020'
CalendarYear SMALLINT NOT NULL, -- ex: 9/1/2019 = 2020
DayOfMonth TINYINT NOT NULL, -- 1 - 30|31
DaySuffix CHAR(2) NOT NULL , -- 1st, 2nd, 3rd
DayName NVARCHAR(15) NOT NULL, -- Monday, Tuesday
DayNameShort NVARCHAR(15) NOT NULL, -- Mon, Tue
DayOfWeek TINYINT NOT NULL, -- 1 - 7
WeekInMonth TINYINT NOT NULL, -- 1 - 4 or 5 -- this counts 7 days starting on the 1st of the month
WeekOfMonth TINYINT NOT NULL, -- 1 - 4 or 5 -- this is the actual week of the month (starting on sunday)
Weekend_Indicator BIT NOT NULL,
WeekOfYear TINYINT NOT NULL, -- 1 - 53
FirstDayOfWeek DATE NOT NULL,
LastDayOfWeek DATE NOT NULL,
WeekBeforeChristmas_Indicator BIT NOT NULL, -- True,False
[Month] TINYINT NOT NULL, -- 1..12
MonthName NVARCHAR(10) NOT NULL, --January,February,December
MonthNameShort CHAR(3) NOT NULL, --Jan,Feb,Dec
FirstDayOfMonth DATE NOT NULL,
LastDayOfMonth DATE NOT NULL,
FirstDayOfNextMonth DATE NOT NULL,
LastDayOfNextMonth DATE NOT NULL,
DayOfYear SMALLINT NULL, -- 1 - 365 or 366 (Leap Year Every Four Years)
LeapYear_Indicator BIT NOT NULL,
FederalHolidayName NVARCHAR(20) NULL, -- Memorial Day
FederalHoliday_Indicator BIT NOT NULL, -- True,False
--all these vary by school
SchoolKey INT NULL,
DayOfSchoolYear SMALLINT NULL, -- 1 - 180 - based on SIS(ODS) school calendar
SchoolCalendarEventType_CodeValue NVARCHAR(50) NULL, -- Emergency day,Instructional day,Teacher only day
SchoolCalendarEventType_Description NVARCHAR(50) NULL, -- Emergency day,Instructional day,Teacher only day
SchoolTermDescriptor_CodeValue NVARCHAR(50) NULL, -- Year Round,First Quarter, First Trimester, Fall Semester, Fourth Quarter, etc. SELECT * FROM v25_EdFi_Ods_Sandbox_populatedSandbox.edfi.Descriptor where namespace = 'http://ed-fi.org/Descriptor/TermDescriptor.xml'
SchoolTermDescriptor_Description NVARCHAR(50) NULL, -- Year Round,First Quarter, First Trimester, Fall Semester, Fourth Quarter, etc SELECT * FROM v25_EdFi_Ods_Sandbox_populatedSandbox.edfi.Descriptor where namespace = 'http://ed-fi.org/Descriptor/TermDescriptor.xml'
--all indicators were removed until we see actual district's data.
ValidFrom DATETIME NOT NULL,
ValidTo DATETIME NOT NULL,
IsCurrent BIT NOT NULL,
IsLatest BIT NOT NULL,
LineageKey INT NOT NULL,
CONSTRAINT PK_DimTime PRIMARY KEY (TimeKey),
CONSTRAINT FK_DimTime_SchoolKey FOREIGN KEY (SchoolKey) REFERENCES [dbo].[DimSchool] (SchoolKey)
);
CREATE NONCLUSTERED INDEX DimTime_CoveringIndex ON dbo.DimTime( SchoolKey, ValidFrom, ValidTo) INCLUDE (TimeKey);
END;
--time - staging
if NOT EXISTS (select 1
FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_NAME = 'Time'
AND TABLE_SCHEMA = 'Staging')
CREATE TABLE Staging.[Time]
(
TimeKey INT NOT NULL IDENTITY(1,1), -- ex 9/1/2019 : 20190901 -- surrogate
SchoolDate DATE NOT NULL , -- 9/1/2019
SchoolDate_MMYYYY CHAR(6) NOT NULL,
SchoolDate_Fomat1 CHAR(10) NOT NULL,
SchoolDate_Fomat2 CHAR(8) NOT NULL,
SchoolDate_Fomat3 CHAR(10) NOT NULL,
SchoolYear SMALLINT NOT NULL, -- ex: 9/1/2019 = 2020
SchoolYearDescription NVARCHAR(50) NOT NULL, -- '2019-2020 or SchoolYear 2019 - 2020'
CalendarYear SMALLINT NOT NULL, -- ex: 9/1/2019 = 2020
DayOfMonth TINYINT NOT NULL, -- 1 - 30|31
DaySuffix CHAR(2) NOT NULL , -- 1st, 2nd, 3rd
DayName NVARCHAR(15) NOT NULL, -- Monday, Tuesday
DayNameShort NVARCHAR(15) NOT NULL, -- Mon, Tue
DayOfWeek TINYINT NOT NULL, -- 1 - 7
WeekInMonth TINYINT NOT NULL, -- 1 - 4 or 5 -- this counts 7 days starting on the 1st of the month
WeekOfMonth TINYINT NOT NULL, -- 1 - 4 or 5 -- this is the actual week of the month (starting on sunday)
Weekend_Indicator BIT NOT NULL,
WeekOfYear TINYINT NOT NULL, -- 1 - 53
FirstDayOfWeek DATE NOT NULL,
LastDayOfWeek DATE NOT NULL,
WeekBeforeChristmas_Indicator BIT NOT NULL, -- True,False
[Month] TINYINT NOT NULL, -- 1..12
MonthName NVARCHAR(10) NOT NULL, --January,February,December
MonthNameShort CHAR(3) NOT NULL, --Jan,Feb,Dec
FirstDayOfMonth DATE NOT NULL,
LastDayOfMonth DATE NOT NULL,
FirstDayOfNextMonth DATE NOT NULL,
LastDayOfNextMonth DATE NOT NULL,
DayOfYear SMALLINT NULL, -- 1 - 365 or 366 (Leap Year Every Four Years)
LeapYear_Indicator BIT NOT NULL,
FederalHolidayName NVARCHAR(20) NULL, -- Memorial Day
FederalHoliday_Indicator BIT NOT NULL, -- True,False
--all these vary by school
SchoolKey INT NULL,
DayOfSchoolYear SMALLINT NULL, -- 1 - 180 - based on SIS(ODS) school calendar
SchoolCalendarEventType_CodeValue NVARCHAR(50) NULL, -- Emergency day,Instructional day,Teacher only day
SchoolCalendarEventType_Description NVARCHAR(50) NULL, -- Emergency day,Instructional day,Teacher only day
SchoolTermDescriptor_CodeValue NVARCHAR(50) NULL, -- Year Round,First Quarter, First Trimester, Fall Semester, Fourth Quarter, etc. SELECT * FROM v25_EdFi_Ods_Sandbox_populatedSandbox.edfi.Descriptor where namespace = 'http://ed-fi.org/Descriptor/TermDescriptor.xml'
SchoolTermDescriptor_Description NVARCHAR(50) NULL, -- Year Round,First Quarter, First Trimester, Fall Semester, Fourth Quarter, etc SELECT * FROM v25_EdFi_Ods_Sandbox_populatedSandbox.edfi.Descriptor where namespace = 'http://ed-fi.org/Descriptor/TermDescriptor.xml'
SchoolSessionModifiedDate DATETIME NOT NULL,
CalendarEventTypeModifiedDate DATETIME NOT NULL,
_sourceSchoolKey NVARCHAR(50) NULL,
ValidFrom DATETIME NOT NULL,
ValidTo DATETIME NOT NULL,
IsCurrent BIT NOT NULL
CONSTRAINT PK_StagingTime PRIMARY KEY (TimeKey)
);
GO
--Staff - prod
if NOT EXISTS (select 1
FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_NAME = 'DimStaff'
AND TABLE_SCHEMA = 'dbo')
BEGIN
CREATE TABLE dbo.DimStaff
(
StaffKey INT NOT NULL IDENTITY(1,1),
[_sourceKey] NVARCHAR(50) NOT NULL, --'EdFi|StaffUSI'
PrimaryElectronicMailAddress NVARCHAR(128) NULL,
PrimaryElectronicMailTypeDescriptor_CodeValue NVARCHAR(128) NULL, -- Home/Personal, Organization, Other, Work
PrimaryElectronicMailTypeDescriptor_Description NVARCHAR(128) NULL,
EducationOrganizationId INT NOT NULL,
ShortNameOfInstitution nvarchar(500) NULL,
NameOfInstitution nvarchar(500) NOT NULL,
[StaffUniqueId] NVARCHAR(32) NOT NULL,
[PersonalTitlePrefix] NVARCHAR(30) NULL,
[FirstName] NVARCHAR(75) NOT NULL,
[MiddleName] NVARCHAR(75) NULL,
[MiddleInitial] CHAR(1) NULL,
[LastSurname] nvarchar(75) NOT NULL,
[FullName] NVARCHAR(50) NOT NULL,
[GenerationCodeSuffix] NVARCHAR(10) NULL,
[MaidenName] NVARCHAR(75) NULL,
[BirthDate] DATE NULL,
[StaffAge] INT NULL,
SexType_Code NVARCHAR(15) NOT NULL,
SexType_Description NVARCHAR(100) NOT NULL,
SexType_Male_Indicator BIT NOT NULL,
SexType_Female_Indicator BIT NOT NULL,
SexType_NotSelected_Indicator BIT NOT NULL,
[HighestLevelOfEducationDescriptorDescriptor_CodeValue] NVARCHAR(100) NULL,
[HighestLevelOfEducationDescriptorDescriptor_Description] NVARCHAR(100) NULL,
[YearsOfPriorProfessionalExperience] [decimal](5, 2) NULL,
[YearsOfPriorTeachingExperience] [decimal](5, 2) NULL,
[HighlyQualifiedTeacher_Indicator] BIT NULL,
[StaffClassificationDescriptor_CodeValue] NVARCHAR(100) NULL,
[StaffClassificationDescriptor_CodeDescription] NVARCHAR(100) NULL,
ValidFrom DATETIME NOT NULL,
ValidTo DATETIME NOT NULL,
IsCurrent BIT NOT NULL,
IsLatest BIT NOT NULL,
LineageKey INT NOT NULL,
CONSTRAINT PK_DimStaff PRIMARY KEY (StaffKey)
);
CREATE NONCLUSTERED INDEX DimStaff_CoveringIndex ON dbo.DimStaff( [_sourceKey], ValidFrom, ValidTo) INCLUDE (StaffKey);
END
--Staff - staging
if NOT EXISTS (select 1
FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_NAME = 'Staff'
AND TABLE_SCHEMA = 'Staging')
CREATE TABLE Staging.Staff
(
StaffKey INT NOT NULL IDENTITY(1,1),
[_sourceKey] NVARCHAR(50) NOT NULL, --'EdFi|StaffUSI'
PrimaryElectronicMailAddress NVARCHAR(128) NULL,
PrimaryElectronicMailTypeDescriptor_CodeValue NVARCHAR(128) NULL, -- Home/Personal, Organization, Other, Work
PrimaryElectronicMailTypeDescriptor_Description NVARCHAR(128) NULL,
EducationOrganizationId INT NOT NULL,
ShortNameOfInstitution nvarchar(500) NOT NULL,
NameOfInstitution nvarchar(500) NOT NULL,
[StaffUniqueId] NVARCHAR(32) NOT NULL,
[PersonalTitlePrefix] NVARCHAR(30) NULL,
[FirstName] NVARCHAR(75) NOT NULL,
[MiddleName] NVARCHAR(75) NULL,
[MiddleInitial] CHAR(1) NULL,
[LastSurname] nvarchar(75) NOT NULL,
[FullName] NVARCHAR(50) NOT NULL,
[GenerationCodeSuffix] NVARCHAR(10) NULL,
[MaidenName] NVARCHAR(75) NULL,
[BirthDate] DATE NULL,
[StaffAge] INT NULL,
SexType_Code NVARCHAR(15) NOT NULL,
SexType_Description NVARCHAR(100) NOT NULL,
SexType_Male_Indicator BIT NOT NULL,
SexType_Female_Indicator BIT NOT NULL,
SexType_NotSelected_Indicator BIT NOT NULL,
[HighestLevelOfEducationDescriptorDescriptor_CodeValue] NVARCHAR(100) NULL,
[HighestLevelOfEducationDescriptorDescriptor_Description] NVARCHAR(100) NULL,
[YearsOfPriorProfessionalExperience] [decimal](5, 2) NULL,
[YearsOfPriorTeachingExperience] [decimal](5, 2) NULL,
[HighlyQualifiedTeacher_Indicator] BIT NULL,
[StaffClassificationDescriptor_CodeValue] NVARCHAR(100) NULL,
[StaffClassificationDescriptor_CodeDescription] NVARCHAR(100) NULL,
StaffMainInfoModifiedDate DATETIME NOT NULL,
StaffEdOrgAssignmentModifiedDate DATETIME NOT NULL,
StaffEdOrgEmploymentModifiedDate DATETIME NOT NULL,
ValidFrom DATETIME NOT NULL,
ValidTo DATETIME NOT NULL,
IsCurrent BIT NOT NULL,
CONSTRAINT PK_DimStaff PRIMARY KEY (StaffKey)
);
GO
--Student - prod
if NOT EXISTS (select 1
FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_NAME = 'DimStudent'
AND TABLE_SCHEMA = 'dbo')
BEGIN
CREATE TABLE dbo.DimStudent
(
[StudentKey] INT IDENTITY(1,1) NOT NULL,
[_sourceKey] NVARCHAR(50) NOT NULL,
[StudentUniqueId] NVARCHAR(32) NULL,
[StateId] NVARCHAR(32) NULL,
PrimaryElectronicMailAddress NVARCHAR(128) NULL,
PrimaryElectronicMailTypeDescriptor_CodeValue NVARCHAR(128) NULL, -- Home/Personal, Organization, Other, Work
PrimaryElectronicMailTypeDescriptor_Description NVARCHAR(128) NULL,
[SchoolKey] INT NOT NULL,
[ShortNameOfInstitution] NVARCHAR(500) NOT NULL,
[NameOfInstitution] NVARCHAR(500) NOT NULL,
[GradeLevelDescriptor_CodeValue] NVARCHAR(100) NOT NULL,
[GradeLevelDescriptor_Description] NVARCHAR(500) NOT NULL,
[FirstName] NVARCHAR(100) NOT NULL,
[MiddleInitial] [char](1) NULL,
[MiddleName] NVARCHAR(100) NULL,
[LastSurname] NVARCHAR(100) NOT NULL,
[FullName] NVARCHAR(500) NOT NULL,
[BirthDate] [date] NOT NULL,
[StudentAge] INT NOT NULL,
[GraduationSchoolYear] INT NULL,
[Homeroom] NVARCHAR(500) NULL,
[HomeroomTeacher] NVARCHAR(500) NULL,
[SexType_Code] NVARCHAR(100) NOT NULL,
[SexType_Description] NVARCHAR(100) NOT NULL,
[SexType_Male_Indicator] BIT NOT NULL,
[SexType_Female_Indicator] BIT NOT NULL,
[SexType_NonBinary_Indicator] BIT NOT NULL,
[SexType_NotSelected_Indicator] BIT NOT NULL,
[RaceCode] NVARCHAR(1000) NOT NULL,
[RaceDescription] NVARCHAR(1000) NOT NULL,
[StateRaceCode] NVARCHAR(1000) NOT NULL,
[Race_AmericanIndianAlaskanNative_Indicator] BIT NOT NULL,
[Race_Asian_Indicator] BIT NOT NULL,
[Race_BlackAfricaAmerican_Indicator] BIT NOT NULL,
[Race_NativeHawaiianPacificIslander_Indicator] BIT NOT NULL,
[Race_White_Indicator] BIT NOT NULL,
[Race_MultiRace_Indicator] BIT NOT NULL,
[Race_ChooseNotRespond_Indicator] BIT NOT NULL,
[Race_Other_Indicator] BIT NOT NULL,
[EthnicityCode] NVARCHAR(100) NOT NULL,
[EthnicityDescription] NVARCHAR(100) NOT NULL,
[EthnicityHispanicLatino_Indicator] BIT NOT NULL,
[Migrant_Indicator] BIT NOT NULL,
[Homeless_Indicator] BIT NOT NULL,
[IEP_Indicator] BIT NOT NULL,
[English_Learner_Code_Value] NVARCHAR(100) NOT NULL,
[English_Learner_Description] NVARCHAR(100) NOT NULL,
[English_Learner_Indicator] BIT NOT NULL,
[Former_English_Learner_Indicator] BIT NOT NULL,
[Never_English_Learner_Indicator] BIT NOT NULL,
[EconomicDisadvantage_Indicator] BIT NOT NULL,
[EntryDate] DATETIME2(7) NOT NULL,
[EntrySchoolYear] INT NOT NULL,
[EntryCode] NVARCHAR(25) NOT NULL,
[ExitWithdrawDate] DATETIME2(7) NULL,
[ExitWithdrawSchoolYear] INT NULL,
[ExitWithdrawCode] NVARCHAR(100) NULL,
[ValidFrom] DATETIME NOT NULL,
[ValidTo] DATETIME NOT NULL,
[IsCurrent] BIT NOT NULL,
[IsLatest] BIT NOT NULL,
LineageKey INT NOT NULL,
CONSTRAINT PK_DimStudent PRIMARY KEY (StudentKey)
);
CREATE NONCLUSTERED INDEX DimStudent_CoveringIndex ON dbo.DimStudent( [_sourceKey], ValidFrom, ValidTo) INCLUDE (StudentKey);
CREATE NONCLUSTERED INDEX IX_DimStudent_IsCurrent
ON [dbo].[DimStudent] ([IsCurrent])
END;
--student - staging
if NOT EXISTS (select 1
FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_NAME = 'Student'
AND TABLE_SCHEMA = 'Staging')
CREATE TABLE Staging.Student
(
[StudentKey] INT IDENTITY(1,1) NOT NULL,
[_sourceKey] NVARCHAR(50) NOT NULL,
[StudentUniqueId] NVARCHAR(32) NULL,
[StateId] NVARCHAR(32) NULL,
PrimaryElectronicMailAddress NVARCHAR(128) NULL,
PrimaryElectronicMailTypeDescriptor_CodeValue NVARCHAR(128) NULL, -- Home/Personal, Organization, Other, Work
PrimaryElectronicMailTypeDescriptor_Description NVARCHAR(128) NULL,
[SchoolKey] INT NULL,
[ShortNameOfInstitution] NVARCHAR(500) NULL,
[NameOfInstitution] NVARCHAR(500) NULL,
[GradeLevelDescriptor_CodeValue] NVARCHAR(100) NOT NULL,
[GradeLevelDescriptor_Description] NVARCHAR(500) NOT NULL,
[FirstName] NVARCHAR(100) NOT NULL,
[MiddleInitial] [char](1) NULL,
[MiddleName] NVARCHAR(100) NULL,
[LastSurname] NVARCHAR(100) NOT NULL,
[FullName] NVARCHAR(500) NOT NULL,
[BirthDate] [date] NOT NULL,
[StudentAge] INT NOT NULL,
[GraduationSchoolYear] INT NULL,
[Homeroom] NVARCHAR(500) NULL,
[HomeroomTeacher] NVARCHAR(500) NULL,
[SexType_Code] NVARCHAR(100) NOT NULL,
[SexType_Description] NVARCHAR(100) NOT NULL,
[SexType_Male_Indicator] BIT NOT NULL,
[SexType_Female_Indicator] BIT NOT NULL,
[SexType_NonBinary_Indicator] BIT NOT NULL,
[SexType_NotSelected_Indicator] BIT NOT NULL,
[RaceCode] NVARCHAR(1000) NOT NULL,
[RaceDescription] NVARCHAR(1000) NOT NULL,
[StateRaceCode] NVARCHAR(1000) NOT NULL,
[Race_AmericanIndianAlaskanNative_Indicator] BIT NOT NULL,
[Race_Asian_Indicator] BIT NOT NULL,
[Race_BlackAfricaAmerican_Indicator] BIT NOT NULL,
[Race_NativeHawaiianPacificIslander_Indicator] BIT NOT NULL,
[Race_White_Indicator] BIT NOT NULL,
[Race_MultiRace_Indicator] BIT NOT NULL,
[Race_ChooseNotRespond_Indicator] BIT NOT NULL,
[Race_Other_Indicator] BIT NOT NULL,
[EthnicityCode] NVARCHAR(100) NOT NULL,
[EthnicityDescription] NVARCHAR(100) NOT NULL,
[EthnicityHispanicLatino_Indicator] BIT NOT NULL,
[Migrant_Indicator] BIT NOT NULL,
[Homeless_Indicator] BIT NOT NULL,
[IEP_Indicator] BIT NOT NULL,
[English_Learner_Code_Value] NVARCHAR(100) NOT NULL,
[English_Learner_Description] NVARCHAR(100) NOT NULL,
[English_Learner_Indicator] BIT NOT NULL,
[Former_English_Learner_Indicator] BIT NOT NULL,
[Never_English_Learner_Indicator] BIT NOT NULL,
[EconomicDisadvantage_Indicator] BIT NOT NULL,
[EntryDate] DATETIME2(7) NOT NULL,
[EntrySchoolYear] INT NOT NULL,
[EntryCode] NVARCHAR(25) NOT NULL,
[ExitWithdrawDate] DATETIME2(7) NULL,
[ExitWithdrawSchoolYear] INT NULL,
[ExitWithdrawCode] NVARCHAR(100) NULL,
StudentMainInfoModifiedDate DATETIME NOT NULL,
StudentSchoolAssociationModifiedDate DATETIME NOT NULL,
_sourceSchoolKey NVARCHAR(50) NULL,
[ValidFrom] DATETIME NOT NULL,
[ValidTo] DATETIME NOT NULL,
[IsCurrent] BIT NOT NULL
CONSTRAINT PK_StagingStudent PRIMARY KEY (StudentKey)
);
GO
--attendance event category - prod
if NOT EXISTS (select 1
FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_NAME = 'DimAttendanceEventCategory'
AND TABLE_SCHEMA = 'dbo')
BEGIN
CREATE TABLE dbo.DimAttendanceEventCategory
(
AttendanceEventCategoryKey INT NOT NULL IDENTITY(1,1),
[_sourceKey] NVARCHAR(50) NOT NULL,
AttendanceEventCategoryDescriptor_CodeValue NVARCHAR(50) NOT NULL,
AttendanceEventCategoryDescriptor_Description NVARCHAR(1024) NOT NULL,
[InAttendance_Indicator] BIT NOT NULL,
[UnexcusedAbsence_Indicator] BIT NOT NULL,
[ExcusedAbsence_Indicator] BIT NOT NULL,
[Tardy_Indicator] BIT NOT NULL,
[EarlyDeparture_Indicator] BIT NOT NULL,
ValidFrom DATETIME NOT NULL,
ValidTo DATETIME NOT NULL,
IsCurrent BIT NOT NULL,
IsLatest BIT NOT NULL,
LineageKey INT NOT NULL,
CONSTRAINT PK_DimAttendanceEventCategory PRIMARY KEY (AttendanceEventCategoryKey ASC)
);
CREATE NONCLUSTERED INDEX DimAttendanceEventCategory_CoveringIndex
ON dbo.DimAttendanceEventCategory(_sourceKey, ValidFrom)
INCLUDE ( ValidTo, AttendanceEventCategoryKey);
END;
--attendance event category - staging
if NOT EXISTS (select 1
FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_NAME = 'AttendanceEventCategory'
AND TABLE_SCHEMA = 'Staging')
CREATE TABLE Staging.AttendanceEventCategory
(
AttendanceEventCategoryKey INT NOT NULL IDENTITY(1,1),
[_sourceKey] NVARCHAR(50) NOT NULL,
AttendanceEventCategoryDescriptor_CodeValue nvarchar(50) NOT NULL,
AttendanceEventCategoryDescriptor_Description nvarchar(1024) NOT NULL,
[InAttendance_Indicator] BIT NOT NULL,
[UnexcusedAbsence_Indicator] BIT NOT NULL,
[ExcusedAbsence_Indicator] BIT NOT NULL,
[Tardy_Indicator] BIT NOT NULL,
[EarlyDeparture_Indicator] BIT NOT NULL,
CategoryModifiedDate DATETIME NOT NULL,
ValidFrom DATETIME NOT NULL,
ValidTo DATETIME NOT NULL,
IsCurrent BIT NOT NULL,
CONSTRAINT PK_StagingAttendanceEventCategory PRIMARY KEY (AttendanceEventCategoryKey ASC)
);
GO
--discipline incident - prod
if NOT EXISTS (select 1
FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_NAME = 'DimDisciplineIncident'
AND TABLE_SCHEMA = 'dbo')
BEGIN
CREATE TABLE dbo.DimDisciplineIncident
(
DisciplineIncidentKey INT NOT NULL IDENTITY(1,1),
[_sourceKey] NVARCHAR(50) NOT NULL,
SchoolKey INT NOT NULL,
ShortNameOfInstitution nvarchar(500) NOT NULL,
NameOfInstitution nvarchar(500) NOT NULL,
SchoolYear INT NOT NULL,
IncidentDate DATE NOT NULL,
IncidentTime TIME(7) NOT NULL,
[IncidentDescription] nvarchar(MAX) NULL ,
[BehaviorDescriptor_CodeValue] nvarchar(50) not null, -- IncidentType: Weapons Possession (Firearms and Other Weapons), Drugs, Abuse Of Volatile Chemical,School Code of Conduct, etc
[BehaviorDescriptor_Description] nvarchar(1024) not null,
[LocationDescriptor_CodeValue] nvarchar(50) not null, -- Hallway, Cafeteria, Classroom, etc
[LocationDescriptor_Description] nvarchar(1024) not null,
[DisciplineDescriptor_CodeValue] nvarchar(50) not null, -- Actions: Community Service, Expulsion,In School Suspension,Out of School Suspension, Removal from Classroom, etc
[DisciplineDescriptor_Description] nvarchar(1024) not null,
DisciplineDescriptor_ISS_Indicator BIT NOT NULL,
DisciplineDescriptor_OSS_Indicator BIT NOT NULL,
ReporterDescriptor_CodeValue nvarchar(50) NOT NULL, -- Law enforcement officer,Non-school personnel,Other,Parent/guardian,Staff,Student
ReporterDescriptor_Description nvarchar(1024) NOT NULL,
IncidentReporterName NVARCHAR(100) NOT NULL ,
ReportedToLawEnforcement_Indicator BIT NOT NULL ,
IncidentCost Money NOT NULL,
ValidFrom DATETIME NOT NULL,
ValidTo DATETIME NOT NULL,
IsCurrent BIT NOT NULL,
IsLatest BIT NOT NULL,
LineageKey INT NOT NULL,
CONSTRAINT PK_DimDisciplineIncident PRIMARY KEY (DisciplineIncidentKey ASC)
);
CREATE NONCLUSTERED INDEX DimDisciplineIncident_CoveringIndex ON dbo.DimDisciplineIncident( [_sourceKey], ValidFrom, ValidTo) INCLUDE (DisciplineIncidentKey);
END;
--discipline incident - staging
if NOT EXISTS (select 1
FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_NAME = 'DisciplineIncident'
AND TABLE_SCHEMA = 'Staging')
CREATE TABLE Staging.DisciplineIncident
(
DisciplineIncidentKey INT NOT NULL IDENTITY(1,1),
[_sourceKey] NVARCHAR(50) NOT NULL,
SchoolKey INT NULL,
ShortNameOfInstitution nvarchar(500) NULL,
NameOfInstitution nvarchar(500) NULL,
SchoolYear INT NOT NULL,
IncidentDate DATE NOT NULL,
IncidentTime TIME(7) NOT NULL,
[IncidentDescription] nvarchar(MAX) NULL ,
[BehaviorDescriptor_CodeValue] nvarchar(50) not null, -- IncidentType: Weapons Possession (Firearms and Other Weapons), Drugs, Abuse Of Volatile Chemical,School Code of Conduct, etc
[BehaviorDescriptor_Description] nvarchar(1024) not null,
[LocationDescriptor_CodeValue] nvarchar(50) not null, -- Hallway, Cafeteria, Classroom, etc
[LocationDescriptor_Description] nvarchar(1024) not null,
[DisciplineDescriptor_CodeValue] nvarchar(50) not null, -- Actions: Community Service, Expulsion,In School Suspension,Out of School Suspension, Removal from Classroom, etc
[DisciplineDescriptor_Description] nvarchar(1024) not null,
DisciplineDescriptor_ISS_Indicator BIT NOT NULL,
DisciplineDescriptor_OSS_Indicator BIT NOT NULL,
ReporterDescriptor_CodeValue nvarchar(50) NOT NULL, -- Law enforcement officer,Non-school personnel,Other,Parent/guardian,Staff,Student
ReporterDescriptor_Description nvarchar(1024) NOT NULL,
IncidentReporterName NVARCHAR(100) NOT NULL ,
ReportedToLawEnforcement_Indicator BIT NOT NULL ,
IncidentCost Money NOT NULL,
IncidentModifiedDate DATETIME NOT NULL,
_sourceSchoolKey NVARCHAR(50) NULL,
ValidFrom DATETIME NOT NULL,
ValidTo DATETIME NOT NULL,
IsCurrent BIT NOT NULL,
CONSTRAINT PK_StagingDisciplineIncident PRIMARY KEY (DisciplineIncidentKey ASC)
);
GO
--assessment - prod
if NOT EXISTS (select 1
FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_NAME = 'DimAssessment'
AND TABLE_SCHEMA = 'dbo')
BEGIN
CREATE TABLE dbo.DimAssessment
(
AssessmentKey INT NOT NULL IDENTITY(1,1),
[_sourceKey] NVARCHAR(500) NOT NULL, -- EdFi|AssessmentIdentifier|ObjectiveAssessment_IdentificationCode|AssessmentReportingMethodDescriptor_CodeValue
--assessment
--------------------------------------------------------------------------------------
AssessmentCategoryDescriptor_CodeValue NVARCHAR(50) NOT NULL,
AssessmentCategoryDescriptor_Description NVARCHAR(1024) NOT NULL,
AssessmentFamilyTitle NVARCHAR(100) NULL,
AdaptiveAssessment_Indicator bit NOT NULL,
AssessmentIdentifier NVARCHAR(60) NOT NULL,
AssessmentTitle NVARCHAR(500) NOT NULL,
ReportingMethodDescriptor_CodeValue NVARCHAR(50) NOT NULL,
ReportingMethodDescriptor_Description NVARCHAR(1024) NOT NULL,
ResultDatatypeTypeDescriptor_CodeValue NVARCHAR(50) NOT NULL,
ResultDatatypeTypeDescriptor_Description NVARCHAR(1024) NOT NULL,
AssessmentScore_Indicator BIT NOT NULL,
AssessmentPerformanceLevel_Indicator BIT NOT NULL,
ObjectiveAssessmentScore_Indicator BIT NOT NULL,
ObjectiveAssessmentPerformanceLevel_Indicator BIT NOT NULL,
ValidFrom DATETIME NOT NULL,
ValidTo DATETIME NOT NULL,
IsCurrent BIT NOT NULL,
IsLatest BIT NOT NULL,
LineageKey INT NOT NULL,
CONSTRAINT PK_DimAssessment PRIMARY KEY (AssessmentKey)
);
CREATE NONCLUSTERED INDEX DimAssessment_CoveringIndex ON dbo.DimAssessment( [_sourceKey], ValidFrom, ValidTo) INCLUDE (AssessmentKey);
END;
--assessment - staging
if NOT EXISTS (select 1
FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_NAME = 'Assessment'
AND TABLE_SCHEMA = 'Staging')
BEGIN
CREATE TABLE Staging.Assessment
(
AssessmentKey INT NOT NULL IDENTITY(1,1),
[_sourceKey] NVARCHAR(2000) NOT NULL, -- EdFi|AssessmentIdentifier|ObjectiveAssessment_IdentificationCode|AssessmentReportingMethodDescriptor_CodeValue
--assessment
--------------------------------------------------------------------------------------
AssessmentCategoryDescriptor_CodeValue NVARCHAR(50) NOT NULL,
AssessmentCategoryDescriptor_Description NVARCHAR(1024) NOT NULL,
AssessmentFamilyTitle NVARCHAR(100) NULL,
AdaptiveAssessment_Indicator bit NOT NULL,
AssessmentIdentifier NVARCHAR(60) NOT NULL,
AssessmentTitle NVARCHAR(500) NOT NULL,
ReportingMethodDescriptor_CodeValue NVARCHAR(50) NOT NULL,
ReportingMethodDescriptor_Description NVARCHAR(1024) NOT NULL,
ResultDatatypeTypeDescriptor_CodeValue NVARCHAR(50) NOT NULL,
ResultDatatypeTypeDescriptor_Description NVARCHAR(1024) NOT NULL,
AssessmentScore_Indicator BIT NOT NULL,
AssessmentPerformanceLevel_Indicator BIT NOT NULL,
ObjectiveAssessmentScore_Indicator BIT NOT NULL,
ObjectiveAssessmentPerformanceLevel_Indicator BIT NOT NULL,
AssessmentModifiedDate DATETIME NOT NULL,
ValidFrom DATETIME NOT NULL,
ValidTo DATETIME NOT NULL,
IsCurrent BIT NOT NULL
CONSTRAINT PK_StaginAssessment PRIMARY KEY (AssessmentKey)
);
END;
GO
--course - prod
if NOT EXISTS (select 1
FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_NAME = 'DimCourse'
AND TABLE_SCHEMA = 'dbo')
BEGIN
CREATE TABLE dbo.DimCourse
(
CourseKey INT NOT NULL IDENTITY(1,1), --surrogate
[_sourceKey] NVARCHAR(50) NOT NULL,
LocalCourseCode NVARCHAR(60) NULL,
CourseCode NVARCHAR(60) NOT NULL,
CourseTitle NVARCHAR(100) NOT NULL,
CourseDescription NVARCHAR(100) NOT NULL,
CourseLevelCharacteristicTypeDescriptor_CodeValue NVARCHAR(60) NOT NULL,
CourseLevelCharacteristicTypeDescriptor_Description NVARCHAR(1024) NOT NULL,
AcademicSubjectDescriptor_CodeValue NVARCHAR(60) NOT NULL,
AcademicSubjectDescriptor_Description NVARCHAR(1024) NOT NULL,
HighSchoolCourseRequirement_Indicator BIT NOT NULL,
MinimumAvailableCredits INT NULL,
MaximumAvailableCredits INT NULL,
GPAApplicabilityType_CodeValue NVARCHAR(50) NULL,
GPAApplicabilityType_Description NVARCHAR(50) NULL,
SecondaryCourseLevelCharacteristicTypeDescriptor_CodeValue NVARCHAR(50) NOT NULL,
SecondaryCourseLevelCharacteristicTypeDescriptor_Description NVARCHAR(50) NOT NULL,
ValidFrom DATETIME NOT NULL,
ValidTo DATETIME NOT NULL,
IsCurrent BIT NOT NULL,
IsLatest INT NOT NULL,
LineageKey INT NOT NULL,
CONSTRAINT PK_DimCourse PRIMARY KEY (CourseKey)
);
CREATE NONCLUSTERED INDEX DimCourse_CoveringIndex ON dbo.DimCourse( [_sourceKey], ValidFrom, ValidTo) INCLUDE (CourseKey);