-
Notifications
You must be signed in to change notification settings - Fork 0
/
DW_Data_QA_Indexing_2.5.sql
1613 lines (1571 loc) · 74.9 KB
/
DW_Data_QA_Indexing_2.5.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
/*
---------------------------------------------------------------------------------------------------------------------
--******************************* INDEXING **************************************************************************
---------------------------------------------------------------------------------------------------------------------
--slowly changing dimensions - four-part non-clustered index - covering index
CREATE NONCLUSTERED INDEX DimSchool_CoveringIndex
ON EdFiDW.dbo.DimSchool (_sourceKey, ValidFrom)
INCLUDE ( ValidTo, SchoolKey);
CREATE NONCLUSTERED INDEX DimStudent_CoveringIndex
ON EdFiDW.dbo.DimStudent (_sourceKey, ValidFrom)
INCLUDE ( ValidTo, StudentKey);
CREATE NONCLUSTERED INDEX DimAttendanceEventCategory_CoveringIndex
ON EdFiDW.dbo.DimAttendanceEventCategory(_sourceKey, ValidFrom)
INCLUDE ( ValidTo, AttendanceEventCategoryKey);
CREATE NONCLUSTERED INDEX DimAssessment_CoveringIndex
ON EdFiDW.dbo.DimAssessment(_sourceKey, ValidFrom)
INCLUDE ( ValidTo, AssessmentKey);
CREATE NONCLUSTERED INDEX DimCourse_CoveringIndex
ON EdFiDW.dbo.DimCourse(_sourceKey, ValidFrom)
INCLUDE ( ValidTo, CourseKey);
--DROP INDEX CSI_FactStudentAttendanceByDay
-- ON EdFiDW.dbo.FactStudentAttendanceByDay
--Facts Tables - Using ColumnStore Indexes
CREATE COLUMNSTORE INDEX CSI_FactStudentAttendanceByDay
ON EdFiDW.dbo.FactStudentAttendanceByDay
([StudentKey]
,[TimeKey]
,[SchoolKey]
,[AttendanceEventCategoryKey]
,[AttendanceEventReason]
,[LineageKey])
CREATE COLUMNSTORE INDEX CSI_FactStudentDiscipline
ON EdFiDW.dbo.FactStudentDiscipline
([StudentKey]
,[TimeKey]
,[SchoolKey]
,[DisciplineIncidentKey]
,[LineageKey])
CREATE COLUMNSTORE INDEX CSI_FactStudentAssessmentScore
ON EdFiDW.dbo.FactStudentAssessmentScore
([StudentKey]
,[TimeKey]
,[AssessmentKey]
,[ScoreResult]
,[IntegerScoreResult]
,[DecimalScoreResult]
,[LiteralScoreResult]
,[LineageKey])
CREATE COLUMNSTORE INDEX CSI_FactStudentCourseTranscript
ON EdFiDW.dbo.FactStudentCourseTranscript
([StudentKey]
,[TimeKey]
,[CourseKey]
,[SchoolKey]
,[EarnedCredits]
,[PossibleCredits]
,[FinalLetterGradeEarned]
,[FinalNumericGradeEarned]
,[LineageKey])
CREATE COLUMNSTORE INDEX CSI_Derived_StudentAttendanceByDay
ON EdFiDW.Derived.StudentAttendanceByDay
([StudentKey]
,[TimeKey]
,[SchoolKey]
,[EarlyDeparture]
,[ExcusedAbsence]
,[UnexcusedAbsence]
,[NoContact]
,[InAttendance]
,[Tardy])
CREATE COLUMNSTORE INDEX CSI_Derived_StudentAssessmentScore
ON EdFiDW.Derived.StudentAssessmentScore
([StudentKey]
,[TimeKey]
,[AssessmentKey]
,[AchievementProficiencyLevel]
,[CompositeRating]
,[CompositeScore]
,[PercentileRank]
,[ProficiencyLevel]
,[PromotionScore]
,[RawScore]
,[ScaleScore])
*/
---------------------------------------------------------------------------------------------------------------------
--******************************* Starting Data Q/A *****************************************************************
---------------------------------------------------------------------------------------------------------------------
SELECT 'Starting data quality process (Dimension - Overall Counts).............'
UNION ALL
--DimSchool
------------------------------------------------------------------------------------------
SELECT ' Entity being analyzed: DimSchool'
UNION ALL
----Total
SELECT CONCAT(' Analyzing: Total. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT _sourceKey)
FROM EdFiDW.[dbo].[DimSchool]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0),
' ',
'Records in source system:',
(SELECT COUNT(DISTINCT eo.EducationOrganizationId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.EducationOrganization eo
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.School s
WHERE s.SchoolId = eo.EducationOrganizationId))
)
UNION ALL
----Total Active
SELECT CONCAT(' Analyzing: Total Active. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT SchoolKey)
FROM EdFiDW.[dbo].[DimSchool]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND IsCurrent = 1),
' ',
'Records in source system:',
(SELECT COUNT(DISTINCT eo.EducationOrganizationId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.EducationOrganization eo
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.School s
WHERE s.SchoolId = eo.EducationOrganizationId)
AND EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.OperationalStatusType ost
WHERE eo.OperationalStatusTypeId = ost.OperationalStatusTypeId
AND COALESCE(ost.CodeValue,'N/A') IN ('Active','Added','Changed Agency','Continuing','New','Reopened')))
)
UNION ALL
----Total Elementary
SELECT CONCAT(' Analyzing: Total Elementary. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT SchoolKey)
FROM EdFiDW.[dbo].[DimSchool]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND SchoolCategoryType = 'Elementary School'),
' ',
'Records in source system:',
(SELECT COUNT(DISTINCT eo.EducationOrganizationId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.EducationOrganization eo
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.School s
WHERE s.SchoolId = eo.EducationOrganizationId)
AND EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.SchoolCategory sc
INNER JOIN [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.SchoolCategoryType sct on sc.SchoolCategoryTypeId = sct.SchoolCategoryTypeId
WHERE eo.EducationOrganizationId = sc.SchoolId
AND sct.CodeValue IN ('Elementary School') ))
)
UNION ALL
----Total Middle
SELECT CONCAT(' Analyzing: Total Middle. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT SchoolKey)
FROM EdFiDW.[dbo].[DimSchool]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND SchoolCategoryType = 'Middle School'),
' ',
'Records in source system:',
(SELECT COUNT(DISTINCT eo.EducationOrganizationId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.EducationOrganization eo
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.School s
WHERE s.SchoolId = eo.EducationOrganizationId)
AND EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.SchoolCategory sc
INNER JOIN [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.SchoolCategoryType sct on sc.SchoolCategoryTypeId = sct.SchoolCategoryTypeId
WHERE eo.EducationOrganizationId = sc.SchoolId
AND sct.CodeValue IN ('Middle School') ))
)
UNION ALL
----Total High
SELECT CONCAT(' Analyzing: Total High. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT SchoolKey)
FROM EdFiDW.[dbo].[DimSchool]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND SchoolCategoryType = 'High School'),
' ',
'Records in source system:',
(SELECT COUNT(DISTINCT eo.EducationOrganizationId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.EducationOrganization eo
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.School s
WHERE s.SchoolId = eo.EducationOrganizationId)
AND EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.SchoolCategory sc
INNER JOIN [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.SchoolCategoryType sct on sc.SchoolCategoryTypeId = sct.SchoolCategoryTypeId
WHERE eo.EducationOrganizationId = sc.SchoolId
AND sct.CodeValue IN ('High School') ))
)
UNION ALL
----Total Combined
SELECT CONCAT(' Analyzing: Total Combined. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT SchoolKey)
FROM EdFiDW.[dbo].[DimSchool]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND SchoolCategoryType NOT IN ('Elementary School','Middle School','High School') ),
' ',
'Records in source system:',
(SELECT COUNT(DISTINCT eo.EducationOrganizationId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.EducationOrganization eo
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.School s
WHERE s.SchoolId = eo.EducationOrganizationId)
AND EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.SchoolCategory sc
INNER JOIN [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.SchoolCategoryType sct on sc.SchoolCategoryTypeId = sct.SchoolCategoryTypeId
WHERE eo.EducationOrganizationId = sc.SchoolId
AND sct.CodeValue NOT IN ('Elementary School','Middle School','High School') ))
)
UNION ALL
----Total Title 1
SELECT CONCAT(' Analyzing: Total Title I. => Source: Ed-Fi ODS => ',
'Records in entity:',
(
SELECT COUNT(DISTINCT SchoolKey)
FROM EdFiDW.[dbo].[DimSchool]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND TitleIPartASchoolDesignationTypeCodeValue NOT IN ('Not designated as a Title I Part A school','N/A')
),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT s.SchoolId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.School s
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.TitleIPartASchoolDesignationType t1
WHERE s.TitleIPartASchoolDesignationTypeId = t1.TitleIPartASchoolDesignationTypeId
AND t1.CodeValue NOT IN ('Not designated as a Title I Part A school','N/A') )
)
)
--DimStudent
------------------------------------------------------------------------------------------
UNION ALL
SELECT ' --------------------------------------------------------------------------------------------------------------------------------------'
UNION ALL
SELECT ' Entity being analyzed: DimStudent'
UNION ALL
----Total
SELECT CONCAT(' Analyzing: Total. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT StudentUniqueId)
FROM EdFiDW.[dbo].[DimStudent]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0),
' ',
'Records in source system:',
(SELECT COUNT(DISTINCT s.StudentUniqueId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Student s
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentSchoolAssociation ssa
WHERE s.StudentUSI = ssa.StudentUSI
AND ssa.SchoolYear IN (2019,2020)))
)
UNION ALL
----Total Active
SELECT CONCAT(' Analyzing: Total Active. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT StudentUniqueId)
FROM EdFiDW.[dbo].[DimStudent]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND IsCurrent = 1),
' ',
'Records in source system:',
(SELECT COUNT(DISTINCT s.StudentUniqueId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Student s
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentSchoolAssociation ssa
WHERE s.StudentUSI = ssa.StudentUSI
AND ssa.SchoolYear IN (2019,2020)
AND ssa.ExitWithdrawDate IS NULL))
)
UNION ALL
----Total Race AmericanIndianAlaskanNative
SELECT CONCAT(' Analyzing: Total Race AmericanIndianAlaskanNative. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT StudentUniqueId)
FROM EdFiDW.[dbo].[DimStudent]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND Race_AmericanIndianAlaskanNative_Indicator = 1),
' ',
'Records in source system:',
(SELECT COUNT(DISTINCT s.StudentUniqueId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Student s
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentSchoolAssociation ssa
WHERE s.StudentUSI = ssa.StudentUSI
AND ssa.SchoolYear IN (2019,2020))
AND EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentRace sr
WHERE s.StudentUSI = sr.StudentUSI
AND sr.RaceTypeId = 1))
)
UNION ALL
----Total Race Asian
SELECT CONCAT(' Analyzing: Total Race Asian. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT StudentUniqueId)
FROM EdFiDW.[dbo].[DimStudent]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND Race_Asian_Indicator = 1),
' ',
'Records in source system:',
(SELECT COUNT(DISTINCT s.StudentUniqueId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Student s
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentSchoolAssociation ssa
WHERE s.StudentUSI = ssa.StudentUSI
AND ssa.SchoolYear IN (2019,2020))
AND EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentRace sr
WHERE s.StudentUSI = sr.StudentUSI
AND sr.RaceTypeId = 2))
)
UNION ALL
----Total Race BlackAfricaAmerican
SELECT CONCAT(' Analyzing: Total Race BlackAfricaAmerican. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT StudentUniqueId)
FROM EdFiDW.[dbo].[DimStudent]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND Race_BlackAfricaAmerican_Indicator = 1),
' ',
'Records in source system:',
(SELECT COUNT(DISTINCT s.StudentUniqueId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Student s
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentSchoolAssociation ssa
WHERE s.StudentUSI = ssa.StudentUSI
AND ssa.SchoolYear IN (2019,2020))
AND EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentRace sr
WHERE s.StudentUSI = sr.StudentUSI
AND sr.RaceTypeId = 3))
)
UNION ALL
----Total Race NativeHawaiianPacificIslander
SELECT CONCAT(' Analyzing: Total Race NativeHawaiianPacificIslander. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT StudentUniqueId)
FROM EdFiDW.[dbo].[DimStudent]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND Race_NativeHawaiianPacificIslander_Indicator = 1),
' ',
'Records in source system:',
(SELECT COUNT(DISTINCT s.StudentUniqueId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Student s
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentSchoolAssociation ssa
WHERE s.StudentUSI = ssa.StudentUSI
AND ssa.SchoolYear IN (2019,2020))
AND EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentRace sr
WHERE s.StudentUSI = sr.StudentUSI
AND sr.RaceTypeId = 5))
)
UNION ALL
----Total Race White
SELECT CONCAT(' Analyzing: Total Race White. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT StudentUniqueId)
FROM EdFiDW.[dbo].[DimStudent]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND Race_White_Indicator = 1),
' ',
'Records in source system:',
(SELECT COUNT(DISTINCT s.StudentUniqueId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Student s
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentSchoolAssociation ssa
WHERE s.StudentUSI = ssa.StudentUSI
AND ssa.SchoolYear IN (2019,2020))
AND EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentRace sr
WHERE s.StudentUSI = sr.StudentUSI
AND sr.RaceTypeId = 7))
)
UNION ALL
----Total Race ChooseNotRespond
SELECT CONCAT(' Analyzing: Total Race ChooseNotRespond. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT StudentUniqueId)
FROM EdFiDW.[dbo].[DimStudent]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND Race_ChooseNotRespond_Indicator = 1),
' ',
'Records in source system:',
(SELECT COUNT(DISTINCT s.StudentUniqueId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Student s
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentSchoolAssociation ssa
WHERE s.StudentUSI = ssa.StudentUSI
AND ssa.SchoolYear IN (2019,2020))
AND EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentRace sr
WHERE s.StudentUSI = sr.StudentUSI
AND sr.RaceTypeId =4))
)
UNION ALL
----Total Race Other
SELECT CONCAT(' Analyzing: Total Race Other. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT StudentUniqueId)
FROM EdFiDW.[dbo].[DimStudent]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND Race_Other_Indicator = 1),
' ',
'Records in source system:',
(SELECT COUNT(DISTINCT s.StudentUniqueId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Student s
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentSchoolAssociation ssa
WHERE s.StudentUSI = ssa.StudentUSI
AND ssa.SchoolYear IN (2019,2020))
AND EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentRace sr
WHERE s.StudentUSI = sr.StudentUSI
AND sr.RaceTypeId = 6))
)
UNION ALL
----Total Race Multirace
SELECT CONCAT(' Analyzing: Total Race Multirace. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT StudentUniqueId)
FROM EdFiDW.[dbo].[DimStudent]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND Race_MultiRace_Indicator = 1),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT s.StudentUniqueId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Student s
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentSchoolAssociation ssa
WHERE s.StudentUSI = ssa.StudentUSI
AND ssa.SchoolYear IN (2019,2020))
AND (SELECT COUNT(sr.StudentUSI)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentRace sr
WHERE s.StudentUSI = sr.StudentUSI) > 1
AND s.HispanicLatinoEthnicity = 0
)
)
UNION ALL
----Total Ethnicity Hispanic
SELECT CONCAT(' Analyzing: Total Ethnicity Hispanic. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT StudentUniqueId)
FROM EdFiDW.[dbo].[DimStudent]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND EthnicityHispanicLatino_Indicator = 1),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT s.StudentUniqueId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Student s
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentSchoolAssociation ssa
WHERE s.StudentUSI = ssa.StudentUSI
AND ssa.SchoolYear IN (2019,2020))
AND s.HispanicLatinoEthnicity = 1
)
)
UNION ALL
----Total Migrant
SELECT CONCAT(' Analyzing: Total Migrant. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT StudentUniqueId)
FROM EdFiDW.[dbo].[DimStudent]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND Migrant_Indicator = 1),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT s.StudentUniqueId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Student s
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentSchoolAssociation ssa
WHERE s.StudentUSI = ssa.StudentUSI
AND ssa.SchoolYear IN (2019,2020))
AND EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentProgramAssociation spa
WHERE CHARINDEX('Migrant', spa.ProgramName,1) > 1
AND spa.StudentUSI = s.StudentUSI
AND spa.EndDate IS NULL)
)
)
UNION ALL
----Total Homeless
SELECT CONCAT(' Analyzing: Total Homeless. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT StudentUniqueId)
FROM EdFiDW.[dbo].[DimStudent]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND Homeless_Indicator = 1),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT s.StudentUniqueId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Student s
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentSchoolAssociation ssa
WHERE s.StudentUSI = ssa.StudentUSI
AND ssa.SchoolYear IN (2019,2020))
AND EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentProgramAssociation spa
WHERE CHARINDEX('Homeless', spa.ProgramName,1) > 1
AND spa.StudentUSI = s.StudentUSI
AND spa.EndDate IS NULL)
)
)
UNION ALL
----Total IEP
SELECT CONCAT(' Analyzing: Total IEP. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT StudentUniqueId)
FROM EdFiDW.[dbo].[DimStudent]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND IEP_Indicator = 1),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT s.StudentUniqueId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Student s
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentSchoolAssociation ssa
WHERE s.StudentUSI = ssa.StudentUSI
AND ssa.SchoolYear IN (2019,2020))
AND EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentProgramAssociation spa
WHERE CHARINDEX('IEP', spa.ProgramName,1) > 1
AND spa.StudentUSI = s.StudentUSI
AND spa.EndDate IS NULL)
)
)
UNION ALL
----Total LEP English Learner
SELECT CONCAT(' Analyzing: Total LEP English Learner. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT StudentUniqueId)
FROM EdFiDW.[dbo].[DimStudent]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND English_Learner_Indicator = 1),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT s.StudentUniqueId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Student s
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentSchoolAssociation ssa
WHERE s.StudentUSI = ssa.StudentUSI
AND ssa.SchoolYear IN (2019,2020))
AND EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Descriptor d
WHERE d.DescriptorId = s.LimitedEnglishProficiencyDescriptorId
AND COALESCE(d.CodeValue,'N/A') = 'Limited')
)
)
UNION ALL
----Total LEP Former
SELECT CONCAT(' Analyzing: Total LEP Former. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT StudentUniqueId)
FROM EdFiDW.[dbo].[DimStudent]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND Former_English_Learner_Indicator = 1),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT s.StudentUniqueId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Student s
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentSchoolAssociation ssa
WHERE s.StudentUSI = ssa.StudentUSI
AND ssa.SchoolYear IN (2019,2020))
AND EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Descriptor d
WHERE d.DescriptorId = s.LimitedEnglishProficiencyDescriptorId
AND COALESCE(d.CodeValue,'N/A') = 'Formerly Limited')
)
)
UNION ALL
----Total LEP Not EnglisLearner
SELECT CONCAT(' Analyzing: Total LEP Not EnglisLearner. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT StudentUniqueId)
FROM EdFiDW.[dbo].[DimStudent]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND Never_English_Learner_Indicator = 1),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT s.StudentUniqueId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Student s
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentSchoolAssociation ssa
WHERE s.StudentUSI = ssa.StudentUSI
AND ssa.SchoolYear IN (2019,2020))
AND EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Descriptor d
WHERE d.DescriptorId = s.LimitedEnglishProficiencyDescriptorId
AND COALESCE(d.CodeValue,'N/A') = 'NotLimited')
)
)
UNION ALL
----Total Economically Disadvantaged
SELECT CONCAT(' Analyzing: Total Economically Disadvantaged. => Source: Ed-Fi ODS => ',
'Records in entity:',
(SELECT COUNT(DISTINCT StudentUniqueId)
FROM EdFiDW.[dbo].[DimStudent]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND EconomicDisadvantage_Indicator = 1),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT s.StudentUniqueId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Student s
WHERE EXISTS(SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.StudentSchoolAssociation ssa
WHERE s.StudentUSI = ssa.StudentUSI
AND ssa.SchoolYear IN (2019,2020))
AND s.EconomicDisadvantaged = 1
)
)
--DimAttendanceEventCategory
------------------------------------------------------------------------------------------
UNION ALL
SELECT ' --------------------------------------------------------------------------------------------------------------------------------------'
UNION ALL
SELECT ' Entity being analyzed: DimAttendanceEventCategory'
UNION ALL
----Total
SELECT CONCAT(' Analyzing: Total Attendance Codes. => Source: Ed-Fi ODS => ',
'Records in entity:',
(
SELECT COUNT(DISTINCT _sourceKey)
FROM EdFiDW.[dbo].[DimAttendanceEventCategory]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT d.DescriptorId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Descriptor d
WHERE d.Namespace IN ('http://ed-fi.org/Descriptor/AttendanceEventCategoryDescriptor.xml',
'http://ed-fi.org/Descriptor/Follett/Aspen/AttendanceEventCategoryDescriptor.xml')
)
)
UNION ALL
----Total Active
SELECT CONCAT(' Analyzing: Total Active. => Source: Ed-Fi ODS => ',
'Records in entity:',
(
SELECT COUNT(DISTINCT _sourceKey)
FROM EdFiDW.[dbo].[DimAttendanceEventCategory]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND IsCurrent = 1
),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT d.DescriptorId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Descriptor d
WHERE d.Namespace IN ('http://ed-fi.org/Descriptor/AttendanceEventCategoryDescriptor.xml',
'http://ed-fi.org/Descriptor/Follett/Aspen/AttendanceEventCategoryDescriptor.xml')
)
)
UNION ALL
----Total In-Attendance
SELECT CONCAT(' Analyzing: Total In-Attendance Category. => Source: Ed-Fi ODS => ',
'Records in entity:',
(
SELECT COUNT(DISTINCT _sourceKey)
FROM EdFiDW.[dbo].[DimAttendanceEventCategory]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND InAttendance_Indicator = 1
),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT d.DescriptorId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Descriptor d
WHERE d.Namespace IN ('http://ed-fi.org/Descriptor/AttendanceEventCategoryDescriptor.xml',
'http://ed-fi.org/Descriptor/Follett/Aspen/AttendanceEventCategoryDescriptor.xml')
AND COALESCE(d.CodeValue,'In Attendance') in ('In Attendance','Tardy','Early departure')
)
)
UNION ALL
----Total Unexcused Category
SELECT CONCAT(' Analyzing: Total Unexcused Category. => Source: Ed-Fi ODS => ',
'Records in entity:',
(
SELECT COUNT(DISTINCT _sourceKey)
FROM EdFiDW.[dbo].[DimAttendanceEventCategory]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND UnexcusedAbsence_Indicator = 1
),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT d.DescriptorId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Descriptor d
WHERE d.Namespace IN ('http://ed-fi.org/Descriptor/AttendanceEventCategoryDescriptor.xml',
'http://ed-fi.org/Descriptor/Follett/Aspen/AttendanceEventCategoryDescriptor.xml')
AND COALESCE(d.CodeValue,'In Attendance') in ('Unexcused Absence')
)
)
UNION ALL
----Total Excused Category
SELECT CONCAT(' Analyzing: Total Excused Category. => Source: Ed-Fi ODS => ',
'Records in entity:',
(
SELECT COUNT(DISTINCT _sourceKey)
FROM EdFiDW.[dbo].[DimAttendanceEventCategory]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND ExcusedAbsence_Indicator = 1
),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT d.DescriptorId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Descriptor d
WHERE d.Namespace IN ('http://ed-fi.org/Descriptor/AttendanceEventCategoryDescriptor.xml',
'http://ed-fi.org/Descriptor/Follett/Aspen/AttendanceEventCategoryDescriptor.xml')
AND COALESCE(d.CodeValue,'In Attendance') in ('Excused Absence')
)
)
UNION ALL
----Total Tardy Category
SELECT CONCAT(' Analyzing: Total Tardy Category. => Source: Ed-Fi ODS => ',
'Records in entity:',
(
SELECT COUNT(DISTINCT _sourceKey)
FROM EdFiDW.[dbo].[DimAttendanceEventCategory]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND Tardy_Indicator = 1
),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT d.DescriptorId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Descriptor d
WHERE d.Namespace IN ('http://ed-fi.org/Descriptor/AttendanceEventCategoryDescriptor.xml',
'http://ed-fi.org/Descriptor/Follett/Aspen/AttendanceEventCategoryDescriptor.xml')
AND COALESCE(d.CodeValue,'In Attendance') in ('Tardy')
)
)
UNION ALL
----Total Early departure Category
SELECT CONCAT(' Analyzing: Total Early departure Category. => Source: Ed-Fi ODS => ',
'Records in entity:',
(
SELECT COUNT(DISTINCT _sourceKey)
FROM EdFiDW.[dbo].[DimAttendanceEventCategory]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND EarlyDeparture_Indicator = 1
),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT d.DescriptorId)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Descriptor d
WHERE d.Namespace IN ('http://ed-fi.org/Descriptor/AttendanceEventCategoryDescriptor.xml',
'http://ed-fi.org/Descriptor/Follett/Aspen/AttendanceEventCategoryDescriptor.xml')
AND COALESCE(d.CodeValue,'In Attendance') in ('Early departure')
)
)
--DimDisciplineIncident
------------------------------------------------------------------------------------------
UNION ALL
SELECT ' --------------------------------------------------------------------------------------------------------------------------------------'
UNION ALL
SELECT ' Entity being analyzed: DimDisciplineIncident'
UNION ALL
----Total
SELECT CONCAT(' Analyzing: Total Incidents. => Source: Ed-Fi ODS => ',
'Records in entity:',
(
SELECT COUNT(DISTINCT _sourceKey)
FROM EdFiDW.[dbo].[DimDisciplineIncident]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT di.IncidentIdentifier)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.DisciplineIncident di
INNER JOIN EdFiDW.dbo.DimTime dt ON di.IncidentDate = dt.SchoolDate
INNER JOIN EdFiDW.dbo.DimSchool dschool ON CONCAT_WS('|','Ed-Fi',Convert(NVARCHAR(MAX),di.SchoolId)) = dschool._sourceKey
AND dt.SchoolKey is not null
AND dschool.SchoolKey = dt.SchoolKey
WHERE EdFiDW.dbo.Func_GetSchoolYear(di.IncidentDate) IN (2019,2020)
)
)
UNION ALL
----Total With Actions
SELECT CONCAT(' Analyzing: Total Incidents With Action(s). => Source: Ed-Fi ODS => ',
'Records in entity:',
(
SELECT COUNT(DISTINCT _sourceKey)
FROM EdFiDW.[dbo].[DimDisciplineIncident]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND [DisciplineDescriptor_CodeValue] <> 'N/A'
),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT di.IncidentIdentifier)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.DisciplineIncident di
INNER JOIN EdFiDW.dbo.DimTime dt ON di.IncidentDate = dt.SchoolDate
INNER JOIN EdFiDW.dbo.DimSchool dschool ON CONCAT_WS('|','Ed-Fi',Convert(NVARCHAR(MAX),di.SchoolId)) = dschool._sourceKey
AND dt.SchoolKey is not null
AND dschool.SchoolKey = dt.SchoolKey
INNER JOIN [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.DisciplineActionDisciplineIncident dadi ON di.IncidentIdentifier = dadi.IncidentIdentifier
INNER JOIN [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.DisciplineActionDiscipline dad ON dadi.DisciplineActionIdentifier = dad.DisciplineActionIdentifier
WHERE EdFiDW.dbo.Func_GetSchoolYear(di.IncidentDate) IN (2019,2020)
)
)
UNION ALL
----Total Incidents That Resulted in ISS
SELECT CONCAT(' Analyzing: Total Incidents That Resulted in ISS. => Source: Ed-Fi ODS => ',
'Records in entity:',
(
SELECT COUNT(DISTINCT _sourceKey)
FROM EdFiDW.[dbo].[DimDisciplineIncident]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND DisciplineDescriptor_ISS_Indicator = 1
),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT di.IncidentIdentifier)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.DisciplineIncident di
INNER JOIN EdFiDW.dbo.DimTime dt ON di.IncidentDate = dt.SchoolDate
INNER JOIN EdFiDW.dbo.DimSchool dschool ON CONCAT_WS('|','Ed-Fi',Convert(NVARCHAR(MAX),di.SchoolId)) = dschool._sourceKey
AND dt.SchoolKey is not null
AND dschool.SchoolKey = dt.SchoolKey
INNER JOIN [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.DisciplineActionDisciplineIncident dadi ON di.IncidentIdentifier = dadi.IncidentIdentifier
INNER JOIN [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.DisciplineActionDiscipline dad ON dadi.DisciplineActionIdentifier = dad.DisciplineActionIdentifier
INNER JOIN [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Descriptor d_dia ON dad.DisciplineDescriptorId = d_dia.DescriptorId
WHERE EdFiDW.dbo.Func_GetSchoolYear(di.IncidentDate) IN (2019,2020)
AND COALESCE(d_dia.CodeValue,'N/A') IN ('In School Suspension','In-School Suspension')
)
)
UNION ALL
----Total Incidents That Resulted in OSS
SELECT CONCAT(' Analyzing: Total Incidents That Resulted in OSS. => Source: Ed-Fi ODS => ',
'Records in entity:',
(
SELECT COUNT(DISTINCT _sourceKey)
FROM EdFiDW.[dbo].[DimDisciplineIncident]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND DisciplineDescriptor_OSS_Indicator = 1
),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT di.IncidentIdentifier)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.DisciplineIncident di
INNER JOIN EdFiDW.dbo.DimTime dt ON di.IncidentDate = dt.SchoolDate
INNER JOIN EdFiDW.dbo.DimSchool dschool ON CONCAT_WS('|','Ed-Fi',Convert(NVARCHAR(MAX),di.SchoolId)) = dschool._sourceKey
AND dt.SchoolKey is not null
AND dschool.SchoolKey = dt.SchoolKey
INNER JOIN [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.DisciplineActionDisciplineIncident dadi ON di.IncidentIdentifier = dadi.IncidentIdentifier
INNER JOIN [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.DisciplineActionDiscipline dad ON dadi.DisciplineActionIdentifier = dad.DisciplineActionIdentifier
INNER JOIN [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Descriptor d_dia ON dad.DisciplineDescriptorId = d_dia.DescriptorId
WHERE EdFiDW.dbo.Func_GetSchoolYear(di.IncidentDate) IN (2019,2020)
AND COALESCE(d_dia.CodeValue,'N/A') IN ('Out of School Suspension','Out-Of-School Suspension')
)
)
--DimAssessment
------------------------------------------------------------------------------------------
UNION ALL
SELECT ' --------------------------------------------------------------------------------------------------------------------------------------'
UNION ALL
SELECT ' Entity being analyzed: DimAssessment'
UNION ALL
----Total
SELECT CONCAT(' Analyzing: Total. => Source: Ed-Fi ODS => ',
'Records in entity:',
(
SELECT COUNT(DISTINCT AssessmentIdentifier)
FROM EdFiDW.[dbo].[DimAssessment]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT a.AssessmentIdentifier)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Assessment a
WHERE CHARINDEX('MCAS',a.AssessmentIdentifier,1) = 1
)
)
UNION ALL
----Total Assessment Score Types
SELECT CONCAT(' Analyzing: Total Assessment Score Types. => Source: Ed-Fi ODS => ',
'Records in entity:',
(
SELECT COUNT(DISTINCT ReportingMethodDescriptor_CodeValue)
FROM EdFiDW.[dbo].[DimAssessment]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND AssessmentScore_Indicator = 1
),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT a_s_armt.CodeValue)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Assessment a
INNER JOIN [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.AssessmentScore a_s ON a.AssessmentIdentifier = a_s.AssessmentIdentifier
INNER JOIN [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.AssessmentReportingMethodType a_s_armt ON a_s.AssessmentReportingMethodTypeId = a_s_armt.AssessmentReportingMethodTypeId
WHERE CHARINDEX('MCAS',a.AssessmentIdentifier,1) = 1
)
)
UNION ALL
----Total Assessment Performance Level Types
SELECT CONCAT(' Analyzing: Total Performance Level Types. => Source: Ed-Fi ODS => ',
'Records in entity:',
(
SELECT COUNT(DISTINCT ReportingMethodDescriptor_CodeValue)
FROM EdFiDW.[dbo].[DimAssessment]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND AssessmentPerformanceLevel_Indicator = 1
),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT a_pl_armt.CodeValue)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Assessment a
INNER JOIN [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.AssessmentPerformanceLevel a_pl ON a.AssessmentIdentifier = a_pl.AssessmentIdentifier
INNER JOIN [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.AssessmentReportingMethodType a_pl_armt ON a_pl.AssessmentReportingMethodTypeId = a_pl_armt.AssessmentReportingMethodTypeId
WHERE CHARINDEX('MCAS',a.AssessmentIdentifier,1) = 1
)
)
--DimCourse
------------------------------------------------------------------------------------------
UNION ALL
SELECT ' --------------------------------------------------------------------------------------------------------------------------------------'
UNION ALL
SELECT ' Entity being analyzed: DimCourse'
UNION ALL
----Total
SELECT CONCAT(' Analyzing: Total. => Source: Ed-Fi ODS => ',
'Records in entity:',
(
SELECT COUNT(DISTINCT _sourceKey)
FROM EdFiDW.[dbo].[DimCourse]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT c.CourseCode)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Course c
WHERE EXISTS (SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.CourseOffering co
WHERE c.CourseCode = co.CourseCode
AND co.SchoolYear IN (2019,2020))
)
)
UNION ALL
----Total Course Types
SELECT CONCAT(' Analyzing: Total Course Types. => Source: Ed-Fi ODS => ',
'Records in entity:',
(
SELECT COUNT(DISTINCT CourseLevelCharacteristicTypeDescriptor_CodeValue)
FROM EdFiDW.[dbo].[DimCourse]
WHERE CHARINDEX('Ed-Fi',_sourceKey,1) > 0
AND CourseLevelCharacteristicTypeDescriptor_CodeValue <> 'N/A'
),
' ',
'Records in source system:',
(
SELECT COUNT(DISTINCT clct.CodeValue)
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.Course c
INNER JOIN [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.CourseLevelCharacteristic clc ON c.CourseCode = clc.CourseCode
INNER JOIN [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.CourseLevelCharacteristicType clct ON clc.CourseLevelCharacteristicTypeId = clct.CourseLevelCharacteristicTypeId
WHERE EXISTS (SELECT 1
FROM [EDFISQL01].[EdFi_BPS_Production_Ods].edfi.CourseOffering co