Skip to content

Commit

Permalink
Created job_log_clear() function to clear log data previous to a give…
Browse files Browse the repository at this point in the history
…n interval. Logs it too! Made foreign key in job_detail ON DELETE CASCADE.
  • Loading branch information
keithf4 committed Aug 3, 2012
1 parent 1022a48 commit ebb0469
Show file tree
Hide file tree
Showing 3 changed files with 97 additions and 1 deletion.
4 changes: 4 additions & 0 deletions doc/pg_jobmon.md
Expand Up @@ -41,6 +41,10 @@ LOGGING
p_sql is the full sql query to be run.
Returns the job id that was created for this job and whether the job was successful.

*job_log_clear(p_interval interval) RETURNS void*
Deletes all jobs in job_log and job_detail tables older than the given interval.
Also logs this task as another job itself.

The below functions all return full rows of the format for the given SETOF table, which means you can treat them as tables as far as filtering the result. For all functions that have a default integer parameter at the end, this signifies a default limit on the number of rows returned. You can change this as desired, or just leave out that parameter to get the default limit.
All show functions also automatically uppercase the job name parameter to be consistent with the add_job function.

Expand Down
47 changes: 46 additions & 1 deletion sql/pg_jobmon.sql
Expand Up @@ -35,7 +35,7 @@ CREATE TABLE job_detail (
status text,
message text,
CONSTRAINT job_detail_step_id_pkey PRIMARY KEY (step_id),
CONSTRAINT job_detail_job_id_fkey FOREIGN KEY (job_id) REFERENCES job_log(job_id)
CONSTRAINT job_detail_job_id_fkey FOREIGN KEY (job_id) REFERENCES job_log(job_id) ON DELETE CASCADE
);
CREATE INDEX job_detail_job_id_idx ON job_detail (job_id);
CREATE SEQUENCE job_detail_step_id_seq
Expand Down Expand Up @@ -737,3 +737,48 @@ BEGIN
RETURN;
END
$$;


/*
* Delete jobs from job_log and job_detail table older than a given interval.
* Also logs this job purging task.
*/
CREATE FUNCTION job_log_clear(p_interval interval) RETURNS void
LANGUAGE plpgsql
AS $$
DECLARE

v_boundary timestamptz;
v_job_id bigint;
v_rowcount bigint;
v_step_id bigint;

BEGIN

v_boundary := now() - p_interval;
v_job_id := @extschema@.add_job('Purging pg_jobmon job logs older than '|| v_boundary);
v_step_id := @extschema@.add_step(v_job_id,'Purging pg_jobmon job logs older than '|| v_boundary);

DELETE FROM @extschema@.job_log WHERE start_time <= v_boundary;

GET DIAGNOSTICS v_rowcount = ROW_COUNT;
IF v_rowcount > 0 THEN
RAISE NOTICE 'Deleted % rows from job_log and associated rows in job_detail', v_rowcount;
PERFORM @extschema@.update_step(v_step_id, 'OK', 'Deleted '||v_rowcount||' rows from job_log and associated rows in job_detail');
ELSE
RAISE NOTICE 'No jobs logged older than %', v_boundary;
PERFORM @extschema@.update_step(v_step_id, 'OK', 'No jobs logged older than '|| v_boundary);
END IF;
PERFORM @extschema@.close_job(v_job_id);
RETURN;

EXCEPTION
WHEN OTHERS THEN
IF v_step_id IS NULL THEN
v_step_id := @extschema@.add_step(v_job_id, 'EXCEPTION before first step logged');
END IF;
PERFORM @extschema@.update_step(v_step_id, 'CRITICAL', 'ERROR: '||coalesce(SQLERRM,'unknown'));
PERFORM @extschema@.fail_job(v_job_id);
RAISE EXCEPTION '%', SQLERRM;
END;
$$
47 changes: 47 additions & 0 deletions updates/pg_jobmon--0.4.0--0.4.1.sql
@@ -0,0 +1,47 @@
-- Created job_log_clear() function to clear log data previous to a given interval. Logs it too!
-- Fixed job_detail table to have ON DELETE CASCADE foreign key to make this function easier to write

ALTER TABLE @extschema@.job_detail ADD CONSTRAINT job_detail_job_id_fkey_new FOREIGN KEY (job_id) REFERENCES @extschema@.job_log(job_id) NOT VALID;
ALTER TABLE @extschema@.job_detail DROP CONSTRAINT job_detail_job_id_fkey;
ALTER TABLE @extschema@.job_detail ADD CONSTRAINT job_detail_job_id_fkey FOREIGN KEY (job_id) REFERENCES @extschema@.job_log(job_id) ON DELETE CASCADE;
ALTER TABLE @extschema@.job_detail DROP CONSTRAINT job_detail_job_id_fkey_new;

CREATE FUNCTION job_log_clear(p_interval interval) RETURNS void
LANGUAGE plpgsql
AS $$
DECLARE

v_boundary timestamptz;
v_job_id bigint;
v_rowcount bigint;
v_step_id bigint;

BEGIN

v_boundary := now() - p_interval;
v_job_id := @extschema@.add_job('Purging pg_jobmon job logs older than '|| v_boundary);
v_step_id := @extschema@.add_step(v_job_id,'Purging pg_jobmon job logs older than '|| v_boundary);

DELETE FROM @extschema@.job_log WHERE start_time <= v_boundary;

GET DIAGNOSTICS v_rowcount = ROW_COUNT;
IF v_rowcount > 0 THEN
RAISE NOTICE 'Deleted % rows from job_log and associated rows in job_detail', v_rowcount;
PERFORM @extschema@.update_step(v_step_id, 'OK', 'Deleted '||v_rowcount||' rows from job_log and associated rows in job_detail');
ELSE
RAISE NOTICE 'No jobs logged older than %', v_boundary;
PERFORM @extschema@.update_step(v_step_id, 'OK', 'No jobs logged older than '|| v_boundary);
END IF;
PERFORM @extschema@.close_job(v_job_id);
RETURN;

EXCEPTION
WHEN OTHERS THEN
IF v_step_id IS NULL THEN
v_step_id := @extschema@.add_step(v_job_id, 'EXCEPTION before first step logged');
END IF;
PERFORM @extschema@.update_step(v_step_id, 'CRITICAL', 'ERROR: '||coalesce(SQLERRM,'unknown'));
PERFORM @extschema@.fail_job(v_job_id);
RAISE EXCEPTION '%', SQLERRM;
END;
$$

0 comments on commit ebb0469

Please sign in to comment.