mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-23 17:11:12 -05:00
Implement database queue infrastructure
This commit is contained in:
@@ -2170,7 +2170,19 @@ export type Database = {
|
|||||||
}
|
}
|
||||||
}
|
}
|
||||||
Views: {
|
Views: {
|
||||||
[_ in never]: never
|
moderation_sla_metrics: {
|
||||||
|
Row: {
|
||||||
|
avg_resolution_hours: number | null
|
||||||
|
avg_wait_hours: number | null
|
||||||
|
currently_locked: number | null
|
||||||
|
escalated_count: number | null
|
||||||
|
max_wait_hours: number | null
|
||||||
|
pending_count: number | null
|
||||||
|
reassigned_count: number | null
|
||||||
|
submission_type: string | null
|
||||||
|
}
|
||||||
|
Relationships: []
|
||||||
|
}
|
||||||
}
|
}
|
||||||
Functions: {
|
Functions: {
|
||||||
calculate_submission_priority: {
|
calculate_submission_priority: {
|
||||||
@@ -2218,6 +2230,14 @@ export type Database = {
|
|||||||
Args: Record<PropertyKey, never>
|
Args: Record<PropertyKey, never>
|
||||||
Returns: undefined
|
Returns: undefined
|
||||||
}
|
}
|
||||||
|
extend_submission_lock: {
|
||||||
|
Args: {
|
||||||
|
extension_duration?: unknown
|
||||||
|
moderator_id: string
|
||||||
|
submission_id: string
|
||||||
|
}
|
||||||
|
Returns: string
|
||||||
|
}
|
||||||
extract_cf_image_id: {
|
extract_cf_image_id: {
|
||||||
Args: { url: string }
|
Args: { url: string }
|
||||||
Returns: string
|
Returns: string
|
||||||
@@ -2278,6 +2298,14 @@ export type Database = {
|
|||||||
Args: Record<PropertyKey, never>
|
Args: Record<PropertyKey, never>
|
||||||
Returns: undefined
|
Returns: undefined
|
||||||
}
|
}
|
||||||
|
release_expired_locks: {
|
||||||
|
Args: Record<PropertyKey, never>
|
||||||
|
Returns: number
|
||||||
|
}
|
||||||
|
release_submission_lock: {
|
||||||
|
Args: { moderator_id: string; submission_id: string }
|
||||||
|
Returns: boolean
|
||||||
|
}
|
||||||
update_company_ratings: {
|
update_company_ratings: {
|
||||||
Args: { target_company_id: string }
|
Args: { target_company_id: string }
|
||||||
Returns: undefined
|
Returns: undefined
|
||||||
|
|||||||
@@ -0,0 +1,86 @@
|
|||||||
|
-- Function to release submission lock
|
||||||
|
CREATE OR REPLACE FUNCTION release_submission_lock(
|
||||||
|
submission_id UUID,
|
||||||
|
moderator_id UUID
|
||||||
|
) RETURNS BOOLEAN
|
||||||
|
LANGUAGE plpgsql
|
||||||
|
SECURITY DEFINER
|
||||||
|
SET search_path = public
|
||||||
|
AS $$
|
||||||
|
BEGIN
|
||||||
|
UPDATE content_submissions
|
||||||
|
SET
|
||||||
|
assigned_to = NULL,
|
||||||
|
assigned_at = NULL,
|
||||||
|
locked_until = NULL
|
||||||
|
WHERE id = submission_id
|
||||||
|
AND assigned_to = moderator_id;
|
||||||
|
|
||||||
|
RETURN FOUND;
|
||||||
|
END;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- Function to extend submission lock
|
||||||
|
CREATE OR REPLACE FUNCTION extend_submission_lock(
|
||||||
|
submission_id UUID,
|
||||||
|
moderator_id UUID,
|
||||||
|
extension_duration INTERVAL DEFAULT '15 minutes'
|
||||||
|
) RETURNS TIMESTAMP WITH TIME ZONE
|
||||||
|
LANGUAGE plpgsql
|
||||||
|
SECURITY DEFINER
|
||||||
|
SET search_path = public
|
||||||
|
AS $$
|
||||||
|
DECLARE
|
||||||
|
new_lock_time TIMESTAMP WITH TIME ZONE;
|
||||||
|
BEGIN
|
||||||
|
UPDATE content_submissions
|
||||||
|
SET locked_until = NOW() + extension_duration
|
||||||
|
WHERE id = submission_id
|
||||||
|
AND assigned_to = moderator_id
|
||||||
|
RETURNING locked_until INTO new_lock_time;
|
||||||
|
|
||||||
|
RETURN new_lock_time;
|
||||||
|
END;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- Function to auto-release expired locks
|
||||||
|
CREATE OR REPLACE FUNCTION release_expired_locks()
|
||||||
|
RETURNS INTEGER
|
||||||
|
LANGUAGE plpgsql
|
||||||
|
SECURITY DEFINER
|
||||||
|
SET search_path = public
|
||||||
|
AS $$
|
||||||
|
DECLARE
|
||||||
|
released_count INTEGER;
|
||||||
|
BEGIN
|
||||||
|
UPDATE content_submissions
|
||||||
|
SET
|
||||||
|
assigned_to = NULL,
|
||||||
|
assigned_at = NULL,
|
||||||
|
locked_until = NULL,
|
||||||
|
review_count = review_count + 1
|
||||||
|
WHERE locked_until < NOW()
|
||||||
|
AND assigned_to IS NOT NULL
|
||||||
|
AND status IN ('pending', 'partially_approved');
|
||||||
|
|
||||||
|
GET DIAGNOSTICS released_count = ROW_COUNT;
|
||||||
|
RETURN released_count;
|
||||||
|
END;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- View for SLA monitoring and queue metrics
|
||||||
|
CREATE OR REPLACE VIEW moderation_sla_metrics AS
|
||||||
|
SELECT
|
||||||
|
submission_type,
|
||||||
|
COUNT(*) FILTER (WHERE status IN ('pending', 'partially_approved')) as pending_count,
|
||||||
|
AVG(EXTRACT(EPOCH FROM (NOW() - submitted_at))/3600) FILTER (WHERE status IN ('pending', 'partially_approved')) as avg_wait_hours,
|
||||||
|
MAX(EXTRACT(EPOCH FROM (NOW() - submitted_at))/3600) FILTER (WHERE status IN ('pending', 'partially_approved')) as max_wait_hours,
|
||||||
|
AVG(EXTRACT(EPOCH FROM (resolved_at - submitted_at))/3600) FILTER (WHERE status IN ('approved', 'rejected')) as avg_resolution_hours,
|
||||||
|
COUNT(*) FILTER (WHERE escalated = true AND status IN ('pending', 'partially_approved')) as escalated_count,
|
||||||
|
COUNT(*) FILTER (WHERE review_count > 1) as reassigned_count,
|
||||||
|
COUNT(*) FILTER (WHERE assigned_to IS NOT NULL AND locked_until > NOW()) as currently_locked
|
||||||
|
FROM content_submissions
|
||||||
|
GROUP BY submission_type;
|
||||||
|
|
||||||
|
-- Grant necessary permissions
|
||||||
|
GRANT SELECT ON moderation_sla_metrics TO authenticated;
|
||||||
Reference in New Issue
Block a user