diff --git a/app/db_models/course_relationship.py b/app/db_models/course_relationship.py new file mode 100644 index 0000000..faf24f7 --- /dev/null +++ b/app/db_models/course_relationship.py @@ -0,0 +1,12 @@ +from sqlalchemy.dialects.mysql import ENUM, VARCHAR +from sqlmodel import Field, SQLModel + +_RELATIONSHIP_ENUM = ["Coreq", "Cross"] + + +class Course_Relationship(SQLModel, table=True): + dept: str = Field(primary_key=True, sa_type=VARCHAR(4)) + code_num: str = Field(primary_key=True, sa_type=VARCHAR(4)) + relationship: str = Field(primary_key=True, sa_type=ENUM(*_RELATIONSHIP_ENUM)) + rel_dept: str = Field(primary_key=True, sa_type=VARCHAR(4)) + rel_code_num: str = Field(primary_key=True, sa_type=VARCHAR(4)) diff --git a/app/db_models/course_restriction.py b/app/db_models/course_restriction.py new file mode 100644 index 0000000..a59deea --- /dev/null +++ b/app/db_models/course_restriction.py @@ -0,0 +1,13 @@ +from sqlalchemy.dialects.mysql import ENUM, VARCHAR +from sqlmodel import Field, SQLModel + +_CATEGORY_ENUM = ["Major", "Level", "Classification"] +_RESTRICTION_ENUM = ["Must be", "May not be"] + + +class Course_Restriction(SQLModel, table=True): + dept: str = Field(primary_key=True, sa_type=VARCHAR(4)) + code_num: str = Field(primary_key=True, sa_type=VARCHAR(4)) + category: str = Field(primary_key=True, sa_type=ENUM(*_CATEGORY_ENUM)) + restr_rule: str = Field(primary_key=True, sa_type=ENUM(*_RESTRICTION_ENUM)) + restriction: str = Field(primary_key=True, sa_type=VARCHAR(255)) diff --git a/app/db_models/professor.py b/app/db_models/professor.py new file mode 100644 index 0000000..cac34dc --- /dev/null +++ b/app/db_models/professor.py @@ -0,0 +1,12 @@ +from sqlalchemy.dialects.mysql import ENUM, VARCHAR, SMALLINT +from sqlmodel import Field, SQLModel + +_SEMESTER_ENUM = ["Fall", "Spring", "Summer"] + + +class Professor(SQLModel, table=True): + sem_year: int = Field(primary_key=True, sa_type=SMALLINT) + semester: str = Field(primary_key=True, sa_type=ENUM(*_SEMESTER_ENUM)) + dept: str = Field(primary_key=True, sa_type=VARCHAR(4)) + code_num: str = Field(primary_key=True, sa_type=VARCHAR(4)) + prof_name: str = Field(primary_key=True, sa_type=VARCHAR(255)) diff --git a/app/routers/course.py b/app/routers/course.py index 5dfdb55..55f97cf 100644 --- a/app/routers/course.py +++ b/app/routers/course.py @@ -1,13 +1,14 @@ from enum import Enum from fastapi import APIRouter -from sqlalchemy.sql import text from sqlmodel import select +from sqlmodel.sql.expression import Select, SelectOfScalar from ..db_models.course import Course from ..db_models.course_attribute import Course_Attribute from ..db_models.course_seats import Course_Seats from ..dependencies import SessionDep +from sqlmodel import func, or_, and_, distinct, desc class CourseFilter(str, Enum): @@ -19,65 +20,114 @@ class CourseFilter(str, Enum): router = APIRouter(prefix="/course") -_SEARCH_COURSE_QUERY = text( - """ - SELECT - course.dept AS dept, - course.code_num AS code_num, - course.title AS title, - course.desc_text AS desc_text, - course.credit_min AS credit_min, - course.credit_max AS credit_max, - GROUP_CONCAT(DISTINCT CONCAT(course_seats.semester, ' ', course_seats.sem_year)) AS sem_list, - GROUP_CONCAT(DISTINCT course_attribute.attr ORDER BY course_attribute.attr ASC) AS attr_list, - REGEXP_LIKE(CONCAT(course.dept, ' ', course.code_num), :search_code_regex, 'i') AS code_match, - REGEXP_LIKE(course.title, :search_full_regex, 'i') AS title_exact_match, - REGEXP_LIKE(course.title, :search_start_regex, 'i') AS title_start_match, - REGEXP_LIKE(course.title, :search_any_regex, 'i') AS title_match, - REGEXP_LIKE(course.title, :search_acronym_regex, 'i') AS title_acronym, - REGEXP_LIKE(course.title, :search_abbrev_regex, 'i') AS title_abbrev - FROM - course - INNER JOIN course_seats USING(dept, code_num) - LEFT JOIN course_attribute USING(dept, code_num) - WHERE - REGEXP_LIKE(dept, :dept_filter_regex, 'i') > 0 - GROUP BY - dept, - code_num, - title, - desc_text, - credit_min, - credit_max, - code_match, - title_exact_match, - title_start_match, - title_match, - title_acronym, - title_abbrev - HAVING - ( - code_match > 0 - OR title_exact_match > 0 - OR title_start_match > 0 - OR title_match > 0 - OR title_acronym > 0 - OR title_abbrev > 0 +def search_course_query( + search_code_regex: str, + search_full_regex: str, + search_start_regex: str, + search_any_regex: str, + search_acronym_regex: str, + search_abbrev_regex: str, + dept_filter_regex: str, + attr_filter_regex: str, + sem_filter_regex: str, +) -> Select | SelectOfScalar: + return ( + select( + Course.dept, + Course.code_num, + Course.title, + Course.desc_text, + Course.credit_min, + Course.credit_max, + func.group_concat( + distinct(func.concat(Course_Seats.semester, " ", Course_Seats.sem_year)) + ).label("sem_list"), + func.group_concat(distinct(Course_Attribute.attr)).label("attr_list"), + func.regexp_like( + func.concat(Course.dept, " ", Course.code_num), search_code_regex, "i" + ).label("code_match"), + func.regexp_like(Course.title, search_full_regex, "i").label( + "title_exact_match" + ), + func.regexp_like(Course.title, search_start_regex, "i").label( + "title_start_match" + ), + func.regexp_like(Course.title, search_any_regex, "i").label("title_match"), + func.regexp_like(Course.title, search_acronym_regex, "i").label( + "title_acronym" + ), + func.regexp_like(Course.title, search_abbrev_regex, "i").label( + "title_abbrev" + ), ) - AND REGEXP_LIKE(IFNULL(attr_list, ''), :attr_filter_regex, 'i') > 0 - AND REGEXP_LIKE(sem_list, :sem_filter_regex, 'i') > 0 - ORDER BY - code_match DESC, - title_exact_match DESC, - title_start_match DESC, - title_match DESC, - title_acronym DESC, - title_abbrev DESC, - code_num ASC, - dept ASC - ; -""" -) + .join( + Course_Seats, + and_( + Course.dept == Course_Seats.dept, + Course.code_num == Course_Seats.code_num, + ), + ) + .outerjoin( + Course_Attribute, + and_( + Course.dept == Course_Attribute.dept, + Course.code_num == Course_Attribute.code_num, + ), + ) + .where(func.regexp_like(Course.dept, dept_filter_regex, "i")) + .group_by( + Course.dept, + Course.code_num, + Course.title, + Course.desc_text, + Course.credit_min, + Course.credit_max, + ) + .having( + or_( + func.regexp_like( + func.concat(Course.dept, " ", Course.code_num), + search_code_regex, + "i", + ), + func.regexp_like(Course.title, search_full_regex, "i"), + func.regexp_like(Course.title, search_start_regex, "i"), + func.regexp_like(Course.title, search_any_regex, "i"), + func.regexp_like(Course.title, search_acronym_regex, "i"), + func.regexp_like(Course.title, search_abbrev_regex, "i"), + ), + func.regexp_like( + func.ifnull(func.group_concat(distinct(Course_Attribute.attr)), ""), + attr_filter_regex, + "i", + ), + func.regexp_like( + func.group_concat( + distinct( + func.concat(Course_Seats.semester, " ", Course_Seats.sem_year) + ) + ), + sem_filter_regex, + "i", + ), + ) + .order_by( + desc( + func.regexp_like( + func.concat(Course.dept, " ", Course.code_num), + search_code_regex, + "i", + ) + ), + desc(func.regexp_like(Course.title, search_full_regex, "i")), + desc(func.regexp_like(Course.title, search_start_regex, "i")), + desc(func.regexp_like(Course.title, search_any_regex, "i")), + desc(func.regexp_like(Course.title, search_acronym_regex, "i")), + desc(func.regexp_like(Course.title, search_abbrev_regex, "i")), + Course.code_num, + Course.dept, + ) + ) @router.get("/search") @@ -92,8 +142,9 @@ def search_course( dept_filters = deptFilters.split(",") if deptFilters else None attr_filters = attrFilters.split(",") if attrFilters else None sem_filters = semFilters.split(",") if semFilters else None - if not (searchPrompt or dept_filters or attr_filters or sem_filters): - return [] + if not (dept_filters or attr_filters or sem_filters): + if not searchPrompt or len(searchPrompt) < 3: + return [] regex_code = ".*" regex_full = ".*" regex_start = ".*" @@ -112,7 +163,7 @@ def search_course( if sem_filters and len(sem_filters) > 0: sem_filters.sort() sem_filter_regex = ".*".join(sem_filters) - if searchPrompt and len(searchPrompt) > 0: + if searchPrompt and len(searchPrompt) > 2: reg_start_or_space = "(^|.* )" # Full code match regex_code = f"^{searchPrompt}$" @@ -139,18 +190,19 @@ def search_course( regex_abbrev = regex_abbrev[:-3] else: regex_abbrev = "a^" - params = { - "search_code_regex": regex_code, - "search_full_regex": regex_full, - "search_start_regex": regex_start, - "search_any_regex": regex_any, - "search_acronym_regex": regex_acronym, - "search_abbrev_regex": regex_abbrev, - "dept_filter_regex": dept_filter_regex, - "attr_filter_regex": attr_filter_regex, - "sem_filter_regex": sem_filter_regex, - } - results = session.exec(_SEARCH_COURSE_QUERY, params=params).all() + results = session.exec( + search_course_query( + regex_code, + regex_full, + regex_start, + regex_any, + regex_acronym, + regex_abbrev, + dept_filter_regex, + attr_filter_regex, + sem_filter_regex, + ) + ).all() return [dict(row._mapping) for row in results]