Skip to content

Commit

Permalink
feat: auto unlock locked tasks after 3 days
Browse files Browse the repository at this point in the history
  • Loading branch information
Anuj-Gupta4 committed Dec 12, 2024
1 parent 6f18583 commit 0216242
Show file tree
Hide file tree
Showing 3 changed files with 119 additions and 4 deletions.
16 changes: 12 additions & 4 deletions src/backend/app/db/models.py
Original file line number Diff line number Diff line change
Expand Up @@ -22,7 +22,7 @@
"""

import json
from datetime import timedelta
from datetime import datetime, timedelta
from io import BytesIO
from re import sub
from typing import TYPE_CHECKING, Annotated, Optional, Self
Expand Down Expand Up @@ -1369,6 +1369,7 @@ class DbOdkEntities(BaseModel):
status: EntityState
project_id: int
task_id: int
updated_at: Optional[AwareDatetime] = None

@classmethod
async def upsert(
Expand All @@ -1394,7 +1395,7 @@ async def upsert(

sql = """
INSERT INTO public.odk_entities
(entity_id, status, project_id, task_id)
(entity_id, status, project_id, task_id, updated_at)
VALUES
"""

Expand All @@ -1407,20 +1408,27 @@ async def upsert(
f"(%({entity_index}_entity_id)s, "
f"%({entity_index}_status)s, "
f"%({entity_index}_project_id)s, "
f"%({entity_index}_task_id)s)"
f"%({entity_index}_task_id)s, "
f"%({entity_index}_updated_at)s)"
)
data[f"{entity_index}_entity_id"] = entity["id"]
data[f"{entity_index}_status"] = EntityState(int(entity["status"])).name
data[f"{entity_index}_project_id"] = project_id
task_id = entity["task_id"]
data[f"{entity_index}_task_id"] = int(task_id) if task_id else None
data[f"{entity_index}_updated_at"] = (
datetime.fromisoformat(entity["updatedAt"].replace("Z", "+00:00"))
if entity["updatedAt"]
else None
)

sql += (
", ".join(values)
+ """
ON CONFLICT (entity_id) DO UPDATE SET
status = EXCLUDED.status,
task_id = EXCLUDED.task_id
task_id = EXCLUDED.task_id,
updated_at = EXCLUDED.updated_at
RETURNING True;
"""
)
Expand Down
85 changes: 85 additions & 0 deletions src/backend/app/tasks/task_routes.py
Original file line number Diff line number Diff line change
Expand Up @@ -115,3 +115,88 @@ async def get_task_event_history(
):
"""Get the detailed history for a task."""
return await DbTaskEvent.all(db, task_id=task_id, days=days, comments=comments)


@router.post("/unlock-tasks")
async def trigger_unlock_tasks(db: Annotated[Connection, Depends(db_conn)]):
"""Endpoint to trigger unlock_old_locked_tasks manually."""
await unlock_old_locked_tasks(db)
return {"message": "Old locked tasks unlocked successfully."}


async def unlock_old_locked_tasks(db):
"""Unlock tasks locked for more than 3 days."""
unlock_query = """
BEGIN;
ALTER TABLE task_events DISABLE TRIGGER task_event_state_trigger;
WITH svc_user AS (
SELECT id AS svc_user_id, username AS svc_username
FROM users
WHERE username = 'svcfmtm'
),
recent_events AS (
SELECT DISTINCT ON (t.id, t.project_id)
t.id AS task_id,
t.project_id,
the.created_at AS last_event_time,
the.event AS last_event,
oe.status AS entity_status,
oe.updated_at
FROM tasks t
JOIN task_events the ON t.id = the.task_id AND t.project_id = the.project_id
LEFT JOIN (
SELECT DISTINCT ON (task_id, project_id, entity_id)
entity_id,
status,
project_id,
task_id,
updated_at
FROM odk_entities oe1
WHERE updated_at = (
SELECT MAX(updated_at)
FROM odk_entities oe2
WHERE oe1.task_id = oe2.task_id
AND oe1.project_id = oe2.project_id
)
) oe ON t.id = oe.task_id AND t.project_id = oe.project_id
ORDER BY t.id, t.project_id, the.created_at DESC
),
filtered_events AS (
SELECT *
FROM recent_events
WHERE last_event IN ('MAP', 'ASSIGN')
AND last_event_time < NOW() - INTERVAL '3 days'
AND (
updated_at IS NULL
OR updated_at::timestamp < NOW() - INTERVAL '3 days'
)
)
INSERT INTO task_events (
event_id,
task_id,
project_id,
event,
user_id,
state,
created_at,
username
)
SELECT
gen_random_uuid(),
fe.task_id,
fe.project_id,
'MAP'::taskevent,
svc.svc_user_id,
'UNLOCKED_TO_MAP'::mappingstate,
NOW(),
svc.svc_username
FROM filtered_events fe
CROSS JOIN svc_user svc;
ALTER TABLE task_events ENABLE TRIGGER task_event_state_trigger;
COMMIT;
"""

async with db.cursor() as cur:
await cur.execute(unlock_query)
22 changes: 22 additions & 0 deletions src/backend/migrations/011-add-date-to-entity.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
-- ## Migration to:
-- * track the last time an entity was updated

-- Start a transaction
BEGIN;

-- Add column 'updated_at' to 'odk_entities' table
DO $$
BEGIN
IF NOT EXISTS (
SELECT 1
FROM information_schema.columns
WHERE table_name='odk_entities' AND column_name='updated_at'
) THEN
ALTER TABLE public.odk_entities
ADD COLUMN updated_at VARCHAR;
END IF;
END $$;


-- Commit the transaction
COMMIT;

0 comments on commit 0216242

Please sign in to comment.