diff --git a/.vscode/settings.json b/.vscode/settings.json new file mode 100644 index 0000000..37441be --- /dev/null +++ b/.vscode/settings.json @@ -0,0 +1,3 @@ +{ + "files.eol": "\n" +} \ No newline at end of file diff --git a/samples/Autonomous.sql b/samples/Autonomous.sql index ca5ffc5..d25f985 100644 --- a/samples/Autonomous.sql +++ b/samples/Autonomous.sql @@ -1,41 +1,41 @@ --- An advanced example showing how to use atutonomous tasks. --- This one-task chain will execute test_proc() procedure. --- Since procedure will make two commits (after f1() and f2()) --- we cannot use it as a regular task, because all regular tasks --- must be executed in the context of a single chain transaction. --- Same rule applies for some other SQL commands, --- e.g. CREATE DATABASE, REINDEX, VACUUM, CREATE TABLESPACE, etc. -CREATE OR REPLACE FUNCTION f (msg TEXT) RETURNS void AS $$ -BEGIN - RAISE notice '%', msg; -END; -$$ LANGUAGE PLPGSQL; - -CREATE OR REPLACE PROCEDURE test_proc () AS $$ -BEGIN - PERFORM f('hey 1'); - COMMIT; - PERFORM f('hey 2'); - COMMIT; -END; -$$ -LANGUAGE PLPGSQL; - -WITH - cte_chain (v_chain_id) AS ( - INSERT INTO timetable.chain (chain_name, run_at, max_instances, live, self_destruct) - VALUES ( - 'call proc() every 10 sec', -- chain_name, - '@every 10 seconds', -- run_at, - 1, -- max_instances, - TRUE, -- live, - FALSE -- self_destruct - ) RETURNING chain_id - ), - cte_task(v_task_id) AS ( - INSERT INTO timetable.task (chain_id, task_order, kind, command, ignore_error, autonomous) - SELECT v_chain_id, 10, 'SQL', 'CALL test_proc()', TRUE, TRUE - FROM cte_chain - RETURNING task_id - ) -SELECT v_chain_id, v_task_id FROM cte_task, cte_chain; +-- An advanced example showing how to use atutonomous tasks. +-- This one-task chain will execute test_proc() procedure. +-- Since procedure will make two commits (after f1() and f2()) +-- we cannot use it as a regular task, because all regular tasks +-- must be executed in the context of a single chain transaction. +-- Same rule applies for some other SQL commands, +-- e.g. CREATE DATABASE, REINDEX, VACUUM, CREATE TABLESPACE, etc. +CREATE OR REPLACE FUNCTION f (msg TEXT) RETURNS void AS $$ +BEGIN + RAISE notice '%', msg; +END; +$$ LANGUAGE PLPGSQL; + +CREATE OR REPLACE PROCEDURE test_proc () AS $$ +BEGIN + PERFORM f('hey 1'); + COMMIT; + PERFORM f('hey 2'); + COMMIT; +END; +$$ +LANGUAGE PLPGSQL; + +WITH + cte_chain (v_chain_id) AS ( + INSERT INTO timetable.chain (chain_name, run_at, max_instances, live, self_destruct) + VALUES ( + 'call proc() every 10 sec', -- chain_name, + '@every 10 seconds', -- run_at, + 1, -- max_instances, + TRUE, -- live, + FALSE -- self_destruct + ) RETURNING chain_id + ), + cte_task(v_task_id) AS ( + INSERT INTO timetable.task (chain_id, task_order, kind, command, ignore_error, autonomous) + SELECT v_chain_id, 10, 'SQL', 'CALL test_proc()', TRUE, TRUE + FROM cte_chain + RETURNING task_id + ) +SELECT v_chain_id, v_task_id FROM cte_task, cte_chain; diff --git a/samples/Basic.sql b/samples/Basic.sql index aca5c89..5a9532e 100644 --- a/samples/Basic.sql +++ b/samples/Basic.sql @@ -1,12 +1,12 @@ -SELECT timetable.add_job( - job_name => 'notify every minute', - job_schedule => '* * * * *', - job_command => 'SELECT pg_notify($1, $2)', - job_parameters => '[ "TT_CHANNEL", "Ahoj from SQL base task" ]' :: jsonb, - job_kind => 'SQL'::timetable.command_kind, - job_client_name => NULL, - job_max_instances => 1, - job_live => TRUE, - job_self_destruct => FALSE, - job_ignore_errors => TRUE +SELECT timetable.add_job( + job_name => 'notify every minute', + job_schedule => '* * * * *', + job_command => 'SELECT pg_notify($1, $2)', + job_parameters => '[ "TT_CHANNEL", "Ahoj from SQL base task" ]' :: jsonb, + job_kind => 'SQL'::timetable.command_kind, + job_client_name => NULL, + job_max_instances => 1, + job_live => TRUE, + job_self_destruct => FALSE, + job_ignore_errors => TRUE ) as chain_id; \ No newline at end of file diff --git a/samples/Chain.sql b/samples/Chain.sql index 73f0230..aceeaab 100644 --- a/samples/Chain.sql +++ b/samples/Chain.sql @@ -1,73 +1,73 @@ -DO $$ - - -- In order to create chain of tasks, We will create few base tasks and - -- each command_id will be associated with a task_id. - -- There will be only one HEAD chain (parent_id = null). - -- task_id of HEAD chain will be parent_id of other chains. - -DECLARE - v_parent_id bigint; - v_task_id bigint; - v_chain_id bigint; -BEGIN - -- In order to implement chain pperation, we will create a table - CREATE TABLE IF NOT EXISTS timetable.chain_log ( - chain_log BIGSERIAL, - EVENT TEXT, - time TIMESTAMPTZ, - PRIMARY KEY (chain_log) - ); - - -- Let's create a new chain and add tasks to it later - INSERT INTO timetable.chain ( - chain_id, - chain_name, - run_at, - max_instances, - live, - self_destruct, - exclusive_execution - ) VALUES ( - DEFAULT, -- chain_id, - 'chain operation', -- chain_name - '* * * * *', -- run_at, - 1, -- max_instances, - TRUE, -- live, - FALSE, -- self_destruct, - FALSE -- exclusive_execution, - ) RETURNING chain_id INTO v_chain_id; - - --Add a head task - INSERT INTO timetable.task (chain_id, task_order, command, ignore_error) - VALUES (v_chain_id, 1, 'INSERT INTO timetable.chain_log (EVENT, time) VALUES ($1, CURRENT_TIMESTAMP)', TRUE) - RETURNING task_id INTO v_parent_id; - - -- Add one more task, this task will keep parent_id value which is task_id of the HEAD task - INSERT INTO timetable.task (chain_id, task_order, command, ignore_error) - VALUES (v_chain_id, 2, 'INSERT INTO timetable.chain_log (EVENT, time) VALUES ($1, CURRENT_TIMESTAMP)', TRUE) - RETURNING task_id INTO v_task_id; - - INSERT INTO timetable.parameter(task_id, order_id, value) - VALUES - -- Parameter for HEAD (parent) task - (v_parent_id, 1, '["Added"]' :: jsonb), - -- Parameter for the next task - (v_task_id, 1, '["Updated"]' :: jsonb); - - -- Add one more task swowing IDs for all tasks within the chain - INSERT INTO timetable.task (chain_id, task_order, command, ignore_error) - VALUES (v_chain_id, 3, - $CMD$ - DO $BODY$ - DECLARE tasks TEXT; - BEGIN - SELECT array_agg(task_id ORDER BY task_order) FROM timetable.task - INTO tasks - WHERE chain_id = current_setting('pg_timetable.current_chain_id')::bigint; - RAISE NOTICE 'Task IDs in chain: %', tasks; - END; - $BODY$ - $CMD$, TRUE); - -END; +DO $$ + + -- In order to create chain of tasks, We will create few base tasks and + -- each command_id will be associated with a task_id. + -- There will be only one HEAD chain (parent_id = null). + -- task_id of HEAD chain will be parent_id of other chains. + +DECLARE + v_parent_id bigint; + v_task_id bigint; + v_chain_id bigint; +BEGIN + -- In order to implement chain pperation, we will create a table + CREATE TABLE IF NOT EXISTS timetable.chain_log ( + chain_log BIGSERIAL, + EVENT TEXT, + time TIMESTAMPTZ, + PRIMARY KEY (chain_log) + ); + + -- Let's create a new chain and add tasks to it later + INSERT INTO timetable.chain ( + chain_id, + chain_name, + run_at, + max_instances, + live, + self_destruct, + exclusive_execution + ) VALUES ( + DEFAULT, -- chain_id, + 'chain operation', -- chain_name + '* * * * *', -- run_at, + 1, -- max_instances, + TRUE, -- live, + FALSE, -- self_destruct, + FALSE -- exclusive_execution, + ) RETURNING chain_id INTO v_chain_id; + + --Add a head task + INSERT INTO timetable.task (chain_id, task_order, command, ignore_error) + VALUES (v_chain_id, 1, 'INSERT INTO timetable.chain_log (EVENT, time) VALUES ($1, CURRENT_TIMESTAMP)', TRUE) + RETURNING task_id INTO v_parent_id; + + -- Add one more task, this task will keep parent_id value which is task_id of the HEAD task + INSERT INTO timetable.task (chain_id, task_order, command, ignore_error) + VALUES (v_chain_id, 2, 'INSERT INTO timetable.chain_log (EVENT, time) VALUES ($1, CURRENT_TIMESTAMP)', TRUE) + RETURNING task_id INTO v_task_id; + + INSERT INTO timetable.parameter(task_id, order_id, value) + VALUES + -- Parameter for HEAD (parent) task + (v_parent_id, 1, '["Added"]' :: jsonb), + -- Parameter for the next task + (v_task_id, 1, '["Updated"]' :: jsonb); + + -- Add one more task swowing IDs for all tasks within the chain + INSERT INTO timetable.task (chain_id, task_order, command, ignore_error) + VALUES (v_chain_id, 3, + $CMD$ + DO $BODY$ + DECLARE tasks TEXT; + BEGIN + SELECT array_agg(task_id ORDER BY task_order) FROM timetable.task + INTO tasks + WHERE chain_id = current_setting('pg_timetable.current_chain_id')::bigint; + RAISE NOTICE 'Task IDs in chain: %', tasks; + END; + $BODY$ + $CMD$, TRUE); + +END; $$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/samples/ClientMessages.sql b/samples/ClientMessages.sql index c9360d9..6016966 100644 --- a/samples/ClientMessages.sql +++ b/samples/ClientMessages.sql @@ -1,23 +1,23 @@ -CREATE OR REPLACE FUNCTION raise_func(text) - RETURNS void LANGUAGE plpgsql AS -$BODY$ -BEGIN - RAISE NOTICE 'Message by % from chain %: "%"', - current_setting('pg_timetable.current_client_name')::text, - current_setting('pg_timetable.current_chain_id')::text, - $1; -END; -$BODY$; - -SELECT timetable.add_job( - job_name => 'raise client message every minute', - job_schedule => '* * * * *', - job_command => 'SELECT raise_func($1)', - job_parameters => '[ "Hey from client messages task" ]' :: jsonb, - job_kind => 'SQL'::timetable.command_kind, - job_client_name => NULL, - job_max_instances => 1, - job_live => TRUE, - job_self_destruct => FALSE, - job_ignore_errors => TRUE +CREATE OR REPLACE FUNCTION raise_func(text) + RETURNS void LANGUAGE plpgsql AS +$BODY$ +BEGIN + RAISE NOTICE 'Message by % from chain %: "%"', + current_setting('pg_timetable.current_client_name')::text, + current_setting('pg_timetable.current_chain_id')::text, + $1; +END; +$BODY$; + +SELECT timetable.add_job( + job_name => 'raise client message every minute', + job_schedule => '* * * * *', + job_command => 'SELECT raise_func($1)', + job_parameters => '[ "Hey from client messages task" ]' :: jsonb, + job_kind => 'SQL'::timetable.command_kind, + job_client_name => NULL, + job_max_instances => 1, + job_live => TRUE, + job_self_destruct => FALSE, + job_ignore_errors => TRUE ) as chain_id; \ No newline at end of file diff --git a/samples/CronStyle.sql b/samples/CronStyle.sql index c7d4667..575a4ab 100644 --- a/samples/CronStyle.sql +++ b/samples/CronStyle.sql @@ -1,24 +1,24 @@ --- Create a job with the timetable.add_job function in cron style - --- In order to demonstrate Cron style schduling of job execution, we will create a table(One time) for inserting of data -CREATE TABLE IF NOT EXISTS timetable.dummy_log ( - log_ID BIGSERIAL, - event_name TEXT, - timestmp TIMESTAMPTZ DEFAULT TRANSACTION_TIMESTAMP(), - PRIMARY KEY (log_ID)); - -----CRON-Style --- * * * * * command to execute --- ┬ ┬ ┬ ┬ ┬ --- │ │ │ │ │ --- │ │ │ │ └──── day of the week (0 - 7) (Sunday to Saturday)(0 and 7 is Sunday); --- │ │ │ └────── month (1 - 12) --- │ │ └──────── day of the month (1 - 31) --- │ └────────── hour (0 - 23) --- └──────────── minute (0 - 59) - -SELECT timetable.add_job ( - job_name => 'cron_Job run after 40th minutes after 2 hour on 27th of every month ', - job_schedule => '40 */2 27 * *', - job_command => $$INSERT INTO timetable.dummy_log (event_name) VALUES ('Cron test')$$ +-- Create a job with the timetable.add_job function in cron style + +-- In order to demonstrate Cron style schduling of job execution, we will create a table(One time) for inserting of data +CREATE TABLE IF NOT EXISTS timetable.dummy_log ( + log_ID BIGSERIAL, + event_name TEXT, + timestmp TIMESTAMPTZ DEFAULT TRANSACTION_TIMESTAMP(), + PRIMARY KEY (log_ID)); + +----CRON-Style +-- * * * * * command to execute +-- ┬ ┬ ┬ ┬ ┬ +-- │ │ │ │ │ +-- │ │ │ │ └──── day of the week (0 - 7) (Sunday to Saturday)(0 and 7 is Sunday); +-- │ │ │ └────── month (1 - 12) +-- │ │ └──────── day of the month (1 - 31) +-- │ └────────── hour (0 - 23) +-- └──────────── minute (0 - 59) + +SELECT timetable.add_job ( + job_name => 'cron_Job run after 40th minutes after 2 hour on 27th of every month ', + job_schedule => '40 */2 27 * *', + job_command => $$INSERT INTO timetable.dummy_log (event_name) VALUES ('Cron test')$$ ); \ No newline at end of file diff --git a/samples/Download.sql b/samples/Download.sql index 5e2d9cb..719a0e9 100644 --- a/samples/Download.sql +++ b/samples/Download.sql @@ -1,77 +1,80 @@ --- Prepare the destination table 'location' -CREATE TABLE IF NOT EXISTS city( - city text, - lat numeric, - lng numeric, - country text, - iso2 text, - admin_name text, - capital text, - population bigint, - population_proper bigint); - --- An enhanced example consisting of three tasks: --- 1. Download text file from internet using BUILT-IN command --- 2. Remove accents (diacritic signs) from letters using PROGRAM command (can be done with `unaccent` PostgreSQL extension) --- 3. Import text file as CSV file using BUILT-IN command (can be down with `psql -c /copy`) -DO $$ -DECLARE - v_head_id bigint; - v_task_id bigint; - v_chain_id bigint; -BEGIN - -- Create the chain with default values executed every minute (NULL == '* * * * *' :: timetable.cron) - INSERT INTO timetable.chain (chain_name, live) - VALUES ('Download locations and aggregate', TRUE) - RETURNING chain_id INTO v_chain_id; - - -- Step 1. Download file from the server - -- Create the chain - INSERT INTO timetable.task (chain_id, task_order, kind, command, ignore_error) - VALUES (v_chain_id, 1, 'BUILTIN', 'Download', TRUE) - RETURNING task_id INTO v_task_id; - - -- Create the parameters for the step 1: - INSERT INTO timetable.parameter (task_id, order_id, value) - VALUES (v_task_id, 1, - '{ - "workersnum": 1, - "fileurls": ["https://simplemaps.com/static/data/country-cities/mt/mt.csv"], - "destpath": "." - }'::jsonb); - - RAISE NOTICE 'Step 1 completed. Chain added with ID: %; DownloadFile task added with ID: %', v_chain_id, v_task_id; - - -- Step 2. Transform Unicode characters into ASCII - -- Create the program task to call 'uconv' and name it 'unaccent' - INSERT INTO timetable.task (chain_id, task_order, kind, command, ignore_error, task_name) - VALUES (v_chain_id, 2, 'PROGRAM', 'uconv', TRUE, 'unaccent') - RETURNING task_id INTO v_task_id; - - -- Create the parameters for the 'unaccent' task. Input and output files in this case - -- Under Windows we should call PowerShell instead of "uconv" with command: - -- Set-content "orte_ansi.txt" ((Get-content "orte.txt").Normalize("FormD") -replace '\p{M}', '') - INSERT INTO timetable.parameter (task_id, order_id, value) - VALUES (v_task_id, 1, '["-x", "Latin-ASCII", "-o", "mt_ansi.csv", "mt.csv"]'::jsonb); - - RAISE NOTICE 'Step 2 completed. Unacent task added with ID: %', v_task_id; - - -- Step 3. Import ASCII file to PostgreSQL table using "CopyFromFile" built-in command - INSERT INTO timetable.task (chain_id, task_order, kind, command) - VALUES (v_chain_id, 3, 'BUILTIN', 'CopyFromFile') - RETURNING task_id INTO v_task_id; - - -- Add the parameters for the download task. Execute client side COPY to 'location' from 'orte_ansi.txt' - INSERT INTO timetable.parameter (task_id, order_id, value) - VALUES (v_task_id, 1, '{"sql": "COPY city FROM STDIN (FORMAT csv, HEADER true)", "filename": "mt_ansi.csv" }'::jsonb); - - RAISE NOTICE 'Step 3 completed. Import task added with ID: %', v_task_id; - - INSERT INTO timetable.task (chain_id, task_order, kind, command, ignore_error, task_name) - VALUES (v_chain_id, 4, 'PROGRAM', 'bash', TRUE, 'remove .csv') - RETURNING task_id INTO v_task_id; - - INSERT INTO timetable.parameter (task_id, order_id, value) - VALUES (v_task_id, 1, '["-c", "rm *.csv"]'::jsonb); -END; +-- Prepare the destination table 'location' +CREATE TABLE IF NOT EXISTS public.city( + city text, + lat numeric, + lng numeric, + country text, + iso2 text, + admin_name text, + capital text, + population bigint, + population_proper bigint); + +GRANT ALL ON public.city TO scheduler; + +-- An enhanced example consisting of three tasks: +-- 1. Download text file from internet using BUILT-IN command +-- 2. Remove accents (diacritic signs) from letters using PROGRAM command (can be done with `unaccent` PostgreSQL extension) +-- 3. Import text file as CSV file using BUILT-IN command (can be down with `psql -c /copy`) +DO $$ +DECLARE + v_task_id bigint; + v_chain_id bigint; +BEGIN + -- Create the chain with default values executed every minute (NULL == '* * * * *' :: timetable.cron) + INSERT INTO timetable.chain (chain_name, live) + VALUES ('Download locations and aggregate', TRUE) + RETURNING chain_id INTO v_chain_id; + + -- Step 1. Download file from the server + -- Create the chain + INSERT INTO timetable.task (chain_id, task_order, kind, command, ignore_error) + VALUES (v_chain_id, 1, 'BUILTIN', 'Download', TRUE) + RETURNING task_id INTO v_task_id; + + -- Create the parameters for the step 1: + INSERT INTO timetable.parameter (task_id, order_id, value) + VALUES (v_task_id, 1, + '{ + "workersnum": 1, + "fileurls": ["https://simplemaps.com/static/data/country-cities/mt/mt.csv"], + "destpath": "." + }'::jsonb); + + RAISE NOTICE 'Step 1 completed. Chain added with ID: %; DownloadFile task added with ID: %', v_chain_id, v_task_id; + + -- Step 2. Transform Unicode characters into ASCII + -- Create the program task to call 'uconv' and name it 'unaccent' + INSERT INTO timetable.task (chain_id, task_order, kind, command, ignore_error, task_name) + VALUES (v_chain_id, 2, 'PROGRAM', 'uconv', TRUE, 'unaccent') + RETURNING task_id INTO v_task_id; + + -- Create the parameters for the 'unaccent' task. Input and output files in this case + -- Under Windows we should call PowerShell instead of "uconv" with command: + -- Set-content "orte_ansi.txt" ((Get-content "orte.txt").Normalize("FormD") -replace '\p{M}', '') + INSERT INTO timetable.parameter (task_id, order_id, value) + VALUES (v_task_id, 1, '["-x", "Latin-ASCII", "-o", "mt_ansi.csv", "mt.csv"]'::jsonb); + + RAISE NOTICE 'Step 2 completed. Unacent task added with ID: %', v_task_id; + + -- Step 3. Import ASCII file to PostgreSQL table using "CopyFromFile" built-in command + INSERT INTO timetable.task (chain_id, task_order, kind, command) + VALUES (v_chain_id, 3, 'BUILTIN', 'CopyFromFile') + RETURNING task_id INTO v_task_id; + + -- Add the parameters for the download task. Execute client side COPY to 'location' from 'orte_ansi.txt' + INSERT INTO timetable.parameter (task_id, order_id, value) + VALUES (v_task_id, 1, '{"sql": "COPY city FROM STDIN (FORMAT csv, HEADER true)", "filename": "mt_ansi.csv" }'::jsonb); + + RAISE NOTICE 'Step 3 completed. Import task added with ID: %', v_task_id; + + INSERT INTO timetable.task (chain_id, task_order, kind, command, ignore_error, task_name) + VALUES (v_chain_id, 4, 'PROGRAM', 'bash', TRUE, 'remove .csv') + RETURNING task_id INTO v_task_id; + + INSERT INTO timetable.parameter (task_id, order_id, value) + VALUES (v_task_id, 1, '["-c", "rm *.csv"]'::jsonb); + + RAISE NOTICE 'Step 4 completed. Cleanup task added with ID: %', v_task_id; +END; $$ LANGUAGE PLPGSQL; \ No newline at end of file diff --git a/samples/Log.sql b/samples/Log.sql index ed6bf3f..c0fe4af 100644 --- a/samples/Log.sql +++ b/samples/Log.sql @@ -1,7 +1,7 @@ -SELECT timetable.add_job( - job_name => 'Builtin-in Log', - job_schedule => NULL, -- same as '* * * * *' - job_command => 'Log', - job_kind => 'BUILTIN'::timetable.command_kind, - job_parameters => '{"Description":"Log Execution"}'::jsonb +SELECT timetable.add_job( + job_name => 'Builtin-in Log', + job_schedule => NULL, -- same as '* * * * *' + job_command => 'Log', + job_kind => 'BUILTIN'::timetable.command_kind, + job_parameters => '{"Description":"Log Execution"}'::jsonb ) as chain_id; \ No newline at end of file diff --git a/samples/Mail.sql b/samples/Mail.sql index fc074cb..80a978e 100644 --- a/samples/Mail.sql +++ b/samples/Mail.sql @@ -1,83 +1,83 @@ -DO $$ - -- An example for using the SendMail task. -DECLARE - v_mail_task_id bigint; - v_log_task_id bigint; - v_chain_id bigint; -BEGIN - -- Get the chain id - INSERT INTO timetable.chain (chain_name, max_instances, live) VALUES ('Send Mail', 1, TRUE) - RETURNING chain_id INTO v_chain_id; - - -- Add SendMail task - INSERT INTO timetable.task (chain_id, task_order, kind, command) - SELECT v_chain_id, 10, 'BUILTIN', 'SendMail' - RETURNING task_id INTO v_mail_task_id; - - -- Create the parameters for the SensMail task - -- "username": The username used for authenticating on the mail server - -- "password": The password used for authenticating on the mail server - -- "serverhost": The IP address or hostname of the mail server - -- "serverport": The port of the mail server - -- "senderaddr": The email that will appear as the sender - -- "ccaddr": String array of the recipients(Cc) email addresses - -- "bccaddr": String array of the recipients(Bcc) email addresses - -- "toaddr": String array of the recipients(To) email addresses - -- "subject": Subject of the email - -- "attachment": String array of the attachments (local file) - -- "attachmentdata": Pairs of name and base64-encoded content - -- "msgbody": The body of the email - - INSERT INTO timetable.parameter (task_id, order_id, value) - VALUES (v_mail_task_id, 1, '{ - "username": "user@example.com", - "password": "password", - "serverhost": "smtp.example.com", - "serverport": 587, - "senderaddr": "user@example.com", - "ccaddr": ["recipient_cc@example.com"], - "bccaddr": ["recipient_bcc@example.com"], - "toaddr": ["recipient@example.com"], - "subject": "pg_timetable - No Reply", - "attachment": ["D:\\Go stuff\\Books\\Concurrency in Go.pdf","report.yaml"], - "attachmentdata": [{"name": "File.txt", "base64data": "RmlsZSBDb250ZW50"}], - "msgbody": "Hello User,

I got some Go books for you enjoy

pg_timetable!", - "contenttype": "text/html; charset=UTF-8" - }'::jsonb); - - -- Add Log task and make it the last task using `task_order` column (=30) - INSERT INTO timetable.task (chain_id, task_order, kind, command) - SELECT v_chain_id, 30, 'BUILTIN', 'Log' - RETURNING task_id INTO v_log_task_id; - - -- Add housekeeping task, that will delete sent mail and update parameter for the previous logging task - -- Since we're using special add_task() function we don't need to specify the `chain_id`. - -- Function will take the same `chain_id` from the parent task, SendMail in this particular case - PERFORM timetable.add_task( - kind => 'SQL', - parent_id => v_mail_task_id, - command => format( -$query$WITH sent_mail(toaddr) AS (DELETE FROM timetable.parameter WHERE task_id = %s RETURNING value->>'username') -INSERT INTO timetable.parameter (task_id, order_id, value) -SELECT %s, 1, to_jsonb('Sent emails to: ' || string_agg(sent_mail.toaddr, ';')) -FROM sent_mail -ON CONFLICT (task_id, order_id) DO UPDATE SET value = EXCLUDED.value$query$, - v_mail_task_id, v_log_task_id - ), - order_delta => 10 - ); - --- In the end we should have something like this. Note, that even Log task was created earlier it will be executed later --- due to `task_order` column. - --- timetable=> SELECT task_id, chain_id, kind, left(command, 50) FROM timetable.task ORDER BY task_order; --- task_id | chain_id | task_order | kind | left --- ---------+----------+------------+---------+--------------------------------------------------------------- --- 45 | 24 | 10 | BUILTIN | SendMail --- 47 | 24 | 20 | SQL | WITH sent_mail(toaddr) AS (DELETE FROM timetable.p --- 46 | 24 | 30 | BUILTIN | Log --- (3 rows) - -END; -$$ -LANGUAGE PLPGSQL; +DO $$ + -- An example for using the SendMail task. +DECLARE + v_mail_task_id bigint; + v_log_task_id bigint; + v_chain_id bigint; +BEGIN + -- Get the chain id + INSERT INTO timetable.chain (chain_name, max_instances, live) VALUES ('Send Mail', 1, TRUE) + RETURNING chain_id INTO v_chain_id; + + -- Add SendMail task + INSERT INTO timetable.task (chain_id, task_order, kind, command) + SELECT v_chain_id, 10, 'BUILTIN', 'SendMail' + RETURNING task_id INTO v_mail_task_id; + + -- Create the parameters for the SensMail task + -- "username": The username used for authenticating on the mail server + -- "password": The password used for authenticating on the mail server + -- "serverhost": The IP address or hostname of the mail server + -- "serverport": The port of the mail server + -- "senderaddr": The email that will appear as the sender + -- "ccaddr": String array of the recipients(Cc) email addresses + -- "bccaddr": String array of the recipients(Bcc) email addresses + -- "toaddr": String array of the recipients(To) email addresses + -- "subject": Subject of the email + -- "attachment": String array of the attachments (local file) + -- "attachmentdata": Pairs of name and base64-encoded content + -- "msgbody": The body of the email + + INSERT INTO timetable.parameter (task_id, order_id, value) + VALUES (v_mail_task_id, 1, '{ + "username": "user@example.com", + "password": "password", + "serverhost": "smtp.example.com", + "serverport": 587, + "senderaddr": "user@example.com", + "ccaddr": ["recipient_cc@example.com"], + "bccaddr": ["recipient_bcc@example.com"], + "toaddr": ["recipient@example.com"], + "subject": "pg_timetable - No Reply", + "attachment": ["D:\\Go stuff\\Books\\Concurrency in Go.pdf","report.yaml"], + "attachmentdata": [{"name": "File.txt", "base64data": "RmlsZSBDb250ZW50"}], + "msgbody": "Hello User,

I got some Go books for you enjoy

pg_timetable!", + "contenttype": "text/html; charset=UTF-8" + }'::jsonb); + + -- Add Log task and make it the last task using `task_order` column (=30) + INSERT INTO timetable.task (chain_id, task_order, kind, command) + SELECT v_chain_id, 30, 'BUILTIN', 'Log' + RETURNING task_id INTO v_log_task_id; + + -- Add housekeeping task, that will delete sent mail and update parameter for the previous logging task + -- Since we're using special add_task() function we don't need to specify the `chain_id`. + -- Function will take the same `chain_id` from the parent task, SendMail in this particular case + PERFORM timetable.add_task( + kind => 'SQL', + parent_id => v_mail_task_id, + command => format( +$query$WITH sent_mail(toaddr) AS (DELETE FROM timetable.parameter WHERE task_id = %s RETURNING value->>'username') +INSERT INTO timetable.parameter (task_id, order_id, value) +SELECT %s, 1, to_jsonb('Sent emails to: ' || string_agg(sent_mail.toaddr, ';')) +FROM sent_mail +ON CONFLICT (task_id, order_id) DO UPDATE SET value = EXCLUDED.value$query$, + v_mail_task_id, v_log_task_id + ), + order_delta => 10 + ); + +-- In the end we should have something like this. Note, that even Log task was created earlier it will be executed later +-- due to `task_order` column. + +-- timetable=> SELECT task_id, chain_id, kind, left(command, 50) FROM timetable.task ORDER BY task_order; +-- task_id | chain_id | task_order | kind | left +-- ---------+----------+------------+---------+--------------------------------------------------------------- +-- 45 | 24 | 10 | BUILTIN | SendMail +-- 47 | 24 | 20 | SQL | WITH sent_mail(toaddr) AS (DELETE FROM timetable.p +-- 46 | 24 | 30 | BUILTIN | Log +-- (3 rows) + +END; +$$ +LANGUAGE PLPGSQL; diff --git a/samples/NoOp.sql b/samples/NoOp.sql index 3f214bd..4956232 100644 --- a/samples/NoOp.sql +++ b/samples/NoOp.sql @@ -1,6 +1,6 @@ -SELECT timetable.add_job( - job_name => 'execute noop every minute', - job_schedule => '* * * * *', - job_command => 'NoOp', - job_kind => 'BUILTIN'::timetable.command_kind +SELECT timetable.add_job( + job_name => 'execute noop every minute', + job_schedule => '* * * * *', + job_command => 'NoOp', + job_kind => 'BUILTIN'::timetable.command_kind ) as chain_id; \ No newline at end of file diff --git a/samples/RemoteDB.sql b/samples/RemoteDB.sql index 722a421..ad20ac0 100644 --- a/samples/RemoteDB.sql +++ b/samples/RemoteDB.sql @@ -1,39 +1,39 @@ -DO $$ -DECLARE - v_task_id bigint; - v_chain_id bigint; - v_database_connection bigint; -BEGIN - -- In order to implement remote SQL execution, we will create a table on a remote machine - CREATE TABLE IF NOT EXISTS timetable.remote_log ( - remote_log BIGSERIAL, - remote_event TEXT, - timestmp TIMESTAMPTZ, - PRIMARY KEY (remote_log)); - - -- add a remote job - INSERT INTO timetable.chain (chain_id, chain_name, run_at, live) - VALUES (DEFAULT, 'remote db', '* * * * *', TRUE) - RETURNING chain_id INTO v_chain_id; - - INSERT INTO timetable.task (chain_id, task_order, command, database_connection, ignore_error) - VALUES (v_chain_id, - 1, - 'INSERT INTO timetable.remote_log(remote_event, timestmp) VALUES ($1, CURRENT_TIMESTAMP)', - format('host=%s port=%s dbname=%I user=%I password=somestrong', - inet_server_addr(), - inet_server_port(), - current_database(), - session_user - ), - TRUE) - RETURNING - task_id INTO v_task_id; - - --Parameter values for task - INSERT INTO timetable.parameter (task_id, order_id, value) - VALUES - (v_task_id, 1, '["Row 1 added"]'::jsonb), - (v_task_id, 2, '["Row 2 added"]'::jsonb); -END; -$$ LANGUAGE PLPGSQL; \ No newline at end of file +DO $$ +DECLARE + v_task_id bigint; + v_chain_id bigint; + v_database_connection bigint; +BEGIN + -- In order to implement remote SQL execution, we will create a table on a remote machine + CREATE TABLE IF NOT EXISTS timetable.remote_log ( + remote_log BIGSERIAL, + remote_event TEXT, + timestmp TIMESTAMPTZ, + PRIMARY KEY (remote_log)); + + -- add a remote job + INSERT INTO timetable.chain (chain_id, chain_name, run_at, live) + VALUES (DEFAULT, 'remote db', '* * * * *', TRUE) + RETURNING chain_id INTO v_chain_id; + + INSERT INTO timetable.task (chain_id, task_order, command, database_connection, ignore_error) + VALUES (v_chain_id, + 1, + 'INSERT INTO timetable.remote_log(remote_event, timestmp) VALUES ($1, CURRENT_TIMESTAMP)', + format('host=%s port=%s dbname=%I user=%I password=somestrong', + inet_server_addr(), + inet_server_port(), + current_database(), + session_user + ), + TRUE) + RETURNING + task_id INTO v_task_id; + + --Parameter values for task + INSERT INTO timetable.parameter (task_id, order_id, value) + VALUES + (v_task_id, 1, '["Row 1 added"]'::jsonb), + (v_task_id, 2, '["Row 2 added"]'::jsonb); +END; +$$ LANGUAGE PLPGSQL; diff --git a/samples/SelfDestruct.sql b/samples/SelfDestruct.sql index 5431ee6..6d3f9dd 100644 --- a/samples/SelfDestruct.sql +++ b/samples/SelfDestruct.sql @@ -1,17 +1,17 @@ -CREATE OR REPLACE FUNCTION raise_func(text) - RETURNS void LANGUAGE plpgsql AS -$BODY$ -BEGIN - RAISE NOTICE '%', $1; -END; -$BODY$; - -SELECT timetable.add_job( - job_name => 'notify then destruct', - job_schedule => '* * * * *', - job_command => 'SELECT raise_func($1)', - job_parameters => '[ "Ahoj from self destruct task" ]' :: jsonb, - job_kind => 'SQL'::timetable.command_kind, - job_live => TRUE, - job_self_destruct => TRUE +CREATE OR REPLACE FUNCTION raise_func(text) + RETURNS void LANGUAGE plpgsql AS +$BODY$ +BEGIN + RAISE NOTICE '%', $1; +END; +$BODY$; + +SELECT timetable.add_job( + job_name => 'notify then destruct', + job_schedule => '* * * * *', + job_command => 'SELECT raise_func($1)', + job_parameters => '[ "Ahoj from self destruct task" ]' :: jsonb, + job_kind => 'SQL'::timetable.command_kind, + job_live => TRUE, + job_self_destruct => TRUE ) as chain_id; \ No newline at end of file diff --git a/samples/Shell.sql b/samples/Shell.sql index c5b5455..06236c6 100644 --- a/samples/Shell.sql +++ b/samples/Shell.sql @@ -1,14 +1,14 @@ --- An example for using the PROGRAM task. -SELECT timetable.add_job( - job_name => 'psql chain', - job_schedule => '* * * * *', - job_kind => 'PROGRAM'::timetable.command_kind, - job_command => 'psql', - job_parameters => ('[ - "-h", "' || host(inet_server_addr()) || '", - "-p", "' || inet_server_port() || '", - "-d", "' || current_database() || '", - "-U", "' || current_user || '", - "-w", "-c", "SELECT now();" - ]')::jsonb +-- An example for using the PROGRAM task. +SELECT timetable.add_job( + job_name => 'psql chain', + job_schedule => '* * * * *', + job_kind => 'PROGRAM'::timetable.command_kind, + job_command => 'psql', + job_parameters => ('[ + "-h", "' || host(inet_server_addr()) || '", + "-p", "' || inet_server_port() || '", + "-d", "' || current_database() || '", + "-U", "' || current_user || '", + "-w", "-c", "SELECT now();" + ]')::jsonb ) as chain_id; \ No newline at end of file diff --git a/samples/Sleep.sql b/samples/Sleep.sql index ac6507f..862a87c 100644 --- a/samples/Sleep.sql +++ b/samples/Sleep.sql @@ -1,10 +1,10 @@ -SELECT timetable.add_job( - job_name => 'sleep every minute', - job_schedule => '@every 10 seconds', - job_command => 'Sleep', - job_parameters => '20' :: jsonb, - job_kind => 'BUILTIN'::timetable.command_kind, - job_client_name => NULL, - job_max_instances => 1, - job_live => TRUE +SELECT timetable.add_job( + job_name => 'sleep every minute', + job_schedule => '@every 10 seconds', + job_command => 'Sleep', + job_parameters => '20' :: jsonb, + job_kind => 'BUILTIN'::timetable.command_kind, + job_client_name => NULL, + job_max_instances => 1, + job_live => TRUE ) as chain_id; \ No newline at end of file