-
Notifications
You must be signed in to change notification settings - Fork 402
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
add function to monitor sequences #940
Conversation
👍 |
👎 aka don't merge for now. it does not work for sequences where start_value deviates from min_value |
converting to draft then |
In the formula (abs(last_value::numeric - start_value) + 1) /
(CASE WHEN increment_by > 0 THEN (max_value::numeric - start_value) ELSE (start_value::numeric - min_value) END + 1) * 100
So any change in the formula/query must at least account for the following cases: -- For testing we assume a seq is fine if fewer than 80% of its values are used up
-- seq with enough values left
CREATE SEQUENCE not_exhausted_seq MINVALUE 1 MAXVALUE 10;
SELECT setval('not_exhausted_seq', 7);
-- seq that will soon become exhausted
CREATE SEQUENCE nearly_exhausted_seq MINVALUE 1 MAXVALUE 10;
SELECT setval('nearly_exhausted_seq', 8);
-- seq with no values left
CREATE SEQUENCE exhausted_seq MINVALUE 1 MAXVALUE 10;
SELECT setval('exhausted_seq', 10);
-- seq with an increment other than one
CREATE SEQUENCE nearly_exhausted_seq_with_increment_2 MINVALUE 1 MAXVALUE 10 INCREMENT 2;
SELECT setval('nearly_exhausted_seq_with_increment_2', 8);
-- descending seq in the negative range
-- that one is especially important because for now we fix seq exhaustion by pushing the seq into the negative range
CREATE SEQUENCE nearly_exhausted_seq_in_the_negative_range MINVALUE -10 MAXVALUE -1 INCREMENT -1;
SELECT setval('nearly_exhausted_seq_in_the_negative_range', -9);
-- seq that spans both positive and negative range
CREATE SEQUENCE nearly_exhausted_seq_in_positive_negative_range MINVALUE -5 MAXVALUE 4 INCREMENT -1;
SELECT setval('nearly_exhausted_seq_in_positive_negative_range', -4);
-- seq with the start_value different from the min_value
CREATE SEQUENCE nearly_exhausted_seq_with_nondefault_start_value MINVALUE 1 MAXVALUE 10 START WITH 3;
SELECT setval('nearly_exhausted_seq_with_nondefault_start_value', 9);
-- this seq is not a problem because there is an explicit cycle
CREATE SEQUENCE nearly_exhausted_seq_with_cycle MINVALUE 1 MAXVALUE 10 CYCLE;
SELECT setval('nearly_exhausted_seq_with_cycle', 8);
-- last_value can be NULL if you lack privileges or haven't used the seq yet
CREATE SEQUENCE seq_with_null_last_value MINVALUE 1 MAXVALUE 10;
-- seq with an increment big enough in relation to the seq size
-- it is almost exhausted as there is only one step left before it overflows
-- whether it triggers an alert or not depends on the threshold value: for 80% it will not trigger
CREATE SEQUENCE nearly_exhausted_seq_big_increment MINVALUE 1 MAXVALUE 10 INCREMENT 5;
-- returns 1
SELECT nextval('nearly_exhausted_seq_big_increment');
-- returns 6: at this point the sequence is close to exhaustion
SELECT nextval('nearly_exhausted_seq_big_increment'); if you re-create all of these, the expected output for sequences that have exhausted 80% of their values is
|
The only more edge case I could think about is increment steps bigger than 1/-1. But probably nobody use jumps of 10 or 100 batches. It could be good for a ZMON check to check the trend on EDIT: add this column shows how many increments would be left:
|
Or another try to incorporate increment:
|
👍 |
1 similar comment
👍 |
We want to monitor sequences that are close to their max values.
Unfortunately
pg_sequences
reports sequences only for the database one is connected to. For that reason we need to install the relevant function into each and every database. _zmon_schema.dump does not fit that criterion butmetric_helpers
does.