-
Notifications
You must be signed in to change notification settings - Fork 346
/
rosariosis.sql
3777 lines (2904 loc) · 131 KB
/
rosariosis.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
--
-- PostgreSQL database dump
--
-- Note: Uncheck "Paginate results" when importing with phpPgAdmin
--
SET client_encoding = 'UTF8';
SET check_function_bodies = false;
SET client_min_messages = warning;
-- Fix #102 error language "plpgsql" does not exist
-- http://timmurphy.org/2011/08/27/create-language-if-it-doesnt-exist-in-postgresql/
--
-- Name: create_language_plpgsql(); Type: FUNCTION; Schema: public; Owner: postgres
--
CREATE OR REPLACE FUNCTION create_language_plpgsql() RETURNS boolean AS $$
CREATE LANGUAGE plpgsql;
SELECT TRUE;
$$ LANGUAGE SQL;
SELECT CASE WHEN NOT
(
SELECT TRUE AS exists
FROM pg_language
WHERE lanname = 'plpgsql'
UNION
SELECT FALSE AS exists
ORDER BY exists DESC
LIMIT 1
)
THEN
create_language_plpgsql()
ELSE
FALSE
END AS plpgsql_created;
DROP FUNCTION create_language_plpgsql();
--
-- Name: calc_cum_cr_gpa(mp_id integer, s_id integer); Type: FUNCTION; Schema: public; Owner: postgres
-- @since 11.1 SQL set min Credits to 0 & fix division by zero error
--
CREATE OR REPLACE FUNCTION calc_cum_cr_gpa(mp_id integer, s_id integer) RETURNS integer AS $$
BEGIN
UPDATE student_mp_stats
SET cum_cr_weighted_factor = (case when cr_credits = '0' THEN '0' ELSE cr_weighted_factors/cr_credits END),
cum_cr_unweighted_factor = (case when cr_credits = '0' THEN '0' ELSE cr_unweighted_factors/cr_credits END)
WHERE student_mp_stats.student_id = s_id and student_mp_stats.marking_period_id = mp_id;
RETURN 1;
END;
$$ LANGUAGE plpgsql;
--
-- Name: calc_cum_gpa(mp_id integer, s_id integer); Type: FUNCTION; Schema: public; Owner: postgres
-- @since 11.1 SQL set min Credits to 0 & fix division by zero error
--
CREATE OR REPLACE FUNCTION calc_cum_gpa(mp_id integer, s_id integer) RETURNS integer AS $$
BEGIN
UPDATE student_mp_stats
SET cum_weighted_factor = (case when gp_credits = '0' THEN '0' ELSE sum_weighted_factors/gp_credits END),
cum_unweighted_factor = (case when gp_credits = '0' THEN '0' ELSE sum_unweighted_factors/gp_credits END)
WHERE student_mp_stats.student_id = s_id and student_mp_stats.marking_period_id = mp_id;
RETURN 1;
END;
$$ LANGUAGE plpgsql;
--modif Francois: fix calc_gpa_mp() + credit()
--
-- Name: calc_gpa_mp(s_id integer, mp_id integer); Type: FUNCTION; Schema: public; Owner: postgres
--
CREATE OR REPLACE FUNCTION calc_gpa_mp(s_id integer, mp_id integer) RETURNS integer AS $$
DECLARE
oldrec student_mp_stats%ROWTYPE;
BEGIN
SELECT * INTO oldrec FROM student_mp_stats WHERE student_id = s_id and marking_period_id = mp_id;
IF FOUND THEN
UPDATE student_mp_stats SET
sum_weighted_factors = rcg.sum_weighted_factors,
sum_unweighted_factors = rcg.sum_unweighted_factors,
cr_weighted_factors = rcg.cr_weighted,
cr_unweighted_factors = rcg.cr_unweighted,
gp_credits = rcg.gp_credits,
cr_credits = rcg.cr_credits
FROM (
select
sum(weighted_gp*credit_attempted/gp_scale) as sum_weighted_factors,
sum(unweighted_gp*credit_attempted/gp_scale) as sum_unweighted_factors,
sum(credit_attempted) as gp_credits,
sum( case when class_rank = 'Y' THEN weighted_gp*credit_attempted/gp_scale END ) as cr_weighted,
sum( case when class_rank = 'Y' THEN unweighted_gp*credit_attempted/gp_scale END ) as cr_unweighted,
sum( case when class_rank = 'Y' THEN credit_attempted END) as cr_credits
from student_report_card_grades where student_id = s_id
and marking_period_id = mp_id
and not gp_scale = 0 group by student_id, marking_period_id
) as rcg
WHERE student_id = s_id and marking_period_id = mp_id;
RETURN 1;
ELSE
INSERT INTO student_mp_stats (student_id, marking_period_id, sum_weighted_factors, sum_unweighted_factors, grade_level_short, cr_weighted_factors, cr_unweighted_factors, gp_credits, cr_credits)
select
srcg.student_id,
srcg.marking_period_id,
sum(weighted_gp*credit_attempted/gp_scale) as sum_weighted_factors,
sum(unweighted_gp*credit_attempted/gp_scale) as sum_unweighted_factors,
(select eg.short_name
from enroll_grade eg, marking_periods mp
where eg.student_id = s_id
and eg.syear = mp.syear
and eg.school_id = mp.school_id
and eg.start_date <= mp.end_date
and mp.marking_period_id = mp_id
order by eg.start_date desc
limit 1) as short_name,
sum( case when class_rank = 'Y' THEN weighted_gp*credit_attempted/gp_scale END ) as cr_weighted,
sum( case when class_rank = 'Y' THEN unweighted_gp*credit_attempted/gp_scale END ) as cr_unweighted,
sum(credit_attempted) as gp_credits,
sum(case when class_rank = 'Y' THEN credit_attempted END) as cr_credits
from student_report_card_grades srcg
where srcg.student_id = s_id and srcg.marking_period_id = mp_id and not srcg.gp_scale = 0
group by srcg.student_id, srcg.marking_period_id, short_name;
END IF;
RETURN 0;
END;
$$ LANGUAGE plpgsql;
--
-- Name: credit(cp_id integer, mp_id integer); Type: FUNCTION; Schema: public; Owner: postgres
--
CREATE OR REPLACE FUNCTION credit(cp_id integer, mp_id integer) RETURNS numeric AS $$
DECLARE
course_detail RECORD;
mp_detail RECORD;
val RECORD;
BEGIN
select * into course_detail from course_periods where course_period_id = cp_id;
select * into mp_detail from marking_periods where marking_period_id = mp_id;
IF course_detail.marking_period_id = mp_detail.marking_period_id THEN
return course_detail.credits;
ELSIF course_detail.mp = 'FY' AND mp_detail.mp_type = 'semester' THEN
select into val count(*) as mp_count from marking_periods where parent_id = course_detail.marking_period_id group by parent_id;
ELSIF course_detail.mp = 'FY' and mp_detail.mp_type = 'quarter' THEN
select into val count(*) as mp_count from marking_periods where grandparent_id = course_detail.marking_period_id group by grandparent_id;
ELSIF course_detail.mp = 'SEM' and mp_detail.mp_type = 'quarter' THEN
select into val count(*) as mp_count from marking_periods where parent_id = course_detail.marking_period_id group by parent_id;
ELSE
return course_detail.credits;
END IF;
IF val.mp_count > 0 THEN
return course_detail.credits/val.mp_count;
ELSE
return course_detail.credits;
END IF;
END;
$$ LANGUAGE plpgsql;
--
-- Name: set_class_rank_mp(mp_id integer); Type: FUNCTION; Schema: public; Owner: postgres
--
CREATE OR REPLACE FUNCTION set_class_rank_mp(mp_id integer) RETURNS integer AS $$
BEGIN
update student_mp_stats
set cum_rank = class_rank.class_rank, class_size = class_rank.class_size
from (select mp.marking_period_id, sgm.student_id,
(select count(*)+1
from student_mp_stats sgm3
where sgm3.cum_cr_weighted_factor > sgm.cum_cr_weighted_factor
and sgm3.marking_period_id = mp.marking_period_id
and sgm3.student_id in (select distinct sgm2.student_id
from student_mp_stats sgm2, student_enrollment se2
where sgm2.student_id = se2.student_id
and sgm2.marking_period_id = mp.marking_period_id
and se2.grade_id = se.grade_id
and se2.syear = se.syear)) as class_rank,
(select count(*)
from student_mp_stats sgm4
where sgm4.marking_period_id = mp.marking_period_id
and sgm4.student_id in (select distinct sgm5.student_id
from student_mp_stats sgm5, student_enrollment se3
where sgm5.student_id = se3.student_id
and sgm5.marking_period_id = mp.marking_period_id
and se3.grade_id = se.grade_id
and se3.syear = se.syear)) as class_size
from student_enrollment se, student_mp_stats sgm, marking_periods mp
where se.student_id = sgm.student_id
and sgm.marking_period_id = mp.marking_period_id
and mp.marking_period_id = mp_id
and se.syear = mp.syear
and not sgm.cum_cr_weighted_factor is null) as class_rank
where student_mp_stats.marking_period_id = class_rank.marking_period_id
and student_mp_stats.student_id = class_rank.student_id;
RETURN 1;
END;
$$ LANGUAGE plpgsql;
--
-- Name: t_update_mp_stats(); Type: FUNCTION; Schema: public; Owner: postgres
--
CREATE OR REPLACE FUNCTION t_update_mp_stats() RETURNS "trigger" AS $$
BEGIN
IF tg_op = 'DELETE' THEN
PERFORM calc_gpa_mp(OLD.student_id, OLD.marking_period_id);
PERFORM calc_cum_gpa(OLD.marking_period_id, OLD.student_id);
PERFORM calc_cum_cr_gpa(OLD.marking_period_id, OLD.student_id);
ELSE
--IF tg_op = 'INSERT' THEN
--we need to do stuff here to gather other information since it's a new record.
--ELSE
--if report_card_grade_id changes, then we need to reset gp values
-- IF NOT NEW.report_card_grade_id = OLD.report_card_grade_id THEN
--
PERFORM calc_gpa_mp(NEW.student_id, NEW.marking_period_id);
PERFORM calc_cum_gpa(NEW.marking_period_id, NEW.student_id);
PERFORM calc_cum_cr_gpa(NEW.marking_period_id, NEW.student_id);
END IF;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
--
-- Name: set_updated_at(); Type: FUNCTION; Schema: public; Owner: postgres
-- @link https://stackoverflow.com/questions/36934518/postgresql-trigger-for-all-tables-that-include-create-date
-- @link https://stackoverflow.com/questions/9556474/how-do-i-automatically-update-a-timestamp-in-postgresql
--
CREATE OR REPLACE FUNCTION set_updated_at() RETURNS trigger AS $$
BEGIN
IF row(NEW.*) IS DISTINCT FROM row(OLD.*) THEN
NEW.updated_at := CURRENT_TIMESTAMP;
RETURN NEW;
ELSE
RETURN OLD;
END IF;
END;
$$ LANGUAGE plpgsql;
SET default_tablespace = '';
SET default_with_oids = false;
--
-- Name: schools; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE schools (
syear numeric(4,0) NOT NULL,
id serial,
title varchar(100) NOT NULL,
address varchar(100),
city varchar(100),
state varchar(10),
zipcode varchar(10),
phone varchar(30),
principal varchar(100),
www_address text,
school_number varchar(50),
short_name varchar(25),
reporting_gp_scale numeric(10,3),
number_days_rotation numeric(1,0),
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
PRIMARY KEY (id, syear)
);
--
-- Name: students; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE students (
student_id serial PRIMARY KEY,
last_name varchar(50) NOT NULL,
first_name varchar(50) NOT NULL,
middle_name varchar(50),
name_suffix varchar(3),
username varchar(100) UNIQUE,
password varchar(106),
last_login timestamp,
failed_login integer,
custom_200000000 text,
custom_200000001 text,
custom_200000002 text,
custom_200000003 text,
custom_200000004 date,
custom_200000005 text,
custom_200000006 text,
custom_200000007 text,
custom_200000008 text,
custom_200000009 text,
custom_200000010 char(1),
custom_200000011 text,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp
);
--
-- Name: staff; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE staff (
syear numeric(4,0) NOT NULL,
staff_id serial PRIMARY KEY,
current_school_id integer,
title varchar(5),
first_name varchar(50) NOT NULL,
last_name varchar(50) NOT NULL,
middle_name varchar(50),
name_suffix varchar(3),
username varchar(100),
password varchar(106),
email varchar(255),
custom_200000001 text, -- Old phone column.
profile varchar(30),
schools varchar(150),
last_login timestamp,
failed_login integer,
profile_id integer,
rollover_id integer,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp
);
--
-- Name: school_marking_periods; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE school_marking_periods (
marking_period_id serial PRIMARY KEY,
syear numeric(4,0) NOT NULL,
mp varchar(3) NOT NULL,
school_id integer NOT NULL,
parent_id integer,
title varchar(50) NOT NULL,
short_name varchar(10),
sort_order numeric,
start_date date NOT NULL,
end_date date NOT NULL,
post_start_date date,
post_end_date date,
does_grades varchar(1),
does_comments varchar(1),
rollover_id integer,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
FOREIGN KEY (school_id,syear) REFERENCES schools(id,syear)
);
--
-- Name: courses; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE courses (
syear numeric(4,0) NOT NULL,
course_id serial PRIMARY KEY,
subject_id integer NOT NULL,
school_id integer NOT NULL,
grade_level integer,
title varchar(100) NOT NULL,
short_name varchar(25),
rollover_id integer,
credit_hours numeric(6,2),
description text,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
FOREIGN KEY (school_id,syear) REFERENCES schools(id,syear)
);
--
-- Name: course_periods; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE course_periods (
syear numeric(4,0) NOT NULL,
school_id integer NOT NULL,
course_period_id serial PRIMARY KEY,
course_id integer NOT NULL REFERENCES courses(course_id),
title text,
short_name varchar(25) NOT NULL,
mp varchar(3),
marking_period_id integer NOT NULL REFERENCES school_marking_periods(marking_period_id),
teacher_id integer NOT NULL REFERENCES staff(staff_id),
secondary_teacher_id integer REFERENCES staff(staff_id),
room varchar(10),
total_seats numeric,
filled_seats numeric,
does_attendance text,
does_honor_roll varchar(1),
does_class_rank varchar(1),
gender_restriction varchar(1),
house_restriction varchar(1),
availability numeric,
parent_id integer,
calendar_id integer,
half_day varchar(1), -- @deprecated since 8.9
does_breakoff varchar(1),
rollover_id integer,
grade_scale_id integer,
credits numeric(6,2),
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
FOREIGN KEY (school_id,syear) REFERENCES schools(id,syear)
);
--
-- Name: access_log; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE access_log (
syear numeric(4,0) NOT NULL,
username varchar(100),
profile varchar(30),
login_time timestamp, -- @deprecated since 11.0 use created_at instead
ip_address varchar(50),
user_agent text,
status varchar(50),
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp
);
--
-- Name: accounting_categories; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE accounting_categories (
id serial PRIMARY KEY,
school_id integer NOT NULL,
title text NOT NULL,
short_name varchar(10),
type varchar(100),
sort_order numeric,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp
);
--
-- Name: accounting_incomes; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE accounting_incomes (
assigned_date date,
comments text,
id serial PRIMARY KEY,
title text NOT NULL,
category_id integer REFERENCES accounting_categories(id),
amount numeric(14,2) NOT NULL,
file_attached text,
school_id integer NOT NULL,
syear numeric(4,0) NOT NULL,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
FOREIGN KEY (school_id,syear) REFERENCES schools(id,syear)
);
--
-- Name: accounting_salaries; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE accounting_salaries (
staff_id integer NOT NULL REFERENCES staff(staff_id),
assigned_date date,
due_date date,
comments text,
id serial PRIMARY KEY,
title text NOT NULL,
amount numeric(14,2) NOT NULL,
file_attached text,
school_id integer NOT NULL,
syear numeric(4,0) NOT NULL,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
FOREIGN KEY (school_id,syear) REFERENCES schools(id,syear)
);
--
-- Name: accounting_payments; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE accounting_payments (
id serial PRIMARY KEY,
syear numeric(4,0) NOT NULL,
school_id integer NOT NULL,
staff_id integer REFERENCES staff(staff_id),
title text,
category_id integer REFERENCES accounting_categories(id),
amount numeric(14,2) NOT NULL,
payment_date date,
comments text,
file_attached text,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
FOREIGN KEY (school_id,syear) REFERENCES schools(id,syear)
);
--
-- Name: address; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE address (
address_id serial PRIMARY KEY,
house_no numeric(5,0),
direction varchar(2),
street varchar(30),
apt varchar(5),
zipcode varchar(10),
city text,
state varchar(50),
mail_street varchar(30),
mail_city text,
mail_state varchar(50),
mail_zipcode varchar(10),
address text,
mail_address text,
phone varchar(30),
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp
);
--
-- Name: address_field_categories; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE address_field_categories (
id serial PRIMARY KEY,
title text NOT NULL,
sort_order numeric,
residence char(1),
mailing char(1),
bus char(1),
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp
);
--
-- Name: address_fields; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE address_fields (
id serial PRIMARY KEY,
type varchar(10) NOT NULL,
title text NOT NULL,
sort_order numeric,
select_options text,
category_id integer,
required varchar(1),
default_selection text,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp
);
--
-- Name: attendance_calendar; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE attendance_calendar (
syear numeric(4,0) NOT NULL,
school_id integer NOT NULL,
school_date date NOT NULL,
minutes integer,
block varchar(10),
calendar_id integer NOT NULL,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
PRIMARY KEY (syear, school_id, school_date, calendar_id),
FOREIGN KEY (school_id,syear) REFERENCES schools(id,syear)
);
--
-- Name: attendance_calendars; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE attendance_calendars (
school_id integer NOT NULL,
title varchar(100) NOT NULL,
syear numeric(4,0) NOT NULL,
calendar_id serial PRIMARY KEY,
default_calendar varchar(1),
rollover_id integer,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
FOREIGN KEY (school_id,syear) REFERENCES schools(id,syear)
);
--
-- Name: attendance_code_categories; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE attendance_code_categories (
id serial PRIMARY KEY,
syear numeric(4,0) NOT NULL,
school_id integer NOT NULL,
title text NOT NULL,
sort_order numeric,
rollover_id integer,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
FOREIGN KEY (school_id,syear) REFERENCES schools(id,syear)
);
--
-- Name: attendance_codes; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE attendance_codes (
id serial PRIMARY KEY,
syear numeric(4,0) NOT NULL,
school_id integer NOT NULL,
title text NOT NULL,
short_name varchar(10),
type varchar(10),
state_code varchar(1),
default_code varchar(1),
table_name integer,
sort_order numeric,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
FOREIGN KEY (school_id,syear) REFERENCES schools(id,syear)
);
--
-- Name: attendance_completed; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE attendance_completed (
staff_id integer NOT NULL REFERENCES staff(staff_id),
school_date date NOT NULL,
period_id integer NOT NULL,
table_name integer NOT NULL,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
PRIMARY KEY (staff_id, school_date, period_id, table_name)
);
--
-- Name: attendance_day; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE attendance_day (
student_id integer NOT NULL REFERENCES students(student_id),
school_date date NOT NULL,
minutes_present integer,
state_value numeric(2,1),
syear numeric(4,0),
marking_period_id integer REFERENCES school_marking_periods(marking_period_id),
comment text,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
PRIMARY KEY (student_id, school_date)
);
--
-- Name: attendance_period; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE attendance_period (
student_id integer NOT NULL REFERENCES students(student_id),
school_date date NOT NULL,
period_id integer NOT NULL,
attendance_code integer,
attendance_teacher_code integer,
attendance_reason varchar(100),
admin varchar(1),
course_period_id integer REFERENCES course_periods(course_period_id),
marking_period_id integer REFERENCES school_marking_periods(marking_period_id),
comment varchar(100),
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
PRIMARY KEY (student_id, school_date, period_id)
);
--
-- Name: billing_fees; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE billing_fees (
student_id integer NOT NULL REFERENCES students(student_id),
assigned_date date,
due_date date,
comments text,
id serial PRIMARY KEY,
title text NOT NULL,
amount numeric(14,2) NOT NULL,
file_attached text,
school_id integer NOT NULL,
syear numeric(4,0) NOT NULL,
waived_fee_id integer,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
created_by text,
FOREIGN KEY (school_id,syear) REFERENCES schools(id,syear)
);
--
-- Name: billing_payments; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE billing_payments (
id serial PRIMARY KEY,
syear numeric(4,0) NOT NULL,
school_id integer NOT NULL,
student_id integer NOT NULL REFERENCES students(student_id),
amount numeric(14,2) NOT NULL,
payment_date date,
comments text,
refunded_payment_id integer,
lunch_payment varchar(1),
file_attached text,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
created_by text,
FOREIGN KEY (school_id,syear) REFERENCES schools(id,syear)
);
--
-- Name: calendar_events; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE calendar_events (
id serial PRIMARY KEY,
syear numeric(4,0) NOT NULL,
school_id integer NOT NULL,
school_date date,
title varchar(50) NOT NULL,
description text,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
FOREIGN KEY (school_id,syear) REFERENCES schools(id,syear)
);
--
-- Name: config; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE config (
school_id integer NOT NULL, -- Can be 0.
title varchar(100) NOT NULL,
config_value text,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp
);
--
-- Name: course_details; Type: VIEW; Schema: public; Owner: rosariosis
--
CREATE VIEW course_details AS
SELECT cp.school_id, cp.syear, cp.marking_period_id, c.subject_id, cp.course_id, cp.course_period_id, cp.teacher_id, c.title AS course_title, cp.title AS cp_title, cp.grade_scale_id, cp.mp, cp.credits FROM course_periods cp, courses c WHERE (cp.course_id = c.course_id);
--
-- Name: course_period_school_periods; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE course_period_school_periods (
course_period_school_periods_id serial PRIMARY KEY,
course_period_id integer NOT NULL REFERENCES course_periods(course_period_id),
period_id integer NOT NULL,
days varchar(7),
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
UNIQUE (course_period_id, period_id)
);
--
-- Name: course_subjects; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE course_subjects (
syear numeric(4,0) NOT NULL,
school_id integer NOT NULL,
subject_id serial PRIMARY KEY,
title varchar(100) NOT NULL,
short_name varchar(25),
sort_order numeric,
rollover_id integer,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
FOREIGN KEY (school_id,syear) REFERENCES schools(id,syear)
);
--
-- Name: custom_fields; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE custom_fields (
id serial PRIMARY KEY,
type varchar(10) NOT NULL,
title text NOT NULL,
sort_order numeric,
select_options text,
category_id integer,
required varchar(1),
default_selection text,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp
);
--
-- Name: discipline_field_usage; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE discipline_field_usage (
id serial PRIMARY KEY,
discipline_field_id integer NOT NULL,
syear numeric(4,0) NOT NULL,
school_id integer NOT NULL,
title text NOT NULL,
select_options text,
sort_order numeric,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
FOREIGN KEY (school_id,syear) REFERENCES schools(id,syear)
);
--
-- Name: discipline_fields; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE discipline_fields (
id serial PRIMARY KEY,
title text NOT NULL,
short_name varchar(20),
data_type varchar(30) NOT NULL,
column_name text NOT NULL,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp
);
--
-- Name: discipline_referrals; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE discipline_referrals (
id serial PRIMARY KEY,
syear numeric(4,0) NOT NULL,
student_id integer NOT NULL REFERENCES students(student_id),
school_id integer NOT NULL,
staff_id integer REFERENCES staff(staff_id),
entry_date date,
referral_date date,
category_1 text,
category_2 text,
category_3 varchar(1),
category_4 text,
category_5 text,
category_6 text,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
FOREIGN KEY (school_id,syear) REFERENCES schools(id,syear)
);
--
-- Name: dual; Type: VIEW; Schema: public; Owner: rosariosis
--
-- Compatibility with MySQL 5.6 to avoid syntax error when WHERE without FROM clause
-- @example SELECT 1 FROM dual WHERE NOT EXISTS(...)
-- @link https://pgpedia.info/d/dual-dummy-table.html
--
CREATE VIEW dual AS SELECT 'X' AS dummy;
--
-- Name: eligibility; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE eligibility (
student_id integer NOT NULL REFERENCES students(student_id),
syear numeric(4,0),
school_date date,
period_id integer,
eligibility_code varchar(20),
course_period_id integer NOT NULL REFERENCES course_periods(course_period_id),
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp
);
--
-- Name: eligibility_activities; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE eligibility_activities (
id serial PRIMARY KEY,
syear numeric(4,0) NOT NULL,
school_id integer NOT NULL,
title text NOT NULL,
start_date date,
end_date date,
comment text,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
FOREIGN KEY (school_id,syear) REFERENCES schools(id,syear)
);
--
-- Name: eligibility_completed; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE eligibility_completed (
staff_id integer NOT NULL REFERENCES staff(staff_id),
school_date date NOT NULL,
period_id integer NOT NULL,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp,
PRIMARY KEY (staff_id, school_date, period_id)
);
--
-- Name: food_service_accounts; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE food_service_accounts (
account_id integer PRIMARY KEY,
balance numeric(9,2) NOT NULL,
transaction_id integer,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp
);
--
-- Name: food_service_categories; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE food_service_categories (
category_id serial PRIMARY KEY,
school_id integer NOT NULL,
menu_id integer NOT NULL,
title varchar(25) NOT NULL,
sort_order numeric,
created_at timestamp DEFAULT current_timestamp,
updated_at timestamp
);
--
-- Name: food_service_items; Type: TABLE; Schema: public; Owner: rosariosis; Tablespace:
--
CREATE TABLE food_service_items (
item_id serial PRIMARY KEY,
school_id integer NOT NULL,
short_name varchar(25),
sort_order numeric,
description varchar(25),
icon varchar(50),
price numeric(9,2) NOT NULL,
price_reduced numeric(9,2),
price_free numeric(9,2),
price_staff numeric(9,2) NOT NULL,
created_at timestamp DEFAULT current_timestamp,