├── README.md ├── schema.sql ├── functions.sql ├── LICENSE └── grafana_dashboard.json /README.md: -------------------------------------------------------------------------------- 1 | # sql-task-queue 2 | 3 | ## Usage 4 | 5 | The task queue table definition is in `schema.sql` and the functions are in `functions.sql`. 6 | 7 | The Grafana dashboard JSON is in `grafana_dashboard.json`. You can the dashboard by pasting 8 | the JSON on the Import page in Grafana. 9 | 10 | ## License 11 | 12 | Apache 2.0 (see [LICENSE](https://github.com/ShiftLeftSecurity/sql-task-queue/blob/master/LICENSE)) 13 | -------------------------------------------------------------------------------- /schema.sql: -------------------------------------------------------------------------------- 1 | -- Copyright 2019 ShiftLeft, Inc. 2 | 3 | -- Licensed under the Apache License, Version 2.0 (the "License"); 4 | -- you may not use this file except in compliance with the License. 5 | -- You may obtain a copy of the License at 6 | 7 | -- http://www.apache.org/licenses/LICENSE-2.0 8 | 9 | -- Unless required by applicable law or agreed to in writing, software 10 | -- distributed under the License is distributed on an "AS IS" BASIS, 11 | -- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 12 | -- See the License for the specific language governing permissions and 13 | -- limitations under the License. 14 | 15 | -- 16 | -- Name: queue_tasks_id_seq; Type: SEQUENCE; Schema: public; Owner: - 17 | -- 18 | 19 | CREATE SEQUENCE public.queue_tasks_id_seq 20 | START WITH 1 21 | INCREMENT BY 1 22 | NO MINVALUE 23 | NO MAXVALUE 24 | CACHE 1; 25 | 26 | 27 | -- 28 | -- Name: queue_tasks; Type: TABLE; Schema: public; Owner: - 29 | -- 30 | 31 | CREATE TABLE public.queue_tasks ( 32 | id bigint DEFAULT nextval('public.queue_tasks_id_seq'::regclass) NOT NULL, 33 | topic text NOT NULL, 34 | priority bigint NOT NULL, 35 | consumer_id text, 36 | retries_left bigint NOT NULL, 37 | heartbeat_deadline timestamp with time zone, 38 | added_at timestamp with time zone NOT NULL, 39 | started_at timestamp with time zone, 40 | committed_at timestamp with time zone, 41 | canceled_at timestamp with time zone, 42 | data bytea NOT NULL, 43 | heartbeat_timeout interval 44 | ); 45 | 46 | ALTER TABLE ONLY public.queue_tasks 47 | ADD CONSTRAINT queue_tasks_pkey PRIMARY KEY (id); 48 | 49 | CREATE INDEX idx_tasks_topic_state ON public.queue_tasks USING btree (topic, priority DESC, started_at, canceled_at, heartbeat_deadline, retries_left); 50 | -------------------------------------------------------------------------------- /functions.sql: -------------------------------------------------------------------------------- 1 | -- Copyright 2019 ShiftLeft, Inc. 2 | 3 | -- Licensed under the Apache License, Version 2.0 (the "License"); 4 | -- you may not use this file except in compliance with the License. 5 | -- You may obtain a copy of the License at 6 | 7 | -- http://www.apache.org/licenses/LICENSE-2.0 8 | 9 | -- Unless required by applicable law or agreed to in writing, software 10 | -- distributed under the License is distributed on an "AS IS" BASIS, 11 | -- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 12 | -- See the License for the specific language governing permissions and 13 | -- limitations under the License. 14 | 15 | -- 16 | -- Name: queue_add_task(text, bytea, bigint, bigint, timestamp with time zone); Type: FUNCTION; Schema: public; Owner: - 17 | -- 18 | 19 | CREATE FUNCTION public.queue_add_task(topic text, data bytea, retries bigint DEFAULT '1'::bigint, priority bigint DEFAULT '0'::bigint, now timestamp with time zone DEFAULT now()) RETURNS bigint 20 | LANGUAGE plpgsql 21 | AS $$ 22 | DECLARE 23 | task_id BIGINT; 24 | BEGIN 25 | INSERT INTO queue_tasks (topic, data, retries_left, priority, added_at) 26 | VALUES (topic, data, retries, priority, now) 27 | RETURNING id 28 | INTO task_id; 29 | RETURN task_id; 30 | END; 31 | $$; 32 | 33 | 34 | -- 35 | -- Name: queue_cancel_all_tasks(text, timestamp with time zone); Type: FUNCTION; Schema: public; Owner: - 36 | -- 37 | 38 | CREATE FUNCTION public.queue_cancel_all_tasks(topic_arg text, now timestamp with time zone DEFAULT now()) RETURNS void 39 | LANGUAGE plpgsql 40 | AS $$ 41 | BEGIN 42 | UPDATE queue_tasks 43 | SET canceled_at = now 44 | WHERE topic = topic_arg AND canceled_at IS NULL; 45 | END; 46 | $$; 47 | 48 | 49 | -- 50 | -- Name: queue_cancel_task(bigint, timestamp with time zone); Type: FUNCTION; Schema: public; Owner: - 51 | -- 52 | 53 | CREATE FUNCTION public.queue_cancel_task(task_id bigint, now timestamp with time zone DEFAULT now()) RETURNS void 54 | LANGUAGE plpgsql 55 | AS $$ 56 | BEGIN 57 | UPDATE queue_tasks 58 | SET canceled_at = now 59 | WHERE id = task_id AND canceled_at IS NULL; 60 | END; 61 | $$; 62 | 63 | 64 | -- 65 | -- Name: queue_commit_task(bigint, text, timestamp with time zone); Type: FUNCTION; Schema: public; Owner: - 66 | -- 67 | 68 | CREATE FUNCTION public.queue_commit_task(task_id bigint, consumer_id_arg text, now timestamp with time zone DEFAULT now()) RETURNS void 69 | LANGUAGE plpgsql 70 | AS $$ 71 | BEGIN 72 | UPDATE queue_tasks 73 | SET committed_at = now 74 | WHERE id = task_id AND consumer_id = consumer_id_arg; 75 | END; 76 | $$; 77 | 78 | 79 | -- 80 | -- Name: queue_consume_task(text, text, bigint, interval, timestamp with time zone); Type: FUNCTION; Schema: public; Owner: - 81 | -- 82 | 83 | CREATE FUNCTION public.queue_consume_task(topic_arg text, consumer_id_arg text, min_priority bigint DEFAULT '0'::bigint, heartbeat_timeout_arg interval DEFAULT '00:01:00'::interval, now timestamp with time zone DEFAULT now()) RETURNS record 84 | LANGUAGE plpgsql 85 | AS $$ 86 | DECLARE 87 | ret RECORD; 88 | BEGIN 89 | UPDATE queue_tasks 90 | SET 91 | started_at = now, 92 | consumer_id = consumer_id_arg, 93 | retries_left = retries_left - 1, 94 | heartbeat_deadline = now + heartbeat_timeout_arg, 95 | heartbeat_timeout = heartbeat_timeout_arg 96 | WHERE id IN ( 97 | SELECT id FROM queue_tasks AS task 98 | WHERE topic = topic_arg AND priority >= min_priority AND queue_task_is_waiting_for_consume(task, now) 99 | ORDER BY priority DESC, added_at ASC 100 | LIMIT 1 101 | FOR UPDATE) 102 | RETURNING queue_tasks.id AS id, queue_tasks.data AS data, queue_tasks.retries_left AS retries_left 103 | INTO ret; 104 | RETURN ret; 105 | END; 106 | $$; 107 | 108 | 109 | -- 110 | -- Name: queue_heartbeat_task(bigint, text, timestamp with time zone); Type: FUNCTION; Schema: public; Owner: - 111 | -- 112 | 113 | CREATE FUNCTION public.queue_heartbeat_task(task_id bigint, consumer_id_arg text, now timestamp with time zone DEFAULT now()) RETURNS record 114 | LANGUAGE plpgsql 115 | AS $$ 116 | DECLARE 117 | ret RECORD; 118 | BEGIN 119 | UPDATE queue_tasks 120 | SET heartbeat_deadline = now + heartbeat_timeout 121 | WHERE id = task_id AND consumer_id = consumer_id_arg AND NOT queue_task_is_canceled(queue_tasks, now) 122 | RETURNING queue_tasks.id 123 | INTO ret; 124 | RETURN ret; 125 | END; 126 | $$; 127 | 128 | 129 | -- 130 | -- Name: queue_soft_drop_task(bigint, text, timestamp with time zone); Type: FUNCTION; Schema: public; Owner: - 131 | -- 132 | 133 | CREATE FUNCTION public.queue_soft_drop_task(task_id bigint, consumer_id_arg text, now timestamp with time zone DEFAULT now()) RETURNS record 134 | LANGUAGE plpgsql 135 | AS $$ 136 | DECLARE 137 | ret RECORD; 138 | BEGIN 139 | UPDATE queue_tasks 140 | SET heartbeat_deadline = now - INTERVAL '1 second' 141 | WHERE id = task_id AND consumer_id = consumer_id_arg 142 | RETURNING queue_tasks.id 143 | INTO ret; 144 | RETURN ret; 145 | END; 146 | $$; 147 | 148 | 149 | -- 150 | -- Name: queue_task_is_canceled(public.queue_tasks, timestamp with time zone); Type: FUNCTION; Schema: public; Owner: - 151 | -- 152 | 153 | CREATE FUNCTION public.queue_task_is_canceled(task public.queue_tasks, now timestamp with time zone DEFAULT now()) RETURNS boolean 154 | LANGUAGE plpgsql 155 | AS $$ 156 | BEGIN 157 | RETURN task.canceled_at IS NOT NULL OR 158 | (now > task.heartbeat_deadline AND task.retries_left = 0); 159 | END; 160 | $$; 161 | 162 | 163 | -- 164 | -- Name: queue_task_is_committed(public.queue_tasks); Type: FUNCTION; Schema: public; Owner: - 165 | -- 166 | 167 | CREATE FUNCTION public.queue_task_is_committed(task public.queue_tasks) RETURNS boolean 168 | LANGUAGE plpgsql 169 | AS $$ 170 | BEGIN 171 | RETURN task.committed_at IS NOT NULL; 172 | END; 173 | $$; 174 | 175 | 176 | -- 177 | -- Name: queue_task_is_started(public.queue_tasks, timestamp with time zone); Type: FUNCTION; Schema: public; Owner: - 178 | -- 179 | 180 | CREATE FUNCTION public.queue_task_is_started(task public.queue_tasks, now timestamp with time zone DEFAULT now()) RETURNS boolean 181 | LANGUAGE plpgsql 182 | AS $$ 183 | BEGIN 184 | RETURN task.started_at IS NOT NULL AND 185 | task.committed_at IS NULL AND 186 | task.canceled_at IS NULL AND 187 | now <= task.heartbeat_deadline; 188 | END; 189 | $$; 190 | 191 | 192 | -- 193 | -- Name: queue_task_is_waiting_for_consume(public.queue_tasks, timestamp with time zone); Type: FUNCTION; Schema: public; Owner: - 194 | -- 195 | 196 | CREATE FUNCTION public.queue_task_is_waiting_for_consume(task public.queue_tasks, now timestamp with time zone DEFAULT now()) RETURNS boolean 197 | LANGUAGE plpgsql 198 | AS $$ 199 | BEGIN 200 | RETURN (task.started_at IS NULL OR now > task.heartbeat_deadline) AND 201 | task.canceled_at IS NULL AND 202 | task.retries_left > 0; 203 | END; 204 | $$; 205 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Apache License 2 | Version 2.0, January 2004 3 | http://www.apache.org/licenses/ 4 | 5 | TERMS AND CONDITIONS FOR USE, REPRODUCTION, AND DISTRIBUTION 6 | 7 | 1. Definitions. 8 | 9 | "License" shall mean the terms and conditions for use, reproduction, 10 | and distribution as defined by Sections 1 through 9 of this document. 11 | 12 | "Licensor" shall mean the copyright owner or entity authorized by 13 | the copyright owner that is granting the License. 14 | 15 | "Legal Entity" shall mean the union of the acting entity and all 16 | other entities that control, are controlled by, or are under common 17 | control with that entity. For the purposes of this definition, 18 | "control" means (i) the power, direct or indirect, to cause the 19 | direction or management of such entity, whether by contract or 20 | otherwise, or (ii) ownership of fifty percent (50%) or more of the 21 | outstanding shares, or (iii) beneficial ownership of such entity. 22 | 23 | "You" (or "Your") shall mean an individual or Legal Entity 24 | exercising permissions granted by this License. 25 | 26 | "Source" form shall mean the preferred form for making modifications, 27 | including but not limited to software source code, documentation 28 | source, and configuration files. 29 | 30 | "Object" form shall mean any form resulting from mechanical 31 | transformation or translation of a Source form, including but 32 | not limited to compiled object code, generated documentation, 33 | and conversions to other media types. 34 | 35 | "Work" shall mean the work of authorship, whether in Source or 36 | Object form, made available under the License, as indicated by a 37 | copyright notice that is included in or attached to the work 38 | (an example is provided in the Appendix below). 39 | 40 | "Derivative Works" shall mean any work, whether in Source or Object 41 | form, that is based on (or derived from) the Work and for which the 42 | editorial revisions, annotations, elaborations, or other modifications 43 | represent, as a whole, an original work of authorship. For the purposes 44 | of this License, Derivative Works shall not include works that remain 45 | separable from, or merely link (or bind by name) to the interfaces of, 46 | the Work and Derivative Works thereof. 47 | 48 | "Contribution" shall mean any work of authorship, including 49 | the original version of the Work and any modifications or additions 50 | to that Work or Derivative Works thereof, that is intentionally 51 | submitted to Licensor for inclusion in the Work by the copyright owner 52 | or by an individual or Legal Entity authorized to submit on behalf of 53 | the copyright owner. For the purposes of this definition, "submitted" 54 | means any form of electronic, verbal, or written communication sent 55 | to the Licensor or its representatives, including but not limited to 56 | communication on electronic mailing lists, source code control systems, 57 | and issue tracking systems that are managed by, or on behalf of, the 58 | Licensor for the purpose of discussing and improving the Work, but 59 | excluding communication that is conspicuously marked or otherwise 60 | designated in writing by the copyright owner as "Not a Contribution." 61 | 62 | "Contributor" shall mean Licensor and any individual or Legal Entity 63 | on behalf of whom a Contribution has been received by Licensor and 64 | subsequently incorporated within the Work. 65 | 66 | 2. Grant of Copyright License. Subject to the terms and conditions of 67 | this License, each Contributor hereby grants to You a perpetual, 68 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 69 | copyright license to reproduce, prepare Derivative Works of, 70 | publicly display, publicly perform, sublicense, and distribute the 71 | Work and such Derivative Works in Source or Object form. 72 | 73 | 3. Grant of Patent License. Subject to the terms and conditions of 74 | this License, each Contributor hereby grants to You a perpetual, 75 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 76 | (except as stated in this section) patent license to make, have made, 77 | use, offer to sell, sell, import, and otherwise transfer the Work, 78 | where such license applies only to those patent claims licensable 79 | by such Contributor that are necessarily infringed by their 80 | Contribution(s) alone or by combination of their Contribution(s) 81 | with the Work to which such Contribution(s) was submitted. If You 82 | institute patent litigation against any entity (including a 83 | cross-claim or counterclaim in a lawsuit) alleging that the Work 84 | or a Contribution incorporated within the Work constitutes direct 85 | or contributory patent infringement, then any patent licenses 86 | granted to You under this License for that Work shall terminate 87 | as of the date such litigation is filed. 88 | 89 | 4. Redistribution. You may reproduce and distribute copies of the 90 | Work or Derivative Works thereof in any medium, with or without 91 | modifications, and in Source or Object form, provided that You 92 | meet the following conditions: 93 | 94 | (a) You must give any other recipients of the Work or 95 | Derivative Works a copy of this License; and 96 | 97 | (b) You must cause any modified files to carry prominent notices 98 | stating that You changed the files; and 99 | 100 | (c) You must retain, in the Source form of any Derivative Works 101 | that You distribute, all copyright, patent, trademark, and 102 | attribution notices from the Source form of the Work, 103 | excluding those notices that do not pertain to any part of 104 | the Derivative Works; and 105 | 106 | (d) If the Work includes a "NOTICE" text file as part of its 107 | distribution, then any Derivative Works that You distribute must 108 | include a readable copy of the attribution notices contained 109 | within such NOTICE file, excluding those notices that do not 110 | pertain to any part of the Derivative Works, in at least one 111 | of the following places: within a NOTICE text file distributed 112 | as part of the Derivative Works; within the Source form or 113 | documentation, if provided along with the Derivative Works; or, 114 | within a display generated by the Derivative Works, if and 115 | wherever such third-party notices normally appear. The contents 116 | of the NOTICE file are for informational purposes only and 117 | do not modify the License. You may add Your own attribution 118 | notices within Derivative Works that You distribute, alongside 119 | or as an addendum to the NOTICE text from the Work, provided 120 | that such additional attribution notices cannot be construed 121 | as modifying the License. 122 | 123 | You may add Your own copyright statement to Your modifications and 124 | may provide additional or different license terms and conditions 125 | for use, reproduction, or distribution of Your modifications, or 126 | for any such Derivative Works as a whole, provided Your use, 127 | reproduction, and distribution of the Work otherwise complies with 128 | the conditions stated in this License. 129 | 130 | 5. Submission of Contributions. Unless You explicitly state otherwise, 131 | any Contribution intentionally submitted for inclusion in the Work 132 | by You to the Licensor shall be under the terms and conditions of 133 | this License, without any additional terms or conditions. 134 | Notwithstanding the above, nothing herein shall supersede or modify 135 | the terms of any separate license agreement you may have executed 136 | with Licensor regarding such Contributions. 137 | 138 | 6. Trademarks. This License does not grant permission to use the trade 139 | names, trademarks, service marks, or product names of the Licensor, 140 | except as required for reasonable and customary use in describing the 141 | origin of the Work and reproducing the content of the NOTICE file. 142 | 143 | 7. Disclaimer of Warranty. Unless required by applicable law or 144 | agreed to in writing, Licensor provides the Work (and each 145 | Contributor provides its Contributions) on an "AS IS" BASIS, 146 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or 147 | implied, including, without limitation, any warranties or conditions 148 | of TITLE, NON-INFRINGEMENT, MERCHANTABILITY, or FITNESS FOR A 149 | PARTICULAR PURPOSE. You are solely responsible for determining the 150 | appropriateness of using or redistributing the Work and assume any 151 | risks associated with Your exercise of permissions under this License. 152 | 153 | 8. Limitation of Liability. In no event and under no legal theory, 154 | whether in tort (including negligence), contract, or otherwise, 155 | unless required by applicable law (such as deliberate and grossly 156 | negligent acts) or agreed to in writing, shall any Contributor be 157 | liable to You for damages, including any direct, indirect, special, 158 | incidental, or consequential damages of any character arising as a 159 | result of this License or out of the use or inability to use the 160 | Work (including but not limited to damages for loss of goodwill, 161 | work stoppage, computer failure or malfunction, or any and all 162 | other commercial damages or losses), even if such Contributor 163 | has been advised of the possibility of such damages. 164 | 165 | 9. Accepting Warranty or Additional Liability. While redistributing 166 | the Work or Derivative Works thereof, You may choose to offer, 167 | and charge a fee for, acceptance of support, warranty, indemnity, 168 | or other liability obligations and/or rights consistent with this 169 | License. However, in accepting such obligations, You may act only 170 | on Your own behalf and on Your sole responsibility, not on behalf 171 | of any other Contributor, and only if You agree to indemnify, 172 | defend, and hold each Contributor harmless for any liability 173 | incurred by, or claims asserted against, such Contributor by reason 174 | of your accepting any such warranty or additional liability. 175 | 176 | END OF TERMS AND CONDITIONS 177 | 178 | APPENDIX: How to apply the Apache License to your work. 179 | 180 | To apply the Apache License to your work, attach the following 181 | boilerplate notice, with the fields enclosed by brackets "[]" 182 | replaced with your own identifying information. (Don't include 183 | the brackets!) The text should be enclosed in the appropriate 184 | comment syntax for the file format. We also recommend that a 185 | file or class name and description of purpose be included on the 186 | same "printed page" as the copyright notice for easier 187 | identification within third-party archives. 188 | 189 | Copyright 2019 ShiftLeft, Inc. 190 | 191 | Licensed under the Apache License, Version 2.0 (the "License"); 192 | you may not use this file except in compliance with the License. 193 | You may obtain a copy of the License at 194 | 195 | http://www.apache.org/licenses/LICENSE-2.0 196 | 197 | Unless required by applicable law or agreed to in writing, software 198 | distributed under the License is distributed on an "AS IS" BASIS, 199 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 200 | See the License for the specific language governing permissions and 201 | limitations under the License. 202 | -------------------------------------------------------------------------------- /grafana_dashboard.json: -------------------------------------------------------------------------------- 1 | { 2 | "__inputs": [ 3 | { 4 | "description": "", 5 | "label": "PGSQL", 6 | "name": "DS_PGSQL", 7 | "pluginId": "postgres", 8 | "pluginName": "PostgreSQL", 9 | "type": "datasource" 10 | } 11 | ], 12 | "__requires": [ 13 | { 14 | "id": "grafana", 15 | "name": "Grafana", 16 | "type": "grafana", 17 | "version": "5.2.4" 18 | }, 19 | { 20 | "id": "graph", 21 | "name": "Graph", 22 | "type": "panel", 23 | "version": "5.0.0" 24 | }, 25 | { 26 | "id": "postgres", 27 | "name": "PostgreSQL", 28 | "type": "datasource", 29 | "version": "5.0.0" 30 | }, 31 | { 32 | "id": "table", 33 | "name": "Table", 34 | "type": "panel", 35 | "version": "5.0.0" 36 | } 37 | ], 38 | "annotations": { 39 | "list": [ 40 | { 41 | "builtIn": 1, 42 | "datasource": "-- Grafana --", 43 | "enable": true, 44 | "hide": true, 45 | "iconColor": "rgba(0, 211, 255, 1)", 46 | "name": "Annotations & Alerts", 47 | "type": "dashboard" 48 | } 49 | ] 50 | }, 51 | "editable": true, 52 | "gnetId": null, 53 | "graphTooltip": 0, 54 | "id": null, 55 | "iteration": 1551740766159, 56 | "links": [], 57 | "panels": [ 58 | { 59 | "aliasColors": {}, 60 | "bars": false, 61 | "dashLength": 10, 62 | "dashes": false, 63 | "datasource": "${DS_PGSQL}", 64 | "fill": 0, 65 | "gridPos": { 66 | "h": 5, 67 | "w": 12, 68 | "x": 0, 69 | "y": 0 70 | }, 71 | "id": 2, 72 | "legend": { 73 | "avg": false, 74 | "current": false, 75 | "max": false, 76 | "min": false, 77 | "show": true, 78 | "total": false, 79 | "values": false 80 | }, 81 | "lines": true, 82 | "linewidth": 1, 83 | "links": [], 84 | "nullPointMode": "null", 85 | "percentage": false, 86 | "pointradius": 2, 87 | "points": false, 88 | "renderer": "flot", 89 | "seriesOverrides": [], 90 | "spaceLength": 10, 91 | "stack": false, 92 | "steppedLine": true, 93 | "targets": [ 94 | { 95 | "alias": "", 96 | "format": "time_series", 97 | "rawSql": "WITH topics AS (select distinct topic from queue_tasks)\nSELECT\n to_timestamp(floor(date_part('epoch', dd)/$resolution)*$resolution) as time,\n topics.topic as metric,\n (SELECT COUNT(*) FROM queue_tasks where topic = topics.topic AND to_timestamp(floor(date_part('epoch', added_at)/$resolution)*$resolution) = to_timestamp(floor(date_part('epoch', dd)/$resolution)*$resolution))\nFROM\ngenerate_series(to_timestamp($__unixEpochFrom()), to_timestamp($__unixEpochTo()), $resolution*interval '1 sec') dd\nCROSS JOIN\ntopics\nORDER BY\n dd\n", 98 | "refId": "A" 99 | } 100 | ], 101 | "thresholds": [], 102 | "timeFrom": null, 103 | "timeShift": null, 104 | "title": "Tasks created", 105 | "tooltip": { 106 | "shared": true, 107 | "sort": 2, 108 | "value_type": "individual" 109 | }, 110 | "type": "graph", 111 | "xaxis": { 112 | "buckets": null, 113 | "mode": "time", 114 | "name": null, 115 | "show": true, 116 | "values": [] 117 | }, 118 | "yaxes": [ 119 | { 120 | "format": "short", 121 | "label": null, 122 | "logBase": 1, 123 | "max": null, 124 | "min": null, 125 | "show": true 126 | }, 127 | { 128 | "format": "short", 129 | "label": null, 130 | "logBase": 1, 131 | "max": null, 132 | "min": null, 133 | "show": true 134 | } 135 | ], 136 | "yaxis": { 137 | "align": false, 138 | "alignLevel": null 139 | } 140 | }, 141 | { 142 | "aliasColors": {}, 143 | "bars": false, 144 | "dashLength": 10, 145 | "dashes": false, 146 | "datasource": "${DS_PGSQL}", 147 | "fill": 0, 148 | "gridPos": { 149 | "h": 5, 150 | "w": 12, 151 | "x": 12, 152 | "y": 0 153 | }, 154 | "id": 14, 155 | "legend": { 156 | "avg": false, 157 | "current": false, 158 | "max": false, 159 | "min": false, 160 | "show": true, 161 | "total": false, 162 | "values": false 163 | }, 164 | "lines": true, 165 | "linewidth": 1, 166 | "links": [], 167 | "nullPointMode": "null", 168 | "percentage": false, 169 | "pointradius": 2, 170 | "points": false, 171 | "renderer": "flot", 172 | "seriesOverrides": [], 173 | "spaceLength": 10, 174 | "stack": false, 175 | "steppedLine": true, 176 | "targets": [ 177 | { 178 | "alias": "", 179 | "format": "time_series", 180 | "rawSql": "WITH topics AS (select distinct topic from queue_tasks)\nSELECT\n to_timestamp(floor(date_part('epoch', dd)/$resolution)*$resolution) as time,\n topics.topic as metric,\n (SELECT COUNT(*) FROM queue_tasks where topic = topics.topic AND to_timestamp(floor(date_part('epoch', canceled_at)/$resolution)*$resolution) = to_timestamp(floor(date_part('epoch', dd)/$resolution)*$resolution))\nFROM\ngenerate_series(to_timestamp($__unixEpochFrom()), to_timestamp($__unixEpochTo()), $resolution*interval '1 sec') dd\nCROSS JOIN\ntopics\nORDER BY\n dd\n", 181 | "refId": "A" 182 | } 183 | ], 184 | "thresholds": [], 185 | "timeFrom": null, 186 | "timeShift": null, 187 | "title": "Tasks canceled", 188 | "tooltip": { 189 | "shared": true, 190 | "sort": 2, 191 | "value_type": "individual" 192 | }, 193 | "type": "graph", 194 | "xaxis": { 195 | "buckets": null, 196 | "mode": "time", 197 | "name": null, 198 | "show": true, 199 | "values": [] 200 | }, 201 | "yaxes": [ 202 | { 203 | "format": "short", 204 | "label": null, 205 | "logBase": 1, 206 | "max": null, 207 | "min": null, 208 | "show": true 209 | }, 210 | { 211 | "format": "short", 212 | "label": null, 213 | "logBase": 1, 214 | "max": null, 215 | "min": null, 216 | "show": true 217 | } 218 | ], 219 | "yaxis": { 220 | "align": false, 221 | "alignLevel": null 222 | } 223 | }, 224 | { 225 | "aliasColors": {}, 226 | "bars": false, 227 | "dashLength": 10, 228 | "dashes": false, 229 | "datasource": "${DS_PGSQL}", 230 | "fill": 0, 231 | "gridPos": { 232 | "h": 5, 233 | "w": 12, 234 | "x": 0, 235 | "y": 5 236 | }, 237 | "id": 15, 238 | "legend": { 239 | "avg": false, 240 | "current": false, 241 | "max": false, 242 | "min": false, 243 | "show": true, 244 | "total": false, 245 | "values": false 246 | }, 247 | "lines": true, 248 | "linewidth": 1, 249 | "links": [], 250 | "nullPointMode": "null", 251 | "percentage": false, 252 | "pointradius": 2, 253 | "points": false, 254 | "renderer": "flot", 255 | "seriesOverrides": [], 256 | "spaceLength": 10, 257 | "stack": false, 258 | "steppedLine": true, 259 | "targets": [ 260 | { 261 | "alias": "", 262 | "format": "time_series", 263 | "rawSql": "WITH topics AS (select distinct topic from queue_tasks)\nSELECT\n to_timestamp(floor(date_part('epoch', dd)/$resolution)*$resolution) as time,\n topics.topic as metric,\n (SELECT COUNT(*) FROM queue_tasks where topic = topics.topic AND to_timestamp(floor(date_part('epoch', started_at)/$resolution)*$resolution) = to_timestamp(floor(date_part('epoch', dd)/$resolution)*$resolution))\nFROM\ngenerate_series(to_timestamp($__unixEpochFrom()), to_timestamp($__unixEpochTo()), $resolution*interval '1 sec') dd\nCROSS JOIN\ntopics\nORDER BY\n dd\n", 264 | "refId": "A" 265 | } 266 | ], 267 | "thresholds": [], 268 | "timeFrom": null, 269 | "timeShift": null, 270 | "title": "Tasks started", 271 | "tooltip": { 272 | "shared": true, 273 | "sort": 2, 274 | "value_type": "individual" 275 | }, 276 | "type": "graph", 277 | "xaxis": { 278 | "buckets": null, 279 | "mode": "time", 280 | "name": null, 281 | "show": true, 282 | "values": [] 283 | }, 284 | "yaxes": [ 285 | { 286 | "format": "short", 287 | "label": null, 288 | "logBase": 1, 289 | "max": null, 290 | "min": null, 291 | "show": true 292 | }, 293 | { 294 | "format": "short", 295 | "label": null, 296 | "logBase": 1, 297 | "max": null, 298 | "min": null, 299 | "show": true 300 | } 301 | ], 302 | "yaxis": { 303 | "align": false, 304 | "alignLevel": null 305 | } 306 | }, 307 | { 308 | "aliasColors": {}, 309 | "bars": false, 310 | "dashLength": 10, 311 | "dashes": false, 312 | "datasource": "${DS_PGSQL}", 313 | "fill": 0, 314 | "gridPos": { 315 | "h": 9, 316 | "w": 12, 317 | "x": 12, 318 | "y": 5 319 | }, 320 | "id": 13, 321 | "legend": { 322 | "avg": false, 323 | "current": false, 324 | "max": false, 325 | "min": false, 326 | "show": true, 327 | "total": false, 328 | "values": false 329 | }, 330 | "lines": true, 331 | "linewidth": 1, 332 | "links": [], 333 | "nullPointMode": "null", 334 | "percentage": false, 335 | "pointradius": 2, 336 | "points": false, 337 | "renderer": "flot", 338 | "seriesOverrides": [], 339 | "spaceLength": 10, 340 | "stack": false, 341 | "steppedLine": true, 342 | "targets": [ 343 | { 344 | "alias": "", 345 | "format": "time_series", 346 | "rawSql": "SELECT\n date_trunc('min', added_at) as time,\n topic as metric,\n count(*)\nFROM\n queue_tasks\nWHERE\n $__timeFilter(added_at)\n AND started_at is null\nGROUP BY topic, date_trunc('min', added_at)\nORDER BY date_trunc('min', added_at)", 347 | "refId": "A" 348 | } 349 | ], 350 | "thresholds": [], 351 | "timeFrom": null, 352 | "timeShift": null, 353 | "title": "Tasks created but not started", 354 | "tooltip": { 355 | "shared": true, 356 | "sort": 2, 357 | "value_type": "individual" 358 | }, 359 | "type": "graph", 360 | "xaxis": { 361 | "buckets": null, 362 | "mode": "time", 363 | "name": null, 364 | "show": true, 365 | "values": [] 366 | }, 367 | "yaxes": [ 368 | { 369 | "format": "short", 370 | "label": null, 371 | "logBase": 1, 372 | "max": null, 373 | "min": null, 374 | "show": true 375 | }, 376 | { 377 | "format": "short", 378 | "label": null, 379 | "logBase": 1, 380 | "max": null, 381 | "min": null, 382 | "show": true 383 | } 384 | ], 385 | "yaxis": { 386 | "align": false, 387 | "alignLevel": null 388 | } 389 | }, 390 | { 391 | "aliasColors": {}, 392 | "bars": false, 393 | "dashLength": 10, 394 | "dashes": false, 395 | "datasource": "${DS_PGSQL}", 396 | "fill": 0, 397 | "gridPos": { 398 | "h": 5, 399 | "w": 12, 400 | "x": 0, 401 | "y": 10 402 | }, 403 | "id": 3, 404 | "legend": { 405 | "avg": false, 406 | "current": false, 407 | "max": false, 408 | "min": false, 409 | "show": true, 410 | "total": false, 411 | "values": false 412 | }, 413 | "lines": true, 414 | "linewidth": 1, 415 | "links": [], 416 | "nullPointMode": "null", 417 | "percentage": false, 418 | "pointradius": 2, 419 | "points": false, 420 | "renderer": "flot", 421 | "seriesOverrides": [], 422 | "spaceLength": 10, 423 | "stack": false, 424 | "steppedLine": true, 425 | "targets": [ 426 | { 427 | "alias": "", 428 | "format": "time_series", 429 | "rawSql": "WITH topics AS (select distinct topic from queue_tasks)\nSELECT\n to_timestamp(floor(date_part('epoch', dd)/$resolution)*$resolution) as time,\n topics.topic as metric,\n (SELECT COUNT(*) FROM queue_tasks where topic = topics.topic AND to_timestamp(floor(date_part('epoch', committed_at)/$resolution)*$resolution) = to_timestamp(floor(date_part('epoch', dd)/$resolution)*$resolution))\nFROM\ngenerate_series(to_timestamp($__unixEpochFrom()), to_timestamp($__unixEpochTo()), $resolution*interval '1 sec') dd\nCROSS JOIN\ntopics\nORDER BY\n dd\n", 430 | "refId": "A" 431 | } 432 | ], 433 | "thresholds": [], 434 | "timeFrom": null, 435 | "timeShift": null, 436 | "title": "Tasks committed", 437 | "tooltip": { 438 | "shared": true, 439 | "sort": 2, 440 | "value_type": "individual" 441 | }, 442 | "type": "graph", 443 | "xaxis": { 444 | "buckets": null, 445 | "mode": "time", 446 | "name": null, 447 | "show": true, 448 | "values": [] 449 | }, 450 | "yaxes": [ 451 | { 452 | "format": "short", 453 | "label": null, 454 | "logBase": 1, 455 | "max": null, 456 | "min": null, 457 | "show": true 458 | }, 459 | { 460 | "format": "short", 461 | "label": null, 462 | "logBase": 1, 463 | "max": null, 464 | "min": null, 465 | "show": true 466 | } 467 | ], 468 | "yaxis": { 469 | "align": false, 470 | "alignLevel": null 471 | } 472 | }, 473 | { 474 | "columns": [], 475 | "datasource": "${DS_PGSQL}", 476 | "fontSize": "100%", 477 | "gridPos": { 478 | "h": 9, 479 | "w": 12, 480 | "x": 12, 481 | "y": 14 482 | }, 483 | "id": 6, 484 | "links": [], 485 | "pageSize": null, 486 | "scroll": true, 487 | "showHeader": true, 488 | "sort": { 489 | "col": 0, 490 | "desc": true 491 | }, 492 | "styles": [ 493 | { 494 | "alias": "Time", 495 | "dateFormat": "YYYY-MM-DD HH:mm:ss", 496 | "pattern": "Time", 497 | "type": "date" 498 | }, 499 | { 500 | "alias": "", 501 | "colorMode": null, 502 | "colors": [ 503 | "rgba(245, 54, 54, 0.9)", 504 | "rgba(237, 129, 40, 0.89)", 505 | "rgba(50, 172, 45, 0.97)" 506 | ], 507 | "decimals": 2, 508 | "pattern": "/.*/", 509 | "thresholds": [], 510 | "type": "number", 511 | "unit": "short" 512 | } 513 | ], 514 | "targets": [ 515 | { 516 | "alias": "", 517 | "format": "table", 518 | "rawSql": "select\n topic,\n count(*)\nfrom queue_tasks where committed_at is null and canceled_at is null and started_at is null group by topic", 519 | "refId": "A" 520 | } 521 | ], 522 | "title": "Tasks not started", 523 | "transform": "table", 524 | "type": "table" 525 | }, 526 | { 527 | "aliasColors": {}, 528 | "bars": false, 529 | "dashLength": 10, 530 | "dashes": false, 531 | "datasource": "${DS_PGSQL}", 532 | "fill": 0, 533 | "gridPos": { 534 | "h": 11, 535 | "w": 12, 536 | "x": 0, 537 | "y": 15 538 | }, 539 | "id": 4, 540 | "legend": { 541 | "alignAsTable": true, 542 | "avg": true, 543 | "current": false, 544 | "max": true, 545 | "min": false, 546 | "show": true, 547 | "sort": "avg", 548 | "sortDesc": true, 549 | "total": false, 550 | "values": true 551 | }, 552 | "lines": true, 553 | "linewidth": 2, 554 | "links": [], 555 | "nullPointMode": "null", 556 | "percentage": false, 557 | "pointradius": 2, 558 | "points": false, 559 | "renderer": "flot", 560 | "seriesOverrides": [], 561 | "spaceLength": 10, 562 | "stack": false, 563 | "steppedLine": true, 564 | "targets": [ 565 | { 566 | "alias": "", 567 | "format": "time_series", 568 | "rawSql": "SELECT\n date_trunc('min', started_at) as time,\n topic as metric,\n avg(extract(epoch from committed_at - started_at))\nFROM\n queue_tasks\nWHERE\n $__timeFilter(started_at)\nGROUP BY topic, date_trunc('min', started_at)\nORDER BY time", 569 | "refId": "A" 570 | } 571 | ], 572 | "thresholds": [], 573 | "timeFrom": null, 574 | "timeShift": null, 575 | "title": "Average task duration", 576 | "tooltip": { 577 | "shared": true, 578 | "sort": 2, 579 | "value_type": "individual" 580 | }, 581 | "type": "graph", 582 | "xaxis": { 583 | "buckets": null, 584 | "mode": "time", 585 | "name": null, 586 | "show": true, 587 | "values": [] 588 | }, 589 | "yaxes": [ 590 | { 591 | "decimals": null, 592 | "format": "dtdurations", 593 | "label": null, 594 | "logBase": 1, 595 | "max": null, 596 | "min": null, 597 | "show": true 598 | }, 599 | { 600 | "format": "short", 601 | "label": null, 602 | "logBase": 1, 603 | "max": null, 604 | "min": null, 605 | "show": true 606 | } 607 | ], 608 | "yaxis": { 609 | "align": false, 610 | "alignLevel": null 611 | } 612 | }, 613 | { 614 | "columns": [], 615 | "datasource": "${DS_PGSQL}", 616 | "fontSize": "100%", 617 | "gridPos": { 618 | "h": 9, 619 | "w": 12, 620 | "x": 12, 621 | "y": 23 622 | }, 623 | "id": 7, 624 | "links": [], 625 | "pageSize": null, 626 | "scroll": true, 627 | "showHeader": true, 628 | "sort": { 629 | "col": null, 630 | "desc": false 631 | }, 632 | "styles": [ 633 | { 634 | "alias": "Time", 635 | "dateFormat": "YYYY-MM-DD HH:mm:ss", 636 | "pattern": "Time", 637 | "type": "date" 638 | }, 639 | { 640 | "alias": "", 641 | "colorMode": null, 642 | "colors": [ 643 | "rgba(245, 54, 54, 0.9)", 644 | "rgba(237, 129, 40, 0.89)", 645 | "rgba(50, 172, 45, 0.97)" 646 | ], 647 | "dateFormat": "YYYY-MM-DD HH:mm:ss", 648 | "decimals": 2, 649 | "mappingType": 1, 650 | "pattern": "id", 651 | "thresholds": [], 652 | "type": "string", 653 | "unit": "short" 654 | }, 655 | { 656 | "alias": "", 657 | "colorMode": null, 658 | "colors": [ 659 | "rgba(245, 54, 54, 0.9)", 660 | "rgba(237, 129, 40, 0.89)", 661 | "rgba(50, 172, 45, 0.97)" 662 | ], 663 | "decimals": 2, 664 | "pattern": "/.*/", 665 | "thresholds": [], 666 | "type": "number", 667 | "unit": "short" 668 | } 669 | ], 670 | "targets": [ 671 | { 672 | "alias": "", 673 | "format": "table", 674 | "rawSql": "select\n id,\n topic,\n consumer_id\nfrom queue_tasks\nwhere\n committed_at is null\n and canceled_at is null\n and heartbeat_deadline > now()", 675 | "refId": "A" 676 | } 677 | ], 678 | "title": "Tasks in progress", 679 | "transform": "table", 680 | "type": "table" 681 | }, 682 | { 683 | "aliasColors": {}, 684 | "bars": false, 685 | "dashLength": 10, 686 | "dashes": false, 687 | "datasource": "${DS_PGSQL}", 688 | "fill": 0, 689 | "gridPos": { 690 | "h": 11, 691 | "w": 12, 692 | "x": 0, 693 | "y": 26 694 | }, 695 | "id": 8, 696 | "legend": { 697 | "alignAsTable": true, 698 | "avg": true, 699 | "current": false, 700 | "max": true, 701 | "min": false, 702 | "show": true, 703 | "sort": "avg", 704 | "sortDesc": true, 705 | "total": false, 706 | "values": true 707 | }, 708 | "lines": true, 709 | "linewidth": 2, 710 | "links": [], 711 | "nullPointMode": "null", 712 | "percentage": false, 713 | "pointradius": 2, 714 | "points": false, 715 | "renderer": "flot", 716 | "seriesOverrides": [], 717 | "spaceLength": 10, 718 | "stack": false, 719 | "steppedLine": true, 720 | "targets": [ 721 | { 722 | "alias": "", 723 | "format": "time_series", 724 | "rawSql": "SELECT\n date_trunc('min', added_at) as time,\n topic as metric,\n avg(extract(epoch from started_at - added_at))\nFROM\n queue_tasks\nWHERE\n $__timeFilter(added_at)\nGROUP BY topic, date_trunc('min', added_at)\nORDER BY time", 725 | "refId": "A" 726 | } 727 | ], 728 | "thresholds": [], 729 | "timeFrom": null, 730 | "timeShift": null, 731 | "title": "Average task wait time", 732 | "tooltip": { 733 | "shared": true, 734 | "sort": 2, 735 | "value_type": "individual" 736 | }, 737 | "type": "graph", 738 | "xaxis": { 739 | "buckets": null, 740 | "mode": "time", 741 | "name": null, 742 | "show": true, 743 | "values": [] 744 | }, 745 | "yaxes": [ 746 | { 747 | "decimals": null, 748 | "format": "dtdurations", 749 | "label": null, 750 | "logBase": 1, 751 | "max": null, 752 | "min": null, 753 | "show": true 754 | }, 755 | { 756 | "format": "short", 757 | "label": null, 758 | "logBase": 1, 759 | "max": null, 760 | "min": null, 761 | "show": true 762 | } 763 | ], 764 | "yaxis": { 765 | "align": false, 766 | "alignLevel": null 767 | } 768 | }, 769 | { 770 | "columns": [], 771 | "datasource": "${DS_PGSQL}", 772 | "fontSize": "100%", 773 | "gridPos": { 774 | "h": 9, 775 | "w": 12, 776 | "x": 12, 777 | "y": 32 778 | }, 779 | "id": 17, 780 | "links": [], 781 | "pageSize": null, 782 | "scroll": true, 783 | "showHeader": true, 784 | "sort": { 785 | "col": 0, 786 | "desc": true 787 | }, 788 | "styles": [ 789 | { 790 | "alias": "ID", 791 | "dateFormat": "YYYY-MM-DD HH:mm:ss", 792 | "pattern": "id", 793 | "type": "string" 794 | }, 795 | { 796 | "alias": "", 797 | "colorMode": null, 798 | "colors": [ 799 | "rgba(245, 54, 54, 0.9)", 800 | "rgba(237, 129, 40, 0.89)", 801 | "rgba(50, 172, 45, 0.97)" 802 | ], 803 | "dateFormat": "YYYY-MM-DD HH:mm:ss", 804 | "decimals": 2, 805 | "mappingType": 1, 806 | "pattern": "/.*/", 807 | "thresholds": [], 808 | "type": "string", 809 | "unit": "short" 810 | } 811 | ], 812 | "targets": [ 813 | { 814 | "alias": "", 815 | "bucketAggs": [ 816 | { 817 | "field": "@timestamp", 818 | "id": "2", 819 | "settings": { 820 | "interval": "auto", 821 | "min_doc_count": 0, 822 | "trimEdges": 0 823 | }, 824 | "type": "date_histogram" 825 | } 826 | ], 827 | "format": "table", 828 | "metrics": [ 829 | { 830 | "field": "select field", 831 | "id": "1", 832 | "type": "count" 833 | } 834 | ], 835 | "rawSql": "SELECT\n id, topic, retries_left, added_at, started_at, committed_at,\n canceled_at\nFROM queue_tasks WHERE $__timeFilter(added_at) OR $__timeFilter(started_at) OR $__timeFilter(committed_at) ORDER BY id DESC LIMIT 100;", 836 | "refId": "A", 837 | "timeField": "@timestamp" 838 | } 839 | ], 840 | "title": "Recent tasks", 841 | "transform": "table", 842 | "type": "table" 843 | } 844 | ], 845 | "refresh": false, 846 | "schemaVersion": 16, 847 | "style": "dark", 848 | "tags": [], 849 | "templating": { 850 | "list": [ 851 | { 852 | "allValue": null, 853 | "current": { 854 | "tags": [], 855 | "text": "300", 856 | "value": "300" 857 | }, 858 | "hide": 0, 859 | "includeAll": false, 860 | "label": "Resolution (sec)", 861 | "multi": false, 862 | "name": "resolution", 863 | "options": [ 864 | { 865 | "selected": true, 866 | "text": "60", 867 | "value": "60" 868 | }, 869 | { 870 | "selected": false, 871 | "text": "300", 872 | "value": "300" 873 | }, 874 | { 875 | "selected": false, 876 | "text": "3600", 877 | "value": "3600" 878 | } 879 | ], 880 | "query": "60,300,3600", 881 | "type": "custom" 882 | } 883 | ] 884 | }, 885 | "time": { 886 | "from": "now-24h", 887 | "to": "now" 888 | }, 889 | "timepicker": { 890 | "refresh_intervals": [ 891 | "5s", 892 | "10s", 893 | "30s", 894 | "1m", 895 | "5m", 896 | "15m", 897 | "30m", 898 | "1h", 899 | "2h", 900 | "1d" 901 | ], 902 | "time_options": [ 903 | "5m", 904 | "15m", 905 | "1h", 906 | "6h", 907 | "12h", 908 | "24h", 909 | "2d", 910 | "7d", 911 | "30d" 912 | ] 913 | }, 914 | "timezone": "", 915 | "title": "SQL Task Queue", 916 | "uid": "4aPOj4ymz", 917 | "version": 8 918 | } 919 | --------------------------------------------------------------------------------