Skip to content

Commit 173cb5d

Browse files
authored
Merge pull request #2 from Project-CARPI/main-preview
Add more SQLModel functionality
2 parents 6765c79 + 9705130 commit 173cb5d

File tree

4 files changed

+163
-74
lines changed

4 files changed

+163
-74
lines changed
Lines changed: 12 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,12 @@
1+
from sqlalchemy.dialects.mysql import ENUM, VARCHAR
2+
from sqlmodel import Field, SQLModel
3+
4+
_RELATIONSHIP_ENUM = ["Coreq", "Cross"]
5+
6+
7+
class Course_Relationship(SQLModel, table=True):
8+
dept: str = Field(primary_key=True, sa_type=VARCHAR(4))
9+
code_num: str = Field(primary_key=True, sa_type=VARCHAR(4))
10+
relationship: str = Field(primary_key=True, sa_type=ENUM(*_RELATIONSHIP_ENUM))
11+
rel_dept: str = Field(primary_key=True, sa_type=VARCHAR(4))
12+
rel_code_num: str = Field(primary_key=True, sa_type=VARCHAR(4))
Lines changed: 13 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,13 @@
1+
from sqlalchemy.dialects.mysql import ENUM, VARCHAR
2+
from sqlmodel import Field, SQLModel
3+
4+
_CATEGORY_ENUM = ["Major", "Level", "Classification"]
5+
_RESTRICTION_ENUM = ["Must be", "May not be"]
6+
7+
8+
class Course_Restriction(SQLModel, table=True):
9+
dept: str = Field(primary_key=True, sa_type=VARCHAR(4))
10+
code_num: str = Field(primary_key=True, sa_type=VARCHAR(4))
11+
category: str = Field(primary_key=True, sa_type=ENUM(*_CATEGORY_ENUM))
12+
restr_rule: str = Field(primary_key=True, sa_type=ENUM(*_RESTRICTION_ENUM))
13+
restriction: str = Field(primary_key=True, sa_type=VARCHAR(255))

app/db_models/professor.py

Lines changed: 12 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,12 @@
1+
from sqlalchemy.dialects.mysql import ENUM, VARCHAR, SMALLINT
2+
from sqlmodel import Field, SQLModel
3+
4+
_SEMESTER_ENUM = ["Fall", "Spring", "Summer"]
5+
6+
7+
class Professor(SQLModel, table=True):
8+
sem_year: int = Field(primary_key=True, sa_type=SMALLINT)
9+
semester: str = Field(primary_key=True, sa_type=ENUM(*_SEMESTER_ENUM))
10+
dept: str = Field(primary_key=True, sa_type=VARCHAR(4))
11+
code_num: str = Field(primary_key=True, sa_type=VARCHAR(4))
12+
prof_name: str = Field(primary_key=True, sa_type=VARCHAR(255))

app/routers/course.py

Lines changed: 126 additions & 74 deletions
Original file line numberDiff line numberDiff line change
@@ -1,13 +1,14 @@
11
from enum import Enum
22

33
from fastapi import APIRouter
4-
from sqlalchemy.sql import text
54
from sqlmodel import select
5+
from sqlmodel.sql.expression import Select, SelectOfScalar
66

77
from ..db_models.course import Course
88
from ..db_models.course_attribute import Course_Attribute
99
from ..db_models.course_seats import Course_Seats
1010
from ..dependencies import SessionDep
11+
from sqlmodel import func, or_, and_, distinct, desc
1112

1213

1314
class CourseFilter(str, Enum):
@@ -19,65 +20,114 @@ class CourseFilter(str, Enum):
1920
router = APIRouter(prefix="/course")
2021

2122

22-
_SEARCH_COURSE_QUERY = text(
23-
"""
24-
SELECT
25-
course.dept AS dept,
26-
course.code_num AS code_num,
27-
course.title AS title,
28-
course.desc_text AS desc_text,
29-
course.credit_min AS credit_min,
30-
course.credit_max AS credit_max,
31-
GROUP_CONCAT(DISTINCT CONCAT(course_seats.semester, ' ', course_seats.sem_year)) AS sem_list,
32-
GROUP_CONCAT(DISTINCT course_attribute.attr ORDER BY course_attribute.attr ASC) AS attr_list,
33-
REGEXP_LIKE(CONCAT(course.dept, ' ', course.code_num), :search_code_regex, 'i') AS code_match,
34-
REGEXP_LIKE(course.title, :search_full_regex, 'i') AS title_exact_match,
35-
REGEXP_LIKE(course.title, :search_start_regex, 'i') AS title_start_match,
36-
REGEXP_LIKE(course.title, :search_any_regex, 'i') AS title_match,
37-
REGEXP_LIKE(course.title, :search_acronym_regex, 'i') AS title_acronym,
38-
REGEXP_LIKE(course.title, :search_abbrev_regex, 'i') AS title_abbrev
39-
FROM
40-
course
41-
INNER JOIN course_seats USING(dept, code_num)
42-
LEFT JOIN course_attribute USING(dept, code_num)
43-
WHERE
44-
REGEXP_LIKE(dept, :dept_filter_regex, 'i') > 0
45-
GROUP BY
46-
dept,
47-
code_num,
48-
title,
49-
desc_text,
50-
credit_min,
51-
credit_max,
52-
code_match,
53-
title_exact_match,
54-
title_start_match,
55-
title_match,
56-
title_acronym,
57-
title_abbrev
58-
HAVING
59-
(
60-
code_match > 0
61-
OR title_exact_match > 0
62-
OR title_start_match > 0
63-
OR title_match > 0
64-
OR title_acronym > 0
65-
OR title_abbrev > 0
23+
def search_course_query(
24+
search_code_regex: str,
25+
search_full_regex: str,
26+
search_start_regex: str,
27+
search_any_regex: str,
28+
search_acronym_regex: str,
29+
search_abbrev_regex: str,
30+
dept_filter_regex: str,
31+
attr_filter_regex: str,
32+
sem_filter_regex: str,
33+
) -> Select | SelectOfScalar:
34+
return (
35+
select(
36+
Course.dept,
37+
Course.code_num,
38+
Course.title,
39+
Course.desc_text,
40+
Course.credit_min,
41+
Course.credit_max,
42+
func.group_concat(
43+
distinct(func.concat(Course_Seats.semester, " ", Course_Seats.sem_year))
44+
).label("sem_list"),
45+
func.group_concat(distinct(Course_Attribute.attr)).label("attr_list"),
46+
func.regexp_like(
47+
func.concat(Course.dept, " ", Course.code_num), search_code_regex, "i"
48+
).label("code_match"),
49+
func.regexp_like(Course.title, search_full_regex, "i").label(
50+
"title_exact_match"
51+
),
52+
func.regexp_like(Course.title, search_start_regex, "i").label(
53+
"title_start_match"
54+
),
55+
func.regexp_like(Course.title, search_any_regex, "i").label("title_match"),
56+
func.regexp_like(Course.title, search_acronym_regex, "i").label(
57+
"title_acronym"
58+
),
59+
func.regexp_like(Course.title, search_abbrev_regex, "i").label(
60+
"title_abbrev"
61+
),
6662
)
67-
AND REGEXP_LIKE(IFNULL(attr_list, ''), :attr_filter_regex, 'i') > 0
68-
AND REGEXP_LIKE(sem_list, :sem_filter_regex, 'i') > 0
69-
ORDER BY
70-
code_match DESC,
71-
title_exact_match DESC,
72-
title_start_match DESC,
73-
title_match DESC,
74-
title_acronym DESC,
75-
title_abbrev DESC,
76-
code_num ASC,
77-
dept ASC
78-
;
79-
"""
80-
)
63+
.join(
64+
Course_Seats,
65+
and_(
66+
Course.dept == Course_Seats.dept,
67+
Course.code_num == Course_Seats.code_num,
68+
),
69+
)
70+
.outerjoin(
71+
Course_Attribute,
72+
and_(
73+
Course.dept == Course_Attribute.dept,
74+
Course.code_num == Course_Attribute.code_num,
75+
),
76+
)
77+
.where(func.regexp_like(Course.dept, dept_filter_regex, "i"))
78+
.group_by(
79+
Course.dept,
80+
Course.code_num,
81+
Course.title,
82+
Course.desc_text,
83+
Course.credit_min,
84+
Course.credit_max,
85+
)
86+
.having(
87+
or_(
88+
func.regexp_like(
89+
func.concat(Course.dept, " ", Course.code_num),
90+
search_code_regex,
91+
"i",
92+
),
93+
func.regexp_like(Course.title, search_full_regex, "i"),
94+
func.regexp_like(Course.title, search_start_regex, "i"),
95+
func.regexp_like(Course.title, search_any_regex, "i"),
96+
func.regexp_like(Course.title, search_acronym_regex, "i"),
97+
func.regexp_like(Course.title, search_abbrev_regex, "i"),
98+
),
99+
func.regexp_like(
100+
func.ifnull(func.group_concat(distinct(Course_Attribute.attr)), ""),
101+
attr_filter_regex,
102+
"i",
103+
),
104+
func.regexp_like(
105+
func.group_concat(
106+
distinct(
107+
func.concat(Course_Seats.semester, " ", Course_Seats.sem_year)
108+
)
109+
),
110+
sem_filter_regex,
111+
"i",
112+
),
113+
)
114+
.order_by(
115+
desc(
116+
func.regexp_like(
117+
func.concat(Course.dept, " ", Course.code_num),
118+
search_code_regex,
119+
"i",
120+
)
121+
),
122+
desc(func.regexp_like(Course.title, search_full_regex, "i")),
123+
desc(func.regexp_like(Course.title, search_start_regex, "i")),
124+
desc(func.regexp_like(Course.title, search_any_regex, "i")),
125+
desc(func.regexp_like(Course.title, search_acronym_regex, "i")),
126+
desc(func.regexp_like(Course.title, search_abbrev_regex, "i")),
127+
Course.code_num,
128+
Course.dept,
129+
)
130+
)
81131

82132

83133
@router.get("/search")
@@ -92,8 +142,9 @@ def search_course(
92142
dept_filters = deptFilters.split(",") if deptFilters else None
93143
attr_filters = attrFilters.split(",") if attrFilters else None
94144
sem_filters = semFilters.split(",") if semFilters else None
95-
if not (searchPrompt or dept_filters or attr_filters or sem_filters):
96-
return []
145+
if not (dept_filters or attr_filters or sem_filters):
146+
if not searchPrompt or len(searchPrompt) < 3:
147+
return []
97148
regex_code = ".*"
98149
regex_full = ".*"
99150
regex_start = ".*"
@@ -112,7 +163,7 @@ def search_course(
112163
if sem_filters and len(sem_filters) > 0:
113164
sem_filters.sort()
114165
sem_filter_regex = ".*".join(sem_filters)
115-
if searchPrompt and len(searchPrompt) > 0:
166+
if searchPrompt and len(searchPrompt) > 2:
116167
reg_start_or_space = "(^|.* )"
117168
# Full code match
118169
regex_code = f"^{searchPrompt}$"
@@ -139,18 +190,19 @@ def search_course(
139190
regex_abbrev = regex_abbrev[:-3]
140191
else:
141192
regex_abbrev = "a^"
142-
params = {
143-
"search_code_regex": regex_code,
144-
"search_full_regex": regex_full,
145-
"search_start_regex": regex_start,
146-
"search_any_regex": regex_any,
147-
"search_acronym_regex": regex_acronym,
148-
"search_abbrev_regex": regex_abbrev,
149-
"dept_filter_regex": dept_filter_regex,
150-
"attr_filter_regex": attr_filter_regex,
151-
"sem_filter_regex": sem_filter_regex,
152-
}
153-
results = session.exec(_SEARCH_COURSE_QUERY, params=params).all()
193+
results = session.exec(
194+
search_course_query(
195+
regex_code,
196+
regex_full,
197+
regex_start,
198+
regex_any,
199+
regex_acronym,
200+
regex_abbrev,
201+
dept_filter_regex,
202+
attr_filter_regex,
203+
sem_filter_regex,
204+
)
205+
).all()
154206
return [dict(row._mapping) for row in results]
155207

156208

0 commit comments

Comments
 (0)