From f3c9e78d6699cc4c8e237a39f0c709519c42eefd Mon Sep 17 00:00:00 2001 From: Mark Liffiton Date: Tue, 16 Jul 2024 11:53:05 -0500 Subject: [PATCH] Optimize queries: add indexes and help older query planners. --- .../20240716--codehelp--add-indexes.sql | 17 +++++++++++++++++ src/codehelp/schema.sql | 8 ++++++++ src/gened/instructor.py | 2 +- 3 files changed, 26 insertions(+), 1 deletion(-) create mode 100644 src/codehelp/migrations/20240716--codehelp--add-indexes.sql diff --git a/src/codehelp/migrations/20240716--codehelp--add-indexes.sql b/src/codehelp/migrations/20240716--codehelp--add-indexes.sql new file mode 100644 index 0000000..8776b80 --- /dev/null +++ b/src/codehelp/migrations/20240716--codehelp--add-indexes.sql @@ -0,0 +1,17 @@ +-- SPDX-FileCopyrightText: 2024 Mark Liffiton +-- +-- SPDX-License-Identifier: AGPL-3.0-only + +BEGIN; + +DROP INDEX IF EXISTS queries_by_user; +CREATE INDEX queries_by_user ON queries(user_id); +DROP INDEX IF EXISTS queries_by_role; +CREATE INDEX queries_by_role ON queries(role_id); + +DROP INDEX IF EXISTS tutor_chats_by_user; +CREATE INDEX tutor_chats_by_user ON tutor_chats(user_id); +DROP INDEX IF EXISTS tutor_chats_by_role; +CREATE INDEX tutor_chats_by_role ON tutor_chats(role_id); + +COMMIT; diff --git a/src/codehelp/schema.sql b/src/codehelp/schema.sql index eb4597f..b2b638c 100644 --- a/src/codehelp/schema.sql +++ b/src/codehelp/schema.sql @@ -22,6 +22,10 @@ CREATE TABLE queries ( FOREIGN KEY(user_id) REFERENCES users(id), FOREIGN KEY(role_id) REFERENCES roles(id) ); +DROP INDEX IF EXISTS queries_by_user; +CREATE INDEX queries_by_user ON queries(user_id); +DROP INDEX IF EXISTS queries_by_role; +CREATE INDEX queries_by_role ON queries(role_id); DROP TABLE IF EXISTS tutor_chats; CREATE TABLE tutor_chats ( @@ -34,3 +38,7 @@ CREATE TABLE tutor_chats ( FOREIGN KEY(user_id) REFERENCES users(id), FOREIGN KEY(role_id) REFERENCES roles(id) ); +DROP INDEX IF EXISTS tutor_chats_by_user; +CREATE INDEX tutor_chats_by_user ON tutor_chats(user_id); +DROP INDEX IF EXISTS tutor_chats_by_role; +CREATE INDEX tutor_chats_by_role ON tutor_chats(role_id); diff --git a/src/gened/instructor.py b/src/gened/instructor.py index 6c3ec35..042a7dd 100644 --- a/src/gened/instructor.py +++ b/src/gened/instructor.py @@ -25,7 +25,7 @@ def get_queries(class_id: int, user: int | None = None) -> list[Row]: db = get_db() - where_clause = "WHERE roles.class_id=?" + where_clause = "WHERE UNLIKELY(roles.class_id=?)" # UNLIKELY() to help query planner in older sqlite versions params = [class_id] if user is not None: