Skip to content

Commit 75cab80

Browse files
committed
Add indices
1 parent 2c91f65 commit 75cab80

File tree

2 files changed

+202
-15
lines changed

2 files changed

+202
-15
lines changed

gefapi/services/user_service.py

Lines changed: 16 additions & 15 deletions
Original file line numberDiff line numberDiff line change
@@ -765,16 +765,17 @@ def delete_user(user_id):
765765

766766
user_uuid = str(user.id)
767767

768-
# Use raw SQL for maximum performance - single pass through each table
769-
# Delete status logs via JOIN to executions (StatusLog uses String FK)
768+
# Use PostgreSQL DELETE...USING for efficient JOIN-based deletes
769+
# This is faster than subqueries as PostgreSQL can use indexes
770+
771+
# Delete status logs via JOIN (StatusLog uses String FK)
770772
logger.info("[DB]: Deleting status logs for user's executions")
771773
db.session.execute(
772774
text("""
773-
DELETE FROM status_log
774-
WHERE execution_id IN (
775-
SELECT CAST(id AS VARCHAR)
776-
FROM execution WHERE user_id = :user_id
777-
)
775+
DELETE FROM status_log s
776+
USING execution e
777+
WHERE s.execution_id = CAST(e.id AS VARCHAR)
778+
AND e.user_id = :user_id
778779
"""),
779780
{"user_id": user_uuid},
780781
)
@@ -783,10 +784,10 @@ def delete_user(user_id):
783784
logger.info("[DB]: Deleting execution logs for user's executions")
784785
db.session.execute(
785786
text("""
786-
DELETE FROM execution_log
787-
WHERE execution_id IN (
788-
SELECT id FROM execution WHERE user_id = :user_id
789-
)
787+
DELETE FROM execution_log el
788+
USING execution e
789+
WHERE el.execution_id = e.id
790+
AND e.user_id = :user_id
790791
"""),
791792
{"user_id": user_uuid},
792793
)
@@ -802,10 +803,10 @@ def delete_user(user_id):
802803
logger.info("[DB]: Deleting script logs for user's scripts")
803804
db.session.execute(
804805
text("""
805-
DELETE FROM script_log
806-
WHERE script_id IN (
807-
SELECT id FROM script WHERE user_id = :user_id
808-
)
806+
DELETE FROM script_log sl
807+
USING script s
808+
WHERE sl.script_id = s.id
809+
AND s.user_id = :user_id
809810
"""),
810811
{"user_id": user_uuid},
811812
)
Lines changed: 186 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,186 @@
1+
"""Add indexes for faster API operations
2+
3+
Revision ID: dfeac915776c
4+
Revises: 2c4f8e1a9b3d
5+
Create Date: 2026-01-27 02:45:00.000000
6+
7+
This migration adds indexes to optimize:
8+
1. User deletion (cascading deletes through related tables)
9+
2. Execution listing/filtering (status, date, user)
10+
3. Status log queries for monitoring dashboards
11+
4. User authentication lookups
12+
"""
13+
14+
from alembic import op
15+
16+
# revision identifiers, used by Alembic.
17+
revision = "dfeac915776c"
18+
down_revision = "2c4f8e1a9b3d"
19+
branch_labels = None
20+
depends_on = None
21+
22+
23+
def upgrade():
24+
# ============================================================
25+
# INDEXES FOR USER DELETION (cascading deletes)
26+
# PostgreSQL does NOT auto-create indexes on foreign key columns
27+
# ============================================================
28+
29+
# Index on execution.user_id - critical for finding user's executions
30+
op.create_index(
31+
"ix_execution_user_id",
32+
"execution",
33+
["user_id"],
34+
unique=False,
35+
if_not_exists=True,
36+
)
37+
38+
# Index on script.user_id - critical for finding user's scripts
39+
op.create_index(
40+
"ix_script_user_id",
41+
"script",
42+
["user_id"],
43+
unique=False,
44+
if_not_exists=True,
45+
)
46+
47+
# Index on status_log.execution_id - for deleting status logs by execution
48+
op.create_index(
49+
"ix_status_log_execution_id",
50+
"status_log",
51+
["execution_id"],
52+
unique=False,
53+
if_not_exists=True,
54+
)
55+
56+
# Index on execution_log.execution_id - for deleting execution logs
57+
op.create_index(
58+
"ix_execution_log_execution_id",
59+
"execution_log",
60+
["execution_id"],
61+
unique=False,
62+
if_not_exists=True,
63+
)
64+
65+
# Index on script_log.script_id - for deleting script logs
66+
op.create_index(
67+
"ix_script_log_script_id",
68+
"script_log",
69+
["script_id"],
70+
unique=False,
71+
if_not_exists=True,
72+
)
73+
74+
# ============================================================
75+
# INDEXES FOR EXECUTION LISTING/FILTERING (API UI dashboard)
76+
# ============================================================
77+
78+
# Index on execution.status - frequently filtered (PENDING, RUNNING, etc.)
79+
op.create_index(
80+
"ix_execution_status",
81+
"execution",
82+
["status"],
83+
unique=False,
84+
if_not_exists=True,
85+
)
86+
87+
# Index on execution.start_date - for date filtering and sorting
88+
op.create_index(
89+
"ix_execution_start_date",
90+
"execution",
91+
["start_date"],
92+
unique=False,
93+
if_not_exists=True,
94+
)
95+
96+
# Composite index for common query: status + start_date
97+
op.create_index(
98+
"ix_execution_status_start_date",
99+
"execution",
100+
["status", "start_date"],
101+
unique=False,
102+
if_not_exists=True,
103+
)
104+
105+
# Index on execution.script_id - for finding executions by script
106+
op.create_index(
107+
"ix_execution_script_id",
108+
"execution",
109+
["script_id"],
110+
unique=False,
111+
if_not_exists=True,
112+
)
113+
114+
# ============================================================
115+
# INDEXES FOR STATUS LOG MONITORING (dashboard graphs)
116+
# ============================================================
117+
118+
# Index on status_log.timestamp - for time-series queries
119+
op.create_index(
120+
"ix_status_log_timestamp",
121+
"status_log",
122+
["timestamp"],
123+
unique=False,
124+
if_not_exists=True,
125+
)
126+
127+
# ============================================================
128+
# INDEXES FOR USER OPERATIONS
129+
# ============================================================
130+
131+
# Index on user.created_at - for sorting users list
132+
op.create_index(
133+
"ix_user_created_at",
134+
"user",
135+
["created_at"],
136+
unique=False,
137+
if_not_exists=True,
138+
)
139+
140+
# Index on user.role - for filtering by role
141+
op.create_index(
142+
"ix_user_role",
143+
"user",
144+
["role"],
145+
unique=False,
146+
if_not_exists=True,
147+
)
148+
149+
# ============================================================
150+
# INDEXES FOR SCRIPT OPERATIONS
151+
# ============================================================
152+
153+
# Index on script.status - for filtering scripts by status
154+
op.create_index(
155+
"ix_script_status",
156+
"script",
157+
["status"],
158+
unique=False,
159+
if_not_exists=True,
160+
)
161+
162+
163+
def downgrade():
164+
# User deletion indexes
165+
op.drop_index("ix_execution_user_id", table_name="execution")
166+
op.drop_index("ix_script_user_id", table_name="script")
167+
op.drop_index("ix_status_log_execution_id", table_name="status_log")
168+
op.drop_index("ix_execution_log_execution_id", table_name="execution_log")
169+
op.drop_index("ix_script_log_script_id", table_name="script_log")
170+
171+
# Execution listing indexes
172+
op.drop_index("ix_execution_status", table_name="execution")
173+
op.drop_index("ix_execution_start_date", table_name="execution")
174+
op.drop_index("ix_execution_status_start_date", table_name="execution")
175+
op.drop_index("ix_execution_script_id", table_name="execution")
176+
177+
# Status log indexes
178+
op.drop_index("ix_status_log_timestamp", table_name="status_log")
179+
180+
# User indexes
181+
op.drop_index("ix_user_created_at", table_name="user")
182+
op.drop_index("ix_user_role", table_name="user")
183+
184+
# Script indexes
185+
op.drop_index("ix_script_status", table_name="script")
186+
op.drop_index("ix_script_log_script_id", table_name="script_log")

0 commit comments

Comments
 (0)