├── ChangeLog ├── LICENSE ├── Makefile ├── README.md ├── bin └── pg_dbms_job ├── etc └── pg_dbms_job.conf ├── pg_dbms_job.control ├── sql ├── pg_dbms_job--1.0.1.sql ├── pg_dbms_job--1.2.0.sql ├── pg_dbms_job--1.3.0.sql ├── pg_dbms_job--1.4.0.sql └── pg_dbms_job--1.5.0.sql ├── t ├── 01_lint.t ├── 02_basic.t ├── 03_async.t ├── 04_signal.t ├── 05_async_error.t ├── 06_queue_interval.t ├── 07_scheduled.t ├── 08_procedures.t └── 09_run.t ├── test ├── regress_dbms_job.conf └── sql │ ├── async.sql │ ├── async_error.sql │ ├── async_queue_interval.sql │ ├── run.sql │ ├── scheduled.sql │ └── submit.sql └── updates ├── pg_dbms_job--1.0.1--1.1.0.sql ├── pg_dbms_job--1.1.0--1.2.0.sql ├── pg_dbms_job--1.2.0--1.3.0.sql ├── pg_dbms_job--1.3.0--1.4.0.sql └── pg_dbms_job--1.4.0--1.5.0.sql /ChangeLog: -------------------------------------------------------------------------------- 1 | Sun Oct 02 2022 - Version 1.5.0 2 | 3 | This release is maintenance release to fix one major issue. 4 | 5 | - Fix get_scheduled_jobs() to avoid executing already running jobs if it 6 | takes longer to complete than the frequency at which it is programmed. 7 | Thanks to Petru Ghita for the report. 8 | 9 | Tue Aug 22 2022 - Version 1.4.0 10 | 11 | This release is maintenance release to fix two major issues. 12 | 13 | - Fix function dbms_job.interval() that was not using dybnamic SQL 14 | for the UPDATE statement. Thanks to Eric-zch for the report. 15 | - Fix installation of extension's update files that was not copied 16 | in the right place. 17 | 18 | Tue Aug 16 2022 - Version 1.3.0 19 | 20 | This release is maintenance release since last release to fix issues 21 | reported by users. 22 | 23 | - Fix extension file and regression test to remove the creation of 24 | the extension's schema if it not exist per CVE-2022-2625. 25 | - Fix case where pg_dbms_job does not run job anymore after a PG 26 | restart. Thanks to longforrich for the patch. 27 | 28 | Mon Apr 11 2022 - Version 1.2.0 29 | 30 | This release is maintenance release since last release to fix issues 31 | reported by users since the past height months. It also adds some 32 | improvements. 33 | 34 | * Add configuration directive job_queue_processes to control the 35 | maximum number of job processed at the same time. 36 | * Keep entries in the jobs table to be able to monitor the duration 37 | of a task. Thank to Jagrab3 for the patch. 38 | * Allow strftime() escapes in log filename, for example to have a 39 | log file per week day use %a in the file name. 40 | * Add new configuration directive log_truncate_on_rotation to truncate file 41 | on rotation. When activated an existing log file with the same name as the 42 | new log file will be truncated rather than appended to. But such truncation 43 | only occurs on time-driven rotation, not on restarts. 44 | Thanks to K RamaKrishna Sastry for the feature request. 45 | * Allow pg_dbms_job to run on a standby server without reporting error. 46 | The daemon detects that it is running on a standby and disconnect 47 | immediately, it will try to connect 3 seconds later. Thanks to 48 | K RamaKrishna Sastry for the feature request. 49 | * Try to reconnect PostgreSQL after 3 seconds when the connection fail. 50 | Thanks to K RamaKrishna Sastry for the report. 51 | 52 | Here is the complete list of other changes: 53 | 54 | - Fix an extract comma that make the update on failure fail. 55 | - Fix single execution mode with lasted change on connection error and 56 | update regression tests configuration file. 57 | - Prevent removing the pid file if pg_dbms_job can't find the 58 | configuration file and the -k option is used. 59 | - Do not die on error when pg_dbms_job reload the configuration file. 60 | - Explain the behavior of the update done on table dbms_job.all_scheduled_jobs 61 | after a job completion when it fails or it is successful. 62 | 63 | Sat Aug 28 2021 - Version 1.1.0 64 | 65 | This release is maintenance release since last release to fix some 66 | possible wrong behaviors, control other ones and improve documentation. 67 | 68 | - Add configuration directive job_queue_processes to control the limit 69 | of jobs that can be run at the same time. 70 | - Fix insertion failure in job history table when PQSTATUS returned 71 | contains single quote. 72 | - Fix possible case where asynchronous jobs can be executed twice 73 | if they are not removed fast enough from the queue. 74 | - Fix regression test to use latest SQL version of the extension. 75 | - Add limitations on pg_dbms_job use and especially about the NOTIFY 76 | queue size limits. Thanks to Julien Rouhaud for the report. 77 | - Add missing information on how to stop or reload configuration of 78 | the scheduler. 79 | - Add information that unlike with cron-like scheduler, when the scheduler 80 | starts it executes all active jobs with a next date in the past. 81 | - Add information that jobs are executed with the role that has submitted 82 | the job and with the search path was used at job creation time. 83 | 84 | To upgrade installed pg_dbms_job version 1.0.1 execute: 85 | 86 | ALTER EXTENSION pg_dbms_job UPDATE; 87 | 88 | after installing the new version using: make && sudo make install 89 | 90 | 91 | Wed Aug 25 2021: Version 1.0.1 92 | 93 | - Fix CREATE EXTENSION that was broken. 94 | 95 | Wed Aug 25 2021: Version 1.0.0 96 | 97 | - Initial release 98 | 99 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | PostgreSQL License 2 | 3 | Copyright (c) 2021-2023, MigOps Inc 4 | 5 | Permission to use, copy, modify, and distribute this software and its 6 | documentation for any purpose, without fee, and without a written agreement is 7 | hereby granted, provided that the above copyright notice and this paragraph 8 | and the following two paragraphs appear in all copies. 9 | 10 | IN NO EVENT SHALL MigOps Inc BE LIABLE TO ANY PARTY FOR DIRECT, INDIRECT, 11 | SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING LOST PROFITS, ARISING 12 | OUT OF THE USE OF THIS SOFTWARE AND ITS DOCUMENTATION, EVEN IF MigOps Inc 13 | HAS BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 14 | 15 | MiOps Inc SPECIFICALLY DISCLAIMS ANY WARRANTIES, INCLUDING, BUT NOT 16 | LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A 17 | PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS ON AN "AS IS" BASIS, 18 | AND MigOps HAS NO OBLIGATIONS TO PROVIDE MAINTENANCE, SUPPORT, UPDATES, 19 | ENHANCEMENTS, OR MODIFICATIONS. 20 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | EXTENSION = pg_dbms_job 2 | EXTVERSION = $(shell grep default_version $(EXTENSION).control | \ 3 | sed -e "s/default_version[[:space:]]*=[[:space:]]*'\([^']*\)'/\1/") 4 | 5 | PGFILEDESC = "pg_dbms_job - Propose Oracle DBMS_JOB compatibility for PostgreSQL" 6 | 7 | PG_CONFIG = pg_config 8 | PG91 = $(shell $(PG_CONFIG) --version | egrep " 8\.| 9\.0" > /dev/null && echo no || echo yes) 9 | 10 | ifeq ($(PG91),yes) 11 | DOCS = $(wildcard README*) 12 | SCRIPTS = bin/* 13 | MODULES = 14 | 15 | DATA = $(wildcard updates/*--*.sql) sql/$(EXTENSION)--$(EXTVERSION).sql 16 | else 17 | $(error Minimum version of PostgreSQL required is 9.1.0) 18 | endif 19 | 20 | PGXS := $(shell $(PG_CONFIG) --pgxs) 21 | include $(PGXS) 22 | 23 | install: distconf 24 | 25 | distconf: 26 | install -D --mode=600 --owner=postgres etc/$(EXTENSION).conf /etc/$(EXTENSION)/$(EXTENSION).conf.dist 27 | 28 | installcheck: 29 | $(PROVE) 30 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # pg_dbms_job 2 | 3 | PostgreSQL extension to schedules and manages jobs in a job queue similar to Oracle DBMS_JOB package. 4 | 5 | * [Description](#description) 6 | * [Installation](#installation) 7 | * [Manage the extension](#manage-the-extension) 8 | * [Running the scheduler](#running-the-scheduler) 9 | * [Configuration](#configuration) 10 | * [Jobs definition](#jobs-definition) 11 | - [Scheduled jobs](#scheduled-jobs) 12 | - [Asynchronous jobs](#asynchronous-jobs) 13 | * [View ALL_JOBS](#view-all_jobs) 14 | * [Security](#secutity) 15 | * [Jobs execution history](#jobs-execution-history) 16 | * [Procedures](#procedures) 17 | - [BROKEN](#broken) 18 | - [CHANGE](#change) 19 | - [INTERVAL](#interval) 20 | - [NEXT_DATE](#next_date) 21 | - [REMOVE](#remove) 22 | - [RUN](#run) 23 | - [SUBMIT](#submit) 24 | - [WHAT](#what) 25 | * [Limitations](#limitations) 26 | * [Authors](#authors) 27 | * [License](#license) 28 | 29 | ## [Description](#description) 30 | 31 | This PostgreSQL extension provided full compatibility with the DBMS_JOB Oracle module. 32 | 33 | It allows to manage scheduled jobs from a job queue or to execute immediately jobs asynchronously. A job definition consist on a code to execute, the next date of execution and how often the job is to be run. A job runs a SQL command, plpgsql code or an existing stored procedure. 34 | 35 | If the submit stored procedure is called without the next_date (when) and interval (how often) attributes, the job is executed immediately in an asynchronous process. If interval is NULL and that next_date is lower or equal to current timestamp the job is also executed immediately as an asynchronous process. In all other cases the job is to be started when appropriate but if interval is NULL the job is executed only once and the job is deleted. 36 | 37 | If a scheduled job completes successfully, then its new execution date is placed in next_date. The new date is calculated by evaluating the SQL expression defined as interval. The interval parameter must evaluate to a time in the future. 38 | 39 | This extension consist in a SQL script to create all the objects related to its operation and a daemon that must be run attached to the database where jobs are defined. The daemon is responsible to execute the queued asynchronous jobs and the scheduled ones. It can be run on the same host of the database, where the jobs are defined, or on any other host. The schedule time is taken from the database host not where the daemon is running. 40 | 41 | The number of jobs that can be executed at the same time is limited to 1000 by default. If this limit is reached the daemon will wait that a process ends to run a new one. 42 | 43 | The use of an external scheduler daemon instead of a background worker is a choice, being able to fork thousands of sub-processes from a background worker is not a good idea. 44 | 45 | The job execution is caused by a NOTIFY event received by the scheduler when a new job is submitted or modified. The notifications are polled every 0.1 second. When there is no notification the scheduler polls every `job_queue_interval` seconds (5 seconds by default) the tables where job definition are stored. This mean that at worst a job will be executed `job_queue_interval` seconds after the next execution date defined. 46 | 47 | 48 | ## [Installation](#installation) 49 | 50 | There is no special requirement to run this extension but your PostgreSQL version must support extensions (>= 9.1) and Perl must be available as well as the DBI, DBD::Pg and Time::Hires Perl modules. If your distribution doesn't include these Perl modules you can always install them using CPAN: 51 | 52 | perl -MCPAN -e 'install DBI' 53 | perl -MCPAN -e 'install DBD::Pg' 54 | 55 | or in Debian like distribution use: 56 | 57 | apt install libdbi-perl libpg-perl 58 | 59 | and on RPM based system: 60 | 61 | yum install perl-DBI perl-DBD-Pg perl-Time-HiRes 62 | 63 | To install the extension execute 64 | 65 | make 66 | sudo make install 67 | 68 | Test of the extension can be done using: 69 | 70 | make installcheck 71 | 72 | ## [Manage the extension](#manage-the-extension) 73 | 74 | Each database that needs to use `pg_dbms_job` must creates the extension: 75 | 76 | psql -d mydb -c "CREATE EXTENSION pg_dbms_job" 77 | 78 | To upgrade to a new version execute: 79 | 80 | psql -d mydb -c 'ALTER EXTENSION pg_dbms_job UPDATE TO "1.4.0"' 81 | 82 | If you doesn't have the privileges to create an extension you can just import the extension file into the database, for example: 83 | 84 | psql -d mydb -f sql/pg_dbms_job--1.4.0.sql 85 | 86 | This is especially useful for database in DBaas cloud services. To upgrade just import the extension upgrade files using psql. 87 | 88 | A dedicated scheduler per database using the extension must be started. 89 | 90 | ## [Running the scheduler](#running-the-scheduler) 91 | 92 | The scheduler is a Perl program that runs in background it can be executed by any system user as follow: 93 | 94 | pg_dbms_job -c /etc/pg_dbms_job/mydb-dbms_job.conf 95 | 96 | There must be one scheduler daemon running per database using the extension with a dedicated configuration file. 97 | 98 | The configuration file must define the database connection settings where the pg_dbms_job extension is used. This connection must be the extension tables owner or have the superuser privileges to be able to bypass the Row Level Security rules defined on the pg_dbms_job tables. 99 | 100 | ``` 101 | usage: pg_dbms_job [options] 102 | 103 | options: 104 | 105 | -c, --config file configuration file. Default: /etc/pg_dbms_job/pg_dbms_job.conf 106 | -d, --debug run in debug mode. 107 | -k, --kill stop current running daemon gracefully waiting 108 | for all job completion. 109 | -m, --immediate stop running daemon and jobs immediatly. 110 | -r, --reload reload configuration file and jobs definition. 111 | -s, --single do not detach and run in single loop mode and exit. 112 | ``` 113 | 114 | To stop gracefully the scheduler daemon after all running jobs are terminated, you can run the same command but with the `-k` option: 115 | ``` 116 | pg_dbms_job -c /etc/pg_dbms_job/mydb-dbms_job.conf -k 117 | ``` 118 | you can also send the TERM signal to the main process: 119 | ``` 120 | $ ps auwx | grep "pg_dbms_job:main" | grep -v grep 121 | gilles 14754 0.0 0.0 39636 17492 ? Ss 10:15 0:00 pg_dbms_job:main 122 | 123 | $ kill -15 14754 124 | ``` 125 | 126 | To force the scheduler to stop immedialely interrupting the running jobs use the `-m` option: 127 | ``` 128 | pg_dbms_job -c /etc/pg_dbms_job/mydb-dbms_job.conf -m 129 | ``` 130 | or send the INT signal: 131 | ``` 132 | $ ps auwx | grep "pg_dbms_job:main" | grep -v grep 133 | gilles 14754 0.0 0.0 39636 17492 ? Ss 10:15 0:00 pg_dbms_job:main 134 | 135 | $ kill -2 14754 136 | ``` 137 | 138 | ## [Configuration](#configuration) 139 | 140 | The format of the configuration file is the same as `postgresql.conf`. 141 | 142 | ### General 143 | 144 | - `debug`: debug mode. Default 0, disabled. 145 | - `pidfile`: path to pid file. Default to `/tmp/pg_dbms_job.pid`. 146 | - `logfile`: log file name pattern, can include strftime() escapes, for example 147 | to have a log file per week day use `%a` in the log file name. 148 | Default `/tmp/pg_dbms_job.log`. 149 | - `log_truncate_on_rotation`: If activated an existing log file with the same 150 | name as the new log file will be truncated rather than appended to. But such 151 | truncation only occurs on time-driven rotation, not on restarts. Default `0`, 152 | disabled. 153 | - `job_queue_interval`: poll interval of the jobs queue. Default 5 seconds. 154 | - `job_queue_processes`: Maximum number of job processed at the same time. 155 | Default `1000`. 156 | - `nap_time`: Time to wait in the main loop before each run. Default `100ms` 157 | 158 | ### Database 159 | 160 | - `host`: ip adresse or hostname where the PostgreSQL cluster is running. 161 | - `port`: port where the PostgreSQL cluster is listening. 162 | - `database`: name of the database where to connect. 163 | - `user`: username used to connect to the database, it must be a superuser role. 164 | - `passwd`: password for this role. 165 | 166 | ### Example 167 | ``` 168 | #----------- 169 | # General 170 | #----------- 171 | # Toogle debug mode 172 | debug=0 173 | # Path to the pid file 174 | pidfile=/tmp/pg_dbms_job.pid 175 | # log file name pattern, can include strftime() escapes, for example 176 | # to have a log file per week day use %a in the log file name. 177 | logfile=/tmp/pg_dbms_job.log 178 | # If activated an existing log file with the same name as the new log 179 | # file will be truncated rather than appended to. But such truncation 180 | # only occurs on time-driven rotation, not on restarts. 181 | log_truncate_on_rotation=0 182 | # Poll interval of the job queue 183 | job_queue_interval=5 184 | #Maximum number of job processed at the same time 185 | job_queue_processes=1000 186 | # Time to wait in the main loop before each run (to free some CPU resources) 187 | nap_time = 0.1 188 | 189 | #----------- 190 | # Database 191 | #----------- 192 | host=localhost 193 | port=5432 194 | database=dbms_job 195 | user=gilles 196 | passwd=gilles 197 | ``` 198 | 199 | To force the scheduler to reread the configuration file after changes you can use the `-r` option: 200 | ``` 201 | pg_dbms_job -c /etc/pg_dbms_job/mydb-dbms_job.conf -r 202 | ``` 203 | or send the HUP signal: 204 | ``` 205 | $ ps auwx | grep "pg_dbms_job:main" | grep -g grep 206 | gilles 14758 0.0 0.0 39636 17492 ? Ss 10:17 0:00 pg_dbms_job:main 207 | 208 | $ kill -1 14758 209 | ``` 210 | 211 | ## [Jobs definition](#jobs-definition) 212 | 213 | ### [Scheduled jobs](#scheduled-jobs) 214 | 215 | Jobs to run are stored in table `dbms_job.all_scheduled_jobs` which is the same structure as the one in Oracle. Some columns are just here for compatibility but are not used. They are executed when current timestamp of the database polled by the scheduler is upper or equal to the date defined in the `next_date` attribute. 216 | 217 | Unlike with cron-like scheduler, when the pg_dbms_job scheduler starts it executes all active jobs with a next date in the past. That also mean that the interval of execution will be the same but the first execution date will change. 218 | 219 | ``` 220 | CREATE TABLE dbms_job.all_scheduled_jobs 221 | ( 222 | job bigint DEFAULT nextval('dbms_job.jobseq') PRIMARY KEY, -- identifier of job 223 | log_user name DEFAULT current_user, -- user that submit the job 224 | priv_user name DEFAULT current_user, -- user whose default privileges apply to this job (not used) 225 | schema_user text DEFAULT current_setting('search_path'), -- default schema used to parse the job 226 | last_date timestamp with time zone, -- date on which this job last successfully executed 227 | last_sec text, -- same as last_date (not used) 228 | this_date timestamp with time zone, -- date that this job started executing, null when the job is not running 229 | this_sec text, -- same as this_date (not used) 230 | next_date timestamp(0) with time zone NOT NULL, -- date that this job will next be executed 231 | next_sec timestamp with time zone, -- same as next_date (not used) 232 | total_time interval, -- total wall clock time spent by the system on this job, in seconds 233 | broken boolean DEFAULT false, -- true: no attempt is made to run this job, false: an attempt is made to run this job 234 | interval text, -- a date function, evaluated at the start of execution, becomes next next_date 235 | failures bigint, -- number of times the job has started and failed since its last success 236 | what text NOT NULL, -- body of the anonymous pl/sql block that the job executes 237 | nls_env text, -- session parameters describing the nls environment of the job (not used) 238 | misc_env bytea, -- Other session parameters that apply to this job (not used) 239 | instance integer DEFAULT 0 -- ID of the instance that can execute or is executing the job (not used) 240 | ); 241 | ``` 242 | 243 | ### [Asynchronous jobs](#asynchronous-jobs) 244 | 245 | Job submitted without execution date are jobs that need to be executed asynchronously as soon as possible after being created. They are stored in the queue (FIFO) table `dbms_job.all_async_jobs`. 246 | 247 | Same as for scheduled jobs, if jobs exist in the queue at start of the scheduler, they are executed immediately. 248 | 249 | ``` 250 | CREATE TABLE dbms_job.all_async_jobs 251 | ( 252 | job bigint DEFAULT nextval('dbms_job.jobseq') PRIMARY KEY, -- identifier of job 253 | log_user name DEFAULT current_user, -- user that submit the job 254 | schema_user text DEFAULT current_setting('search_path'), -- default search_path used to execute the job 255 | create_date timestamp with time zone DEFAULT current_timestamp, -- date on which this job has been created. 256 | what text NOT NULL -- body of the anonymous pl/sql block that the job executes 257 | ); 258 | ``` 259 | ## [View ALL_JOBS](#view-all_jobs) 260 | 261 | All jobs that have to be executed can be listed from the view `dbms_job.all_jobs`, this is the equivalent of the Oracle table DBMS_JOB.ALL_JOBS. This view reports all jobs to be run by execution a union between the two tables described in previous chapters. 262 | 263 | ## [Security](#secutity) 264 | 265 | Jobs are only visible by their own creator. A user can not access to a job defined by an other user unless it has the superuser privileges or it is the owner of the pg_dbms_job tables. 266 | 267 | By default a user can not use pg_dbms_job, he must be granted privileges to the pg_dbms_job objects as follow. 268 | 269 | ``` 270 | GRANT USAGE ON SCHEMA dbms_job TO ; 271 | GRANT ALL ON ALL TABLES IN SCHEMA dbms_job TO ; 272 | GRANT ALL ON ALL SEQUENCES IN SCHEMA dbms_job TO ; 273 | GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA dbms_job TO ; 274 | GRANT EXECUTE ON ALL PROCEDURES IN SCHEMA dbms_job TO ; 275 | ``` 276 | 277 | A job will be taken in account by the scheduler only when the transaction where it has been created is committed. It is transactional so no risk that it will be executed if the transaction is aborted. 278 | 279 | When starting or when it is reloaded the pg_dbms_job daemon first checks that another daemon is not already attached to the same database. If this is the case it will refuse to continue. This is a double verification, the first one is on an existing pid file and the second is done by looking at pg_stat_activity to see if a `pg_dbms_job:main` process already exists. 280 | 281 | By default the scheduler allow 1000 job to be executed at the same time, you may want to control this value to a lower or a upper value. This limit can be changed in the configuration file with directive `job_queue_processes`. Note that if your system doesn't enough resources to run all the job at the same time it could be problematic. You must also take attention to who is authorised to submit jobs because this could affect the performances of the server. 282 | 283 | Jobs are executed with as the user that defined the job and with the search path used at the time of the job submission. This information is available in attributes `log_user` and `schema_user` of table `dbms_job.all_scheduled_jobs` and `dbms_job.all_async_jobs`. That mean that the database connection user of the scheduler must have the privilege to change the user using `SET ROLE .`. This allow the user that have submitted the job to view its entries in the history table. 284 | 285 | 286 | ## [Jobs execution history](#jobs-execution-history) 287 | 288 | Oracle DBMS_JOB doesn't provide a log history. This feature is available in DBMS_SCHEDULER and the past activity of the scheduler can be seen in table ALL_SCHEDULER_JOB_RUN_DETAILS. This extension stores all PG_DBMS_JOB activity in a similar table named `dbms_job.all_scheduler_job_run_details`. 289 | 290 | ``` 291 | CREATE TABLE dbms_job.all_scheduler_job_run_details 292 | ( 293 | log_id bigserial PRIMARY KEY, -- unique identifier of the log entry 294 | log_date timestamp with time zone DEFAULT current_timestamp, -- date of the log entry 295 | owner name, -- owner of the scheduler job 296 | job_name varchar(261), -- name of the scheduler job 297 | job_subname varchar(261), -- Subname of the Scheduler job (for a chain step job) 298 | status varchar(128), -- status of the job run 299 | error char(5), -- error code in the case of an error 300 | req_start_date timestamp with time zone, -- requested start date of the job run 301 | actual_start_date timestamp with time zone, -- actual date on which the job was run 302 | run_duration bigint, -- duration of the job run in seconds 303 | instance_id integer, -- identifier of the instance on which the job was run 304 | session_id integer, -- session identifier of the job run 305 | slave_pid integer, -- process identifier of the slave on which the job was run 306 | cpu_used integer, -- amount of cpu used for the job run 307 | additional_info text -- additional information on the job run, error message, etc. 308 | ); 309 | ``` 310 | 311 | ## [Procedures](#procedures) 312 | 313 | ### [BROKEN](#broken) 314 | 315 | Disables or suspend job execution. This procedure sets the broken flag. Broken jobs are never run. 316 | 317 | Syntax: 318 | 319 | pg_dbms_job.broken ( 320 | job IN bigint, 321 | broken IN boolean 322 | next_date IN timestamp DEFAULT current_timestamp); 323 | 324 | Parameters: 325 | 326 | - job : ID of the job being run. 327 | - broken : Sets the job as broken or not broken. `true` sets it as broken; `false` sets it as not broken. 328 | - next_date : Next date when the job will be run, default is `current_timestamp`. 329 | 330 | If you set job as broken while it is running, unlike Oracle, the scheduler will not reset the job's status to normal after the job completes. Therefore, you can execute this procedure for jobs when they are running they will be disabled. 331 | 332 | Example: 333 | 334 | BEGIN; 335 | CALL pg_dbms_job.broken(12345, true); 336 | COMMIT; 337 | 338 | ### [CHANGE](#change) 339 | 340 | Alters any of the user-definable parameters associated with a job. Any value you do not want to change can be specified as NULL. 341 | 342 | Syntax: 343 | 344 | dbms_job.change ( 345 | job IN bigint, 346 | what IN text, 347 | next_date IN timestamp with time zone, 348 | interval IN text 349 | [, instance IN integer DEFAULT 0, 350 | force IN boolean DEFAULT false ]); 351 | 352 | Parameters: 353 | 354 | - job : ID of the job being run. 355 | - what : PL/SQL procedure to run. 356 | - next_date : Next date when the job will be run. 357 | - interval : Date function; evaluated immediately before the job starts running. 358 | - instance : unused 359 | - force : unused 360 | 361 | Your job change will not be available for processing by the job queue in the background until it is committed. 362 | If the parameters what, next_date, or interval are NULL, then leave that value as it is. 363 | 364 | Example: 365 | 366 | Change the interval of execution of job 12345 to run every 3 days 367 | 368 | BEGIN; 369 | CALL pg_dbms_job.change(12345, null, null, 'current_timestamp + ''3 days''::interval'); 370 | COMMIT; 371 | 372 | ### [INTERVAL](#interval) 373 | 374 | Alters the interval between executions for a specified job 375 | 376 | Syntax: 377 | 378 | dbms_job.interval ( 379 | job IN bigint, 380 | interval IN text); 381 | 382 | Parameters: 383 | 384 | - job : ID of the job being run. 385 | - interval : Code of the date function, evaluated immediately before the job starts running. 386 | 387 | If the job completes successfully, then this new date is placed in next_date. `interval` is evaluated by plugging it into the statement select interval into next_date; 388 | 389 | The interval parameter must evaluate to a time in the future. 390 | 391 | If interval evaluates to NULL and if a job completes successfully, then the job is automatically deleted from the queue. 392 | 393 | With Oracle this is the kind of interval values that we can find: 394 | 395 | - Execute daily: `SYSDATE + 1` 396 | - Execute once per week: `SYSDATE + 7` 397 | - Execute hourly: `SYSDATE + 1/24` 398 | - Execute every 2 hour: `SYSDATE + 2/24` 399 | - Execute every 12 hour: `SYSDATE + 12/24` 400 | - Execute every 10 min.: `SYSDATE + 10/1440` 401 | - Execute every 30 sec.: `SYSDATE + 30/86400` 402 | 403 | The equivalent to use with pg_dbms_job are the following: 404 | 405 | - Execute daily: `date_trunc('second',LOCALTIMESTAMP) + '1 day'::interval` 406 | - Execute once per week: `date_trunc('second',LOCALTIMESTAMP) + '7 days'::interval` or `date_trunc('second',current_timestamp) + '1 week'::interval` 407 | - Execute hourly: `date_trunc('second',LOCALTIMESTAMP) + '1 hour'::interval` 408 | - Execute every 2 hour: `date_trunc('second',LOCALTIMESTAMP) + '2 hours'::interval` 409 | - Execute every 12 hour: `date_trunc('second',LOCALTIMESTAMP) + '12 hours'::interval` 410 | - Execute every 10 min.: `date_trunc('second',LOCALTIMESTAMP) + '10 minutes'::interval` 411 | - Execute every 30 sec.: `date_trunc('second',LOCALTIMESTAMP) + '30 secondes'::interval` 412 | 413 | Example: 414 | 415 | BEGIN; 416 | CALL pg_dbms_job.interval(12345, 'current_timestamp + '10 seconds'::interval); 417 | COMMIT; 418 | 419 | ### [NEXT_DATE](#next_date) 420 | 421 | Alters the next execution time for a specified job 422 | 423 | Syntax: 424 | 425 | dbms_job.next_date ( 426 | job IN bigint, 427 | next_date IN timestamp with time zone); 428 | 429 | Parameters: 430 | 431 | - job : ID of the job being run. 432 | - next_date : Date of the next refresh: it is when the job will be automatically run, assuming there are background processes attempting to run it. 433 | 434 | Example: 435 | 436 | BEGIN; 437 | CALL pg_dbms_job.next_date(12345, current_timestamp + '1 day'::interval); 438 | COMMIT; 439 | 440 | ### [REMOVE](#remove) 441 | 442 | Removes specified job from the job queue. You can only remove jobs that you own. If this is run while the job is executing, it will not be interrupted but will not be run again. 443 | 444 | Syntax: 445 | 446 | dbms_job.remove ( 447 | job IN bigint); 448 | 449 | Parameters: 450 | 451 | - job : ID of the job being run. 452 | 453 | Example: 454 | 455 | BEGIN; 456 | CALL pg_dbms_job.remove(12345); 457 | COMMIT; 458 | 459 | ### [RUN](#run) 460 | 461 | Forces a specified job to run. This procedure runs the job now. It runs even if it is broken. If it was broken and it runs successfully, the job is updated to indicates that it is no longer broken and goes back to running on its schedule. 462 | 463 | Running the job recomputes next_date based on the time you run the procedure. 464 | 465 | When runs in foreground there is no logging to the jobs history table but information on the dbms_job.all_scheduled_jobs table are updated in case of error or success. In case of error the exception is raise to the client. 466 | 467 | Syntax: 468 | 469 | dbms_job.run ( 470 | job IN bigint); 471 | 472 | Parameters: 473 | 474 | - job : ID of the job being run. 475 | 476 | Example: 477 | 478 | BEGIN; 479 | CALL pg_dbms_job.run(12345, false); 480 | COMMIT; 481 | 482 | ### [SUBMIT](#submit) 483 | 484 | Submits a new job to the job queue. It chooses the job from the sequence dbms_job.jobseq. 485 | 486 | Actually this is a function as PostgreSQL < 14 do not support out parameters. 487 | 488 | Syntax 489 | 490 | dbms_job.submit ( 491 | job OUT bigint, 492 | what IN text, 493 | [ next_date IN timestamp(0) with time zone DEFAULT current_timestamp 494 | [ , interval IN text DEFAULT NULL 495 | [ , no_parse IN boolean DEFAULT false ] ] ] ); 496 | 497 | Parameters: 498 | 499 | - job : ID of the job being run. 500 | - what : text of the code to the job to be run. This must be a valid SQL statement or block of plpgsql code. The SQL code that you submit in the `what` parameter is wrapped in the following plpgsql block: 501 | ``` 502 | DO $$ 503 | DECLARE 504 | job bigint := $jobid; 505 | next_date timestamp with time zone := current_timestamp; 506 | broken boolean := false; 507 | BEGIN 508 | WHAT 509 | END; 510 | $$; 511 | ``` 512 | 513 | Ensure that you include the ; semi-colon with the statement. 514 | 515 | - next_date : Next date when the job will be run. 516 | - interval : Date function that calculates the next time to run the job. The default is NULL. This must evaluate to a either a future point in time or NULL. 517 | - no_parse : Unused. 518 | 519 | Example: 520 | 521 | This submits a new job to the job queue. The job calls ANALYZE to generate optimizer statistics for the table public.accounts. The job is run every 24 hours: 522 | 523 | BEGIN; 524 | DO $$ 525 | DECLARE 526 | jobno bigint; 527 | BEGIN 528 | SELECT dbms_job.submit( 529 | 'ANALYZE public.accounts.', 530 | LOCALTIMESTAMP, 'LOCALTIMESTAMP + ''1 day''::interval') INTO jobno; 531 | END; 532 | COMMIT; 533 | 534 | ### [WHAT](#what) 535 | 536 | Alters the job description for a specified job. This procedure changes what an existing job does, and replaces its environment. 537 | 538 | Syntax: 539 | 540 | dbms_job.what ( 541 | job IN bigint, 542 | what IN text); 543 | 544 | Parameters: 545 | 546 | - job : ID of the job being run. 547 | - what : PL/SQL procedure to run. 548 | 549 | Example: 550 | 551 | BEGIN; 552 | CALL dbms_job.what('ANALYZE public.accounts.'); 553 | COMMIT; 554 | 555 | ## [Limitations](#limitations) 556 | 557 | Following the job activity a certain amount of bloat can be created in queues tables which can slow down the collect of job to execute by the scheduler. In this case it is recommended to execute a VACUUM FULL on these tables periodically when there is no activity. 558 | 559 | ``` 560 | VACUUM FULL dbms_job.all_scheduled_jobs, dbms_job.all_async_jobs; 561 | ``` 562 | 563 | If you have a very high job execution use that generates thousands of NOTIFY per seconds you should better disable this feature to avoid filling the notify queue. The queue is quite large (8GB in a standard installation) but when it is full the transaction that emit the NOTIFY will fail. Once the queue is half full you will see warnings in the log file. If you experience this limitation you can disable this feature by dropping the triggers responsible of the notification. 564 | ``` 565 | DROP TRIGGER dbms_job_scheduled_notify_trg ON dbms_job.all_scheduled_jobs; 566 | DROP TRIGGER dbms_job_async_notify_trg ON dbms_job.all_async_jobs; 567 | ``` 568 | Once the trigger are dropped the polling of job will only be done every `job_queue_interval` seconds (5 seconds by default). 569 | 570 | ## [Authors](#authors) 571 | 572 | - Gilles Darold 573 | 574 | ## [License](#license) 575 | 576 | This extension is free software distributed under the PostgreSQL 577 | License. 578 | 579 | Copyright (c) 2021-2023 MigOps Inc. 580 | -------------------------------------------------------------------------------- /bin/pg_dbms_job: -------------------------------------------------------------------------------- 1 | #!/usr/bin/perl 2 | #------------------------------------------------------------------------- 3 | # pg_dbms_job 4 | # 5 | # Perl scheduler daemon to emulate Oracle DBMS_JOB for PostgreSQL. 6 | # 7 | # Author: Gilles Darold 8 | # Licence: PostgreSQL 9 | # Copyright (c) 2021-2023, MigOps Inc, 10 | #------------------------------------------------------------------------- 11 | use vars qw($VERSION $PROGRAM); 12 | use strict; 13 | 14 | use IO::File; 15 | use Getopt::Long qw(:config bundling no_ignore_case_always); 16 | use POSIX qw(locale_h sys_wait_h _exit strftime); 17 | setlocale(LC_NUMERIC, ''); 18 | setlocale(LC_ALL, 'C'); 19 | use DBI; 20 | use DBD::Pg; 21 | use Time::HiRes; 22 | use Time::Piece; 23 | 24 | $| = 1; 25 | 26 | $VERSION = '1.5'; 27 | $PROGRAM = 'pg_dbms_job'; 28 | 29 | $SIG{'CHLD'} = 'DEFAULT'; 30 | 31 | # Global variables 32 | my $CONFIG_FILE = "/etc/pg_dbms_job/pg_dbms_job.conf"; 33 | my %CONFIG = ( 34 | 'debug' => 0, 35 | 'pidfile' => '/tmp/pg_dbms_job.pid', 36 | 'logfile' => '', 37 | ); 38 | my $ABORT = 0; 39 | my $KILL = 0; 40 | my $RELOAD = 0; 41 | my %RUNNING_PIDS = (); 42 | my %DBINFO = (); 43 | my $HELP = 0; 44 | my $SHOWVER = 0; 45 | my %SCHEDULED_JOBS = (); 46 | my %ASYNC_JOBS = (); 47 | my $SINGLE = 0; 48 | 49 | my %PQSTATUS = ( 50 | 0 => "Empty query string", 51 | 1 => "Query returning no data success", 52 | 2 => "Query returning data success", 53 | 3 => "COPY OUT transfer in progress", 54 | 4 => "COPY IN transfer is in progress", 55 | 5 => "Unexpected response received", 56 | 6 => "A nonfatal error occurred", 57 | 7 => "The query failed", 58 | 8 => "COPY IN/OUT transfer in progress", 59 | 9 => "Single tuple from larger resultset", 60 | 10 => "Pipeline synchronization point", 61 | 11 => "Command didn't run because of an abort earlier in a pipeline" 62 | ); 63 | 64 | # Time to wait in the main loop before each runs to free some CPU cycle 65 | my $naptime = 0.1; 66 | 67 | # Main database connection handler 68 | my $dbh = undef; 69 | 70 | # Flag to terminate all actions and exit when SIGINT is received 71 | my $fini = 0; 72 | 73 | # Flag to signal that the configuration need to be reread 74 | my $config_invalidated = 0; 75 | 76 | # Flag for initial import of jobs 77 | my $startup = 1; 78 | 79 | # Maximum number of job processed at the same time 80 | my $job_queue_processes = 1000; 81 | 82 | # Interval to force a poll of the job queue in case there was no 83 | # notification to execute old scheduled jobs. Default 5 seconds. 84 | my $job_queue_interval = 5; 85 | 86 | # Global variable to register current log file for rotation 87 | my $old_log_file = ''; 88 | 89 | # Process command line options 90 | my $result = GetOptions 91 | ( 92 | "c|config=s" => \$CONFIG_FILE, 93 | "d|debug!" => \$CONFIG{ 'debug' }, 94 | "h|help!" => \$HELP, 95 | "k|kill!" => \$KILL, 96 | "m|immediate!"=> \$ABORT, 97 | "r|reload!" => \$RELOAD, 98 | "s|single!" => \$SINGLE, 99 | "v|version!" => \$SHOWVER, 100 | ); 101 | 102 | # Display usage if help is asked and exit 103 | usage() if $HELP; 104 | 105 | # Show version if asked end exit 106 | if ($SHOWVER) 107 | { 108 | print "Version: $VERSION\n"; 109 | exit 0; 110 | } 111 | 112 | # Look at configuration file 113 | read_config(); 114 | 115 | #### 116 | # The daemon should be stopped, send signal to the process and exit 117 | #### 118 | if ($KILL) { 119 | signal_handling('TERM'); 120 | } elsif ($ABORT) { 121 | signal_handling('INT'); 122 | } elsif ($RELOAD) { 123 | signal_handling('HUP'); 124 | } 125 | 126 | # Verify that an other process is not running 127 | if (-e $CONFIG{ 'pidfile' }) { 128 | die "FATAL: pid file already exists at $CONFIG{ 'pidfile' }, does another pg_dbms_job process is running?\n"; 129 | } 130 | 131 | #### 132 | # Method used to fork a subprocess 133 | #### 134 | sub spawn 135 | { 136 | my $coderef = shift; 137 | 138 | unless (@_ == 0 and $coderef and ref($coderef) eq 'CODE') { 139 | print "usage: spawn CODEREF"; 140 | exit 0; 141 | } 142 | 143 | my $pid; 144 | if (!defined($pid = fork)) { 145 | dprint('ERROR', "cannot fork: $!\n"); 146 | return; 147 | } elsif ($pid) { 148 | $RUNNING_PIDS{$pid} = 1; 149 | return; # the parent 150 | } 151 | # the child -- go spawn 152 | $< = $>; 153 | $( = $); # suid progs only 154 | 155 | exit &$coderef(); 156 | } 157 | 158 | #### 159 | # Die cleanly on signal 160 | #### 161 | sub terminate 162 | { 163 | my $sig = shift; 164 | 165 | $fini = 1; 166 | 167 | dprint('LOG', "Received terminating signal $sig."); 168 | 169 | $SIG{INT} = \&terminate; 170 | $SIG{TERM} = \&terminate; 171 | $SIG{HUP} = \&reload; 172 | 173 | unlink("$CONFIG{ 'pidfile' }") if (-f $CONFIG{ 'pidfile' }); 174 | 175 | # Wait for all child processes to die 176 | &wait_all_childs(); 177 | 178 | $dbh->disconnect() if (defined $dbh); 179 | 180 | _exit(0); 181 | } 182 | 183 | #### 184 | # Instruct the program to reread configuration 185 | # file and refresh all the jobs definitions. 186 | #### 187 | sub reload 188 | { 189 | my $sig = shift; 190 | 191 | dprint('LOG', "Received reload signal $sig."); 192 | 193 | $SIG{INT} = \&terminate; 194 | $SIG{TERM} = \&terminate; 195 | $SIG{HUP} = \&reload; 196 | 197 | my $old_pidfile = $CONFIG{ 'pidfile' }; 198 | &read_config(1); 199 | 200 | # In case the pid file path have change rename 201 | # it or keep the old one in case of failure 202 | if ($CONFIG{ 'pidfile' } and $CONFIG{ 'pidfile' } ne $old_pidfile) 203 | { 204 | unless (rename($old_pidfile, "$CONFIG{ 'pidfile' }")) 205 | { 206 | dprint('ERROR', "can't change path to pid keeping old one $old_pidfile, $!"); 207 | $CONFIG{ 'pidfile' } = $old_pidfile 208 | } 209 | else 210 | { 211 | dprint('LOG', "path to pid file has changed, rename $old_pidfile into $CONFIG{ 'pidfile' }"); 212 | } 213 | } 214 | 215 | # instruct main loop that it have to rebuild jobs cache 216 | $config_invalidated = 1; 217 | } 218 | 219 | # Die on kill -2, -3 or -15 220 | $SIG{'INT'} = $SIG{'TERM'} = \&terminate; 221 | $SIG{'HUP'} = \&reload; 222 | 223 | # Detach from terminal if we are not running in single mode 224 | if (!$SINGLE) 225 | { 226 | my $pid = fork; 227 | exit 0 if ($pid); 228 | die "FATAL: Couldn't fork: $!" unless defined($pid); 229 | POSIX::setsid() or die "Can't detach: \$!"; 230 | &dprint('DEBUG', "Detach from terminal with pid: $$"); 231 | open(STDIN , '<', "/dev/null"); 232 | open(STDOUT, '>', "/dev/null"); 233 | } 234 | 235 | # Set name of the program without path 236 | my $orig_name = $0; 237 | $0 = $PROGRAM; 238 | 239 | # Create pid file 240 | my $fhp = IO::File->new($CONFIG{ 'pidfile' }, 'w'); 241 | if (not defined $fhp) { 242 | die "FATAL: can't create pid file $CONFIG{ 'pidfile' }, $!\n"; 243 | } 244 | print $fhp $$; 245 | close($fhp); 246 | 247 | #### 248 | # Entering main loop 249 | #### 250 | dprint('LOG', "Entering main loop."); 251 | my $previous_async_exec = 0; 252 | my $previous_scheduled_exec = 0; 253 | # exit loop when SIGTERM is received or we are running in single mode 254 | while (!$fini) 255 | { 256 | # Stores loop start time 257 | my $t0 = Time::HiRes::time; 258 | 259 | #### 260 | # look if there are some child processes dead to register 261 | #### 262 | foreach my $k (keys %RUNNING_PIDS) 263 | { 264 | my $kid = waitpid(-1, WNOHANG); 265 | if ($kid > 0) { 266 | delete $RUNNING_PIDS{$kid}; 267 | } 268 | } 269 | 270 | # When the configuration is invalidated we must also disconnect 271 | # from the database in case the connection settings have changed 272 | if ($config_invalidated) 273 | { 274 | # We need to reconnect in the main loop 275 | $dbh->disconnect() if (defined $dbh); 276 | $dbh = undef; 277 | } 278 | 279 | # Connect to the database if this is not already the case 280 | $dbh = connect_db() if (not defined $dbh); 281 | 282 | #### 283 | # Look if we have received some notification from the database 284 | #### 285 | my $async_count = 0; 286 | my $scheduled_count = 0; 287 | if (defined $dbh) 288 | { 289 | $config_invalidated = 0; 290 | while (my $notify = $dbh->pg_notifies) 291 | { 292 | my ($topic, $pid, $payload) = @$notify; 293 | dprint('DEBUG', "Received notification: ($topic, $pid, $payload)"); 294 | $async_count++ if ($topic eq 'dbms_job_async_notify'); 295 | $scheduled_count++ if ($topic eq 'dbms_job_scheduled_notify'); 296 | } 297 | } 298 | else 299 | { 300 | # In case we can not connect to the database or we 301 | # are on a standby wait three seconds and try again. 302 | sleep(3); 303 | $startup = 1; 304 | $config_invalidated = 1; 305 | next; 306 | } 307 | 308 | #### 309 | # In case we do not receive notification in the job_queue_interval 310 | # interval, force the collect of the async job to execute in case 311 | # there is an old one with a next_date that has expired. 312 | #### 313 | if ( !$async_count and !$startup and $t0 >= ($previous_async_exec+$job_queue_interval) ) { 314 | dprint('DEBUG', "job_queue_interval reached, forcing collect of asynchronous jobs"); 315 | $async_count = 1; 316 | } 317 | if ( !$scheduled_count and !$startup and $t0 >= ($previous_scheduled_exec+$job_queue_interval) ) { 318 | dprint('DEBUG', "job_queue_interval reached, forcing collect of scheduledhronous jobs"); 319 | $scheduled_count = 1; 320 | } 321 | 322 | #### 323 | # Get a list of asynchrous queued jobs to execute 324 | #### 325 | if ($async_count || $startup) 326 | { 327 | %ASYNC_JOBS = get_async_jobs($async_count); 328 | # Register last execution time 329 | $previous_async_exec = Time::HiRes::time; 330 | } 331 | 332 | #### 333 | # Get jobs defined in the remote database if they are not 334 | # already cached or that the cache have been invalidated. 335 | #### 336 | if ($scheduled_count || $startup) 337 | { 338 | %SCHEDULED_JOBS = get_scheduled_jobs(); 339 | # Register last execution time 340 | $previous_scheduled_exec = Time::HiRes::time; 341 | # If we lost the connection 342 | if ($config_invalidated) { 343 | sleep(3); 344 | $startup = 1; 345 | next; 346 | } 347 | } 348 | 349 | # Init flags 350 | $config_invalidated = 0; 351 | $startup = 0; 352 | 353 | #### 354 | # Process all the scheduled jobs in a dedicated process each. 355 | #### 356 | foreach my $job (sort { $a <=> $b } keys %SCHEDULED_JOBS) 357 | { 358 | # If we have forked too much processes wait one second until a process die 359 | while (scalar keys %RUNNING_PIDS >= $job_queue_processes) { 360 | dprint('WARNING', "max job queue size is reached ($job_queue_processes) waiting the end of an other job"); 361 | sleep(1); 362 | } 363 | 364 | spawn sub 365 | { 366 | &subprocess_scheduled_jobs( $job ); 367 | }; 368 | } 369 | %SCHEDULED_JOBS = (); 370 | 371 | #### 372 | # Process all the asynchronous jobs in a dedicated process each. 373 | #### 374 | foreach my $job (sort { $a <=> $b } keys %ASYNC_JOBS) 375 | { 376 | # If we have forked too much processes wait one second until a process die 377 | while (scalar keys %RUNNING_PIDS >= $job_queue_processes) { 378 | dprint('WARNING', "max job queue size is reached ($job_queue_processes) waiting the end of an other job"); 379 | sleep(1); 380 | } 381 | 382 | spawn sub 383 | { 384 | &subprocess_asynchronous_jobs( $job ); 385 | }; 386 | } 387 | %ASYNC_JOBS = (); 388 | 389 | last if ($SINGLE); 390 | 391 | # We can not loop quicker than naptime, 0.1 second by default 392 | Time::HiRes::sleep($naptime); 393 | } 394 | 395 | # Wait for last child stop 396 | &wait_all_childs(); 397 | 398 | if (-f $CONFIG{ 'pidfile' }) { 399 | unlink("$CONFIG{ 'pidfile' }") or dprint('ERROR', "Unable to remove pid file $CONFIG{ 'pidfile' }, $!"); 400 | } 401 | 402 | dprint('LOG', "pg_dbms_job scheduler stopped."); 403 | 404 | exit 0; 405 | 406 | 407 | #------------------------------------------------------------------------------ 408 | # METHODS 409 | #------------------------------------------------------------------------------ 410 | 411 | #### 412 | # Show help 413 | #### 414 | sub usage 415 | { 416 | print qq{ 417 | usage: $PROGRAM [options] 418 | 419 | options: 420 | 421 | -c, --config file configuration file. Default: $CONFIG_FILE 422 | -d, --debug run in debug mode. 423 | -k, --kill stop current running daemon gracefully waiting 424 | for all job completion. 425 | -m, --immediate stop running daemon and jobs immediatly. 426 | -r, --reload reload configuration file and jobs definition. 427 | -s, --single do not detach and run in single loop mode and exit. 428 | }; 429 | 430 | exit 0; 431 | } 432 | 433 | #### 434 | # Same as local_die but with pid file cleanup 435 | #### 436 | sub local_die 437 | { 438 | unlink("$CONFIG{ 'pidfile' }") if (-f $CONFIG{ 'pidfile' }); 439 | die "$_[0]"; 440 | } 441 | 442 | #### 443 | # Send a signal to the pg_dbms_job daemon 444 | #### 445 | sub signal_handling 446 | { 447 | my $sig = shift; 448 | 449 | my $proc = ''; 450 | if (-e "$CONFIG{ 'pidfile' }") { 451 | $proc = `cat $CONFIG{ 'pidfile' }`; 452 | } else { 453 | $proc = `ps h -opid -C$PROGRAM | head -1`; 454 | } 455 | chomp($proc); 456 | $proc =~ s/ //g; 457 | 458 | if (!$proc) { 459 | die "ERROR: can't find a pid to send SIG$sig, is $PROGRAM running?\n"; 460 | } 461 | 462 | kill "-$sig", $proc; 463 | if ($? == -1) { 464 | print "FATAL: failed to execute: $!\n"; 465 | } elsif ($? & 127) { 466 | printf "ERROR: child died with signal %d, %s coredump\n", ($? & 127), ($? & 128) ? 'with' : 'without'; 467 | } else { 468 | printf "OK: $PROGRAM exited with value %d\n", $? >> 8; 469 | } 470 | exit 0; 471 | } 472 | 473 | #### 474 | # Read configuration file 475 | #### 476 | sub read_config 477 | { 478 | my $nodie = shift; # When reload is called, set to 1 479 | 480 | if (!-e $CONFIG_FILE) { 481 | if (!$nodie) { 482 | die("FATAL: can not find the configuration file $CONFIG_FILE\n"); 483 | } else { 484 | dprint('ERROR', "can not find the configuration file $CONFIG_FILE"); 485 | return; 486 | } 487 | } 488 | 489 | my $curfh = IO::File->new($CONFIG_FILE, 'r'); 490 | if (defined $curfh) 491 | { 492 | my @content = <$curfh>; 493 | $curfh->close(); 494 | 495 | # Set the logfile first to be able to log the configuratioin changes 496 | foreach my $l ( @content ) 497 | { 498 | chomp($l); 499 | # cleanup the line 500 | $l =~ s/\r//s; 501 | $l =~ s/^\s*\#.*//; 502 | $l =~ s/^\s+//; 503 | $l =~ s/\s+$//; 504 | next if (!$l); 505 | 506 | my ($var, $val) = split(/\s*=\s*/, $l); 507 | $var = lc($var); 508 | if ($var eq 'logfile') 509 | { 510 | if ($CONFIG{ 'logfile' } ne $val) 511 | { 512 | $CONFIG{ 'logfile' } = $val; 513 | dprint('LOG', "Setting logfile from configuration file to $CONFIG{ 'logfile' }"); 514 | } 515 | } 516 | } 517 | 518 | foreach my $l ( @content ) 519 | { 520 | chomp($l); 521 | # cleanup the line 522 | $l =~ s/\r//s; 523 | $l =~ s/^\s*\#.*//; 524 | $l =~ s/^\s+//; 525 | $l =~ s/\s+$//; 526 | next if (!$l); 527 | 528 | my ($var, $val) = split(/\s*=\s*/, $l); 529 | $var = lc($var); 530 | if ($var eq 'pidfile') 531 | { 532 | if ($CONFIG{ 'pidfile' } ne $val) 533 | { 534 | $CONFIG{ 'pidfile' } = $val; 535 | dprint('LOG', "Setting pidfile from configuration file to $CONFIG{ 'pidfile' }"); 536 | } 537 | } 538 | elsif ($var eq 'debug') 539 | { 540 | $val = int($val); 541 | if ($CONFIG{ 'debug' } ne $val) 542 | { 543 | $CONFIG{ 'debug' } = $val; 544 | dprint('LOG', "Setting debug from configuration file to $CONFIG{ 'debug' }"); 545 | } 546 | } 547 | elsif ($var eq 'job_queue_interval') 548 | { 549 | $job_queue_interval = $val; 550 | dprint('LOG', "Setting job_queue_interval from configuration file to $job_queue_interval"); 551 | } 552 | elsif ($var eq 'job_queue_processes') 553 | { 554 | $val = int($val); 555 | if ($job_queue_processes != $val) 556 | { 557 | $job_queue_processes = $val; 558 | dprint('LOG', "Setting job_queue_processes from configuration file to $job_queue_processes"); 559 | } 560 | } 561 | elsif ($var eq 'nap_time') 562 | { 563 | $naptime = $val; 564 | dprint('LOG', "Setting nap_time from configuration file to $naptime"); 565 | } 566 | elsif ($var =~ /^(host|database|user|passwd|port)$/) 567 | { 568 | $val = int($val) if ($var eq 'port'); 569 | if (not exists $DBINFO{$var} or $DBINFO{$var} ne $val) 570 | { 571 | $DBINFO{$var} = $val; 572 | if ($var !~ /passwd/) { 573 | dprint('LOG', "Setting $var from configuration file to $DBINFO{$var}"); 574 | } 575 | } 576 | } 577 | } 578 | } 579 | } 580 | 581 | #### 582 | # Wait for all subprocesses die 583 | #### 584 | sub wait_all_childs 585 | { 586 | while (scalar keys %RUNNING_PIDS > 0) 587 | { 588 | my $kid = waitpid(-1, WNOHANG); 589 | if ($kid > 0) 590 | { 591 | delete $RUNNING_PIDS{$kid}; 592 | } 593 | sleep(1); 594 | } 595 | } 596 | 597 | #### 598 | # Log messages to file 599 | #### 600 | sub dprint 601 | { 602 | my ($level, $msg) = @_; 603 | 604 | my ($package, $filename, $line) = caller; 605 | 606 | return if ($KILL or (uc($level) eq 'DEBUG' and !$CONFIG{ 'debug' })); 607 | 608 | my $t = strftime('%Y-%m-%d %H:%M:%S', localtime); 609 | 610 | my $fname = $CONFIG{ 'logfile' } || ''; 611 | 612 | # Apply the strftime formatting if required 613 | $fname = localtime->strftime($fname) if ($fname =~ /\%/); 614 | # If required we truncate the log file on rotation 615 | if ($CONFIG{ 'log_truncate_on_rotation' } && $old_log_file) 616 | { 617 | if ($fname ne $old_log_file && -e $fname) { 618 | unlink($fname); 619 | } 620 | } 621 | $old_log_file = $fname; 622 | 623 | if ($fname && open(my $out, '>>', $fname)) 624 | { 625 | flock($out, 2) or return; 626 | print $out "$t [$$]: [$line] $level: $msg\n"; 627 | close($out); 628 | } else { 629 | print STDERR "ERROR: can't write to log file $fname, $!\n"; 630 | print STDERR "$t [$$]: [$line] $level: $msg\n"; 631 | } 632 | } 633 | 634 | #### 635 | # Connect to the database and return the global database connection handler 636 | #### 637 | sub connect_db 638 | { 639 | $0 = 'pg_dbms_job:main'; 640 | my $ldbh = DBI->connect("dbi:Pg:dbname=$DBINFO{database};host=$DBINFO{host};port=$DBINFO{port}", 641 | $DBINFO{user}, 642 | $DBINFO{passwd}, 643 | {AutoInactiveDestroy => 1, PrintError => 0, AutoCommit => 1}); 644 | # Check for connection failure 645 | if (not defined $ldbh) 646 | { 647 | dprint('FATAL', "can't connect to \"dbi:Pg:dbname=$DBINFO{database};host=$DBINFO{host};port=$DBINFO{port}\", $DBI::errstr"); 648 | return undef; 649 | } 650 | 651 | # Set application name to pg_dbms_job:main 652 | if (not $ldbh->do("SET application_name TO 'pg_dbms_job:main'")) 653 | { 654 | dprint('ERROR', "can not set application_name, reason: " . $ldbh->errstr); 655 | $ldbh->disconnect() if (defined $ldbh); 656 | return undef; 657 | } 658 | 659 | #### 660 | # Now that we are connected verify that there is no other 661 | # scheduler already runing on this database by looking for 662 | # entries with the same application_name in pg_stat_activity. 663 | # We additionaly detect if we are running on a standby server. 664 | #### 665 | my $query = "SELECT count(*), pg_is_in_recovery() FROM pg_catalog.pg_stat_activity WHERE datname='$DBINFO{database}' AND application_name='pg_dbms_job:main'"; 666 | my $sth = $ldbh->prepare($query); 667 | if (!defined $sth) 668 | { 669 | dprint('ERROR', "can't prepare statement, $DBI::errstr"); 670 | $ldbh->disconnect() if (defined $ldbh); 671 | return undef; 672 | } 673 | 674 | $sth->execute; 675 | if ($sth->err) 676 | { 677 | dprint('ERROR', "can't execute statement, $DBI::errstr"); 678 | $ldbh->disconnect() if (defined $ldbh); 679 | return undef; 680 | } 681 | my @row = $sth->fetchrow; 682 | if ($row[0] > 1) 683 | { 684 | dprint('FATAL', "another pg_dbms_job process is running on this database! Aborting."); 685 | $ldbh->disconnect() if (defined $ldbh); 686 | local_die("FATAL: another pg_dbms_job process is running on this database! Aborting.\n"); 687 | } 688 | 689 | # Close the connection if we are running on a standby, 690 | # there is nothing to do on a standby it is readonly. 691 | if ($row[1]) 692 | { 693 | $ldbh->disconnect() if (defined $ldbh); 694 | return undef; 695 | } 696 | 697 | # Subscribe to pg_dbms_job notification channels 698 | $ldbh->do("LISTEN dbms_job_scheduled_notify"); 699 | $ldbh->do("LISTEN dbms_job_async_notify"); 700 | 701 | return $ldbh; 702 | } 703 | 704 | #### 705 | # Get all jobs defined in the remote database. 706 | #### 707 | sub get_scheduled_jobs 708 | { 709 | dprint('DEBUG', 'Get scheduled jobs to run'); 710 | 711 | my %alljobs = (); 712 | 713 | # Get all scheduled jobs from table ALL_JOBS that 714 | # must be run and set the next execution date. 715 | my $query = "UPDATE dbms_job.all_scheduled_jobs SET"; 716 | $query .= " this_date = current_timestamp,"; 717 | $query .= " next_date = dbms_job.get_next_date(interval),"; 718 | $query .= " instance = instance+1"; # internal used only to not be notified for this change 719 | $query .= " WHERE interval IS NOT NULL AND NOT broken AND this_date IS NULL"; 720 | $query .= " AND next_date <= current_timestamp RETURNING *"; 721 | my $sth = $dbh->prepare($query); 722 | if (!defined $sth) 723 | { 724 | dprint('ERROR', "can't prepare statement, $DBI::errstr"); 725 | $config_invalidated = 1 if (!$SINGLE); 726 | return %alljobs; 727 | } 728 | 729 | $sth->execute; 730 | if ($sth->err) 731 | { 732 | dprint('ERROR', "can't execute statement, $DBI::errstr"); 733 | $config_invalidated = 1 if (!$SINGLE); 734 | return %alljobs; 735 | } 736 | 737 | while (my $row = $sth->fetchrow_hashref) 738 | { 739 | # Register the jobs information into a hash by job id 740 | foreach my $k (keys %$row) { 741 | $alljobs{$row->{job}}{$k} = $row->{$k}; 742 | } 743 | } 744 | $sth->finish(); 745 | 746 | dprint('DEBUG', "Found " . (scalar keys %alljobs) . " scheduled jobs to run"); 747 | 748 | return %alljobs; 749 | } 750 | 751 | #### 752 | # Get asynchronous jobs to execute and delete them from the queue. 753 | #### 754 | sub get_async_jobs 755 | { 756 | my %asyncjobs = (); 757 | my $limit = ''; 758 | 759 | # Get all jobs to be executed asap from table ALL_ASYNC_JOBS 760 | # we change this_date to avoid reading it again 761 | my $query = "UPDATE dbms_job.all_async_jobs SET"; 762 | $query .= " this_date = current_timestamp"; 763 | $query .= " WHERE this_date IS NULL RETURNING *"; 764 | my $sth = $dbh->prepare($query); 765 | if (!defined $sth) 766 | { 767 | dprint('ERROR', "can't prepare statement, $DBI::errstr"); 768 | return %asyncjobs; 769 | } 770 | 771 | $sth->execute; 772 | if ($sth->err) 773 | { 774 | dprint('ERROR', "can't execute statement, $DBI::errstr"); 775 | return %asyncjobs; 776 | } 777 | while (my $row = $sth->fetchrow_hashref) 778 | { 779 | # Register the jobs information into a hash by job id 780 | foreach my $k (keys %$row) { 781 | $asyncjobs{$row->{job}}{$k} = $row->{$k}; 782 | } 783 | } 784 | $sth->finish(); 785 | 786 | # Get all jobs with no interval from table ALL_SCHEDULEd_JOBS 787 | # where the next_date value is lower or equal to current timestamp 788 | # as they also need to be executed immediately and removed from the 789 | # dbms_job.all_scheduled_jobs table as they are no more used. 790 | $query = "UPDATE dbms_job.all_scheduled_jobs SET"; 791 | $query .= " this_date = current_timestamp"; 792 | $query .= " WHERE this_date IS NULL AND interval IS NULL AND next_date <= current_timestamp RETURNING *"; 793 | $sth = $dbh->prepare($query); 794 | if (!defined $sth) 795 | { 796 | dprint('ERROR', "can't prepare statement, $DBI::errstr"); 797 | return %asyncjobs; 798 | } 799 | 800 | $sth->execute; 801 | if ($sth->err) 802 | { 803 | dprint('ERROR', "can't execute statement, $DBI::errstr"); 804 | return %asyncjobs; 805 | } 806 | while (my $row = $sth->fetchrow_hashref) 807 | { 808 | # Register the jobs information into a hash by job id 809 | foreach my $k (keys %$row) { 810 | $asyncjobs{$row->{job}}{$k} = $row->{$k}; 811 | } 812 | } 813 | $sth->finish(); 814 | 815 | dprint('DEBUG', "Found " . (scalar keys %asyncjobs) . " asynchronous jobs to run"); 816 | 817 | return %asyncjobs; 818 | } 819 | 820 | #### 821 | # Deleting job from queue 822 | #### 823 | sub delete_job 824 | { 825 | my ($ldbh, $jobid) = @_; 826 | 827 | dprint('DEBUG', "Deleting asynchronous job $jobid from queue"); 828 | 829 | my $query = "DELETE FROM dbms_job.all_async_jobs WHERE job = $jobid RETURNING job"; 830 | my $sth = $ldbh->prepare($query); 831 | if (!defined $sth) { 832 | dprint('ERROR', "can't prepare statement, $DBI::errstr"); 833 | end_subprocess($ldbh, $jobid); 834 | } 835 | $sth->execute; 836 | if ($sth->err) { 837 | dprint('ERROR', "can't execute statement, $DBI::errstr"); 838 | end_subprocess($ldbh, $jobid); 839 | } 840 | my $row = $sth->fetchrow; 841 | $sth->finish(); 842 | 843 | # If no deleted job was returned, this was a scheduled job without interval 844 | if (not defined $row) 845 | { 846 | $query = "DELETE FROM dbms_job.all_scheduled_jobs WHERE job = $jobid"; 847 | my $sth = $ldbh->prepare($query); 848 | if (!defined $sth) { 849 | dprint('ERROR', "can't prepare statement, $DBI::errstr"); 850 | end_subprocess($ldbh, $jobid); 851 | } 852 | $sth->execute; 853 | if ($sth->err) { 854 | dprint('ERROR', "can't execute statement, $DBI::errstr"); 855 | end_subprocess($ldbh, $jobid); 856 | } 857 | } 858 | } 859 | 860 | #### 861 | # End a subprocess with some cleanup 862 | #### 863 | sub end_subprocess 864 | { 865 | my ($ldbh, $jobid) = @_; 866 | 867 | $ldbh->disconnect() if (defined $ldbh); 868 | dprint('LOG', "end of subprocess executing job $jobid"); 869 | exit(0); 870 | } 871 | 872 | #### 873 | # Execute the asynchronous job's plpgsql code on the remote database 874 | #### 875 | sub subprocess_asynchronous_jobs 876 | { 877 | my $jobid = shift; 878 | 879 | my $start_t = strftime('%Y-%m-%d %H:%M:%S', localtime); 880 | 881 | $0 = "pg_dbms_job:async:$jobid"; 882 | 883 | # Subprocess must completed their work in case 884 | # of interruption unless we received SIGINT 885 | $SIG{TERM} = 'IGNORE'; 886 | $SIG{HUP} = 'IGNORE'; 887 | 888 | dprint('LOG', "executing job $jobid"); 889 | 890 | if ($CONFIG{ 'debug' }) 891 | { 892 | foreach my $k (sort { $a <=> $b } keys %{ $ASYNC_JOBS{ $jobid } }) 893 | { 894 | dprint('DEBUG', "job $jobid with parameter $k: $ASYNC_JOBS{ $jobid }{ $k }"); 895 | } 896 | } 897 | 898 | # Clone the connection to the database 899 | my $ldbh = $dbh->clone(); 900 | 901 | if (defined $ldbh) 902 | { 903 | #### 904 | # Set application name to pg_dbms_job:jobid 905 | #### 906 | if (not $ldbh->do("SET application_name TO 'pg_dbms_job:async:$jobid'")) { 907 | dprint('ERROR', "can not set application_name, reason: " . $ldbh->errstr); 908 | end_subprocess($ldbh, $jobid); 909 | } 910 | 911 | #### 912 | # Set role for the code execution 913 | #### 914 | if ($ASYNC_JOBS{ $jobid }{ 'log_user' }) 915 | { 916 | if (not $ldbh->do("SET ROLE $ASYNC_JOBS{ $jobid }{ 'log_user' }")) { 917 | dprint('ERROR', "can not change role, reason: " . $ldbh->errstr); 918 | end_subprocess($ldbh, $jobid); 919 | } 920 | } 921 | 922 | #### 923 | # start a transaction 924 | #### 925 | if (not $ldbh->do("BEGIN")) { 926 | dprint('ERROR', "can not start a transaction, reason: " . $ldbh->errstr); 927 | end_subprocess($ldbh, $jobid); 928 | } 929 | 930 | #### 931 | # Set search_path for the code execution 932 | #### 933 | if ($ASYNC_JOBS{ $jobid }{ 'schema_user' }) 934 | { 935 | if (not $ldbh->do("SET LOCAL search_path TO $ASYNC_JOBS{ $jobid }{ 'schema_user' }")) { 936 | dprint('ERROR', "can not change the search_path, reason: " . $ldbh->errstr); 937 | end_subprocess($ldbh, $jobid); 938 | } 939 | } 940 | 941 | #### 942 | # Execute the code of the WHAT column 943 | #### 944 | my $success = 1; 945 | my $errstr = ''; 946 | my $status = ''; 947 | my $sqlstate = ''; 948 | my $t0 = Time::HiRes::time; 949 | 950 | my $codetoexec = qq{DO \$pg_dbms_job\$ 951 | DECLARE 952 | job bigint := $jobid; 953 | next_date timestamp with time zone := current_timestamp; 954 | broken boolean := false; 955 | BEGIN 956 | $ASYNC_JOBS{ $jobid }{ 'what' } 957 | END; 958 | \$pg_dbms_job\$; 959 | }; 960 | dprint('DEBUG', "executing code of job id $jobid: $ASYNC_JOBS{ $jobid }{ 'what' }"); 961 | if (not $ldbh->do($codetoexec)) 962 | { 963 | $success = 0; 964 | $errstr = $ldbh->errstr; 965 | $status = $PQSTATUS{$ldbh->err} || ''; 966 | $sqlstate = $ldbh->state || ''; 967 | dprint('ERROR', "job $jobid failure, reason: $errstr"); 968 | # Rollback the transaction 969 | if (not $ldbh->do("ROLLBACK")) { 970 | dprint('ERROR', "can not rollback a transaction, reason: " . $ldbh->errstr); 971 | delete_job($ldbh, $jobid); 972 | end_subprocess($ldbh, $jobid); 973 | } 974 | } 975 | else 976 | { 977 | # Commit the transaction 978 | if (not $ldbh->do("COMMIT")) { 979 | dprint('ERROR', "can not commit a transaction, reason: " . $ldbh->errstr); 980 | delete_job($ldbh, $jobid); 981 | end_subprocess($ldbh, $jobid); 982 | } 983 | } 984 | delete_job($ldbh, $jobid); 985 | 986 | my $t1 = Time::HiRes::time; 987 | # Store the execution result in table all_job_run_details 988 | my @ret = store_job_execution_details( $ldbh, $ASYNC_JOBS{ $jobid }{ 'log_user' }, 989 | $jobid, $start_t, $t1 - $t0, 990 | $status, $errstr, $success, $sqlstate); 991 | 992 | $ldbh->disconnect() if (defined $ldbh); 993 | if ($#ret >= 0) { 994 | print STDERR "ERROR: can't execute statement: \"$ret[0]\", $ret[1]\n"; 995 | } 996 | } 997 | 998 | end_subprocess($ldbh, $jobid); 999 | } 1000 | 1001 | #### 1002 | # Store the history of the job execution 1003 | #### 1004 | sub store_job_execution_details 1005 | { 1006 | my ($ldbh, $owner, $jobid, $start_date, $duration, $errstr, $pqstatus, $success, $sqlstate) = @_; 1007 | 1008 | $pqstatus =~ s/'/''/g; 1009 | $errstr =~ s/'/''/g; 1010 | $sqlstate =~ s/'/''/g; 1011 | 1012 | my $query = "INSERT INTO dbms_job.all_scheduler_job_run_details (owner, job_name, status, error, req_start_date, actual_start_date, run_duration, slave_pid, additional_info)"; 1013 | $query .= " VALUES ('$owner', '$jobid', "; 1014 | $query .= "'$pqstatus', '$sqlstate', NULL, '$start_date', $duration, "; 1015 | $query .= "$$, '$errstr')"; 1016 | 1017 | if (not $ldbh->do($query)) 1018 | { 1019 | dprint('ERROR', "can't execute statement: \"$query\", $DBI::errstr"); 1020 | return ($query, $DBI::errstr);; 1021 | } 1022 | return (); 1023 | } 1024 | 1025 | #### 1026 | # Execute the scheduled job's plpgsql code on the remote database 1027 | #### 1028 | sub subprocess_scheduled_jobs 1029 | { 1030 | my $jobid = shift; 1031 | 1032 | my $start_t = strftime('%Y-%m-%d %H:%M:%S', localtime); 1033 | 1034 | $0 = "pg_dbms_job:scheduled:$jobid"; 1035 | 1036 | # Subprocess must completed their work in case 1037 | # of interruption unless we received SIGINT 1038 | $SIG{TERM} = 'IGNORE'; 1039 | $SIG{HUP} = 'IGNORE'; 1040 | 1041 | dprint('LOG', "executing job $jobid"); 1042 | if ($CONFIG{ 'debug' }) 1043 | { 1044 | foreach my $k (sort { $a <=> $b } keys %{ $SCHEDULED_JOBS{ $jobid } }) 1045 | { 1046 | dprint('DEBUG', "job $jobid with parameter $k: $SCHEDULED_JOBS{ $jobid }{ $k }"); 1047 | } 1048 | } 1049 | 1050 | # Clone the connection to the database 1051 | my $ldbh = $dbh->clone(); 1052 | 1053 | if (defined $ldbh) 1054 | { 1055 | my $t0 = Time::HiRes::time; 1056 | 1057 | # Set application name to pg_dbms_job:jobid 1058 | if (not $ldbh->do("SET application_name TO 'pg_dbms_job:scheduled:$jobid'")) 1059 | { 1060 | dprint('ERROR', "can not set application_name, reason: " . $ldbh->errstr); 1061 | end_subprocess($ldbh, $jobid); 1062 | } 1063 | 1064 | # Set role for the code execution 1065 | if ($SCHEDULED_JOBS{ $jobid }{ 'log_user' }) 1066 | { 1067 | if (not $ldbh->do("SET ROLE $SCHEDULED_JOBS{ $jobid }{ 'log_user' }")) 1068 | { 1069 | dprint('ERROR', "can not change role, reason: " . $ldbh->errstr); 1070 | end_subprocess($ldbh, $jobid); 1071 | } 1072 | } 1073 | 1074 | # start a transaction 1075 | if (not $ldbh->do("BEGIN")) 1076 | { 1077 | dprint('ERROR', "can not start a transaction, reason: " . $ldbh->errstr); 1078 | end_subprocess($ldbh, $jobid); 1079 | } 1080 | 1081 | # Set search_path for the code execution 1082 | if ($SCHEDULED_JOBS{ $jobid }{ 'schema_user' }) 1083 | { 1084 | if (not $ldbh->do("SET LOCAL search_path TO $SCHEDULED_JOBS{ $jobid }{ 'schema_user' }")) 1085 | { 1086 | dprint('ERROR', "can not change the search_path, reason: " . $ldbh->errstr); 1087 | end_subprocess($ldbh, $jobid); 1088 | } 1089 | } 1090 | 1091 | my $success = 1; 1092 | my $errstr = ''; 1093 | my $status = ''; 1094 | my $sqlstate = ''; 1095 | 1096 | my $codetoexec = qq{DO \$pg_dbms_job\$ 1097 | DECLARE 1098 | job bigint := $jobid; 1099 | next_date timestamp with time zone := current_timestamp; 1100 | broken boolean := false; 1101 | BEGIN 1102 | $SCHEDULED_JOBS{ $jobid }{ 'what' } 1103 | END; 1104 | \$pg_dbms_job\$; 1105 | }; 1106 | dprint('DEBUG', "executing code of job id $jobid: $SCHEDULED_JOBS{ $jobid }{ 'what' }"); 1107 | 1108 | # ----------------------------------------------------------------------------- 1109 | # In 12c when a job fails dbms_jobs.last_date retains the previous date 1110 | # of the last successful run and dbms_jobs.failures is incremented. 1111 | # When the job completes successfully dbms_jobs.last_date is updated and 1112 | # dbms_jobs.failures is set to zero. If a new job never runs successfully 1113 | # dbms_jobs.last_date will remain null and dbms_jobs.failures increments. 1114 | # 1115 | # In 19c when a job fails dbms_jobs.last_date is updated and dbms_jobs.failures 1116 | # is incremented. When the job completes successfully dbms_jobs.last_date is 1117 | # updated however dbms_jobs.failures does not get reset to zero. If a new job 1118 | # never runs successfully dbms_jobs.last_date is updated and dbms_jobs.failures 1119 | # increments. 1120 | # 1121 | # Here this is the 12c behavior who is retained. 1122 | # ----------------------------------------------------------------------------- 1123 | 1124 | # Execute the code of the WHAT column 1125 | if (not $ldbh->do($codetoexec)) 1126 | { 1127 | $success = 0; 1128 | $errstr = $ldbh->errstr; 1129 | $status = $PQSTATUS{$ldbh->err} || ''; 1130 | $sqlstate = $ldbh->state || ''; 1131 | dprint('ERROR', "job $jobid failure, reason: $errstr"); 1132 | # Rollback the transaction 1133 | if (not $ldbh->do("ROLLBACK")) 1134 | { 1135 | dprint('ERROR', "can not rollback a transaction, reason: " . $ldbh->errstr); 1136 | end_subprocess($ldbh, $jobid); 1137 | } 1138 | else 1139 | { 1140 | my $t1 = Time::HiRes::time; 1141 | my $timediff = $t1 - $t0; 1142 | # Update the begin execution date for this job and the total 1143 | # number of times that the job has failed to complete since 1144 | # it’s last successful execution. 1145 | my $updt = "UPDATE dbms_job.all_scheduled_jobs SET"; 1146 | $updt .= " this_date = NULL,"; 1147 | $updt .= " failures = failures+1"; 1148 | $updt .= " WHERE job = $jobid"; 1149 | if (not $ldbh->do($updt)) 1150 | { 1151 | dprint('ERROR', "can not update dbms_job.all_scheduled_jobs for job id $jobid, reason: " . $ldbh->errstr); 1152 | end_subprocess($ldbh, $jobid); 1153 | } 1154 | } 1155 | } 1156 | else 1157 | { 1158 | # Commit the transaction 1159 | if (not $ldbh->do("COMMIT")) 1160 | { 1161 | dprint('ERROR', "can not commit a transaction, reason: " . $ldbh->errstr); 1162 | end_subprocess($ldbh, $jobid); 1163 | } 1164 | } 1165 | 1166 | my $t1 = Time::HiRes::time; 1167 | 1168 | my $timediff = $t1 - $t0; 1169 | # Update the begin execution date for this job, the last successful execution date 1170 | # the total execution time of the job and reset the failure counter 1171 | my $updt = "UPDATE dbms_job.all_scheduled_jobs SET"; 1172 | $updt .= " this_date = NULL,"; 1173 | $updt .= " last_date = current_timestamp,"; 1174 | $updt .= " total_time = '$timediff seconds'::interval,"; 1175 | $updt .= " failures = 0,"; 1176 | $updt .= " instance = instance+1"; # internal used only to not be notified for this change 1177 | $updt .= " WHERE job = $jobid"; 1178 | if (not $ldbh->do($updt)) 1179 | { 1180 | dprint('ERROR', "can not update dbms_job.all_scheduled_jobs for job id $jobid, reason: " . $ldbh->errstr); 1181 | end_subprocess($ldbh, $jobid); 1182 | } 1183 | 1184 | # Store the execution result in table all_job_run_details 1185 | my @ret = store_job_execution_details( $ldbh, $SCHEDULED_JOBS{ $jobid }{ 'log_user' }, 1186 | $jobid, $start_t, $t1 - $t0, 1187 | $status, $errstr, $success, $sqlstate); 1188 | 1189 | $ldbh->disconnect() if (defined $ldbh); 1190 | if ($#ret >= 0) { 1191 | print STDERR "ERROR: can't execute statement: \"$ret[0]\", $ret[1]\n"; 1192 | } 1193 | } 1194 | end_subprocess($ldbh, $jobid); 1195 | } 1196 | 1197 | -------------------------------------------------------------------------------- /etc/pg_dbms_job.conf: -------------------------------------------------------------------------------- 1 | #----------- 2 | # General 3 | #----------- 4 | # Toogle debug mode 5 | debug=0 6 | # Path to the pid file 7 | pidfile=/tmp/pg_dbms_job.pid 8 | # log file name pattern, can include strftime() escapes, for example 9 | # to have a log file per week day use %a in the log file name. 10 | logfile=/tmp/pg_dbms_job.log 11 | # If activated an existing log file with the same name as the new log 12 | # file will be truncated rather than appended to. But such truncation 13 | # only occurs on time-driven rotation, not on restarts. 14 | log_truncate_on_rotation=0 15 | # Poll interval of the job queue 16 | job_queue_interval=5 17 | # Maximum number of job processed at the same time 18 | job_queue_processes=1000 19 | # Time to wait in the main loop before each run (to free some CPU resources) 20 | nap_time = 0.1 21 | 22 | #----------- 23 | # Database 24 | #----------- 25 | host=localhost 26 | port=5432 27 | database=dbms_job 28 | user=gilles 29 | passwd=gilles 30 | 31 | -------------------------------------------------------------------------------- /pg_dbms_job.control: -------------------------------------------------------------------------------- 1 | comment = 'Extension to add Oracle DBMS_JOB full compatibility to PostgreSQL' 2 | default_version = '1.5.0' 3 | module_pathname = '$libdir/pg_dbms_job' 4 | schema = 'dbms_job' 5 | relocatable = false 6 | -------------------------------------------------------------------------------- /sql/pg_dbms_job--1.0.1.sql: -------------------------------------------------------------------------------- 1 | ---- 2 | -- Script to create the base objects of the pg_dbms_job extension 3 | ---- 4 | CREATE SEQUENCE dbms_job.jobseq; 5 | 6 | -- Table used to store the jobs to run by the scheduler 7 | CREATE TABLE dbms_job.all_scheduled_jobs ( 8 | job bigint DEFAULT nextval('dbms_job.jobseq') PRIMARY KEY, -- identifier of job 9 | log_user name DEFAULT current_user, -- user that submit the job 10 | priv_user name DEFAULT current_user, -- user whose default privileges apply to this job (not used) 11 | schema_user text DEFAULT current_setting('search_path'), -- default schema used to parse the job 12 | last_date timestamp with time zone, -- date on which this job last successfully executed 13 | last_sec text, -- same as last_date (not used) 14 | this_date timestamp with time zone, -- date that this job started executing, null when the job is not running 15 | this_sec text, -- same as this_date (not used) 16 | next_date timestamp(0) with time zone NOT NULL, -- date that this job will next be executed 17 | next_sec timestamp with time zone, -- same as next_date (not used) 18 | total_time interval, -- total wall clock time spent by the system on this job, in seconds 19 | broken boolean DEFAULT false, -- true: no attempt is made to run this job, false: an attempt is made to run this job 20 | interval text, -- a date function, evaluated at the start of execution, becomes next next_date 21 | failures bigint, -- number of times the job has started and failed since its last success 22 | what text NOT NULL, -- body of the anonymous pl/sql block that the job executes 23 | nls_env text, -- session parameters describing the nls environment of the job (not used) 24 | misc_env bytea, -- Other session parameters that apply to this job (not used) 25 | instance integer DEFAULT 0 -- ID of the instance that can execute or is executing the job (not used) 26 | ); 27 | COMMENT ON TABLE dbms_job.all_scheduled_jobs 28 | IS 'Table used to store the periodical jobs to run by the scheduler.'; 29 | REVOKE ALL ON dbms_job.all_scheduled_jobs FROM PUBLIC; 30 | 31 | -- The user can only see the job that he has created 32 | ALTER TABLE dbms_job.all_scheduled_jobs ENABLE ROW LEVEL SECURITY; 33 | CREATE POLICY dbms_job_policy ON dbms_job.all_scheduled_jobs USING (log_user = current_user); 34 | 35 | -- Create the asynchronous jobs queue, for immediat execution 36 | CREATE TABLE dbms_job.all_async_jobs ( 37 | job bigint DEFAULT nextval('dbms_job.jobseq') PRIMARY KEY, -- identifier of job 38 | log_user name DEFAULT current_user, -- user that submit the job 39 | schema_user text DEFAULT current_setting('search_path'), -- default search_path used to execute the job 40 | create_date timestamp with time zone DEFAULT current_timestamp, -- date on which this job has been created. 41 | what text NOT NULL -- body of the anonymous pl/sql block that the job executes 42 | ); 43 | COMMENT ON TABLE dbms_job.all_async_jobs 44 | IS 'Table used to store the jobs to be run asynchronously by the scheduler.'; 45 | REVOKE ALL ON dbms_job.all_async_jobs FROM PUBLIC; 46 | 47 | -- The user can only see the job that he has created 48 | ALTER TABLE dbms_job.all_async_jobs ENABLE ROW LEVEL SECURITY; 49 | CREATE POLICY dbms_job_policy ON dbms_job.all_async_jobs USING (log_user = current_user); 50 | 51 | -- Create a view similar to DMBS_JOB.ALL_JOBS 52 | CREATE VIEW dbms_job.all_jobs AS 53 | SELECT * FROM dbms_job.all_scheduled_jobs 54 | UNION 55 | SELECT job, log_user, NULL priv_user, schema_user, NULL last_date, NULL last_sec, 56 | NULL this_date, NULL this_sec, create_date next_date, NULL next_sec, NULL total_time, 57 | 'f' broken, NULL "interval", NULL failures, what, NULL nls_env, NULL misc_env, 58 | 0 instance FROM dbms_job.all_async_jobs; 59 | COMMENT ON VIEW dbms_job.all_jobs 60 | IS 'View registering all jobs to be run asynchronously or scheduled.'; 61 | REVOKE ALL ON dbms_job.all_jobs FROM PUBLIC; 62 | 63 | -- Create a table to store the result of the job execution 64 | CREATE TABLE dbms_job.all_scheduler_job_run_details ( 65 | log_id bigserial PRIMARY KEY, -- unique identifier of the log entry 66 | log_date timestamp with time zone DEFAULT current_timestamp, -- date of the log entry 67 | owner name, -- owner of the scheduler job 68 | job_name varchar(261), -- name of the scheduler job 69 | job_subname varchar(261), -- Subname of the Scheduler job (for a chain step job) 70 | status text, -- status of the job run 71 | error char(5), -- error code in the case of an error 72 | req_start_date timestamp with time zone, -- requested start date of the job run 73 | actual_start_date timestamp with time zone, -- actual date on which the job was run 74 | run_duration bigint, -- duration of the job run in seconds 75 | instance_id integer, -- identifier of the instance on which the job was run 76 | session_id integer, -- session identifier of the job run 77 | slave_pid integer, -- process identifier of the slave on which the job was run 78 | cpu_used integer, -- amount of cpu used for the job run 79 | additional_info text -- additional information on the job run, error message, etc. 80 | ); 81 | COMMENT ON TABLE dbms_job.all_scheduler_job_run_details 82 | IS 'Table used to store the information about the jobs executed.'; 83 | REVOKE ALL ON dbms_job.all_scheduler_job_run_details FROM PUBLIC; 84 | 85 | -- The user can only see the job that he has created 86 | ALTER TABLE dbms_job.all_scheduler_job_run_details ENABLE ROW LEVEL SECURITY; 87 | CREATE POLICY dbms_job_policy ON dbms_job.all_scheduler_job_run_details USING (owner = current_user); 88 | 89 | ---- 90 | -- Stored procedures 91 | ---- 92 | CREATE PROCEDURE dbms_job.broken( 93 | jobid IN bigint, 94 | broken IN boolean, 95 | next_date IN timestamp(0) with time zone DEFAULT current_timestamp) 96 | LANGUAGE PLPGSQL 97 | AS $$ 98 | BEGIN 99 | -- interval must be in the future 100 | IF next_date < current_timestamp THEN 101 | RAISE EXCEPTION 'next_val must be a time in the future: %', next_date USING ERRCODE = '23420'; 102 | END IF; 103 | UPDATE dbms_job.all_scheduled_jobs SET broken=$2,next_date=$3 WHERE job=$1; 104 | IF NOT FOUND THEN 105 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 106 | END IF; 107 | END; 108 | $$; 109 | 110 | COMMENT ON PROCEDURE dbms_job.broken(bigint,boolean,timestamp with time zone) 111 | IS 'Disables job execution. Broken jobs are never run.'; 112 | REVOKE ALL ON PROCEDURE dbms_job.broken FROM PUBLIC; 113 | 114 | CREATE PROCEDURE dbms_job.change( 115 | job IN bigint, 116 | what IN text, 117 | next_date IN timestamp(0) with time zone, 118 | job_interval IN text, 119 | instance IN bigint DEFAULT 0, 120 | force IN boolean DEFAULT false) 121 | LANGUAGE PLPGSQL 122 | AS $$ 123 | DECLARE 124 | cols_modified text; 125 | future_date timestamp with time zone; 126 | v_ret bigint; 127 | BEGIN 128 | -- If what, next_date or job_interval are NULL they are kept unchanged 129 | IF what IS NOT NULL THEN 130 | cols_modified := coalesce(cols_modified, '') || 'what=' || quote_literal(what) || ','; 131 | END IF; 132 | IF next_date IS NOT NULL THEN 133 | cols_modified := coalesce(cols_modified, '') || 'next_date=' || quote_literal(next_date) || ','; 134 | END IF; 135 | IF job_interval IS NOT NULL THEN 136 | -- interval must be in the future 137 | future_date := dbms_job.get_next_date(job_interval); 138 | IF future_date < current_timestamp THEN 139 | RAISE EXCEPTION 'Interval must evaluate to a time in the future: %', future_date USING ERRCODE = '23420'; 140 | END IF; 141 | cols_modified := coalesce(cols_modified, '') || 'interval=' || quote_literal(job_interval) || ','; 142 | END IF; 143 | IF cols_modified IS NOT NULL THEN 144 | EXECUTE 'UPDATE dbms_job.all_scheduled_jobs SET ' || rtrim(cols_modified, ',') || ' WHERE job=$1 RETURNING job'INTO v_ret USING job; 145 | IF v_ret IS NULL THEN 146 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 147 | END IF; 148 | END IF; 149 | END; 150 | $$; 151 | COMMENT ON PROCEDURE dbms_job.change(bigint,text,timestamp with time zone,text,bigint,boolean) 152 | IS 'Alters any of the user-definable parameters associated with a job'; 153 | REVOKE ALL ON PROCEDURE dbms_job.change FROM PUBLIC; 154 | 155 | CREATE PROCEDURE dbms_job.interval( 156 | jobid IN bigint, 157 | job_interval IN text) 158 | LANGUAGE PLPGSQL 159 | AS $$ 160 | DECLARE 161 | next_date timestamp with time zone; 162 | BEGIN 163 | IF job_interval IS NULL THEN 164 | UPDATE dbms_job.all_scheduled_jobs SET interval = NULL WHERE job = jobid; 165 | ELSE 166 | -- interval must be in the future 167 | next_date := dbms_job.get_next_date(job_interval); 168 | IF next_date < current_timestamp THEN 169 | RAISE EXCEPTION 'Interval must evaluate to a time in the future: %', next_date USING ERRCODE = '23420'; 170 | END IF; 171 | UPDATE dbms_job.all_scheduled_jobs SET interval = quote_literal(job_interval) WHERE job = jobid; 172 | END IF; 173 | IF NOT FOUND THEN 174 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 175 | END IF; 176 | END; 177 | $$; 178 | 179 | COMMENT ON PROCEDURE dbms_job.interval(bigint,text) 180 | IS 'Alters the interval between executions for a specified job'; 181 | REVOKE ALL ON PROCEDURE dbms_job.interval FROM PUBLIC; 182 | 183 | CREATE PROCEDURE dbms_job.next_date( 184 | jobid IN bigint, 185 | next_date IN timestamp(0) with time zone) 186 | LANGUAGE PLPGSQL 187 | AS $$ 188 | BEGIN 189 | IF next_date IS NULL THEN 190 | RAISE EXCEPTION 'Next date can not be NULL'; 191 | END IF; 192 | UPDATE dbms_job.all_scheduled_jobs SET next_date = $2 WHERE job = jobid; 193 | IF NOT FOUND THEN 194 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 195 | END IF; 196 | END; 197 | $$; 198 | 199 | COMMENT ON PROCEDURE dbms_job.next_date(bigint,timestamp with time zone) 200 | IS 'Alters the next execution time for a specified job'; 201 | REVOKE ALL ON PROCEDURE dbms_job.next_date FROM PUBLIC; 202 | 203 | CREATE PROCEDURE dbms_job.remove( 204 | jobid IN bigint) 205 | LANGUAGE PLPGSQL 206 | AS $$ 207 | BEGIN 208 | DELETE FROM dbms_job.all_scheduled_jobs WHERE job = jobid; 209 | IF NOT FOUND THEN 210 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 211 | END IF; 212 | END; 213 | $$; 214 | 215 | COMMENT ON PROCEDURE dbms_job.remove(bigint) 216 | IS 'Removes specified job from the job queue'; 217 | REVOKE ALL ON PROCEDURE dbms_job.remove FROM PUBLIC; 218 | 219 | CREATE PROCEDURE dbms_job.run( 220 | jobid IN bigint, 221 | force IN boolean DEFAULT false) 222 | LANGUAGE PLPGSQL 223 | AS $$ 224 | DECLARE 225 | v_what text; 226 | tmp_what text; 227 | start_t timestamp with time zone; 228 | end_t timestamp with time zone; 229 | v_state text; 230 | v_msg text; 231 | v_detail text; 232 | v_hint text; 233 | v_context text; 234 | BEGIN 235 | IF jobid IS NULL THEN 236 | RETURN; 237 | END IF; 238 | -- Get the job definition 239 | SELECT what INTO v_what FROM dbms_job.all_scheduled_jobs WHERE job = jobid; 240 | IF v_what IS NULL THEN 241 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 242 | END IF; 243 | -- When force is false execute the job immediatly in foreground 244 | IF NOT force THEN 245 | start_t := clock_timestamp(); 246 | -- Remove BEGIN/END from the code 247 | SELECT regexp_replace(v_what, 'BEGIN\s+(.*)\s*END;', '\1', 'i') INTO tmp_what; 248 | UPDATE dbms_job.all_scheduled_jobs SET this_date = start_t WHERE job = jobid; 249 | BEGIN 250 | EXECUTE tmp_what; 251 | EXCEPTION 252 | WHEN others THEN 253 | -- Increase the failure count 254 | UPDATE dbms_job.all_scheduled_jobs SET 255 | failures = failures + 1 256 | WHERE job = jobid; 257 | -- Rethrow the exception 258 | RAISE; 259 | END; 260 | end_t := clock_timestamp(); 261 | -- Update job's statistics 262 | UPDATE dbms_job.all_scheduled_jobs SET 263 | last_date = end_t, 264 | this_date = NULL, 265 | total_time = total_time + ((EXTRACT(EPOCH FROM end_t) - EXTRACT(EPOCH FROM start_t)) || ' seconds')::interval, 266 | failures = 0, 267 | instance = instance+1, 268 | broken = false, 269 | next_date = dbms_job.get_next_date(interval) 270 | WHERE job = jobid; 271 | -- No write to history table in foreground mode 272 | ELSE 273 | -- Execute the job in background by submitting an asynchronous job 274 | SELECT dbms_job.submit(v_what) INTO jobid; 275 | END IF; 276 | END; 277 | $$; 278 | COMMENT ON PROCEDURE dbms_job.run(bigint, boolean) 279 | IS 'Forces a specified job to run immediatly. It runs even if it is broken'; 280 | REVOKE ALL ON PROCEDURE dbms_job.run FROM PUBLIC; 281 | 282 | CREATE FUNCTION dbms_job.submit( 283 | jobid OUT bigint, 284 | what IN text, 285 | next_date IN timestamp(0) with time zone DEFAULT current_timestamp, 286 | job_interval IN text DEFAULT NULL, 287 | no_parse IN boolean DEFAULT false) 288 | RETURNS bigint 289 | LANGUAGE PLPGSQL 290 | AS $$ 291 | BEGIN 292 | -- interval must be in the future 293 | IF next_date < current_timestamp THEN 294 | RAISE EXCEPTION 'next_date must be a time in the future: %', next_date USING ERRCODE = '23420'; 295 | END IF; 296 | -- When an interval is defined this is a job to be scheduled 297 | IF job_interval IS NOT NULL THEN 298 | INSERT INTO dbms_job.all_scheduled_jobs (what,next_date,interval) VALUES ($2,$3,$4) RETURNING job INTO jobid; 299 | ELSE 300 | -- With no interval verify if the job is planned in 301 | -- the future or that it must be executed immediatly 302 | IF next_date > current_timestamp THEN 303 | INSERT INTO dbms_job.all_scheduled_jobs (what,next_date,interval) VALUES ($2,$3,$4) RETURNING job INTO jobid; 304 | ELSE 305 | -- This is an immediate asynchronous execution, use the special queue 306 | INSERT INTO dbms_job.all_async_jobs (what) VALUES ($2) RETURNING job INTO jobid; 307 | END IF; 308 | END IF; 309 | END; 310 | $$; 311 | COMMENT ON FUNCTION dbms_job.submit(text,timestamp with time zone,text,boolean) 312 | IS 'Submits a new job to the job queue.'; 313 | REVOKE ALL ON FUNCTION dbms_job.submit FROM PUBLIC; 314 | 315 | CREATE PROCEDURE dbms_job.what( 316 | job IN bigint, 317 | what IN text) 318 | LANGUAGE SQL 319 | AS 'UPDATE dbms_job.all_scheduled_jobs SET what=$2 WHERE job=$1'; 320 | COMMENT ON PROCEDURE dbms_job.what(bigint,text) 321 | IS 'Alters the job description for a specified job'; 322 | REVOKE ALL ON PROCEDURE dbms_job.what FROM PUBLIC; 323 | 324 | CREATE FUNCTION dbms_job.job_scheduled_notify() 325 | RETURNS trigger 326 | LANGUAGE PLPGSQL 327 | AS $$ 328 | BEGIN 329 | -- Force interval to be NULL if this is set to an empty string 330 | IF TG_OP = 'UPDATE' OR TG_OP = 'INSERT' THEN 331 | IF NEW.interval = '' THEN 332 | NEW.interval := NULL; 333 | END IF; 334 | END IF; 335 | -- When a change occurs in the all_scheduled_jobs table, notify the scheduler. 336 | IF TG_OP = 'UPDATE' THEN 337 | -- We do not notify the scheduler if it is at the origine of the UPDATE. 338 | -- We increment the value of the instance column when this is an internal 339 | -- update after an execution. 340 | IF NEW.instance = OLD.instance THEN 341 | PERFORM pg_notify('dbms_job_scheduled_notify', TG_OP || ':' || OLD.job || ':' || NEW.job); 342 | END IF; 343 | RETURN NEW; 344 | END IF; 345 | IF TG_OP = 'INSERT' THEN 346 | PERFORM pg_notify('dbms_job_scheduled_notify', TG_OP || ':' || NEW.job); 347 | RETURN NEW; 348 | END IF; 349 | IF TG_OP = 'DELETE' THEN 350 | PERFORM pg_notify('dbms_job_scheduled_notify', TG_OP || ':' || OLD.job); 351 | RETURN OLD; 352 | END IF; 353 | -- TRUNCATE 354 | PERFORM pg_notify('dbms_job_scheduled_notify', TG_OP); 355 | RETURN OLD; 356 | END; 357 | $$; 358 | COMMENT ON FUNCTION dbms_job.job_scheduled_notify() 359 | IS 'Notify the scheduler that the job cache must be invalidated'; 360 | 361 | -- When there is a modification in the JOB table invalidate the cache 362 | -- to inform the background worker to reread the table 363 | CREATE TRIGGER dbms_job_scheduled_notify_trg 364 | AFTER INSERT OR UPDATE OR DELETE OR TRUNCATE 365 | ON dbms_job.all_scheduled_jobs 366 | FOR STATEMENT EXECUTE FUNCTION dbms_job.job_scheduled_notify(); 367 | 368 | CREATE FUNCTION dbms_job.job_async_notify() 369 | RETURNS trigger 370 | LANGUAGE PLPGSQL 371 | AS $$ 372 | BEGIN 373 | -- When a new async job is submitted, notify the scheduler 374 | PERFORM pg_notify('dbms_job_async_notify', 'New asynchronous job received'); 375 | RETURN NEW; 376 | END; 377 | $$; 378 | COMMENT ON FUNCTION dbms_job.job_async_notify() 379 | IS 'Notify the scheduler that a new asynchronous job was submitted'; 380 | 381 | -- When there is a new asynchronous job submited 382 | -- to inform the daemon to reread the table 383 | CREATE TRIGGER dbms_job_async_notify_trg 384 | AFTER INSERT 385 | ON dbms_job.all_async_jobs 386 | FOR STATEMENT EXECUTE FUNCTION dbms_job.job_async_notify(); 387 | 388 | CREATE FUNCTION dbms_job.get_next_date(text) 389 | RETURNS timestamp(0) with time zone 390 | LANGUAGE PLPGSQL 391 | AS $$ 392 | DECLARE 393 | next_date timestamp(0) with time zone; 394 | BEGIN 395 | EXECUTE 'SELECT '||$1 INTO next_date; 396 | RETURN next_date; 397 | END; 398 | $$; 399 | COMMENT ON FUNCTION dbms_job.get_next_date(text) 400 | IS 'Used to get the next date returned by the interval code'; 401 | 402 | -------------------------------------------------------------------------------- /sql/pg_dbms_job--1.2.0.sql: -------------------------------------------------------------------------------- 1 | ---- 2 | -- Script to create the base objects of the pg_dbms_job extension 3 | ---- 4 | CREATE SEQUENCE dbms_job.jobseq; 5 | 6 | -- Table used to store the jobs to run by the scheduler 7 | CREATE TABLE dbms_job.all_scheduled_jobs ( 8 | job bigint DEFAULT nextval('dbms_job.jobseq') PRIMARY KEY, -- identifier of job 9 | log_user name DEFAULT current_user, -- user that submit the job 10 | priv_user name DEFAULT current_user, -- user whose default privileges apply to this job (not used) 11 | schema_user text DEFAULT current_setting('search_path'), -- default schema used to parse the job 12 | last_date timestamp with time zone, -- date on which this job last successfully executed 13 | last_sec text, -- same as last_date (not used) 14 | this_date timestamp with time zone, -- date that this job started executing, null when the job is not running 15 | this_sec text, -- same as this_date (not used) 16 | next_date timestamp(0) with time zone NOT NULL, -- date that this job will next be executed 17 | next_sec timestamp with time zone, -- same as next_date (not used) 18 | total_time interval, -- total wall clock time spent by the system on this job, in seconds 19 | broken boolean DEFAULT false, -- true: no attempt is made to run this job, false: an attempt is made to run this job 20 | interval text, -- a date function, evaluated at the start of execution, becomes next next_date 21 | failures bigint, -- number of times the job has started and failed since its last success 22 | what text NOT NULL, -- body of the anonymous pl/sql block that the job executes 23 | nls_env text, -- session parameters describing the nls environment of the job (not used) 24 | misc_env bytea, -- Other session parameters that apply to this job (not used) 25 | instance integer DEFAULT 0 -- ID of the instance that can execute or is executing the job (not used) 26 | ); 27 | COMMENT ON TABLE dbms_job.all_scheduled_jobs 28 | IS 'Table used to store the periodical jobs to run by the scheduler.'; 29 | REVOKE ALL ON dbms_job.all_scheduled_jobs FROM PUBLIC; 30 | 31 | -- The user can only see the job that he has created 32 | ALTER TABLE dbms_job.all_scheduled_jobs ENABLE ROW LEVEL SECURITY; 33 | CREATE POLICY dbms_job_policy ON dbms_job.all_scheduled_jobs USING (log_user = current_user); 34 | 35 | -- Create the asynchronous jobs queue, for immediat execution 36 | CREATE TABLE dbms_job.all_async_jobs ( 37 | job bigint DEFAULT nextval('dbms_job.jobseq') PRIMARY KEY, -- identifier of job 38 | log_user name DEFAULT current_user, -- user that submit the job 39 | schema_user text DEFAULT current_setting('search_path'), -- default search_path used to execute the job 40 | create_date timestamp with time zone DEFAULT current_timestamp, -- date on which this job has been created. 41 | what text NOT NULL, -- body of the anonymous pl/sql block that the job executes 42 | this_date timestamp with time zone -- date that this job started executing, null when the job is not running 43 | ); 44 | COMMENT ON TABLE dbms_job.all_async_jobs 45 | IS 'Table used to store the jobs to be run asynchronously by the scheduler.'; 46 | REVOKE ALL ON dbms_job.all_async_jobs FROM PUBLIC; 47 | 48 | -- The user can only see the job that he has created 49 | ALTER TABLE dbms_job.all_async_jobs ENABLE ROW LEVEL SECURITY; 50 | CREATE POLICY dbms_job_policy ON dbms_job.all_async_jobs USING (log_user = current_user); 51 | 52 | -- Create a view similar to DMBS_JOB.ALL_JOBS 53 | CREATE VIEW dbms_job.all_jobs AS 54 | SELECT * FROM dbms_job.all_scheduled_jobs 55 | UNION 56 | SELECT job, log_user, NULL priv_user, schema_user, NULL last_date, NULL last_sec, 57 | NULL this_date, NULL this_sec, create_date next_date, NULL next_sec, NULL total_time, 58 | 'f' broken, NULL "interval", NULL failures, what, NULL nls_env, NULL misc_env, 59 | 0 instance FROM dbms_job.all_async_jobs; 60 | COMMENT ON VIEW dbms_job.all_jobs 61 | IS 'View registering all jobs to be run asynchronously or scheduled.'; 62 | REVOKE ALL ON dbms_job.all_jobs FROM PUBLIC; 63 | 64 | -- Create a table to store the result of the job execution 65 | CREATE TABLE dbms_job.all_scheduler_job_run_details ( 66 | log_id bigserial PRIMARY KEY, -- unique identifier of the log entry 67 | log_date timestamp with time zone DEFAULT current_timestamp, -- date of the log entry 68 | owner name, -- owner of the scheduler job 69 | job_name varchar(261), -- name of the scheduler job 70 | job_subname varchar(261), -- Subname of the Scheduler job (for a chain step job) 71 | status text, -- status of the job run 72 | error char(5), -- error code in the case of an error 73 | req_start_date timestamp with time zone, -- requested start date of the job run 74 | actual_start_date timestamp with time zone, -- actual date on which the job was run 75 | run_duration bigint, -- duration of the job run in seconds 76 | instance_id integer, -- identifier of the instance on which the job was run 77 | session_id integer, -- session identifier of the job run 78 | slave_pid integer, -- process identifier of the slave on which the job was run 79 | cpu_used integer, -- amount of cpu used for the job run 80 | additional_info text -- additional information on the job run, error message, etc. 81 | ); 82 | COMMENT ON TABLE dbms_job.all_scheduler_job_run_details 83 | IS 'Table used to store the information about the jobs executed.'; 84 | REVOKE ALL ON dbms_job.all_scheduler_job_run_details FROM PUBLIC; 85 | 86 | -- The user can only see the job that he has created 87 | ALTER TABLE dbms_job.all_scheduler_job_run_details ENABLE ROW LEVEL SECURITY; 88 | CREATE POLICY dbms_job_policy ON dbms_job.all_scheduler_job_run_details USING (owner = current_user); 89 | 90 | ---- 91 | -- Stored procedures 92 | ---- 93 | CREATE PROCEDURE dbms_job.broken( 94 | jobid IN bigint, 95 | broken IN boolean, 96 | next_date IN timestamp(0) with time zone DEFAULT current_timestamp) 97 | LANGUAGE PLPGSQL 98 | AS $$ 99 | BEGIN 100 | -- interval must be in the future 101 | IF next_date < current_timestamp THEN 102 | RAISE EXCEPTION 'next_val must be a time in the future: %', next_date USING ERRCODE = '23420'; 103 | END IF; 104 | UPDATE dbms_job.all_scheduled_jobs SET broken=$2,next_date=$3 WHERE job=$1; 105 | IF NOT FOUND THEN 106 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 107 | END IF; 108 | END; 109 | $$; 110 | 111 | COMMENT ON PROCEDURE dbms_job.broken(bigint,boolean,timestamp with time zone) 112 | IS 'Disables job execution. Broken jobs are never run.'; 113 | REVOKE ALL ON PROCEDURE dbms_job.broken FROM PUBLIC; 114 | 115 | CREATE PROCEDURE dbms_job.change( 116 | job IN bigint, 117 | what IN text, 118 | next_date IN timestamp(0) with time zone, 119 | job_interval IN text, 120 | instance IN bigint DEFAULT 0, 121 | force IN boolean DEFAULT false) 122 | LANGUAGE PLPGSQL 123 | AS $$ 124 | DECLARE 125 | cols_modified text; 126 | future_date timestamp with time zone; 127 | v_ret bigint; 128 | BEGIN 129 | -- If what, next_date or job_interval are NULL they are kept unchanged 130 | IF what IS NOT NULL THEN 131 | cols_modified := coalesce(cols_modified, '') || 'what=' || quote_literal(what) || ','; 132 | END IF; 133 | IF next_date IS NOT NULL THEN 134 | cols_modified := coalesce(cols_modified, '') || 'next_date=' || quote_literal(next_date) || ','; 135 | END IF; 136 | IF job_interval IS NOT NULL THEN 137 | -- interval must be in the future 138 | future_date := dbms_job.get_next_date(job_interval); 139 | IF future_date < current_timestamp THEN 140 | RAISE EXCEPTION 'Interval must evaluate to a time in the future: %', future_date USING ERRCODE = '23420'; 141 | END IF; 142 | cols_modified := coalesce(cols_modified, '') || 'interval=' || quote_literal(job_interval) || ','; 143 | END IF; 144 | IF cols_modified IS NOT NULL THEN 145 | EXECUTE 'UPDATE dbms_job.all_scheduled_jobs SET ' || rtrim(cols_modified, ',') || ' WHERE job=$1 RETURNING job'INTO v_ret USING job; 146 | IF v_ret IS NULL THEN 147 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 148 | END IF; 149 | END IF; 150 | END; 151 | $$; 152 | COMMENT ON PROCEDURE dbms_job.change(bigint,text,timestamp with time zone,text,bigint,boolean) 153 | IS 'Alters any of the user-definable parameters associated with a job'; 154 | REVOKE ALL ON PROCEDURE dbms_job.change FROM PUBLIC; 155 | 156 | CREATE PROCEDURE dbms_job.interval( 157 | jobid IN bigint, 158 | job_interval IN text) 159 | LANGUAGE PLPGSQL 160 | AS $$ 161 | DECLARE 162 | next_date timestamp with time zone; 163 | BEGIN 164 | IF job_interval IS NULL THEN 165 | UPDATE dbms_job.all_scheduled_jobs SET interval = NULL WHERE job = jobid; 166 | ELSE 167 | -- interval must be in the future 168 | next_date := dbms_job.get_next_date(job_interval); 169 | IF next_date < current_timestamp THEN 170 | RAISE EXCEPTION 'Interval must evaluate to a time in the future: %', next_date USING ERRCODE = '23420'; 171 | END IF; 172 | UPDATE dbms_job.all_scheduled_jobs SET interval = quote_literal(job_interval) WHERE job = jobid; 173 | END IF; 174 | IF NOT FOUND THEN 175 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 176 | END IF; 177 | END; 178 | $$; 179 | 180 | COMMENT ON PROCEDURE dbms_job.interval(bigint,text) 181 | IS 'Alters the interval between executions for a specified job'; 182 | REVOKE ALL ON PROCEDURE dbms_job.interval FROM PUBLIC; 183 | 184 | CREATE PROCEDURE dbms_job.next_date( 185 | jobid IN bigint, 186 | next_date IN timestamp(0) with time zone) 187 | LANGUAGE PLPGSQL 188 | AS $$ 189 | BEGIN 190 | IF next_date IS NULL THEN 191 | RAISE EXCEPTION 'Next date can not be NULL'; 192 | END IF; 193 | UPDATE dbms_job.all_scheduled_jobs SET next_date = $2 WHERE job = jobid; 194 | IF NOT FOUND THEN 195 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 196 | END IF; 197 | END; 198 | $$; 199 | 200 | COMMENT ON PROCEDURE dbms_job.next_date(bigint,timestamp with time zone) 201 | IS 'Alters the next execution time for a specified job'; 202 | REVOKE ALL ON PROCEDURE dbms_job.next_date FROM PUBLIC; 203 | 204 | CREATE PROCEDURE dbms_job.remove( 205 | jobid IN bigint) 206 | LANGUAGE PLPGSQL 207 | AS $$ 208 | BEGIN 209 | DELETE FROM dbms_job.all_scheduled_jobs WHERE job = jobid; 210 | IF NOT FOUND THEN 211 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 212 | END IF; 213 | END; 214 | $$; 215 | 216 | COMMENT ON PROCEDURE dbms_job.remove(bigint) 217 | IS 'Removes specified job from the job queue'; 218 | REVOKE ALL ON PROCEDURE dbms_job.remove FROM PUBLIC; 219 | 220 | CREATE PROCEDURE dbms_job.run( 221 | jobid IN bigint, 222 | force IN boolean DEFAULT false) 223 | LANGUAGE PLPGSQL 224 | AS $$ 225 | DECLARE 226 | v_what text; 227 | tmp_what text; 228 | start_t timestamp with time zone; 229 | end_t timestamp with time zone; 230 | v_state text; 231 | v_msg text; 232 | v_detail text; 233 | v_hint text; 234 | v_context text; 235 | BEGIN 236 | IF jobid IS NULL THEN 237 | RETURN; 238 | END IF; 239 | -- Get the job definition 240 | SELECT what INTO v_what FROM dbms_job.all_scheduled_jobs WHERE job = jobid; 241 | IF v_what IS NULL THEN 242 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 243 | END IF; 244 | -- When force is false execute the job immediatly in foreground 245 | IF NOT force THEN 246 | start_t := clock_timestamp(); 247 | -- Remove BEGIN/END from the code 248 | SELECT regexp_replace(v_what, 'BEGIN\s+(.*)\s*END;', '\1', 'i') INTO tmp_what; 249 | UPDATE dbms_job.all_scheduled_jobs SET this_date = start_t WHERE job = jobid; 250 | BEGIN 251 | EXECUTE tmp_what; 252 | EXCEPTION 253 | WHEN others THEN 254 | -- Increase the failure count 255 | UPDATE dbms_job.all_scheduled_jobs SET 256 | failures = failures + 1 257 | WHERE job = jobid; 258 | -- Rethrow the exception 259 | RAISE; 260 | END; 261 | end_t := clock_timestamp(); 262 | -- Update job's statistics 263 | UPDATE dbms_job.all_scheduled_jobs SET 264 | last_date = end_t, 265 | this_date = NULL, 266 | total_time = total_time + ((EXTRACT(EPOCH FROM end_t) - EXTRACT(EPOCH FROM start_t)) || ' seconds')::interval, 267 | failures = 0, 268 | instance = instance+1, 269 | broken = false, 270 | next_date = dbms_job.get_next_date(interval) 271 | WHERE job = jobid; 272 | -- No write to history table in foreground mode 273 | ELSE 274 | -- Execute the job in background by submitting an asynchronous job 275 | SELECT dbms_job.submit(v_what) INTO jobid; 276 | END IF; 277 | END; 278 | $$; 279 | COMMENT ON PROCEDURE dbms_job.run(bigint, boolean) 280 | IS 'Forces a specified job to run immediatly. It runs even if it is broken'; 281 | REVOKE ALL ON PROCEDURE dbms_job.run FROM PUBLIC; 282 | 283 | CREATE FUNCTION dbms_job.submit( 284 | jobid OUT bigint, 285 | what IN text, 286 | next_date IN timestamp(0) with time zone DEFAULT current_timestamp, 287 | job_interval IN text DEFAULT NULL, 288 | no_parse IN boolean DEFAULT false) 289 | RETURNS bigint 290 | LANGUAGE PLPGSQL 291 | AS $$ 292 | BEGIN 293 | -- interval must be in the future 294 | IF next_date < current_timestamp THEN 295 | RAISE EXCEPTION 'next_date must be a time in the future: %', next_date USING ERRCODE = '23420'; 296 | END IF; 297 | -- When an interval is defined this is a job to be scheduled 298 | IF job_interval IS NOT NULL THEN 299 | INSERT INTO dbms_job.all_scheduled_jobs (what,next_date,interval) VALUES ($2,$3,$4) RETURNING job INTO jobid; 300 | ELSE 301 | -- With no interval verify if the job is planned in 302 | -- the future or that it must be executed immediatly 303 | IF next_date > current_timestamp THEN 304 | INSERT INTO dbms_job.all_scheduled_jobs (what,next_date,interval) VALUES ($2,$3,$4) RETURNING job INTO jobid; 305 | ELSE 306 | -- This is an immediate asynchronous execution, use the special queue 307 | INSERT INTO dbms_job.all_async_jobs (what) VALUES ($2) RETURNING job INTO jobid; 308 | END IF; 309 | END IF; 310 | END; 311 | $$; 312 | COMMENT ON FUNCTION dbms_job.submit(text,timestamp with time zone,text,boolean) 313 | IS 'Submits a new job to the job queue.'; 314 | REVOKE ALL ON FUNCTION dbms_job.submit FROM PUBLIC; 315 | 316 | CREATE PROCEDURE dbms_job.what( 317 | job IN bigint, 318 | what IN text) 319 | LANGUAGE SQL 320 | AS 'UPDATE dbms_job.all_scheduled_jobs SET what=$2 WHERE job=$1'; 321 | COMMENT ON PROCEDURE dbms_job.what(bigint,text) 322 | IS 'Alters the job description for a specified job'; 323 | REVOKE ALL ON PROCEDURE dbms_job.what FROM PUBLIC; 324 | 325 | CREATE FUNCTION dbms_job.job_scheduled_notify() 326 | RETURNS trigger 327 | LANGUAGE PLPGSQL 328 | AS $$ 329 | BEGIN 330 | -- Force interval to be NULL if this is set to an empty string 331 | IF TG_OP = 'UPDATE' OR TG_OP = 'INSERT' THEN 332 | IF NEW.interval = '' THEN 333 | NEW.interval := NULL; 334 | END IF; 335 | END IF; 336 | -- When a change occurs in the all_scheduled_jobs table, notify the scheduler. 337 | IF TG_OP = 'UPDATE' THEN 338 | -- We do not notify the scheduler if it is at the origine of the UPDATE. 339 | -- We increment the value of the instance column when this is an internal 340 | -- update after an execution. 341 | IF NEW.instance = OLD.instance THEN 342 | PERFORM pg_notify('dbms_job_scheduled_notify', TG_OP || ':' || OLD.job || ':' || NEW.job); 343 | END IF; 344 | RETURN NEW; 345 | END IF; 346 | IF TG_OP = 'INSERT' THEN 347 | PERFORM pg_notify('dbms_job_scheduled_notify', TG_OP || ':' || NEW.job); 348 | RETURN NEW; 349 | END IF; 350 | IF TG_OP = 'DELETE' THEN 351 | PERFORM pg_notify('dbms_job_scheduled_notify', TG_OP || ':' || OLD.job); 352 | RETURN OLD; 353 | END IF; 354 | -- TRUNCATE 355 | PERFORM pg_notify('dbms_job_scheduled_notify', TG_OP); 356 | RETURN OLD; 357 | END; 358 | $$; 359 | COMMENT ON FUNCTION dbms_job.job_scheduled_notify() 360 | IS 'Notify the scheduler that the job cache must be invalidated'; 361 | 362 | -- When there is a modification in the JOB table invalidate the cache 363 | -- to inform the background worker to reread the table 364 | CREATE TRIGGER dbms_job_scheduled_notify_trg 365 | AFTER INSERT OR UPDATE OR DELETE OR TRUNCATE 366 | ON dbms_job.all_scheduled_jobs 367 | FOR STATEMENT EXECUTE FUNCTION dbms_job.job_scheduled_notify(); 368 | 369 | CREATE FUNCTION dbms_job.job_async_notify() 370 | RETURNS trigger 371 | LANGUAGE PLPGSQL 372 | AS $$ 373 | BEGIN 374 | -- When a new async job is submitted, notify the scheduler 375 | PERFORM pg_notify('dbms_job_async_notify', 'New asynchronous job received'); 376 | RETURN NEW; 377 | END; 378 | $$; 379 | COMMENT ON FUNCTION dbms_job.job_async_notify() 380 | IS 'Notify the scheduler that a new asynchronous job was submitted'; 381 | 382 | -- When there is a new asynchronous job submited 383 | -- to inform the daemon to reread the table 384 | CREATE TRIGGER dbms_job_async_notify_trg 385 | AFTER INSERT 386 | ON dbms_job.all_async_jobs 387 | FOR STATEMENT EXECUTE FUNCTION dbms_job.job_async_notify(); 388 | 389 | CREATE FUNCTION dbms_job.get_next_date(text) 390 | RETURNS timestamp(0) with time zone 391 | LANGUAGE PLPGSQL 392 | AS $$ 393 | DECLARE 394 | next_date timestamp(0) with time zone; 395 | BEGIN 396 | EXECUTE 'SELECT '||$1 INTO next_date; 397 | RETURN next_date; 398 | END; 399 | $$; 400 | COMMENT ON FUNCTION dbms_job.get_next_date(text) 401 | IS 'Used to get the next date returned by the interval code'; 402 | 403 | -------------------------------------------------------------------------------- /sql/pg_dbms_job--1.3.0.sql: -------------------------------------------------------------------------------- 1 | ---- 2 | -- Script to create the base objects of the pg_dbms_job extension 3 | ---- 4 | CREATE SEQUENCE dbms_job.jobseq; 5 | 6 | -- Table used to store the jobs to run by the scheduler 7 | CREATE TABLE dbms_job.all_scheduled_jobs ( 8 | job bigint DEFAULT nextval('dbms_job.jobseq') PRIMARY KEY, -- identifier of job 9 | log_user name DEFAULT current_user, -- user that submit the job 10 | priv_user name DEFAULT current_user, -- user whose default privileges apply to this job (not used) 11 | schema_user text DEFAULT current_setting('search_path'), -- default schema used to parse the job 12 | last_date timestamp with time zone, -- date on which this job last successfully executed 13 | last_sec text, -- same as last_date (not used) 14 | this_date timestamp with time zone, -- date that this job started executing, null when the job is not running 15 | this_sec text, -- same as this_date (not used) 16 | next_date timestamp(0) with time zone NOT NULL, -- date that this job will next be executed 17 | next_sec timestamp with time zone, -- same as next_date (not used) 18 | total_time interval, -- total wall clock time spent by the system on this job, in seconds 19 | broken boolean DEFAULT false, -- true: no attempt is made to run this job, false: an attempt is made to run this job 20 | interval text, -- a date function, evaluated at the start of execution, becomes next next_date 21 | failures bigint, -- number of times the job has started and failed since its last success 22 | what text NOT NULL, -- body of the anonymous pl/sql block that the job executes 23 | nls_env text, -- session parameters describing the nls environment of the job (not used) 24 | misc_env bytea, -- Other session parameters that apply to this job (not used) 25 | instance integer DEFAULT 0 -- ID of the instance that can execute or is executing the job (not used) 26 | ); 27 | COMMENT ON TABLE dbms_job.all_scheduled_jobs 28 | IS 'Table used to store the periodical jobs to run by the scheduler.'; 29 | REVOKE ALL ON dbms_job.all_scheduled_jobs FROM PUBLIC; 30 | 31 | -- The user can only see the job that he has created 32 | ALTER TABLE dbms_job.all_scheduled_jobs ENABLE ROW LEVEL SECURITY; 33 | CREATE POLICY dbms_job_policy ON dbms_job.all_scheduled_jobs USING (log_user = current_user); 34 | 35 | -- Create the asynchronous jobs queue, for immediat execution 36 | CREATE TABLE dbms_job.all_async_jobs ( 37 | job bigint DEFAULT nextval('dbms_job.jobseq') PRIMARY KEY, -- identifier of job 38 | log_user name DEFAULT current_user, -- user that submit the job 39 | schema_user text DEFAULT current_setting('search_path'), -- default search_path used to execute the job 40 | create_date timestamp with time zone DEFAULT current_timestamp, -- date on which this job has been created. 41 | what text NOT NULL, -- body of the anonymous pl/sql block that the job executes 42 | this_date timestamp with time zone -- date that this job started executing, null when the job is not running 43 | ); 44 | COMMENT ON TABLE dbms_job.all_async_jobs 45 | IS 'Table used to store the jobs to be run asynchronously by the scheduler.'; 46 | REVOKE ALL ON dbms_job.all_async_jobs FROM PUBLIC; 47 | 48 | -- The user can only see the job that he has created 49 | ALTER TABLE dbms_job.all_async_jobs ENABLE ROW LEVEL SECURITY; 50 | CREATE POLICY dbms_job_policy ON dbms_job.all_async_jobs USING (log_user = current_user); 51 | 52 | -- Create a view similar to DMBS_JOB.ALL_JOBS 53 | CREATE VIEW dbms_job.all_jobs AS 54 | SELECT * FROM dbms_job.all_scheduled_jobs 55 | UNION 56 | SELECT job, log_user, NULL priv_user, schema_user, NULL last_date, NULL last_sec, 57 | NULL this_date, NULL this_sec, create_date next_date, NULL next_sec, NULL total_time, 58 | 'f' broken, NULL "interval", NULL failures, what, NULL nls_env, NULL misc_env, 59 | 0 instance FROM dbms_job.all_async_jobs; 60 | COMMENT ON VIEW dbms_job.all_jobs 61 | IS 'View registering all jobs to be run asynchronously or scheduled.'; 62 | REVOKE ALL ON dbms_job.all_jobs FROM PUBLIC; 63 | 64 | -- Create a table to store the result of the job execution 65 | CREATE TABLE dbms_job.all_scheduler_job_run_details ( 66 | log_id bigserial PRIMARY KEY, -- unique identifier of the log entry 67 | log_date timestamp with time zone DEFAULT current_timestamp, -- date of the log entry 68 | owner name, -- owner of the scheduler job 69 | job_name varchar(261), -- name of the scheduler job 70 | job_subname varchar(261), -- Subname of the Scheduler job (for a chain step job) 71 | status text, -- status of the job run 72 | error char(5), -- error code in the case of an error 73 | req_start_date timestamp with time zone, -- requested start date of the job run 74 | actual_start_date timestamp with time zone, -- actual date on which the job was run 75 | run_duration bigint, -- duration of the job run in seconds 76 | instance_id integer, -- identifier of the instance on which the job was run 77 | session_id integer, -- session identifier of the job run 78 | slave_pid integer, -- process identifier of the slave on which the job was run 79 | cpu_used integer, -- amount of cpu used for the job run 80 | additional_info text -- additional information on the job run, error message, etc. 81 | ); 82 | COMMENT ON TABLE dbms_job.all_scheduler_job_run_details 83 | IS 'Table used to store the information about the jobs executed.'; 84 | REVOKE ALL ON dbms_job.all_scheduler_job_run_details FROM PUBLIC; 85 | 86 | -- The user can only see the job that he has created 87 | ALTER TABLE dbms_job.all_scheduler_job_run_details ENABLE ROW LEVEL SECURITY; 88 | CREATE POLICY dbms_job_policy ON dbms_job.all_scheduler_job_run_details USING (owner = current_user); 89 | 90 | ---- 91 | -- Stored procedures 92 | ---- 93 | CREATE PROCEDURE dbms_job.broken( 94 | jobid IN bigint, 95 | broken IN boolean, 96 | next_date IN timestamp(0) with time zone DEFAULT current_timestamp) 97 | LANGUAGE PLPGSQL 98 | AS $$ 99 | BEGIN 100 | -- interval must be in the future 101 | IF next_date < current_timestamp THEN 102 | RAISE EXCEPTION 'next_val must be a time in the future: %', next_date USING ERRCODE = '23420'; 103 | END IF; 104 | UPDATE dbms_job.all_scheduled_jobs SET broken=$2,next_date=$3 WHERE job=$1; 105 | IF NOT FOUND THEN 106 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 107 | END IF; 108 | END; 109 | $$; 110 | 111 | COMMENT ON PROCEDURE dbms_job.broken(bigint,boolean,timestamp with time zone) 112 | IS 'Disables job execution. Broken jobs are never run.'; 113 | REVOKE ALL ON PROCEDURE dbms_job.broken FROM PUBLIC; 114 | 115 | CREATE PROCEDURE dbms_job.change( 116 | job IN bigint, 117 | what IN text, 118 | next_date IN timestamp(0) with time zone, 119 | job_interval IN text, 120 | instance IN bigint DEFAULT 0, 121 | force IN boolean DEFAULT false) 122 | LANGUAGE PLPGSQL 123 | AS $$ 124 | DECLARE 125 | cols_modified text; 126 | future_date timestamp with time zone; 127 | v_ret bigint; 128 | BEGIN 129 | -- If what, next_date or job_interval are NULL they are kept unchanged 130 | IF what IS NOT NULL THEN 131 | cols_modified := coalesce(cols_modified, '') || 'what=' || quote_literal(what) || ','; 132 | END IF; 133 | IF next_date IS NOT NULL THEN 134 | cols_modified := coalesce(cols_modified, '') || 'next_date=' || quote_literal(next_date) || ','; 135 | END IF; 136 | IF job_interval IS NOT NULL THEN 137 | -- interval must be in the future 138 | future_date := dbms_job.get_next_date(job_interval); 139 | IF future_date < current_timestamp THEN 140 | RAISE EXCEPTION 'Interval must evaluate to a time in the future: %', future_date USING ERRCODE = '23420'; 141 | END IF; 142 | cols_modified := coalesce(cols_modified, '') || 'interval=' || quote_literal(job_interval) || ','; 143 | END IF; 144 | IF cols_modified IS NOT NULL THEN 145 | EXECUTE 'UPDATE dbms_job.all_scheduled_jobs SET ' || rtrim(cols_modified, ',') || ' WHERE job=$1 RETURNING job'INTO v_ret USING job; 146 | IF v_ret IS NULL THEN 147 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 148 | END IF; 149 | END IF; 150 | END; 151 | $$; 152 | COMMENT ON PROCEDURE dbms_job.change(bigint,text,timestamp with time zone,text,bigint,boolean) 153 | IS 'Alters any of the user-definable parameters associated with a job'; 154 | REVOKE ALL ON PROCEDURE dbms_job.change FROM PUBLIC; 155 | 156 | CREATE PROCEDURE dbms_job.interval( 157 | jobid IN bigint, 158 | job_interval IN text) 159 | LANGUAGE PLPGSQL 160 | AS $$ 161 | DECLARE 162 | next_date timestamp with time zone; 163 | BEGIN 164 | IF job_interval IS NULL THEN 165 | UPDATE dbms_job.all_scheduled_jobs SET interval = NULL WHERE job = jobid; 166 | ELSE 167 | -- interval must be in the future 168 | next_date := dbms_job.get_next_date(job_interval); 169 | IF next_date < current_timestamp THEN 170 | RAISE EXCEPTION 'Interval must evaluate to a time in the future: %', next_date USING ERRCODE = '23420'; 171 | END IF; 172 | UPDATE dbms_job.all_scheduled_jobs SET interval = quote_literal(job_interval) WHERE job = jobid; 173 | END IF; 174 | IF NOT FOUND THEN 175 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 176 | END IF; 177 | END; 178 | $$; 179 | 180 | COMMENT ON PROCEDURE dbms_job.interval(bigint,text) 181 | IS 'Alters the interval between executions for a specified job'; 182 | REVOKE ALL ON PROCEDURE dbms_job.interval FROM PUBLIC; 183 | 184 | CREATE PROCEDURE dbms_job.next_date( 185 | jobid IN bigint, 186 | next_date IN timestamp(0) with time zone) 187 | LANGUAGE PLPGSQL 188 | AS $$ 189 | BEGIN 190 | IF next_date IS NULL THEN 191 | RAISE EXCEPTION 'Next date can not be NULL'; 192 | END IF; 193 | UPDATE dbms_job.all_scheduled_jobs SET next_date = $2 WHERE job = jobid; 194 | IF NOT FOUND THEN 195 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 196 | END IF; 197 | END; 198 | $$; 199 | 200 | COMMENT ON PROCEDURE dbms_job.next_date(bigint,timestamp with time zone) 201 | IS 'Alters the next execution time for a specified job'; 202 | REVOKE ALL ON PROCEDURE dbms_job.next_date FROM PUBLIC; 203 | 204 | CREATE PROCEDURE dbms_job.remove( 205 | jobid IN bigint) 206 | LANGUAGE PLPGSQL 207 | AS $$ 208 | BEGIN 209 | DELETE FROM dbms_job.all_scheduled_jobs WHERE job = jobid; 210 | IF NOT FOUND THEN 211 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 212 | END IF; 213 | END; 214 | $$; 215 | 216 | COMMENT ON PROCEDURE dbms_job.remove(bigint) 217 | IS 'Removes specified job from the job queue'; 218 | REVOKE ALL ON PROCEDURE dbms_job.remove FROM PUBLIC; 219 | 220 | CREATE PROCEDURE dbms_job.run( 221 | jobid IN bigint, 222 | force IN boolean DEFAULT false) 223 | LANGUAGE PLPGSQL 224 | AS $$ 225 | DECLARE 226 | v_what text; 227 | tmp_what text; 228 | start_t timestamp with time zone; 229 | end_t timestamp with time zone; 230 | v_state text; 231 | v_msg text; 232 | v_detail text; 233 | v_hint text; 234 | v_context text; 235 | BEGIN 236 | IF jobid IS NULL THEN 237 | RETURN; 238 | END IF; 239 | -- Get the job definition 240 | SELECT what INTO v_what FROM dbms_job.all_scheduled_jobs WHERE job = jobid; 241 | IF v_what IS NULL THEN 242 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 243 | END IF; 244 | -- When force is false execute the job immediatly in foreground 245 | IF NOT force THEN 246 | start_t := clock_timestamp(); 247 | -- Remove BEGIN/END from the code 248 | SELECT regexp_replace(v_what, 'BEGIN\s+(.*)\s*END;', '\1', 'i') INTO tmp_what; 249 | UPDATE dbms_job.all_scheduled_jobs SET this_date = start_t WHERE job = jobid; 250 | BEGIN 251 | EXECUTE tmp_what; 252 | EXCEPTION 253 | WHEN others THEN 254 | -- Increase the failure count 255 | UPDATE dbms_job.all_scheduled_jobs SET 256 | failures = failures + 1 257 | WHERE job = jobid; 258 | -- Rethrow the exception 259 | RAISE; 260 | END; 261 | end_t := clock_timestamp(); 262 | -- Update job's statistics 263 | UPDATE dbms_job.all_scheduled_jobs SET 264 | last_date = end_t, 265 | this_date = NULL, 266 | total_time = total_time + ((EXTRACT(EPOCH FROM end_t) - EXTRACT(EPOCH FROM start_t)) || ' seconds')::interval, 267 | failures = 0, 268 | instance = instance+1, 269 | broken = false, 270 | next_date = dbms_job.get_next_date(interval) 271 | WHERE job = jobid; 272 | -- No write to history table in foreground mode 273 | ELSE 274 | -- Execute the job in background by submitting an asynchronous job 275 | SELECT dbms_job.submit(v_what) INTO jobid; 276 | END IF; 277 | END; 278 | $$; 279 | COMMENT ON PROCEDURE dbms_job.run(bigint, boolean) 280 | IS 'Forces a specified job to run immediatly. It runs even if it is broken'; 281 | REVOKE ALL ON PROCEDURE dbms_job.run FROM PUBLIC; 282 | 283 | CREATE FUNCTION dbms_job.submit( 284 | jobid OUT bigint, 285 | what IN text, 286 | next_date IN timestamp(0) with time zone DEFAULT current_timestamp, 287 | job_interval IN text DEFAULT NULL, 288 | no_parse IN boolean DEFAULT false) 289 | RETURNS bigint 290 | LANGUAGE PLPGSQL 291 | AS $$ 292 | BEGIN 293 | -- interval must be in the future 294 | IF next_date < current_timestamp THEN 295 | RAISE EXCEPTION 'next_date must be a time in the future: %', next_date USING ERRCODE = '23420'; 296 | END IF; 297 | -- When an interval is defined this is a job to be scheduled 298 | IF job_interval IS NOT NULL THEN 299 | INSERT INTO dbms_job.all_scheduled_jobs (what,next_date,interval) VALUES ($2,$3,$4) RETURNING job INTO jobid; 300 | ELSE 301 | -- With no interval verify if the job is planned in 302 | -- the future or that it must be executed immediatly 303 | IF next_date > current_timestamp THEN 304 | INSERT INTO dbms_job.all_scheduled_jobs (what,next_date,interval) VALUES ($2,$3,$4) RETURNING job INTO jobid; 305 | ELSE 306 | -- This is an immediate asynchronous execution, use the special queue 307 | INSERT INTO dbms_job.all_async_jobs (what) VALUES ($2) RETURNING job INTO jobid; 308 | END IF; 309 | END IF; 310 | END; 311 | $$; 312 | COMMENT ON FUNCTION dbms_job.submit(text,timestamp with time zone,text,boolean) 313 | IS 'Submits a new job to the job queue.'; 314 | REVOKE ALL ON FUNCTION dbms_job.submit FROM PUBLIC; 315 | 316 | CREATE PROCEDURE dbms_job.what( 317 | job IN bigint, 318 | what IN text) 319 | LANGUAGE SQL 320 | AS 'UPDATE dbms_job.all_scheduled_jobs SET what=$2 WHERE job=$1'; 321 | COMMENT ON PROCEDURE dbms_job.what(bigint,text) 322 | IS 'Alters the job description for a specified job'; 323 | REVOKE ALL ON PROCEDURE dbms_job.what FROM PUBLIC; 324 | 325 | CREATE FUNCTION dbms_job.job_scheduled_notify() 326 | RETURNS trigger 327 | LANGUAGE PLPGSQL 328 | AS $$ 329 | BEGIN 330 | -- Force interval to be NULL if this is set to an empty string 331 | IF TG_OP = 'UPDATE' OR TG_OP = 'INSERT' THEN 332 | IF NEW.interval = '' THEN 333 | NEW.interval := NULL; 334 | END IF; 335 | END IF; 336 | -- When a change occurs in the all_scheduled_jobs table, notify the scheduler. 337 | IF TG_OP = 'UPDATE' THEN 338 | -- We do not notify the scheduler if it is at the origine of the UPDATE. 339 | -- We increment the value of the instance column when this is an internal 340 | -- update after an execution. 341 | IF NEW.instance = OLD.instance THEN 342 | PERFORM pg_notify('dbms_job_scheduled_notify', TG_OP || ':' || OLD.job || ':' || NEW.job); 343 | END IF; 344 | RETURN NEW; 345 | END IF; 346 | IF TG_OP = 'INSERT' THEN 347 | PERFORM pg_notify('dbms_job_scheduled_notify', TG_OP || ':' || NEW.job); 348 | RETURN NEW; 349 | END IF; 350 | IF TG_OP = 'DELETE' THEN 351 | PERFORM pg_notify('dbms_job_scheduled_notify', TG_OP || ':' || OLD.job); 352 | RETURN OLD; 353 | END IF; 354 | -- TRUNCATE 355 | PERFORM pg_notify('dbms_job_scheduled_notify', TG_OP); 356 | RETURN OLD; 357 | END; 358 | $$; 359 | COMMENT ON FUNCTION dbms_job.job_scheduled_notify() 360 | IS 'Notify the scheduler that the job cache must be invalidated'; 361 | 362 | -- When there is a modification in the JOB table invalidate the cache 363 | -- to inform the background worker to reread the table 364 | CREATE TRIGGER dbms_job_scheduled_notify_trg 365 | AFTER INSERT OR UPDATE OR DELETE OR TRUNCATE 366 | ON dbms_job.all_scheduled_jobs 367 | FOR STATEMENT EXECUTE FUNCTION dbms_job.job_scheduled_notify(); 368 | 369 | CREATE FUNCTION dbms_job.job_async_notify() 370 | RETURNS trigger 371 | LANGUAGE PLPGSQL 372 | AS $$ 373 | BEGIN 374 | -- When a new async job is submitted, notify the scheduler 375 | PERFORM pg_notify('dbms_job_async_notify', 'New asynchronous job received'); 376 | RETURN NEW; 377 | END; 378 | $$; 379 | COMMENT ON FUNCTION dbms_job.job_async_notify() 380 | IS 'Notify the scheduler that a new asynchronous job was submitted'; 381 | 382 | -- When there is a new asynchronous job submited 383 | -- to inform the daemon to reread the table 384 | CREATE TRIGGER dbms_job_async_notify_trg 385 | AFTER INSERT 386 | ON dbms_job.all_async_jobs 387 | FOR STATEMENT EXECUTE FUNCTION dbms_job.job_async_notify(); 388 | 389 | CREATE FUNCTION dbms_job.get_next_date(text) 390 | RETURNS timestamp(0) with time zone 391 | LANGUAGE PLPGSQL 392 | AS $$ 393 | DECLARE 394 | next_date timestamp(0) with time zone; 395 | BEGIN 396 | EXECUTE 'SELECT '||$1 INTO next_date; 397 | RETURN next_date; 398 | END; 399 | $$; 400 | COMMENT ON FUNCTION dbms_job.get_next_date(text) 401 | IS 'Used to get the next date returned by the interval code'; 402 | 403 | -------------------------------------------------------------------------------- /sql/pg_dbms_job--1.4.0.sql: -------------------------------------------------------------------------------- 1 | ---- 2 | -- Script to create the base objects of the pg_dbms_job extension 3 | ---- 4 | CREATE SEQUENCE dbms_job.jobseq; 5 | 6 | -- Table used to store the jobs to run by the scheduler 7 | CREATE TABLE dbms_job.all_scheduled_jobs ( 8 | job bigint DEFAULT nextval('dbms_job.jobseq') PRIMARY KEY, -- identifier of job 9 | log_user name DEFAULT current_user, -- user that submit the job 10 | priv_user name DEFAULT current_user, -- user whose default privileges apply to this job (not used) 11 | schema_user text DEFAULT current_setting('search_path'), -- default schema used to parse the job 12 | last_date timestamp with time zone, -- date on which this job last successfully executed 13 | last_sec text, -- same as last_date (not used) 14 | this_date timestamp with time zone, -- date that this job started executing, null when the job is not running 15 | this_sec text, -- same as this_date (not used) 16 | next_date timestamp(0) with time zone NOT NULL, -- date that this job will next be executed 17 | next_sec timestamp with time zone, -- same as next_date (not used) 18 | total_time interval, -- total wall clock time spent by the system on this job, in seconds 19 | broken boolean DEFAULT false, -- true: no attempt is made to run this job, false: an attempt is made to run this job 20 | interval text, -- a date function, evaluated at the start of execution, becomes next next_date 21 | failures bigint, -- number of times the job has started and failed since its last success 22 | what text NOT NULL, -- body of the anonymous pl/sql block that the job executes 23 | nls_env text, -- session parameters describing the nls environment of the job (not used) 24 | misc_env bytea, -- Other session parameters that apply to this job (not used) 25 | instance integer DEFAULT 0 -- ID of the instance that can execute or is executing the job (not used) 26 | ); 27 | COMMENT ON TABLE dbms_job.all_scheduled_jobs 28 | IS 'Table used to store the periodical jobs to run by the scheduler.'; 29 | REVOKE ALL ON dbms_job.all_scheduled_jobs FROM PUBLIC; 30 | 31 | -- The user can only see the job that he has created 32 | ALTER TABLE dbms_job.all_scheduled_jobs ENABLE ROW LEVEL SECURITY; 33 | CREATE POLICY dbms_job_policy ON dbms_job.all_scheduled_jobs USING (log_user = current_user); 34 | 35 | -- Create the asynchronous jobs queue, for immediat execution 36 | CREATE TABLE dbms_job.all_async_jobs ( 37 | job bigint DEFAULT nextval('dbms_job.jobseq') PRIMARY KEY, -- identifier of job 38 | log_user name DEFAULT current_user, -- user that submit the job 39 | schema_user text DEFAULT current_setting('search_path'), -- default search_path used to execute the job 40 | create_date timestamp with time zone DEFAULT current_timestamp, -- date on which this job has been created. 41 | what text NOT NULL, -- body of the anonymous pl/sql block that the job executes 42 | this_date timestamp with time zone -- date that this job started executing, null when the job is not running 43 | ); 44 | COMMENT ON TABLE dbms_job.all_async_jobs 45 | IS 'Table used to store the jobs to be run asynchronously by the scheduler.'; 46 | REVOKE ALL ON dbms_job.all_async_jobs FROM PUBLIC; 47 | 48 | -- The user can only see the job that he has created 49 | ALTER TABLE dbms_job.all_async_jobs ENABLE ROW LEVEL SECURITY; 50 | CREATE POLICY dbms_job_policy ON dbms_job.all_async_jobs USING (log_user = current_user); 51 | 52 | -- Create a view similar to DMBS_JOB.ALL_JOBS 53 | CREATE VIEW dbms_job.all_jobs AS 54 | SELECT * FROM dbms_job.all_scheduled_jobs 55 | UNION 56 | SELECT job, log_user, NULL priv_user, schema_user, NULL last_date, NULL last_sec, 57 | NULL this_date, NULL this_sec, create_date next_date, NULL next_sec, NULL total_time, 58 | 'f' broken, NULL "interval", NULL failures, what, NULL nls_env, NULL misc_env, 59 | 0 instance FROM dbms_job.all_async_jobs; 60 | COMMENT ON VIEW dbms_job.all_jobs 61 | IS 'View registering all jobs to be run asynchronously or scheduled.'; 62 | REVOKE ALL ON dbms_job.all_jobs FROM PUBLIC; 63 | 64 | -- Create a table to store the result of the job execution 65 | CREATE TABLE dbms_job.all_scheduler_job_run_details ( 66 | log_id bigserial PRIMARY KEY, -- unique identifier of the log entry 67 | log_date timestamp with time zone DEFAULT current_timestamp, -- date of the log entry 68 | owner name, -- owner of the scheduler job 69 | job_name varchar(261), -- name of the scheduler job 70 | job_subname varchar(261), -- Subname of the Scheduler job (for a chain step job) 71 | status text, -- status of the job run 72 | error char(5), -- error code in the case of an error 73 | req_start_date timestamp with time zone, -- requested start date of the job run 74 | actual_start_date timestamp with time zone, -- actual date on which the job was run 75 | run_duration bigint, -- duration of the job run in seconds 76 | instance_id integer, -- identifier of the instance on which the job was run 77 | session_id integer, -- session identifier of the job run 78 | slave_pid integer, -- process identifier of the slave on which the job was run 79 | cpu_used integer, -- amount of cpu used for the job run 80 | additional_info text -- additional information on the job run, error message, etc. 81 | ); 82 | COMMENT ON TABLE dbms_job.all_scheduler_job_run_details 83 | IS 'Table used to store the information about the jobs executed.'; 84 | REVOKE ALL ON dbms_job.all_scheduler_job_run_details FROM PUBLIC; 85 | 86 | -- The user can only see the job that he has created 87 | ALTER TABLE dbms_job.all_scheduler_job_run_details ENABLE ROW LEVEL SECURITY; 88 | CREATE POLICY dbms_job_policy ON dbms_job.all_scheduler_job_run_details USING (owner = current_user); 89 | 90 | ---- 91 | -- Stored procedures 92 | ---- 93 | CREATE PROCEDURE dbms_job.broken( 94 | jobid IN bigint, 95 | broken IN boolean, 96 | next_date IN timestamp(0) with time zone DEFAULT current_timestamp) 97 | LANGUAGE PLPGSQL 98 | AS $$ 99 | BEGIN 100 | -- interval must be in the future 101 | IF next_date < current_timestamp THEN 102 | RAISE EXCEPTION 'next_val must be a time in the future: %', next_date USING ERRCODE = '23420'; 103 | END IF; 104 | UPDATE dbms_job.all_scheduled_jobs SET broken=$2,next_date=$3 WHERE job=$1; 105 | IF NOT FOUND THEN 106 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 107 | END IF; 108 | END; 109 | $$; 110 | 111 | COMMENT ON PROCEDURE dbms_job.broken(bigint,boolean,timestamp with time zone) 112 | IS 'Disables job execution. Broken jobs are never run.'; 113 | REVOKE ALL ON PROCEDURE dbms_job.broken FROM PUBLIC; 114 | 115 | CREATE PROCEDURE dbms_job.change( 116 | job IN bigint, 117 | what IN text, 118 | next_date IN timestamp(0) with time zone, 119 | job_interval IN text, 120 | instance IN bigint DEFAULT 0, 121 | force IN boolean DEFAULT false) 122 | LANGUAGE PLPGSQL 123 | AS $$ 124 | DECLARE 125 | cols_modified text; 126 | future_date timestamp with time zone; 127 | v_ret bigint; 128 | BEGIN 129 | -- If what, next_date or job_interval are NULL they are kept unchanged 130 | IF what IS NOT NULL THEN 131 | cols_modified := coalesce(cols_modified, '') || 'what=' || quote_literal(what) || ','; 132 | END IF; 133 | IF next_date IS NOT NULL THEN 134 | cols_modified := coalesce(cols_modified, '') || 'next_date=' || quote_literal(next_date) || ','; 135 | END IF; 136 | IF job_interval IS NOT NULL THEN 137 | -- interval must be in the future 138 | future_date := dbms_job.get_next_date(job_interval); 139 | IF future_date < current_timestamp THEN 140 | RAISE EXCEPTION 'Interval must evaluate to a time in the future: %', future_date USING ERRCODE = '23420'; 141 | END IF; 142 | cols_modified := coalesce(cols_modified, '') || 'interval=' || quote_literal(job_interval) || ','; 143 | END IF; 144 | IF cols_modified IS NOT NULL THEN 145 | EXECUTE 'UPDATE dbms_job.all_scheduled_jobs SET ' || rtrim(cols_modified, ',') || ' WHERE job=$1 RETURNING job'INTO v_ret USING job; 146 | IF v_ret IS NULL THEN 147 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 148 | END IF; 149 | END IF; 150 | END; 151 | $$; 152 | COMMENT ON PROCEDURE dbms_job.change(bigint,text,timestamp with time zone,text,bigint,boolean) 153 | IS 'Alters any of the user-definable parameters associated with a job'; 154 | REVOKE ALL ON PROCEDURE dbms_job.change FROM PUBLIC; 155 | 156 | CREATE PROCEDURE dbms_job.interval( 157 | jobid IN bigint, 158 | job_interval IN text) 159 | LANGUAGE PLPGSQL 160 | AS $$ 161 | DECLARE 162 | next_date timestamp with time zone; 163 | v_interval text; 164 | v_retval bigint; 165 | BEGIN 166 | IF job_interval IS NULL THEN 167 | UPDATE dbms_job.all_scheduled_jobs SET interval = NULL WHERE job = jobid; 168 | ELSE 169 | -- interval must be in the future 170 | next_date := dbms_job.get_next_date(job_interval); 171 | IF next_date < current_timestamp THEN 172 | RAISE EXCEPTION 'Interval must evaluate to a time in the future: %', next_date USING ERRCODE = '23420'; 173 | END IF; 174 | v_interval := 'UPDATE dbms_job.all_scheduled_jobs SET interval = ' || quote_literal(job_interval) || ' WHERE job = ' || jobid || ' RETURNING job'; 175 | EXECUTE v_interval INTO v_retval; 176 | IF v_retval IS NULL THEN 177 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 178 | END IF; 179 | END IF; 180 | END; 181 | $$; 182 | 183 | COMMENT ON PROCEDURE dbms_job.interval(bigint,text) 184 | IS 'Alters the interval between executions for a specified job'; 185 | REVOKE ALL ON PROCEDURE dbms_job.interval FROM PUBLIC; 186 | 187 | CREATE PROCEDURE dbms_job.next_date( 188 | jobid IN bigint, 189 | next_date IN timestamp(0) with time zone) 190 | LANGUAGE PLPGSQL 191 | AS $$ 192 | BEGIN 193 | IF next_date IS NULL THEN 194 | RAISE EXCEPTION 'Next date can not be NULL'; 195 | END IF; 196 | UPDATE dbms_job.all_scheduled_jobs SET next_date = $2 WHERE job = jobid; 197 | IF NOT FOUND THEN 198 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 199 | END IF; 200 | END; 201 | $$; 202 | 203 | COMMENT ON PROCEDURE dbms_job.next_date(bigint,timestamp with time zone) 204 | IS 'Alters the next execution time for a specified job'; 205 | REVOKE ALL ON PROCEDURE dbms_job.next_date FROM PUBLIC; 206 | 207 | CREATE PROCEDURE dbms_job.remove( 208 | jobid IN bigint) 209 | LANGUAGE PLPGSQL 210 | AS $$ 211 | BEGIN 212 | DELETE FROM dbms_job.all_scheduled_jobs WHERE job = jobid; 213 | IF NOT FOUND THEN 214 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 215 | END IF; 216 | END; 217 | $$; 218 | 219 | COMMENT ON PROCEDURE dbms_job.remove(bigint) 220 | IS 'Removes specified job from the job queue'; 221 | REVOKE ALL ON PROCEDURE dbms_job.remove FROM PUBLIC; 222 | 223 | CREATE PROCEDURE dbms_job.run( 224 | jobid IN bigint, 225 | force IN boolean DEFAULT false) 226 | LANGUAGE PLPGSQL 227 | AS $$ 228 | DECLARE 229 | v_what text; 230 | tmp_what text; 231 | start_t timestamp with time zone; 232 | end_t timestamp with time zone; 233 | v_state text; 234 | v_msg text; 235 | v_detail text; 236 | v_hint text; 237 | v_context text; 238 | BEGIN 239 | IF jobid IS NULL THEN 240 | RETURN; 241 | END IF; 242 | -- Get the job definition 243 | SELECT what INTO v_what FROM dbms_job.all_scheduled_jobs WHERE job = jobid; 244 | IF v_what IS NULL THEN 245 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 246 | END IF; 247 | -- When force is false execute the job immediatly in foreground 248 | IF NOT force THEN 249 | start_t := clock_timestamp(); 250 | -- Remove BEGIN/END from the code 251 | SELECT regexp_replace(v_what, 'BEGIN\s+(.*)\s*END;', '\1', 'i') INTO tmp_what; 252 | UPDATE dbms_job.all_scheduled_jobs SET this_date = start_t WHERE job = jobid; 253 | BEGIN 254 | EXECUTE tmp_what; 255 | EXCEPTION 256 | WHEN others THEN 257 | -- Increase the failure count 258 | UPDATE dbms_job.all_scheduled_jobs SET 259 | failures = failures + 1 260 | WHERE job = jobid; 261 | -- Rethrow the exception 262 | RAISE; 263 | END; 264 | end_t := clock_timestamp(); 265 | -- Update job's statistics 266 | UPDATE dbms_job.all_scheduled_jobs SET 267 | last_date = end_t, 268 | this_date = NULL, 269 | total_time = total_time + ((EXTRACT(EPOCH FROM end_t) - EXTRACT(EPOCH FROM start_t)) || ' seconds')::interval, 270 | failures = 0, 271 | instance = instance+1, 272 | broken = false, 273 | next_date = dbms_job.get_next_date(interval) 274 | WHERE job = jobid; 275 | -- No write to history table in foreground mode 276 | ELSE 277 | -- Execute the job in background by submitting an asynchronous job 278 | SELECT dbms_job.submit(v_what) INTO jobid; 279 | END IF; 280 | END; 281 | $$; 282 | COMMENT ON PROCEDURE dbms_job.run(bigint, boolean) 283 | IS 'Forces a specified job to run immediatly. It runs even if it is broken'; 284 | REVOKE ALL ON PROCEDURE dbms_job.run FROM PUBLIC; 285 | 286 | CREATE FUNCTION dbms_job.submit( 287 | jobid OUT bigint, 288 | what IN text, 289 | next_date IN timestamp(0) with time zone DEFAULT current_timestamp, 290 | job_interval IN text DEFAULT NULL, 291 | no_parse IN boolean DEFAULT false) 292 | RETURNS bigint 293 | LANGUAGE PLPGSQL 294 | AS $$ 295 | BEGIN 296 | -- interval must be in the future 297 | IF next_date < current_timestamp THEN 298 | RAISE EXCEPTION 'next_date must be a time in the future: %', next_date USING ERRCODE = '23420'; 299 | END IF; 300 | -- When an interval is defined this is a job to be scheduled 301 | IF job_interval IS NOT NULL THEN 302 | INSERT INTO dbms_job.all_scheduled_jobs (what,next_date,interval) VALUES ($2,$3,$4) RETURNING job INTO jobid; 303 | ELSE 304 | -- With no interval verify if the job is planned in 305 | -- the future or that it must be executed immediatly 306 | IF next_date > current_timestamp THEN 307 | INSERT INTO dbms_job.all_scheduled_jobs (what,next_date,interval) VALUES ($2,$3,$4) RETURNING job INTO jobid; 308 | ELSE 309 | -- This is an immediate asynchronous execution, use the special queue 310 | INSERT INTO dbms_job.all_async_jobs (what) VALUES ($2) RETURNING job INTO jobid; 311 | END IF; 312 | END IF; 313 | END; 314 | $$; 315 | COMMENT ON FUNCTION dbms_job.submit(text,timestamp with time zone,text,boolean) 316 | IS 'Submits a new job to the job queue.'; 317 | REVOKE ALL ON FUNCTION dbms_job.submit FROM PUBLIC; 318 | 319 | CREATE PROCEDURE dbms_job.what( 320 | job IN bigint, 321 | what IN text) 322 | LANGUAGE SQL 323 | AS 'UPDATE dbms_job.all_scheduled_jobs SET what=$2 WHERE job=$1'; 324 | COMMENT ON PROCEDURE dbms_job.what(bigint,text) 325 | IS 'Alters the job description for a specified job'; 326 | REVOKE ALL ON PROCEDURE dbms_job.what FROM PUBLIC; 327 | 328 | CREATE FUNCTION dbms_job.job_scheduled_notify() 329 | RETURNS trigger 330 | LANGUAGE PLPGSQL 331 | AS $$ 332 | BEGIN 333 | -- Force interval to be NULL if this is set to an empty string 334 | IF TG_OP = 'UPDATE' OR TG_OP = 'INSERT' THEN 335 | IF NEW.interval = '' THEN 336 | NEW.interval := NULL; 337 | END IF; 338 | END IF; 339 | -- When a change occurs in the all_scheduled_jobs table, notify the scheduler. 340 | IF TG_OP = 'UPDATE' THEN 341 | -- We do not notify the scheduler if it is at the origine of the UPDATE. 342 | -- We increment the value of the instance column when this is an internal 343 | -- update after an execution. 344 | IF NEW.instance = OLD.instance THEN 345 | PERFORM pg_notify('dbms_job_scheduled_notify', TG_OP || ':' || OLD.job || ':' || NEW.job); 346 | END IF; 347 | RETURN NEW; 348 | END IF; 349 | IF TG_OP = 'INSERT' THEN 350 | PERFORM pg_notify('dbms_job_scheduled_notify', TG_OP || ':' || NEW.job); 351 | RETURN NEW; 352 | END IF; 353 | IF TG_OP = 'DELETE' THEN 354 | PERFORM pg_notify('dbms_job_scheduled_notify', TG_OP || ':' || OLD.job); 355 | RETURN OLD; 356 | END IF; 357 | -- TRUNCATE 358 | PERFORM pg_notify('dbms_job_scheduled_notify', TG_OP); 359 | RETURN OLD; 360 | END; 361 | $$; 362 | COMMENT ON FUNCTION dbms_job.job_scheduled_notify() 363 | IS 'Notify the scheduler that the job cache must be invalidated'; 364 | 365 | -- When there is a modification in the JOB table invalidate the cache 366 | -- to inform the background worker to reread the table 367 | CREATE TRIGGER dbms_job_scheduled_notify_trg 368 | AFTER INSERT OR UPDATE OR DELETE OR TRUNCATE 369 | ON dbms_job.all_scheduled_jobs 370 | FOR STATEMENT EXECUTE FUNCTION dbms_job.job_scheduled_notify(); 371 | 372 | CREATE FUNCTION dbms_job.job_async_notify() 373 | RETURNS trigger 374 | LANGUAGE PLPGSQL 375 | AS $$ 376 | BEGIN 377 | -- When a new async job is submitted, notify the scheduler 378 | PERFORM pg_notify('dbms_job_async_notify', 'New asynchronous job received'); 379 | RETURN NEW; 380 | END; 381 | $$; 382 | COMMENT ON FUNCTION dbms_job.job_async_notify() 383 | IS 'Notify the scheduler that a new asynchronous job was submitted'; 384 | 385 | -- When there is a new asynchronous job submited 386 | -- to inform the daemon to reread the table 387 | CREATE TRIGGER dbms_job_async_notify_trg 388 | AFTER INSERT 389 | ON dbms_job.all_async_jobs 390 | FOR STATEMENT EXECUTE FUNCTION dbms_job.job_async_notify(); 391 | 392 | CREATE FUNCTION dbms_job.get_next_date(text) 393 | RETURNS timestamp(0) with time zone 394 | LANGUAGE PLPGSQL 395 | AS $$ 396 | DECLARE 397 | next_date timestamp(0) with time zone; 398 | BEGIN 399 | EXECUTE 'SELECT '||$1 INTO next_date; 400 | RETURN next_date; 401 | END; 402 | $$; 403 | COMMENT ON FUNCTION dbms_job.get_next_date(text) 404 | IS 'Used to get the next date returned by the interval code'; 405 | 406 | -------------------------------------------------------------------------------- /sql/pg_dbms_job--1.5.0.sql: -------------------------------------------------------------------------------- 1 | ---- 2 | -- Script to create the base objects of the pg_dbms_job extension 3 | ---- 4 | CREATE SEQUENCE dbms_job.jobseq; 5 | 6 | -- Table used to store the jobs to run by the scheduler 7 | CREATE TABLE dbms_job.all_scheduled_jobs ( 8 | job bigint DEFAULT nextval('dbms_job.jobseq') PRIMARY KEY, -- identifier of job 9 | log_user name DEFAULT current_user, -- user that submit the job 10 | priv_user name DEFAULT current_user, -- user whose default privileges apply to this job (not used) 11 | schema_user text DEFAULT current_setting('search_path'), -- default schema used to parse the job 12 | last_date timestamp with time zone, -- date on which this job last successfully executed 13 | last_sec text, -- same as last_date (not used) 14 | this_date timestamp with time zone, -- date that this job started executing, null when the job is not running 15 | this_sec text, -- same as this_date (not used) 16 | next_date timestamp with time zone NOT NULL, -- date that this job will next be executed 17 | next_sec timestamp with time zone, -- same as next_date (not used) 18 | total_time interval, -- total wall clock time spent by the system on this job, in seconds 19 | broken boolean DEFAULT false, -- true: no attempt is made to run this job, false: an attempt is made to run this job 20 | interval text, -- a date function, evaluated at the start of execution, becomes next next_date 21 | failures bigint, -- number of times the job has started and failed since its last success 22 | what text NOT NULL, -- body of the anonymous pl/sql block that the job executes 23 | nls_env text, -- session parameters describing the nls environment of the job (not used) 24 | misc_env bytea, -- Other session parameters that apply to this job (not used) 25 | instance integer DEFAULT 0 -- ID of the instance that can execute or is executing the job (not used) 26 | ); 27 | COMMENT ON TABLE dbms_job.all_scheduled_jobs 28 | IS 'Table used to store the periodical jobs to run by the scheduler.'; 29 | REVOKE ALL ON dbms_job.all_scheduled_jobs FROM PUBLIC; 30 | 31 | -- The user can only see the job that he has created 32 | ALTER TABLE dbms_job.all_scheduled_jobs ENABLE ROW LEVEL SECURITY; 33 | CREATE POLICY dbms_job_policy ON dbms_job.all_scheduled_jobs USING (log_user = current_user); 34 | 35 | -- Create the asynchronous jobs queue, for immediat execution 36 | CREATE TABLE dbms_job.all_async_jobs ( 37 | job bigint DEFAULT nextval('dbms_job.jobseq') PRIMARY KEY, -- identifier of job 38 | log_user name DEFAULT current_user, -- user that submit the job 39 | schema_user text DEFAULT current_setting('search_path'), -- default search_path used to execute the job 40 | create_date timestamp with time zone DEFAULT current_timestamp, -- date on which this job has been created. 41 | what text NOT NULL, -- body of the anonymous pl/sql block that the job executes 42 | this_date timestamp with time zone -- date that this job started executing, null when the job is not running 43 | ); 44 | COMMENT ON TABLE dbms_job.all_async_jobs 45 | IS 'Table used to store the jobs to be run asynchronously by the scheduler.'; 46 | REVOKE ALL ON dbms_job.all_async_jobs FROM PUBLIC; 47 | 48 | -- The user can only see the job that he has created 49 | ALTER TABLE dbms_job.all_async_jobs ENABLE ROW LEVEL SECURITY; 50 | CREATE POLICY dbms_job_policy ON dbms_job.all_async_jobs USING (log_user = current_user); 51 | 52 | -- Create a view similar to DMBS_JOB.ALL_JOBS 53 | CREATE VIEW dbms_job.all_jobs AS 54 | SELECT * FROM dbms_job.all_scheduled_jobs 55 | UNION 56 | SELECT job, log_user, NULL priv_user, schema_user, NULL last_date, NULL last_sec, 57 | NULL this_date, NULL this_sec, create_date next_date, NULL next_sec, NULL total_time, 58 | 'f' broken, NULL "interval", NULL failures, what, NULL nls_env, NULL misc_env, 59 | 0 instance FROM dbms_job.all_async_jobs; 60 | COMMENT ON VIEW dbms_job.all_jobs 61 | IS 'View registering all jobs to be run asynchronously or scheduled.'; 62 | REVOKE ALL ON dbms_job.all_jobs FROM PUBLIC; 63 | 64 | -- Create a table to store the result of the job execution 65 | CREATE TABLE dbms_job.all_scheduler_job_run_details ( 66 | log_id bigserial PRIMARY KEY, -- unique identifier of the log entry 67 | log_date timestamp with time zone DEFAULT current_timestamp, -- date of the log entry 68 | owner name, -- owner of the scheduler job 69 | job_name varchar(261), -- name of the scheduler job 70 | job_subname varchar(261), -- Subname of the Scheduler job (for a chain step job) 71 | status text, -- status of the job run 72 | error char(5), -- error code in the case of an error 73 | req_start_date timestamp with time zone, -- requested start date of the job run 74 | actual_start_date timestamp with time zone, -- actual date on which the job was run 75 | run_duration bigint, -- duration of the job run in seconds 76 | instance_id integer, -- identifier of the instance on which the job was run 77 | session_id integer, -- session identifier of the job run 78 | slave_pid integer, -- process identifier of the slave on which the job was run 79 | cpu_used integer, -- amount of cpu used for the job run 80 | additional_info text -- additional information on the job run, error message, etc. 81 | ); 82 | COMMENT ON TABLE dbms_job.all_scheduler_job_run_details 83 | IS 'Table used to store the information about the jobs executed.'; 84 | REVOKE ALL ON dbms_job.all_scheduler_job_run_details FROM PUBLIC; 85 | 86 | -- The user can only see the job that he has created 87 | ALTER TABLE dbms_job.all_scheduler_job_run_details ENABLE ROW LEVEL SECURITY; 88 | CREATE POLICY dbms_job_policy ON dbms_job.all_scheduler_job_run_details USING (owner = current_user); 89 | 90 | ---- 91 | -- Stored procedures 92 | ---- 93 | CREATE PROCEDURE dbms_job.broken( 94 | jobid IN bigint, 95 | broken IN boolean, 96 | next_date IN timestamp with time zone DEFAULT current_timestamp) 97 | LANGUAGE PLPGSQL 98 | AS $$ 99 | BEGIN 100 | -- interval must be in the future 101 | IF next_date < current_timestamp THEN 102 | RAISE EXCEPTION 'next_val must be a time in the future: %', next_date USING ERRCODE = '23420'; 103 | END IF; 104 | UPDATE dbms_job.all_scheduled_jobs SET broken=$2,next_date=$3 WHERE job=$1; 105 | IF NOT FOUND THEN 106 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 107 | END IF; 108 | END; 109 | $$; 110 | 111 | COMMENT ON PROCEDURE dbms_job.broken(bigint,boolean,timestamp with time zone) 112 | IS 'Disables job execution. Broken jobs are never run.'; 113 | REVOKE ALL ON PROCEDURE dbms_job.broken FROM PUBLIC; 114 | 115 | CREATE PROCEDURE dbms_job.change( 116 | job IN bigint, 117 | what IN text, 118 | next_date IN timestamp with time zone, 119 | job_interval IN text, 120 | instance IN bigint DEFAULT 0, 121 | force IN boolean DEFAULT false) 122 | LANGUAGE PLPGSQL 123 | AS $$ 124 | DECLARE 125 | cols_modified text; 126 | future_date timestamp with time zone; 127 | v_ret bigint; 128 | BEGIN 129 | -- If what, next_date or job_interval are NULL they are kept unchanged 130 | IF what IS NOT NULL THEN 131 | cols_modified := coalesce(cols_modified, '') || 'what=' || quote_literal(what) || ','; 132 | END IF; 133 | IF next_date IS NOT NULL THEN 134 | cols_modified := coalesce(cols_modified, '') || 'next_date=' || quote_literal(next_date) || ','; 135 | END IF; 136 | IF job_interval IS NOT NULL THEN 137 | -- interval must be in the future 138 | future_date := dbms_job.get_next_date(job_interval); 139 | IF future_date < current_timestamp THEN 140 | RAISE EXCEPTION 'Interval must evaluate to a time in the future: %', future_date USING ERRCODE = '23420'; 141 | END IF; 142 | cols_modified := coalesce(cols_modified, '') || 'interval=' || quote_literal(job_interval) || ','; 143 | END IF; 144 | IF cols_modified IS NOT NULL THEN 145 | EXECUTE 'UPDATE dbms_job.all_scheduled_jobs SET ' || rtrim(cols_modified, ',') || ' WHERE job=$1 RETURNING job'INTO v_ret USING job; 146 | IF v_ret IS NULL THEN 147 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 148 | END IF; 149 | END IF; 150 | END; 151 | $$; 152 | COMMENT ON PROCEDURE dbms_job.change(bigint,text,timestamp with time zone,text,bigint,boolean) 153 | IS 'Alters any of the user-definable parameters associated with a job'; 154 | REVOKE ALL ON PROCEDURE dbms_job.change FROM PUBLIC; 155 | 156 | CREATE PROCEDURE dbms_job.interval( 157 | jobid IN bigint, 158 | job_interval IN text) 159 | LANGUAGE PLPGSQL 160 | AS $$ 161 | DECLARE 162 | next_date timestamp with time zone; 163 | v_interval text; 164 | v_retval bigint; 165 | BEGIN 166 | IF job_interval IS NULL THEN 167 | UPDATE dbms_job.all_scheduled_jobs SET interval = NULL WHERE job = jobid; 168 | ELSE 169 | -- interval must be in the future 170 | next_date := dbms_job.get_next_date(job_interval); 171 | IF next_date < current_timestamp THEN 172 | RAISE EXCEPTION 'Interval must evaluate to a time in the future: %', next_date USING ERRCODE = '23420'; 173 | END IF; 174 | v_interval := 'UPDATE dbms_job.all_scheduled_jobs SET interval = ' || quote_literal(job_interval) || ' WHERE job = ' || jobid || ' RETURNING job'; 175 | EXECUTE v_interval INTO v_retval; 176 | IF v_retval IS NULL THEN 177 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 178 | END IF; 179 | END IF; 180 | END; 181 | $$; 182 | 183 | COMMENT ON PROCEDURE dbms_job.interval(bigint,text) 184 | IS 'Alters the interval between executions for a specified job'; 185 | REVOKE ALL ON PROCEDURE dbms_job.interval FROM PUBLIC; 186 | 187 | CREATE PROCEDURE dbms_job.next_date( 188 | jobid IN bigint, 189 | next_date IN timestamp with time zone) 190 | LANGUAGE PLPGSQL 191 | AS $$ 192 | BEGIN 193 | IF next_date IS NULL THEN 194 | RAISE EXCEPTION 'Next date can not be NULL'; 195 | END IF; 196 | UPDATE dbms_job.all_scheduled_jobs SET next_date = $2 WHERE job = jobid; 197 | IF NOT FOUND THEN 198 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 199 | END IF; 200 | END; 201 | $$; 202 | 203 | COMMENT ON PROCEDURE dbms_job.next_date(bigint,timestamp with time zone) 204 | IS 'Alters the next execution time for a specified job'; 205 | REVOKE ALL ON PROCEDURE dbms_job.next_date FROM PUBLIC; 206 | 207 | CREATE PROCEDURE dbms_job.remove( 208 | jobid IN bigint) 209 | LANGUAGE PLPGSQL 210 | AS $$ 211 | BEGIN 212 | DELETE FROM dbms_job.all_scheduled_jobs WHERE job = jobid; 213 | IF NOT FOUND THEN 214 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 215 | END IF; 216 | END; 217 | $$; 218 | 219 | COMMENT ON PROCEDURE dbms_job.remove(bigint) 220 | IS 'Removes specified job from the job queue'; 221 | REVOKE ALL ON PROCEDURE dbms_job.remove FROM PUBLIC; 222 | 223 | CREATE PROCEDURE dbms_job.run( 224 | jobid IN bigint, 225 | force IN boolean DEFAULT false) 226 | LANGUAGE PLPGSQL 227 | AS $$ 228 | DECLARE 229 | v_what text; 230 | tmp_what text; 231 | start_t timestamp with time zone; 232 | end_t timestamp with time zone; 233 | v_state text; 234 | v_msg text; 235 | v_detail text; 236 | v_hint text; 237 | v_context text; 238 | BEGIN 239 | IF jobid IS NULL THEN 240 | RETURN; 241 | END IF; 242 | -- Get the job definition 243 | SELECT what INTO v_what FROM dbms_job.all_scheduled_jobs WHERE job = jobid; 244 | IF v_what IS NULL THEN 245 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 246 | END IF; 247 | -- When force is false execute the job immediatly in foreground 248 | IF NOT force THEN 249 | start_t := clock_timestamp(); 250 | -- Remove BEGIN/END from the code 251 | SELECT regexp_replace(v_what, 'BEGIN\s+(.*)\s*END;', '\1', 'i') INTO tmp_what; 252 | UPDATE dbms_job.all_scheduled_jobs SET this_date = start_t WHERE job = jobid; 253 | BEGIN 254 | EXECUTE tmp_what; 255 | EXCEPTION 256 | WHEN others THEN 257 | -- Increase the failure count 258 | UPDATE dbms_job.all_scheduled_jobs SET 259 | failures = failures + 1 260 | WHERE job = jobid; 261 | -- Rethrow the exception 262 | RAISE; 263 | END; 264 | end_t := clock_timestamp(); 265 | -- Update job's statistics 266 | UPDATE dbms_job.all_scheduled_jobs SET 267 | last_date = end_t, 268 | this_date = NULL, 269 | total_time = total_time + ((EXTRACT(EPOCH FROM end_t) - EXTRACT(EPOCH FROM start_t)) || ' seconds')::interval, 270 | failures = 0, 271 | instance = instance+1, 272 | broken = false, 273 | next_date = dbms_job.get_next_date(interval) 274 | WHERE job = jobid; 275 | -- No write to history table in foreground mode 276 | ELSE 277 | -- Execute the job in background by submitting an asynchronous job 278 | SELECT dbms_job.submit(v_what) INTO jobid; 279 | END IF; 280 | END; 281 | $$; 282 | COMMENT ON PROCEDURE dbms_job.run(bigint, boolean) 283 | IS 'Forces a specified job to run immediatly. It runs even if it is broken'; 284 | REVOKE ALL ON PROCEDURE dbms_job.run FROM PUBLIC; 285 | 286 | CREATE FUNCTION dbms_job.submit( 287 | jobid OUT bigint, 288 | what IN text, 289 | next_date IN timestamp with time zone DEFAULT current_timestamp, 290 | job_interval IN text DEFAULT NULL, 291 | no_parse IN boolean DEFAULT false) 292 | RETURNS bigint 293 | LANGUAGE PLPGSQL 294 | AS $$ 295 | BEGIN 296 | -- interval must be in the future 297 | IF next_date < current_timestamp THEN 298 | RAISE EXCEPTION 'next_date must be a time in the future: %', next_date USING ERRCODE = '23420'; 299 | END IF; 300 | -- When an interval is defined this is a job to be scheduled 301 | IF job_interval IS NOT NULL THEN 302 | INSERT INTO dbms_job.all_scheduled_jobs (what,next_date,interval) VALUES ($2,$3,$4) RETURNING job INTO jobid; 303 | ELSE 304 | -- With no interval verify if the job is planned in 305 | -- the future or that it must be executed immediatly 306 | IF next_date > current_timestamp THEN 307 | INSERT INTO dbms_job.all_scheduled_jobs (what,next_date,interval) VALUES ($2,$3,$4) RETURNING job INTO jobid; 308 | ELSE 309 | -- This is an immediate asynchronous execution, use the special queue 310 | INSERT INTO dbms_job.all_async_jobs (what) VALUES ($2) RETURNING job INTO jobid; 311 | END IF; 312 | END IF; 313 | END; 314 | $$; 315 | COMMENT ON FUNCTION dbms_job.submit(text,timestamp with time zone,text,boolean) 316 | IS 'Submits a new job to the job queue.'; 317 | REVOKE ALL ON FUNCTION dbms_job.submit FROM PUBLIC; 318 | 319 | CREATE PROCEDURE dbms_job.what( 320 | job IN bigint, 321 | what IN text) 322 | LANGUAGE SQL 323 | AS 'UPDATE dbms_job.all_scheduled_jobs SET what=$2 WHERE job=$1'; 324 | COMMENT ON PROCEDURE dbms_job.what(bigint,text) 325 | IS 'Alters the job description for a specified job'; 326 | REVOKE ALL ON PROCEDURE dbms_job.what FROM PUBLIC; 327 | 328 | CREATE FUNCTION dbms_job.job_scheduled_notify() 329 | RETURNS trigger 330 | LANGUAGE PLPGSQL 331 | AS $$ 332 | BEGIN 333 | -- Force interval to be NULL if this is set to an empty string 334 | IF TG_OP = 'UPDATE' OR TG_OP = 'INSERT' THEN 335 | IF NEW.interval = '' THEN 336 | NEW.interval := NULL; 337 | END IF; 338 | END IF; 339 | -- When a change occurs in the all_scheduled_jobs table, notify the scheduler. 340 | IF TG_OP = 'UPDATE' THEN 341 | -- We do not notify the scheduler if it is at the origine of the UPDATE. 342 | -- We increment the value of the instance column when this is an internal 343 | -- update after an execution. 344 | IF NEW.instance = OLD.instance THEN 345 | PERFORM pg_notify('dbms_job_scheduled_notify', TG_OP || ':' || OLD.job || ':' || NEW.job); 346 | END IF; 347 | RETURN NEW; 348 | END IF; 349 | IF TG_OP = 'INSERT' THEN 350 | PERFORM pg_notify('dbms_job_scheduled_notify', TG_OP || ':' || NEW.job); 351 | RETURN NEW; 352 | END IF; 353 | IF TG_OP = 'DELETE' THEN 354 | PERFORM pg_notify('dbms_job_scheduled_notify', TG_OP || ':' || OLD.job); 355 | RETURN OLD; 356 | END IF; 357 | -- TRUNCATE 358 | PERFORM pg_notify('dbms_job_scheduled_notify', TG_OP); 359 | RETURN OLD; 360 | END; 361 | $$; 362 | COMMENT ON FUNCTION dbms_job.job_scheduled_notify() 363 | IS 'Notify the scheduler that the job cache must be invalidated'; 364 | 365 | -- When there is a modification in the JOB table invalidate the cache 366 | -- to inform the background worker to reread the table 367 | CREATE TRIGGER dbms_job_scheduled_notify_trg 368 | AFTER INSERT OR UPDATE OR DELETE OR TRUNCATE 369 | ON dbms_job.all_scheduled_jobs 370 | FOR STATEMENT EXECUTE FUNCTION dbms_job.job_scheduled_notify(); 371 | 372 | CREATE FUNCTION dbms_job.job_async_notify() 373 | RETURNS trigger 374 | LANGUAGE PLPGSQL 375 | AS $$ 376 | BEGIN 377 | -- When a new async job is submitted, notify the scheduler 378 | PERFORM pg_notify('dbms_job_async_notify', 'New asynchronous job received'); 379 | RETURN NEW; 380 | END; 381 | $$; 382 | COMMENT ON FUNCTION dbms_job.job_async_notify() 383 | IS 'Notify the scheduler that a new asynchronous job was submitted'; 384 | 385 | -- When there is a new asynchronous job submited 386 | -- to inform the daemon to reread the table 387 | CREATE TRIGGER dbms_job_async_notify_trg 388 | AFTER INSERT 389 | ON dbms_job.all_async_jobs 390 | FOR STATEMENT EXECUTE FUNCTION dbms_job.job_async_notify(); 391 | 392 | CREATE FUNCTION dbms_job.get_next_date(text) 393 | RETURNS timestamp with time zone 394 | LANGUAGE PLPGSQL 395 | AS $$ 396 | DECLARE 397 | next_date timestamp with time zone; 398 | BEGIN 399 | EXECUTE 'SELECT '||$1 INTO next_date; 400 | RETURN next_date; 401 | END; 402 | $$; 403 | COMMENT ON FUNCTION dbms_job.get_next_date(text) 404 | IS 'Used to get the next date returned by the interval code'; 405 | 406 | -------------------------------------------------------------------------------- /t/01_lint.t: -------------------------------------------------------------------------------- 1 | use Test::Simple tests => 2; 2 | 3 | # Check that the program can be executed 4 | 5 | my $ret = `perl -wc bin/pg_dbms_job 2>&1`; 6 | ok( $? == 0, "PERL syntax check"); 7 | 8 | $ret = `perl bin/pg_dbms_job --help 2>&1`; 9 | ok( $? == 0, "Program usage"); 10 | -------------------------------------------------------------------------------- /t/02_basic.t: -------------------------------------------------------------------------------- 1 | use Test::Simple tests => 15; 2 | 3 | # Test that the ademon can be started and stopped 4 | # as well as default privileges on objects 5 | 6 | # Cleanup garbage from previous regression test runs 7 | `rm -f /tmp/regress_dbms_job.*`; 8 | 9 | # First drop the test database and users 10 | `psql -c "DROP DATABASE regress_dbms_job" 2>/dev/null`; 11 | `psql -c "DROP ROLE regress_dbms_job_user" 2>/dev/null`; 12 | `psql -c "DROP ROLE regress_dbms_job_dba" 2>/dev/null`; 13 | 14 | # Create the test scheduler dameon connection user, need to be superuser 15 | my $ret = `psql -c "CREATE ROLE regress_dbms_job_dba LOGIN SUPERUSER PASSWORD 'regress_dbms_job_dba'"`; 16 | ok( $? == 0, "Create regression test supuser: regress_dbms_job_dba"); 17 | 18 | # Create the test user 19 | $ret = `psql -c "CREATE ROLE regress_dbms_job_user LOGIN PASSWORD 'regress_dbms_job_user'"`; 20 | ok( $? == 0, "Create regression test user: regress_dbms_job_user"); 21 | 22 | 23 | # Create the test database 24 | $ret = `psql -c "CREATE DATABASE regress_dbms_job OWNER regress_dbms_job_dba"`; 25 | ok( $? == 0, "Create test regression database: regress_dbms_job"); 26 | 27 | # Start the scheduler when the pg_dbms_job extension doesn't exists, it must stop 28 | $ret = `perl bin/pg_dbms_job -c test/regress_dbms_job.conf -s >/dev/null 2>&1`; 29 | $ret = `ls /tmp/regress_dbms_job.* | wc -l`; 30 | chomp($ret); 31 | ok( $ret eq "1", "Scheduler stopped, no pid file"); 32 | 33 | # Create the schema and object of the pg_dbms_job extension 34 | my $ver = `grep default_version pg_dbms_job.control | sed -E "s/.*'(.*)'/\\1/"`; 35 | chomp($ver); 36 | $ret = `psql -d regress_dbms_job -c "CREATE SCHEMA dbms_job;" > /dev/null 2>&1`; 37 | ok( $? == 0, "Create dbms_job schema"); 38 | 39 | $ret = `psql -d regress_dbms_job -f sql/pg_dbms_job--$ver.sql > /dev/null 2>&1`; 40 | ok( $? == 0, "Import manually pg_dbms_job extension file"); 41 | 42 | # Start the scheduler daemon and verify that the pid and log files are created 43 | `perl bin/pg_dbms_job -c test/regress_dbms_job.conf 2>/dev/null`; 44 | $ret = `ls /tmp/regress_dbms_job.* | wc -l`; 45 | chomp($ret); 46 | ok( $ret eq "2" , "Check for pid and log file creation"); 47 | 48 | # Verify that the process is running 49 | $ret = `ps auwx | grep pg_dbms_job: | grep -v grep | wc -l`; 50 | chomp($ret); 51 | ok( $ret eq "1", "Deamon pg_dbms_job is running"); 52 | 53 | # Set privilege to allow user regress_dbms_job_user to work with the extension 54 | $ret = `psql -d regress_dbms_job -c "GRANT USAGE ON SCHEMA dbms_job TO regress_dbms_job_user"`; 55 | ok( $? == 0, "Add privileges to test user on pg_dbms_job schema"); 56 | $ret = `psql -d regress_dbms_job -c "GRANT ALL ON ALL TABLES IN SCHEMA dbms_job TO regress_dbms_job_user"`; 57 | ok( $? == 0, "Add privileges to test user on pg_dbms_job tables"); 58 | $ret = `psql -d regress_dbms_job -c "GRANT ALL ON ALL SEQUENCES IN SCHEMA dbms_job TO regress_dbms_job_user"`; 59 | ok( $? == 0, "Add privileges to test user on pg_dbms_job sequences"); 60 | $ret = `psql -d regress_dbms_job -c "GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA dbms_job TO regress_dbms_job_user"`; 61 | ok( $? == 0, "Add privileges to test user on pg_dbms_job functions"); 62 | $ret = `psql -d regress_dbms_job -c "GRANT EXECUTE ON ALL PROCEDURES IN SCHEMA dbms_job TO regress_dbms_job_user"`; 63 | ok( $? == 0, "Add privileges to test user on pg_dbms_job procedures"); 64 | 65 | # Stop the daemon 66 | $ret = `perl bin/pg_dbms_job -c test/regress_dbms_job.conf -k`; 67 | $ret = `ls /tmp/regress_dbms_job.pid 2>/dev/null | wc -l`; 68 | chomp($ret); 69 | ok( $ret eq "0", "Check that pid file has been removed"); 70 | 71 | # Verify that the process is stopped 72 | $ret = `ps auwx | grep pg_dbms_job: | grep -v grep | wc -l`; 73 | chomp($ret); 74 | ok( $ret eq "0", "Deamon pg_dbms_job is not running"); 75 | -------------------------------------------------------------------------------- /t/03_async.t: -------------------------------------------------------------------------------- 1 | use Test::Simple tests => 7; 2 | 3 | # Test asynchronous jobs 4 | 5 | # Cleanup garbage from previous regression test runs 6 | `rm -f /tmp/regress_dbms_job.*`; 7 | 8 | # Start the scheduler 9 | $ret = `perl bin/pg_dbms_job -c test/regress_dbms_job.conf`; 10 | $ret = `ls /tmp/regress_dbms_job.* | wc -l`; 11 | chomp($ret); 12 | ok( $ret eq "2", "pg_dbms_job daemon started"); 13 | # Verify that the process is running 14 | $ret = `ps auwx | grep pg_dbms_job: | grep -v grep | wc -l`; 15 | chomp($ret); 16 | ok( $ret eq "1", "Daemon pg_dbms_job is running"); 17 | 18 | # Create an asynchronous job 19 | $ret = `psql -d regress_dbms_job -f test/sql/async.sql > /dev/null 2>&1`; 20 | ok( $? == 0, "Submit job"); 21 | sleep(2); 22 | 23 | # Stop the daemon 24 | $ret = `perl bin/pg_dbms_job -c test/regress_dbms_job.conf -k`; 25 | sleep(1); 26 | # We should have the daemon and the child still running, 27 | # the current running jobs must not be stopped 28 | $ret = `ps auwx | grep pg_dbms_job: | grep -v grep | wc -l`; 29 | chomp($ret); 30 | ok( $ret eq "2", "Daemon pg_dbms_job and subprocess are still running: $ret"); 31 | 32 | # Be sure that the job have been processed 33 | sleep(3); 34 | 35 | # Verify that the job have been removed from the queue 36 | my $ret = `psql -d regress_dbms_job -Atc "SELECT count(*) FROM dbms_job.all_async_jobs;" | grep -v SET`; 37 | chomp($ret); 38 | ok( $? == 0 && $ret eq "0", "Asynchronous job have been removed"); 39 | 40 | # Look if the job have been registered in the history table 41 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT count(*) FROM dbms_job.all_scheduler_job_run_details;" | grep -v SET`; 42 | chomp($ret); 43 | ok( $? == 0 && $ret eq "1", "Found $ret async job in the history"); 44 | 45 | sleep(1); 46 | 47 | # Now all process must be terminated 48 | $ret = `ps auwx | grep pg_dbms_job: | grep -v grep | wc -l`; 49 | chomp($ret); 50 | ok( $ret eq "0", "Daemon pg_dbms_job is stopped"); 51 | -------------------------------------------------------------------------------- /t/04_signal.t: -------------------------------------------------------------------------------- 1 | use Test::Simple tests => 8; 2 | 3 | # Test reload and interrupt signals, kill has already been tested. 4 | 5 | # Cleanup garbage from previous regression test runs 6 | `rm -f /tmp/regress_dbms_job.*`; 7 | 8 | # Cleanup history table 9 | $ret = `psql -d regress_dbms_job -c "TRUNCATE dbms_job.all_scheduler_job_run_details" > /dev/null 2>&1`; 10 | ok( $? == 0, "truncate table dbms_job.all_scheduler_job_run_details"); 11 | 12 | # Start the scheduler 13 | $ret = `perl bin/pg_dbms_job -c test/regress_dbms_job.conf`; 14 | $ret = `ps auwx | grep pg_dbms_job: | grep -v grep | wc -l`; 15 | chomp($ret); 16 | ok( $ret eq "1", "Daemon pg_dbms_job is running"); 17 | 18 | # Create an asynchronous job 19 | $ret = `psql -d regress_dbms_job -f test/sql/async.sql > /dev/null 2>&1`; 20 | ok( $? == 0, "Import pg_dbms_job schema"); 21 | sleep(2); 22 | 23 | # Reload the daemon 24 | $ret = `perl bin/pg_dbms_job -c test/regress_dbms_job.conf -r`; 25 | sleep(1); 26 | # We should have the daemon and the child still running, 27 | $ret = `ps auwx | grep pg_dbms_job: | grep -v grep | wc -l`; 28 | chomp($ret); 29 | ok( $ret eq "2", "Daemon pg_dbms_job and subprocess are still running: $ret"); 30 | 31 | # Be sure that the job have been processed 32 | sleep(3); 33 | 34 | # Look if the job have been registered in the history table 35 | my $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT count(*) FROM dbms_job.all_scheduler_job_run_details;" | grep -v SET`; 36 | chomp($ret); 37 | ok( $? == 0 && $ret eq "1", "Found $ret async job in the history"); 38 | 39 | # Create another asynchronous job 40 | $ret = `psql -d regress_dbms_job -f test/sql/async.sql > /dev/null 2>&1`; 41 | ok( $? == 0, "Submit job"); 42 | sleep(2); 43 | 44 | # Interrupt immediatly the daemon 45 | $ret = `perl bin/pg_dbms_job -c test/regress_dbms_job.conf -m`; 46 | sleep(5); 47 | 48 | # Now all process must be terminated 49 | $ret = `ps auwx | grep pg_dbms_job: | grep -v grep | wc -l`; 50 | chomp($ret); 51 | ok( $ret eq "0", "Daemon pg_dbms_job is interrupted: $ret"); 52 | 53 | # Look if the last job have been registered in the history table, it must not 54 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT count(*) FROM dbms_job.all_scheduler_job_run_details;" | grep -v SET`; 55 | chomp($ret); 56 | ok( $? == 0 && $ret eq "1", "Found $ret async job in the history"); 57 | -------------------------------------------------------------------------------- /t/05_async_error.t: -------------------------------------------------------------------------------- 1 | use Test::Simple tests => 5; 2 | 3 | # Submit an asynchronous job with a failure 4 | 5 | # Cleanup garbage from previous regression test runs 6 | `rm -f /tmp/regress_dbms_job.*`; 7 | 8 | # Start the scheduler 9 | $ret = `perl bin/pg_dbms_job -c test/regress_dbms_job.conf 2>/dev/null`; 10 | $ret = `ls /tmp/regress_dbms_job.* | wc -l`; 11 | chomp($ret); 12 | ok( $ret eq "2", "pg_dbms_job daemon started"); 13 | # Verify that the process is running 14 | $ret = `ps auwx | grep pg_dbms_job: | grep -v grep | wc -l`; 15 | chomp($ret); 16 | ok( $ret eq "1", "Daemon pg_dbms_job is running"); 17 | 18 | # Create an asynchronous job 19 | $ret = `psql -d regress_dbms_job -f test/sql/async_error.sql > /dev/null 2>&1`; 20 | ok( $? == 0, "Submit job"); 21 | sleep(2); 22 | 23 | # Look if the job have been registered in the history table 24 | my $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT count(*) FROM dbms_job.all_scheduler_job_run_details;" | grep -v SET`; 25 | chomp($ret); 26 | ok( $? == 0 && $ret eq "1", "Found $ret async job in the history"); 27 | 28 | # Stop the daemon 29 | $ret = `perl bin/pg_dbms_job -c test/regress_dbms_job.conf -k`; 30 | sleep(2); 31 | # Now all process must be terminated 32 | $ret = `ps auwx | grep pg_dbms_job: | grep -v grep | wc -l`; 33 | chomp($ret); 34 | ok( $ret eq "0", "Daemon pg_dbms_job is stopped"); 35 | -------------------------------------------------------------------------------- /t/06_queue_interval.t: -------------------------------------------------------------------------------- 1 | use Test::Simple tests => 6; 2 | 3 | # Submit an asynchronous job and validate that queue_job_interval is respected 4 | 5 | # Cleanup garbage from previous regression test runs 6 | `rm -f /tmp/regress_dbms_job.*`; 7 | 8 | # Start the scheduler 9 | $ret = `perl bin/pg_dbms_job -c test/regress_dbms_job.conf`; 10 | $ret = `ls /tmp/regress_dbms_job.* | wc -l`; 11 | chomp($ret); 12 | ok( $ret eq "2", "pg_dbms_job daemon started"); 13 | # Verify that the process is running 14 | $ret = `ps auwx | grep pg_dbms_job: | grep -v grep | wc -l`; 15 | chomp($ret); 16 | ok( $ret eq "1", "Daemon pg_dbms_job is running"); 17 | 18 | # Create an asynchronous job that must be executed later in 3 seconds 19 | $ret = `psql -d regress_dbms_job -f test/sql/async_queue_interval.sql > /dev/null 2>&1`; 20 | ok( $? == 0, "Submit job"); 21 | sleep(1); 22 | 23 | # Look if the job have been registered in the history table, it should not 24 | my $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT count(*) FROM dbms_job.all_scheduler_job_run_details;" | grep -v SET`; 25 | chomp($ret); 26 | ok( $? == 0 && $ret eq "0", "No async job found in the history: $ret"); 27 | 28 | # Wait to reach job_queue_interval 29 | sleep(5); 30 | 31 | # Now verify that the job have been run 32 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT count(*) FROM dbms_job.all_scheduler_job_run_details;" | grep -v SET`; 33 | chomp($ret); 34 | ok( $? == 0 && $ret eq "1", "Found $ret async job in the history"); 35 | 36 | # Stop the daemon 37 | $ret = `perl bin/pg_dbms_job -c test/regress_dbms_job.conf -k`; 38 | sleep(1); 39 | # We should have the daemon and the child still running, 40 | # the current running jobs must not be stopped 41 | $ret = `ps auwx | grep pg_dbms_job: | grep -v grep | wc -l`; 42 | chomp($ret); 43 | ok( $ret eq "0", "Daemon pg_dbms_job was stopped"); 44 | -------------------------------------------------------------------------------- /t/07_scheduled.t: -------------------------------------------------------------------------------- 1 | use Test::Simple tests => 11; 2 | 3 | # Test scheduled job with an interval of 6 seconds 4 | 5 | # Cleanup garbage from previous regression test runs 6 | `rm -f /tmp/regress_dbms_job.*`; 7 | 8 | # Start the scheduler 9 | $ret = `perl bin/pg_dbms_job -c test/regress_dbms_job.conf`; 10 | $ret = `ls /tmp/regress_dbms_job.* | wc -l`; 11 | chomp($ret); 12 | ok( $ret eq "2", "pg_dbms_job daemon started"); 13 | # Verify that the process is running 14 | $ret = `ps auwx | grep pg_dbms_job: | grep -v grep | wc -l`; 15 | chomp($ret); 16 | ok( $ret eq "1", "Daemon pg_dbms_job is running"); 17 | 18 | # Create an scheduled job that must be executed later in 3 seconds and each 6 seconds after 19 | $ret = `psql -d regress_dbms_job -f test/sql/scheduled.sql > /dev/null 2>&1`; 20 | ok( $? == 0, "Submit job"); 21 | sleep(1); 22 | 23 | # Look if the job have been registered in the history table, it should not 24 | my $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT count(*) FROM dbms_job.all_scheduler_job_run_details;" | grep -v SET`; 25 | chomp($ret); 26 | ok( $? == 0 && $ret eq "0", "No async job found in the history: $ret"); 27 | 28 | # Wait to reach job_queue_interval 29 | sleep(7); 30 | 31 | # Now verify that the job have been run 32 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT count(*) FROM dbms_job.all_scheduler_job_run_details;" | grep -v SET`; 33 | chomp($ret); 34 | ok( $? == 0 && $ret eq "1", "Found $ret async job in the history"); 35 | 36 | # Wait that at least 2 more job execution was done (12 seconds) 37 | sleep(15); 38 | 39 | # Now verify that we have 2 jobs that have been run 40 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT count(*) FROM dbms_job.all_scheduler_job_run_details;" | grep -v SET`; 41 | chomp($ret); 42 | ok( $? == 0 && $ret eq "2", "Found $ret async job in the history"); 43 | 44 | sleep(6); 45 | 46 | # Mark the job as broken to stop its execution, we should have a third trace in the history 47 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user; CALL dbms_job.broken(6, true);" | grep -v SET`; 48 | chomp($ret); 49 | ok( $? == 0 && $ret eq "CALL", "Call to broken procedure"); 50 | 51 | sleep(15); 52 | 53 | # Now verify that we still have 3 jobs that have been run 54 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT count(*) FROM dbms_job.all_scheduler_job_run_details;" | grep -v SET`; 55 | chomp($ret); 56 | ok( $? == 0 && $ret eq "3", "Found $ret async job in the history"); 57 | 58 | # Mark the job as not broken to restart its execution 59 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user; CALL dbms_job.broken(6, false);" | grep -v SET`; 60 | chomp($ret); 61 | ok( $? == 0 && $ret eq "CALL", "Call to broken procedure"); 62 | 63 | sleep(15); 64 | 65 | # Now verify that we have 5 jobs that have been run 66 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT count(*) FROM dbms_job.all_scheduler_job_run_details;" | grep -v SET`; 67 | chomp($ret); 68 | ok( $? == 0 && $ret eq "5", "Found $ret async job in the history"); 69 | 70 | # Stop the daemon 71 | $ret = `perl bin/pg_dbms_job -c test/regress_dbms_job.conf -k`; 72 | sleep(1); 73 | # We should have the daemon and the child still running, 74 | # the current running jobs must not be stopped 75 | $ret = `ps auwx | grep pg_dbms_job: | grep -v grep | wc -l`; 76 | chomp($ret); 77 | ok( $ret eq "0", "Daemon pg_dbms_job was stopped"); 78 | 79 | 80 | -------------------------------------------------------------------------------- /t/08_procedures.t: -------------------------------------------------------------------------------- 1 | use Test::Simple tests => 21; 2 | 3 | # Test pg_dbms_job procedures 4 | 5 | # Cleanup garbage from previous regression test runs 6 | `rm -f /tmp/regress_dbms_job.*`; 7 | 8 | # Start the scheduler 9 | my $ret = `perl bin/pg_dbms_job -c test/regress_dbms_job.conf`; 10 | $ret = `ls /tmp/regress_dbms_job.* | wc -l`; 11 | chomp($ret); 12 | ok( $ret eq "2", "pg_dbms_job daemon started"); 13 | # Verify that the process is running 14 | $ret = `ps auwx | grep pg_dbms_job: | grep -v grep | wc -l`; 15 | chomp($ret); 16 | ok( $ret eq "1", "Daemon pg_dbms_job is running"); 17 | 18 | # Submit a job that must be executed each days 19 | $ret = `psql -d regress_dbms_job -f test/sql/submit.sql > /dev/null 2>&1`; 20 | ok( $? == 0, "Submit job"); 21 | sleep(1); 22 | 23 | # Get the id of the job that have been registered 24 | my $job = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT job FROM dbms_job.all_scheduled_jobs;" | grep -v SET`; 25 | chomp($job); 26 | ok( $? == 0 && $job ne "" , "Job $job have been created"); 27 | 28 | # Remove the job 29 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;CALL dbms_job.remove($job);" | grep -v SET`; 30 | ok( $? == 0, "Removing job $job"); 31 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT count(*) FROM dbms_job.all_scheduled_jobs;" | grep -v SET`; 32 | chomp($ret); 33 | ok( $? == 0 && $ret eq "0", "Job $job have been removed"); 34 | 35 | # Submit the job again 36 | $ret = `psql -d regress_dbms_job -f test/sql/submit.sql > /dev/null 2>&1`; 37 | ok( $? == 0, "Submit job"); 38 | sleep(1); 39 | 40 | # Get the id of the new job that have been registered 41 | $job = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT job FROM dbms_job.all_scheduled_jobs;" | grep -v SET`; 42 | chomp($job); 43 | ok( $? == 0 && $job ne "", "New job $job have been created"); 44 | 45 | # Change the next execution date to NULL 46 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;CALL dbms_job.next_date($job, NULL);" > /dev/null 2>&1 | grep -v SET`; 47 | ok( $? != 0, "Can not set next_date to NULL for job $job"); 48 | 49 | # Change the next execution date to today + 1 year 50 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;CALL dbms_job.next_date($job, date_trunc('day', current_timestamp) + '1 year'::interval);" | grep -v SET`; 51 | ok( $? == 0, "Change next_date for job $job"); 52 | 53 | # Verify that the new next_date that have been registered 54 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT job FROM dbms_job.all_scheduled_jobs WHERE next_date = date_trunc('day', current_timestamp) + '1 year'::interval;" | grep -v SET`; 55 | chomp($ret); 56 | ok( $? == 0 && $ret eq $job, "New next_date for job $job have been modified"); 57 | 58 | # Change the interval to once a month 59 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;CALL dbms_job.interval($job, 'date_trunc(''day'', current_timestamp) + ''1 month''::interval');" | grep -v SET`; 60 | ok( $? == 0, "Change interval for job $job"); 61 | 62 | # Verify that the new interval that have been registered 63 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT job FROM dbms_job.all_scheduled_jobs WHERE md5(interval) = 'fb9412d079a32a090003d1c080619d72';" | grep -v SET`; 64 | chomp($ret); 65 | ok( $? == 0 && $ret eq $job, "New interval for job $ret have been modified"); 66 | 67 | # Change the action to NULL, should be an error 68 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;CALL dbms_job.what($job, NULL);" > /dev/null 2>&1 | grep -v SET`; 69 | ok( $? != 0, "Change what to NULL for job $job"); 70 | 71 | # Change the action 72 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;CALL dbms_job.what($job, 'BEGIN PERFORM version(); END;');" | grep -v SET`; 73 | ok( $? == 0, "Change what for job $job"); 74 | 75 | # Verify that the new what value that have been registered 76 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT job FROM dbms_job.all_scheduled_jobs WHERE what = 'BEGIN PERFORM version(); END;';" | grep -v SET`; 77 | chomp($ret); 78 | ok( $? == 0 && $ret eq $job, "New what for job $job have been modified"); 79 | 80 | # Change the modifiable columns to NULL, nothing must be changed 81 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;CALL dbms_job.change($job, NULL, NULL, NULL);" | grep -v SET`; 82 | ok( $? == 0, "Change all for job $job to NULL"); 83 | 84 | # Verify that nothing have changed 85 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT count(*) FROM dbms_job.all_scheduled_jobs WHERE md5(what) = '9e5f15c5784fb71b23e3d6419475d6de' AND md5(interval) = 'fb9412d079a32a090003d1c080619d72' AND next_date = date_trunc('day', current_timestamp) + '1 year'::interval;" | grep -v SET`; 86 | chomp($ret); 87 | ok( $? == 0 && $ret eq "1", "Job $job is the same, nothing changed"); 88 | 89 | # Change the modifiable columns 90 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;CALL dbms_job.change($job, 'VACUUM ANALYZE;', date_trunc('day', current_timestamp) + '1 day'::interval, 'current_timestamp + ''1 day''::interval');" | grep -v SET`; 91 | ok( $? == 0, "Change all for job $job"); 92 | 93 | # Verify that all values have changed 94 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT count(*) FROM dbms_job.all_scheduled_jobs WHERE md5(what) = '4819535deca0cb7a637474c659d1b4e5' AND md5(interval) = 'b508a5fc92a976eac08a9c017b049f92' AND next_date = date_trunc('day', current_timestamp) + '1 day'::interval;" | grep -v SET`; 95 | chomp($ret); 96 | ok( $? == 0 && $ret eq "1", "Job $job have been executed and removed"); 97 | 98 | # Stop the daemon 99 | $ret = `perl bin/pg_dbms_job -c test/regress_dbms_job.conf -k`; 100 | sleep(1); 101 | # We should have the daemon and the child still running, 102 | # the current running jobs must not be stopped 103 | $ret = `ps auwx | grep pg_dbms_job: | grep -v grep | wc -l`; 104 | chomp($ret); 105 | ok( $ret eq "0", "Daemon pg_dbms_job was stopped"); 106 | -------------------------------------------------------------------------------- /t/09_run.t: -------------------------------------------------------------------------------- 1 | use Test::Simple tests => 12; 2 | 3 | # Test procedure dbms_job.run 4 | 5 | # Cleanup garbage from previous regression test runs 6 | `rm -f /tmp/regress_dbms_job.*`; 7 | 8 | # Start the scheduler 9 | $ret = `perl bin/pg_dbms_job -c test/regress_dbms_job.conf 2>/dev/null`; 10 | $ret = `ls /tmp/regress_dbms_job.* | wc -l`; 11 | chomp($ret); 12 | ok( $ret eq "2", "pg_dbms_job daemon started"); 13 | # Verify that the process is running 14 | $ret = `ps auwx | grep pg_dbms_job: | grep -v grep | wc -l`; 15 | chomp($ret); 16 | ok( $ret eq "1", "Daemon pg_dbms_job is running"); 17 | 18 | # Create a job 19 | $ret = `psql -d regress_dbms_job -f test/sql/run.sql > /dev/null 2>&1`; 20 | ok( $? == 0, "Submit job"); 21 | 22 | # Get the id of the job that have been registered 23 | my $job = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT job FROM dbms_job.all_scheduled_jobs;" | grep -v SET`; 24 | chomp($job); 25 | ok( $? == 0 && $job ne "" , "Job $job have been created"); 26 | 27 | # Mark the job as broken to stop its automatic execution 28 | my $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user; CALL dbms_job.broken($job, true);" | grep -v SET`; 29 | chomp($ret); 30 | ok( $? == 0 && $ret eq "CALL", "Call to broken procedure"); 31 | sleep(10); 32 | 33 | # Look if the job have been registered in the history table, it should not 34 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT count(*) FROM dbms_job.all_scheduler_job_run_details;" | grep -v SET`; 35 | chomp($ret); 36 | ok( $? == 0 && $ret eq "0", "Good, no job found in the history"); 37 | 38 | # Run the job in foreground 39 | $ret = `psql -d regress_dbms_job -Atc "CALL dbms_job.run($job, false);" | grep -v SET`; 40 | chomp($ret); 41 | ok( $? == 0 && $ret eq "CALL", "Call to run procedure for immediate execution of job $job"); 42 | 43 | # we must have a job registered in the history 44 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user;SELECT count(*) FROM pg_catalog.pg_class WHERE relname = 't1';" | grep -v SET`; 45 | chomp($ret); 46 | ok( $? == 0 && $ret eq "1", "Job $job have been executed in foreground"); 47 | 48 | # Run the job in background 49 | $ret = `psql -d regress_dbms_job -Atc "CALL dbms_job.run($job, true);" | grep -v SET`; 50 | chomp($ret); 51 | ok( $? == 0 && $ret eq "CALL", "Call to run procedure for background execution of job $job"); 52 | sleep(10); 53 | 54 | # Look if the job have been registered in the history table 55 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user; SELECT count(*) FROM dbms_job.all_scheduler_job_run_details;" | grep -v SET`; 56 | chomp($ret); 57 | ok( $? == 0 && $ret eq "1", "Found $ret async job in the history"); 58 | 59 | # we must have 2 rows in the t1 table 60 | $ret = `psql -d regress_dbms_job -Atc "SET ROLE regress_dbms_job_user; SELECT count(*) FROM t1;" | grep -v SET`; 61 | chomp($ret); 62 | ok( $? == 0 && $ret >= 2, "Job $job have been executed in background, $ret rows"); 63 | 64 | # Stop the daemon 65 | $ret = `perl bin/pg_dbms_job -c test/regress_dbms_job.conf -k`; 66 | sleep(2); 67 | # Now all process must be terminated 68 | $ret = `ps auwx | grep pg_dbms_job: | grep -v grep | wc -l`; 69 | chomp($ret); 70 | ok( $ret eq "0", "Daemon pg_dbms_job is stopped"); 71 | -------------------------------------------------------------------------------- /test/regress_dbms_job.conf: -------------------------------------------------------------------------------- 1 | #----------- 2 | # General 3 | #----------- 4 | # Toogle debug mode 5 | debug=1 6 | # Path to the pid file 7 | pidfile=/tmp/regress_dbms_job.pid 8 | # log file name pattern, can include strftime() escapes, for example 9 | # to have a log file per week day use %a in the log file name. 10 | logfile=/tmp/regress_dbms_job.log 11 | # If activated an existing log file with the same name as the new log 12 | # file will be truncated rather than appended to. But such truncation 13 | # only occurs on time-driven rotation, not on restarts. 14 | log_truncate_on_rotation=0 15 | # Poll interval of the job queue 16 | job_queue_interval=5 17 | #Maximum number of job processed at the same time 18 | job_queue_processes=10 19 | 20 | #----------- 21 | # Database 22 | #----------- 23 | host=localhost 24 | port=5432 25 | database=regress_dbms_job 26 | user=regress_dbms_job_dba 27 | passwd=regress_dbms_job_dba 28 | 29 | -------------------------------------------------------------------------------- /test/sql/async.sql: -------------------------------------------------------------------------------- 1 | -- Insert an asynchronous job 2 | SET ROLE regress_dbms_job_user; 3 | DO $$ 4 | DECLARE 5 | jobid bigint; 6 | BEGIN 7 | -- Asynchronous job, must be executed immediately 8 | SELECT dbms_job.submit( 9 | 'BEGIN PERFORM pg_sleep(5); PERFORM current_timestamp; END;' -- what 10 | ) INTO jobid; 11 | END; 12 | $$; 13 | -------------------------------------------------------------------------------- /test/sql/async_error.sql: -------------------------------------------------------------------------------- 1 | -- Insert an asynchronous job 2 | TRUNCATE TABLE dbms_job.all_scheduler_job_run_details; 3 | SET ROLE regress_dbms_job_user; 4 | DO $$ 5 | DECLARE 6 | jobid bigint; 7 | BEGIN 8 | -- Asynchronous job, must be executed immediately, there 9 | -- is no interval and next_date is set to current timestamp 10 | SELECT dbms_job.submit( 11 | 'BEGIN INSERT INTO noexisttable VALUES (NULL); END;', -- what 12 | LOCALTIMESTAMP, NULL 13 | ) INTO jobid; 14 | END; 15 | $$; 16 | -------------------------------------------------------------------------------- /test/sql/async_queue_interval.sql: -------------------------------------------------------------------------------- 1 | -- Insert an asynchronous job that must be executed later 2 | TRUNCATE TABLE dbms_job.all_scheduler_job_run_details; 3 | SET ROLE regress_dbms_job_user; 4 | DO $$ 5 | DECLARE 6 | jobid bigint; 7 | BEGIN 8 | -- Asynchronous job, must be executed immediately, there 9 | -- is no interval and next_date is set to current timestamp 10 | SELECT dbms_job.submit( 11 | 'BEGIN PERFORM current_timestamp; END;', -- what 12 | LOCALTIMESTAMP + '3 seconds'::interval, NULL 13 | ) INTO jobid; 14 | END; 15 | $$; 16 | -------------------------------------------------------------------------------- /test/sql/run.sql: -------------------------------------------------------------------------------- 1 | -- Insert an asynchronous job that must be executed later 2 | TRUNCATE TABLE dbms_job.all_scheduler_job_run_details; 3 | TRUNCATE TABLE dbms_job.all_scheduled_jobs; 4 | SET ROLE regress_dbms_job_user; 5 | DO $$ 6 | DECLARE 7 | jobid bigint; 8 | BEGIN 9 | -- Scheduled job that will be executed in 3 seconds 10 | -- and each 10 seconds after that. 11 | SELECT dbms_job.submit( 12 | 'CREATE TABLE IF NOT EXISTS t1 (id integer); ALTER TABLE t1 OWNER TO regress_dbms_job_user; INSERT INTO t1 VALUES (1);', -- what 13 | LOCALTIMESTAMP + '3 seconds'::interval, -- start the job in 3 seconds 14 | 'LOCALTIMESTAMP + ''6 seconds''::interval' -- repeat the job every 6 seconds 15 | ) INTO jobid; 16 | END; 17 | $$; 18 | -------------------------------------------------------------------------------- /test/sql/scheduled.sql: -------------------------------------------------------------------------------- 1 | -- Insert an asynchronous job that must be executed later 2 | TRUNCATE TABLE dbms_job.all_scheduler_job_run_details; 3 | TRUNCATE TABLE dbms_job.all_scheduled_jobs; 4 | SET ROLE regress_dbms_job_user; 5 | DO $$ 6 | DECLARE 7 | jobid bigint; 8 | BEGIN 9 | -- Scheduled job that will be executed in 3 seconds 10 | -- and each 10 seconds after that. 11 | SELECT dbms_job.submit( 12 | 'BEGIN PERFORM LOCALTIMESTAMP; END;', -- what 13 | LOCALTIMESTAMP + '3 seconds'::interval, -- start the job in 3 seconds 14 | 'LOCALTIMESTAMP + ''6 seconds''::interval' -- repeat the job every 6 seconds 15 | ) INTO jobid; 16 | END; 17 | $$; 18 | -------------------------------------------------------------------------------- /test/sql/submit.sql: -------------------------------------------------------------------------------- 1 | -- Insert a scheduled job 2 | TRUNCATE TABLE dbms_job.all_scheduler_job_run_details; 3 | TRUNCATE TABLE dbms_job.all_scheduled_jobs; 4 | SET ROLE regress_dbms_job_user; 5 | DO $$ 6 | DECLARE 7 | jobid bigint; 8 | BEGIN 9 | -- Scheduled job that must be executed 10 seconds 10 | -- after its creation and then every 10 seconds 11 | SELECT dbms_job.submit( 12 | 'VACUUM ANALYZE;', -- what 13 | current_timestamp + '1 day'::interval, -- next_date 14 | 'current_timestamp + ''1 day''::interval' -- interval 15 | ) INTO jobid; 16 | END; 17 | $$; 18 | -------------------------------------------------------------------------------- /updates/pg_dbms_job--1.0.1--1.1.0.sql: -------------------------------------------------------------------------------- 1 | ALTER TABLE dbms_job.all_async_jobs ADD COLUMN this_date timestamp with time zone; 2 | -------------------------------------------------------------------------------- /updates/pg_dbms_job--1.1.0--1.2.0.sql: -------------------------------------------------------------------------------- 1 | -- Nothing to do 2 | -------------------------------------------------------------------------------- /updates/pg_dbms_job--1.2.0--1.3.0.sql: -------------------------------------------------------------------------------- 1 | -- Nothing to do 2 | -------------------------------------------------------------------------------- /updates/pg_dbms_job--1.3.0--1.4.0.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE PROCEDURE dbms_job.interval( 2 | jobid IN bigint, 3 | job_interval IN text) 4 | LANGUAGE PLPGSQL 5 | AS $$ 6 | DECLARE 7 | next_date timestamp with time zone; 8 | v_interval text; 9 | v_retval bigint; 10 | BEGIN 11 | IF job_interval IS NULL THEN 12 | UPDATE dbms_job.all_scheduled_jobs SET interval = NULL WHERE job = jobid; 13 | ELSE 14 | -- interval must be in the future 15 | next_date := dbms_job.get_next_date(job_interval); 16 | IF next_date < current_timestamp THEN 17 | RAISE EXCEPTION 'Interval must evaluate to a time in the future: %', next_date USING ERRCODE = '23420'; 18 | END IF; 19 | v_interval := 'UPDATE dbms_job.all_scheduled_jobs SET interval = ' || quote_literal(job_interval) || ' WHERE job = ' || jobid || ' RETURNING job'; 20 | EXECUTE v_interval INTO v_retval; 21 | IF v_retval IS NULL THEN 22 | RAISE EXCEPTION 'null_value_not_allowed' USING detail = 'job number is not a job in the job queue'; 23 | END IF; 24 | END IF; 25 | END; 26 | $$; 27 | -------------------------------------------------------------------------------- /updates/pg_dbms_job--1.4.0--1.5.0.sql: -------------------------------------------------------------------------------- 1 | -- Nothing to perform at SQL level for this upgrade 2 | --------------------------------------------------------------------------------