feat: 🎉 postgresql broker first commit of forked prototype from my original code
This commit is contained in:
13
pkg/broker/install/sql/procedures/00_install.sql
Normal file
13
pkg/broker/install/sql/procedures/00_install.sql
Normal file
@@ -0,0 +1,13 @@
|
||||
-- PostgreSQL Broker Procedures Installation Script
|
||||
-- Run this script to create all required stored procedures
|
||||
|
||||
\echo 'Installing PostgreSQL Broker procedures...'
|
||||
|
||||
\i 01_broker_get.sql
|
||||
\i 02_broker_run.sql
|
||||
\i 03_broker_set.sql
|
||||
\i 04_broker_register_instance.sql
|
||||
\i 05_broker_add_job.sql
|
||||
\i 06_broker_ping_instance.sql
|
||||
|
||||
\echo 'PostgreSQL Broker procedures installed successfully!'
|
||||
76
pkg/broker/install/sql/procedures/01_broker_get.sql
Normal file
76
pkg/broker/install/sql/procedures/01_broker_get.sql
Normal file
@@ -0,0 +1,76 @@
|
||||
-- broker_get function
|
||||
-- Fetches the next job from the queue for a given queue number
|
||||
-- Returns: p_retval (0=success, >0=error), p_errmsg (error message), p_job_id (job ID if found)
|
||||
|
||||
CREATE OR REPLACE FUNCTION broker_get(
|
||||
p_queue_number INTEGER,
|
||||
p_instance_id BIGINT DEFAULT NULL,
|
||||
OUT p_retval INTEGER,
|
||||
OUT p_errmsg TEXT,
|
||||
OUT p_job_id BIGINT
|
||||
)
|
||||
RETURNS RECORD
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE
|
||||
v_job_record RECORD;
|
||||
BEGIN
|
||||
p_retval := 0;
|
||||
p_errmsg := '';
|
||||
p_job_id := NULL;
|
||||
|
||||
-- Validate queue number
|
||||
IF p_queue_number IS NULL OR p_queue_number <= 0 THEN
|
||||
p_retval := 1;
|
||||
p_errmsg := 'Invalid queue number';
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Find and lock the next pending job for this queue
|
||||
-- Uses SKIP LOCKED to avoid blocking on jobs being processed by other workers
|
||||
-- Skip jobs with pending dependencies
|
||||
SELECT id_broker_jobs, job_name, job_priority, execute_str
|
||||
INTO v_job_record
|
||||
FROM broker_jobs
|
||||
WHERE job_queue = p_queue_number
|
||||
AND complete_status = 0 -- pending
|
||||
AND (
|
||||
depends_on IS NULL -- no dependencies
|
||||
OR depends_on = '{}' -- empty dependencies
|
||||
OR NOT EXISTS ( -- all dependencies completed
|
||||
SELECT 1
|
||||
FROM broker_jobs dep
|
||||
WHERE dep.job_name = ANY(broker_jobs.depends_on)
|
||||
AND dep.complete_status = 0 -- pending dependency
|
||||
)
|
||||
)
|
||||
ORDER BY job_priority DESC, created_at ASC
|
||||
LIMIT 1
|
||||
FOR UPDATE SKIP LOCKED;
|
||||
|
||||
-- If no job found, return success with NULL job_id
|
||||
IF NOT FOUND THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Update job status to running
|
||||
UPDATE broker_jobs
|
||||
SET complete_status = 1, -- running
|
||||
started_at = NOW(),
|
||||
rid_broker_queueinstance = p_instance_id,
|
||||
updated_at = NOW()
|
||||
WHERE id_broker_jobs = v_job_record.id_broker_jobs;
|
||||
|
||||
-- Return the job ID
|
||||
p_job_id := v_job_record.id_broker_jobs;
|
||||
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
p_retval := 2;
|
||||
p_errmsg := SQLERRM;
|
||||
RAISE WARNING 'broker_get error: %', SQLERRM;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Comments
|
||||
COMMENT ON FUNCTION broker_get IS 'Fetches the next pending job from the specified queue';
|
||||
113
pkg/broker/install/sql/procedures/02_broker_run.sql
Normal file
113
pkg/broker/install/sql/procedures/02_broker_run.sql
Normal file
@@ -0,0 +1,113 @@
|
||||
-- broker_run function
|
||||
-- Executes a job by its ID
|
||||
-- Returns: p_retval (0=success, >0=error), p_errmsg (error message)
|
||||
|
||||
CREATE OR REPLACE FUNCTION broker_run(
|
||||
p_job_id BIGINT,
|
||||
OUT p_retval INTEGER,
|
||||
OUT p_errmsg TEXT
|
||||
)
|
||||
RETURNS RECORD
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE
|
||||
v_job_record RECORD;
|
||||
v_execute_result TEXT;
|
||||
v_error_occurred BOOLEAN := false;
|
||||
BEGIN
|
||||
p_retval := 0;
|
||||
p_errmsg := '';
|
||||
v_execute_result := '';
|
||||
|
||||
-- Validate job ID
|
||||
IF p_job_id IS NULL OR p_job_id <= 0 THEN
|
||||
p_retval := 1;
|
||||
p_errmsg := 'Invalid job ID';
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Get job details
|
||||
SELECT id_broker_jobs, execute_str, job_language, run_as, complete_status
|
||||
INTO v_job_record
|
||||
FROM broker_jobs
|
||||
WHERE id_broker_jobs = p_job_id
|
||||
FOR UPDATE;
|
||||
|
||||
-- Check if job exists
|
||||
IF NOT FOUND THEN
|
||||
p_retval := 2;
|
||||
p_errmsg := 'Job not found';
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Check if job is in running state
|
||||
IF v_job_record.complete_status != 1 THEN
|
||||
p_retval := 3;
|
||||
p_errmsg := format('Job is not in running state (status: %s)', v_job_record.complete_status);
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Execute the job
|
||||
BEGIN
|
||||
-- For SQL/PLPGSQL jobs, execute directly
|
||||
IF v_job_record.job_language IN ('sql', 'plpgsql') THEN
|
||||
EXECUTE v_job_record.execute_str;
|
||||
v_execute_result := 'Success';
|
||||
ELSE
|
||||
-- Other languages would need external execution
|
||||
p_retval := 4;
|
||||
p_errmsg := format('Unsupported job language: %s', v_job_record.job_language);
|
||||
v_error_occurred := true;
|
||||
END IF;
|
||||
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
v_error_occurred := true;
|
||||
p_retval := 5;
|
||||
p_errmsg := SQLERRM;
|
||||
v_execute_result := format('Error: %s', SQLERRM);
|
||||
END;
|
||||
|
||||
-- Update job with results
|
||||
IF v_error_occurred THEN
|
||||
UPDATE broker_jobs
|
||||
SET complete_status = 3, -- failed
|
||||
error_msg = p_errmsg,
|
||||
execute_result = v_execute_result,
|
||||
completed_at = NOW(),
|
||||
updated_at = NOW()
|
||||
WHERE id_broker_jobs = p_job_id;
|
||||
ELSE
|
||||
UPDATE broker_jobs
|
||||
SET complete_status = 2, -- completed
|
||||
execute_result = v_execute_result,
|
||||
error_msg = NULL,
|
||||
completed_at = NOW(),
|
||||
updated_at = NOW()
|
||||
WHERE id_broker_jobs = p_job_id;
|
||||
END IF;
|
||||
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
p_retval := 6;
|
||||
p_errmsg := SQLERRM;
|
||||
RAISE WARNING 'broker_run error: %', SQLERRM;
|
||||
|
||||
-- Try to update job status to failed
|
||||
BEGIN
|
||||
UPDATE broker_jobs
|
||||
SET complete_status = 3, -- failed
|
||||
error_msg = SQLERRM,
|
||||
completed_at = NOW(),
|
||||
updated_at = NOW()
|
||||
WHERE id_broker_jobs = p_job_id;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
-- Ignore update errors
|
||||
NULL;
|
||||
END;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Comments
|
||||
COMMENT ON FUNCTION broker_run IS 'Executes a job by its ID and updates the status';
|
||||
95
pkg/broker/install/sql/procedures/03_broker_set.sql
Normal file
95
pkg/broker/install/sql/procedures/03_broker_set.sql
Normal file
@@ -0,0 +1,95 @@
|
||||
-- broker_set function
|
||||
-- Sets broker runtime options and context
|
||||
-- Supports: user, application_name, and custom settings
|
||||
-- Returns: p_retval (0=success, >0=error), p_errmsg (error message)
|
||||
|
||||
CREATE OR REPLACE FUNCTION broker_set(
|
||||
p_option_name TEXT,
|
||||
p_option_value TEXT,
|
||||
OUT p_retval INTEGER,
|
||||
OUT p_errmsg TEXT
|
||||
)
|
||||
RETURNS RECORD
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE
|
||||
v_sql TEXT;
|
||||
BEGIN
|
||||
p_retval := 0;
|
||||
p_errmsg := '';
|
||||
|
||||
-- Validate inputs
|
||||
IF p_option_name IS NULL OR p_option_name = '' THEN
|
||||
p_retval := 1;
|
||||
p_errmsg := 'Option name is required';
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Handle different option types
|
||||
CASE LOWER(p_option_name)
|
||||
WHEN 'user' THEN
|
||||
-- Set session user context
|
||||
-- This is useful for audit trails and permissions
|
||||
BEGIN
|
||||
v_sql := format('SET SESSION AUTHORIZATION %I', p_option_value);
|
||||
EXECUTE v_sql;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
p_retval := 2;
|
||||
p_errmsg := format('Failed to set user: %s', SQLERRM);
|
||||
RETURN;
|
||||
END;
|
||||
|
||||
WHEN 'application_name' THEN
|
||||
-- Set application name (visible in pg_stat_activity)
|
||||
BEGIN
|
||||
v_sql := format('SET application_name TO %L', p_option_value);
|
||||
EXECUTE v_sql;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
p_retval := 3;
|
||||
p_errmsg := format('Failed to set application_name: %s', SQLERRM);
|
||||
RETURN;
|
||||
END;
|
||||
|
||||
WHEN 'search_path' THEN
|
||||
-- Set schema search path
|
||||
BEGIN
|
||||
v_sql := format('SET search_path TO %s', p_option_value);
|
||||
EXECUTE v_sql;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
p_retval := 4;
|
||||
p_errmsg := format('Failed to set search_path: %s', SQLERRM);
|
||||
RETURN;
|
||||
END;
|
||||
|
||||
WHEN 'timezone' THEN
|
||||
-- Set timezone
|
||||
BEGIN
|
||||
v_sql := format('SET timezone TO %L', p_option_value);
|
||||
EXECUTE v_sql;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
p_retval := 5;
|
||||
p_errmsg := format('Failed to set timezone: %s', SQLERRM);
|
||||
RETURN;
|
||||
END;
|
||||
|
||||
ELSE
|
||||
-- Unknown option
|
||||
p_retval := 10;
|
||||
p_errmsg := format('Unknown option: %s', p_option_name);
|
||||
RETURN;
|
||||
END CASE;
|
||||
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
p_retval := 99;
|
||||
p_errmsg := SQLERRM;
|
||||
RAISE WARNING 'broker_set error: %', SQLERRM;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Comments
|
||||
COMMENT ON FUNCTION broker_set IS 'Sets broker runtime options and session context (user, application_name, search_path, timezone)';
|
||||
@@ -0,0 +1,82 @@
|
||||
-- broker_register_instance function
|
||||
-- Registers a new broker instance in the database
|
||||
-- Returns: p_retval (0=success, >0=error), p_errmsg (error message), p_instance_id (new instance ID)
|
||||
|
||||
CREATE OR REPLACE FUNCTION broker_register_instance(
|
||||
p_name TEXT,
|
||||
p_hostname TEXT,
|
||||
p_pid INTEGER,
|
||||
p_version TEXT,
|
||||
p_queue_count INTEGER,
|
||||
OUT p_retval INTEGER,
|
||||
OUT p_errmsg TEXT,
|
||||
OUT p_instance_id BIGINT
|
||||
)
|
||||
RETURNS RECORD
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE
|
||||
v_active_count INTEGER;
|
||||
BEGIN
|
||||
p_retval := 0;
|
||||
p_errmsg := '';
|
||||
p_instance_id := NULL;
|
||||
|
||||
-- Validate inputs
|
||||
IF p_name IS NULL OR p_name = '' THEN
|
||||
p_retval := 1;
|
||||
p_errmsg := 'Instance name is required';
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
IF p_hostname IS NULL OR p_hostname = '' THEN
|
||||
p_retval := 2;
|
||||
p_errmsg := 'Hostname is required';
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Check for existing active instances
|
||||
-- Only one broker instance should be active per database
|
||||
SELECT COUNT(*)
|
||||
INTO v_active_count
|
||||
FROM broker_queueinstance
|
||||
WHERE status = 'active';
|
||||
|
||||
IF v_active_count > 0 THEN
|
||||
p_retval := 3;
|
||||
p_errmsg := 'Another broker instance is already active in this database. Only one broker instance per database is allowed.';
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Insert new instance
|
||||
INSERT INTO broker_queueinstance (
|
||||
name,
|
||||
hostname,
|
||||
pid,
|
||||
version,
|
||||
status,
|
||||
queue_count,
|
||||
started_at,
|
||||
last_ping_at
|
||||
) VALUES (
|
||||
p_name,
|
||||
p_hostname,
|
||||
p_pid,
|
||||
p_version,
|
||||
'active',
|
||||
p_queue_count,
|
||||
NOW(),
|
||||
NOW()
|
||||
)
|
||||
RETURNING id_broker_queueinstance INTO p_instance_id;
|
||||
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
p_retval := 99;
|
||||
p_errmsg := SQLERRM;
|
||||
RAISE WARNING 'broker_register_instance error: %', SQLERRM;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Comments
|
||||
COMMENT ON FUNCTION broker_register_instance IS 'Registers a new broker instance';
|
||||
91
pkg/broker/install/sql/procedures/05_broker_add_job.sql
Normal file
91
pkg/broker/install/sql/procedures/05_broker_add_job.sql
Normal file
@@ -0,0 +1,91 @@
|
||||
-- broker_add_job function
|
||||
-- Adds a new job to the broker queue and sends a notification
|
||||
-- Returns: p_retval (0=success, >0=error), p_errmsg (error message), p_job_id (new job ID)
|
||||
|
||||
CREATE OR REPLACE FUNCTION broker_add_job(
|
||||
p_job_name TEXT,
|
||||
p_execute_str TEXT,
|
||||
p_job_queue INTEGER DEFAULT 1,
|
||||
p_job_priority INTEGER DEFAULT 0,
|
||||
p_job_language TEXT DEFAULT 'sql',
|
||||
p_run_as TEXT DEFAULT NULL,
|
||||
p_schedule_id BIGINT DEFAULT NULL,
|
||||
p_depends_on TEXT[] DEFAULT NULL,
|
||||
OUT p_retval INTEGER,
|
||||
OUT p_errmsg TEXT,
|
||||
OUT p_job_id BIGINT
|
||||
)
|
||||
RETURNS RECORD
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE
|
||||
v_notification_payload JSON;
|
||||
BEGIN
|
||||
p_retval := 0;
|
||||
p_errmsg := '';
|
||||
p_job_id := NULL;
|
||||
|
||||
-- Validate inputs
|
||||
IF p_job_name IS NULL OR p_job_name = '' THEN
|
||||
p_retval := 1;
|
||||
p_errmsg := 'Job name is required';
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
IF p_execute_str IS NULL OR p_execute_str = '' THEN
|
||||
p_retval := 2;
|
||||
p_errmsg := 'Execute string is required';
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
IF p_job_queue IS NULL OR p_job_queue <= 0 THEN
|
||||
p_retval := 3;
|
||||
p_errmsg := 'Invalid job queue number';
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Insert new job
|
||||
INSERT INTO broker_jobs (
|
||||
job_name,
|
||||
job_priority,
|
||||
job_queue,
|
||||
job_language,
|
||||
execute_str,
|
||||
run_as,
|
||||
rid_broker_schedule,
|
||||
depends_on,
|
||||
complete_status
|
||||
) VALUES (
|
||||
p_job_name,
|
||||
p_job_priority,
|
||||
p_job_queue,
|
||||
p_job_language,
|
||||
p_execute_str,
|
||||
p_run_as,
|
||||
p_schedule_id,
|
||||
p_depends_on,
|
||||
0 -- pending
|
||||
)
|
||||
RETURNING id_broker_jobs INTO p_job_id;
|
||||
|
||||
-- Create notification payload
|
||||
v_notification_payload := json_build_object(
|
||||
'id', p_job_id,
|
||||
'job_name', p_job_name,
|
||||
'job_queue', p_job_queue,
|
||||
'job_priority', p_job_priority
|
||||
);
|
||||
|
||||
-- Send notification to broker
|
||||
PERFORM pg_notify('broker.event', v_notification_payload::text);
|
||||
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
p_retval := 99;
|
||||
p_errmsg := SQLERRM;
|
||||
RAISE WARNING 'broker_add_job error: %', SQLERRM;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Comments
|
||||
COMMENT ON FUNCTION broker_add_job IS 'Adds a new job to the broker queue and sends a NOTIFY event';
|
||||
@@ -0,0 +1,98 @@
|
||||
-- broker_ping_instance function
|
||||
-- Updates the last_ping_at timestamp for a broker instance
|
||||
-- Returns: p_retval (0=success, >0=error), p_errmsg (error message)
|
||||
|
||||
CREATE OR REPLACE FUNCTION broker_ping_instance(
|
||||
p_instance_id BIGINT,
|
||||
p_jobs_handled BIGINT DEFAULT NULL,
|
||||
OUT p_retval INTEGER,
|
||||
OUT p_errmsg TEXT
|
||||
)
|
||||
RETURNS RECORD
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
p_retval := 0;
|
||||
p_errmsg := '';
|
||||
|
||||
-- Validate instance ID
|
||||
IF p_instance_id IS NULL OR p_instance_id <= 0 THEN
|
||||
p_retval := 1;
|
||||
p_errmsg := 'Invalid instance ID';
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Update ping timestamp
|
||||
IF p_jobs_handled IS NOT NULL THEN
|
||||
UPDATE broker_queueinstance
|
||||
SET last_ping_at = NOW(),
|
||||
jobs_handled = p_jobs_handled
|
||||
WHERE id_broker_queueinstance = p_instance_id;
|
||||
ELSE
|
||||
UPDATE broker_queueinstance
|
||||
SET last_ping_at = NOW()
|
||||
WHERE id_broker_queueinstance = p_instance_id;
|
||||
END IF;
|
||||
|
||||
-- Check if instance was found
|
||||
IF NOT FOUND THEN
|
||||
p_retval := 2;
|
||||
p_errmsg := 'Instance not found';
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
p_retval := 99;
|
||||
p_errmsg := SQLERRM;
|
||||
RAISE WARNING 'broker_ping_instance error: %', SQLERRM;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- broker_shutdown_instance function
|
||||
-- Marks a broker instance as shutdown
|
||||
-- Returns: p_retval (0=success, >0=error), p_errmsg (error message)
|
||||
|
||||
CREATE OR REPLACE FUNCTION broker_shutdown_instance(
|
||||
p_instance_id BIGINT,
|
||||
OUT p_retval INTEGER,
|
||||
OUT p_errmsg TEXT
|
||||
)
|
||||
RETURNS RECORD
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
BEGIN
|
||||
p_retval := 0;
|
||||
p_errmsg := '';
|
||||
|
||||
-- Validate instance ID
|
||||
IF p_instance_id IS NULL OR p_instance_id <= 0 THEN
|
||||
p_retval := 1;
|
||||
p_errmsg := 'Invalid instance ID';
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Update instance status
|
||||
UPDATE broker_queueinstance
|
||||
SET status = 'shutdown',
|
||||
shutdown_at = NOW()
|
||||
WHERE id_broker_queueinstance = p_instance_id;
|
||||
|
||||
-- Check if instance was found
|
||||
IF NOT FOUND THEN
|
||||
p_retval := 2;
|
||||
p_errmsg := 'Instance not found';
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
p_retval := 99;
|
||||
p_errmsg := SQLERRM;
|
||||
RAISE WARNING 'broker_shutdown_instance error: %', SQLERRM;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Comments
|
||||
COMMENT ON FUNCTION broker_ping_instance IS 'Updates the last ping timestamp for an instance';
|
||||
COMMENT ON FUNCTION broker_shutdown_instance IS 'Marks an instance as shutdown';
|
||||
10
pkg/broker/install/sql/tables/00_install.sql
Normal file
10
pkg/broker/install/sql/tables/00_install.sql
Normal file
@@ -0,0 +1,10 @@
|
||||
-- PostgreSQL Broker Tables Installation Script
|
||||
-- Run this script to create all required tables
|
||||
|
||||
\echo 'Installing PostgreSQL Broker tables...'
|
||||
|
||||
\i 01_broker_queueinstance.sql
|
||||
\i 03_broker_schedule.sql
|
||||
\i 02_broker_jobs.sql
|
||||
|
||||
\echo 'PostgreSQL Broker tables installed successfully!'
|
||||
31
pkg/broker/install/sql/tables/01_broker_queueinstance.sql
Normal file
31
pkg/broker/install/sql/tables/01_broker_queueinstance.sql
Normal file
@@ -0,0 +1,31 @@
|
||||
-- broker_queueinstance table
|
||||
-- Tracks active and historical broker queue instances
|
||||
|
||||
CREATE TABLE IF NOT EXISTS broker_queueinstance (
|
||||
id_broker_queueinstance BIGSERIAL PRIMARY KEY,
|
||||
name VARCHAR(255) NOT NULL,
|
||||
hostname VARCHAR(255) NOT NULL,
|
||||
pid INTEGER NOT NULL,
|
||||
version VARCHAR(50) NOT NULL,
|
||||
status VARCHAR(20) NOT NULL DEFAULT 'active',
|
||||
started_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
last_ping_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
shutdown_at TIMESTAMP WITH TIME ZONE,
|
||||
queue_count INTEGER NOT NULL DEFAULT 0,
|
||||
jobs_handled BIGINT NOT NULL DEFAULT 0,
|
||||
|
||||
CONSTRAINT broker_queueinstance_status_check CHECK (status IN ('active', 'inactive', 'shutdown'))
|
||||
);
|
||||
|
||||
-- Indexes
|
||||
CREATE INDEX IF NOT EXISTS idx_broker_queueinstance_status ON broker_queueinstance(status);
|
||||
CREATE INDEX IF NOT EXISTS idx_broker_queueinstance_hostname ON broker_queueinstance(hostname);
|
||||
CREATE INDEX IF NOT EXISTS idx_broker_queueinstance_last_ping ON broker_queueinstance(last_ping_at);
|
||||
|
||||
-- Comments
|
||||
COMMENT ON TABLE broker_queueinstance IS 'Tracks broker queue instances (active and historical)';
|
||||
COMMENT ON COLUMN broker_queueinstance.name IS 'Human-readable name of the broker instance';
|
||||
COMMENT ON COLUMN broker_queueinstance.hostname IS 'Hostname where the broker is running';
|
||||
COMMENT ON COLUMN broker_queueinstance.pid IS 'Process ID of the broker';
|
||||
COMMENT ON COLUMN broker_queueinstance.status IS 'Current status: active, inactive, or shutdown';
|
||||
COMMENT ON COLUMN broker_queueinstance.jobs_handled IS 'Total number of jobs handled by this instance';
|
||||
62
pkg/broker/install/sql/tables/02_broker_jobs.sql
Normal file
62
pkg/broker/install/sql/tables/02_broker_jobs.sql
Normal file
@@ -0,0 +1,62 @@
|
||||
-- broker_jobs table
|
||||
-- Stores jobs to be executed by the broker
|
||||
|
||||
CREATE TABLE IF NOT EXISTS broker_jobs (
|
||||
id_broker_jobs BIGSERIAL PRIMARY KEY,
|
||||
job_name VARCHAR(255) NOT NULL,
|
||||
job_priority INTEGER NOT NULL DEFAULT 0,
|
||||
job_queue INTEGER NOT NULL DEFAULT 1,
|
||||
job_language VARCHAR(50) NOT NULL DEFAULT 'sql',
|
||||
execute_str TEXT NOT NULL,
|
||||
execute_result TEXT,
|
||||
error_msg TEXT,
|
||||
complete_status INTEGER NOT NULL DEFAULT 0,
|
||||
run_as VARCHAR(100),
|
||||
rid_broker_schedule BIGINT,
|
||||
rid_broker_queueinstance BIGINT,
|
||||
depends_on TEXT[],
|
||||
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
started_at TIMESTAMP WITH TIME ZONE,
|
||||
completed_at TIMESTAMP WITH TIME ZONE,
|
||||
|
||||
CONSTRAINT broker_jobs_complete_status_check CHECK (complete_status IN (0, 1, 2, 3, 4)),
|
||||
CONSTRAINT broker_jobs_job_queue_check CHECK (job_queue > 0),
|
||||
CONSTRAINT fk_schedule FOREIGN KEY (rid_broker_schedule) REFERENCES broker_schedule(id_broker_schedule) ON DELETE SET NULL,
|
||||
CONSTRAINT fk_instance FOREIGN KEY (rid_broker_queueinstance) REFERENCES broker_queueinstance(id_broker_queueinstance) ON DELETE SET NULL
|
||||
);
|
||||
|
||||
-- Indexes
|
||||
CREATE INDEX IF NOT EXISTS idx_broker_jobs_status ON broker_jobs(complete_status);
|
||||
CREATE INDEX IF NOT EXISTS idx_broker_jobs_queue ON broker_jobs(job_queue, complete_status, job_priority);
|
||||
CREATE INDEX IF NOT EXISTS idx_broker_jobs_schedule ON broker_jobs(rid_broker_schedule);
|
||||
CREATE INDEX IF NOT EXISTS idx_broker_jobs_instance ON broker_jobs(rid_broker_queueinstance);
|
||||
CREATE INDEX IF NOT EXISTS idx_broker_jobs_created ON broker_jobs(created_at);
|
||||
CREATE INDEX IF NOT EXISTS idx_broker_jobs_name ON broker_jobs(job_name, complete_status);
|
||||
|
||||
-- Comments
|
||||
COMMENT ON TABLE broker_jobs IS 'Job queue for broker execution';
|
||||
COMMENT ON COLUMN broker_jobs.job_name IS 'Name/description of the job';
|
||||
COMMENT ON COLUMN broker_jobs.job_priority IS 'Job priority (higher = more important)';
|
||||
COMMENT ON COLUMN broker_jobs.job_queue IS 'Queue number (allows parallel processing)';
|
||||
COMMENT ON COLUMN broker_jobs.job_language IS 'Execution language (sql, plpgsql, etc.)';
|
||||
COMMENT ON COLUMN broker_jobs.execute_str IS 'SQL or code to execute';
|
||||
COMMENT ON COLUMN broker_jobs.complete_status IS '0=pending, 1=running, 2=completed, 3=failed, 4=cancelled';
|
||||
COMMENT ON COLUMN broker_jobs.run_as IS 'User context to run the job as';
|
||||
COMMENT ON COLUMN broker_jobs.rid_broker_schedule IS 'Reference to schedule if job was scheduled';
|
||||
COMMENT ON COLUMN broker_jobs.rid_broker_queueinstance IS 'Instance that processed this job';
|
||||
COMMENT ON COLUMN broker_jobs.depends_on IS 'Array of job names that must be completed before this job can run';
|
||||
|
||||
-- Trigger to update updated_at
|
||||
CREATE OR REPLACE FUNCTION tf_broker_jobs_update_timestamp()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated_at = NOW();
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE TRIGGER t_broker_jobs_updated_at
|
||||
BEFORE UPDATE ON broker_jobs
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION tf_broker_jobs_update_timestamp();
|
||||
50
pkg/broker/install/sql/tables/03_broker_schedule.sql
Normal file
50
pkg/broker/install/sql/tables/03_broker_schedule.sql
Normal file
@@ -0,0 +1,50 @@
|
||||
-- broker_schedule table
|
||||
-- Stores scheduled jobs (cron-like functionality)
|
||||
|
||||
CREATE TABLE IF NOT EXISTS broker_schedule (
|
||||
id_broker_schedule BIGSERIAL PRIMARY KEY,
|
||||
name VARCHAR(255) NOT NULL UNIQUE,
|
||||
cron_expr VARCHAR(100) NOT NULL,
|
||||
enabled BOOLEAN NOT NULL DEFAULT true,
|
||||
job_name VARCHAR(255) NOT NULL,
|
||||
job_priority INTEGER NOT NULL DEFAULT 0,
|
||||
job_queue INTEGER NOT NULL DEFAULT 1,
|
||||
job_language VARCHAR(50) NOT NULL DEFAULT 'sql',
|
||||
execute_str TEXT NOT NULL,
|
||||
run_as VARCHAR(100),
|
||||
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
last_run_at TIMESTAMP WITH TIME ZONE,
|
||||
next_run_at TIMESTAMP WITH TIME ZONE,
|
||||
|
||||
CONSTRAINT broker_schedule_job_queue_check CHECK (job_queue > 0)
|
||||
);
|
||||
|
||||
-- Indexes
|
||||
CREATE INDEX IF NOT EXISTS idx_broker_schedule_enabled ON broker_schedule(enabled);
|
||||
CREATE INDEX IF NOT EXISTS idx_broker_schedule_next_run ON broker_schedule(next_run_at) WHERE enabled = true;
|
||||
CREATE INDEX IF NOT EXISTS idx_broker_schedule_name ON broker_schedule(name);
|
||||
|
||||
-- Comments
|
||||
COMMENT ON TABLE broker_schedule IS 'Scheduled jobs (cron-like functionality)';
|
||||
COMMENT ON COLUMN broker_schedule.name IS 'Unique name for the schedule';
|
||||
COMMENT ON COLUMN broker_schedule.cron_expr IS 'Cron expression for scheduling';
|
||||
COMMENT ON COLUMN broker_schedule.enabled IS 'Whether the schedule is active';
|
||||
COMMENT ON COLUMN broker_schedule.job_name IS 'Name of the job to create';
|
||||
COMMENT ON COLUMN broker_schedule.execute_str IS 'SQL or code to execute';
|
||||
COMMENT ON COLUMN broker_schedule.last_run_at IS 'Last time the job was executed';
|
||||
COMMENT ON COLUMN broker_schedule.next_run_at IS 'Next scheduled execution time';
|
||||
|
||||
-- Trigger to update updated_at
|
||||
CREATE OR REPLACE FUNCTION tf_broker_schedule_update_timestamp()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated_at = NOW();
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE TRIGGER t_broker_schedule_updated_at
|
||||
BEFORE UPDATE ON broker_schedule
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION tf_broker_schedule_update_timestamp();
|
||||
Reference in New Issue
Block a user