|
| 1 | +/* |
| 2 | + * Copyright (c) 2019-2024. Ivan Vakhrushev and others. |
| 3 | + * https://github.com/mfvanek/pg-index-health-sql |
| 4 | + * |
| 5 | + * Licensed under the Apache License 2.0 |
| 6 | + */ |
| 7 | + |
| 8 | +with all_sequences as ( |
| 9 | + select |
| 10 | + s.seqrelid::regclass::text as sequence_name, |
| 11 | + s.seqtypid::regtype as data_type, |
| 12 | + s.seqstart as start_value, |
| 13 | + s.seqmin as min_value, |
| 14 | + s.seqmax as max_value, |
| 15 | + s.seqincrement as increment_by, |
| 16 | + case when has_sequence_privilege(c.oid, 'select,usage'::text) |
| 17 | + then pg_sequence_last_value(c.oid::regclass) |
| 18 | + else null::bigint end as last_value |
| 19 | + from |
| 20 | + pg_sequence s |
| 21 | + join pg_class c on c.oid = s.seqrelid |
| 22 | + left join pg_namespace n on n.oid = c.relnamespace |
| 23 | + where |
| 24 | + not pg_is_other_temp_schema(n.oid) -- not temporary |
| 25 | + and c.relkind = 'S'::char -- sequence object |
| 26 | + and not s.seqcycle -- skip cycle sequences |
| 27 | + and n.nspname = :schema_name_param::text |
| 28 | +), |
| 29 | +sequence_state as ( |
| 30 | + select |
| 31 | + t.sequence_name, |
| 32 | + t.data_type, |
| 33 | + case when t.increment_by > 0 -- ascending or descending sequence |
| 34 | + then 100.0 * (t.max_value - coalesce(t.last_value, t.start_value)) / (t.max_value - t.min_value) |
| 35 | + else 100.0 * (coalesce(t.last_value, t.start_value) - t.min_value) / (t.max_value - t.min_value) |
| 36 | + end ::numeric(5, 2) as remaining_percentage -- percentage of remaining values |
| 37 | + from all_sequences as t |
| 38 | +) |
| 39 | +select s.* |
| 40 | +from sequence_state as s |
| 41 | +where |
| 42 | + s.remaining_percentage <= :remaining_percentage_threshold::numeric(5, 2) |
| 43 | +order by s.sequence_name; |
0 commit comments