Skip to content
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

Query to check sequence overflow sql #42

Merged
merged 3 commits into from
May 15, 2024
Merged

Conversation

BLoHny
Copy link
Collaborator

@BLoHny BLoHny commented May 4, 2024

Copy link
Owner

@mfvanek mfvanek left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Hi @BLoHny,
I've left some comments.

@BLoHny
Copy link
Collaborator Author

BLoHny commented May 5, 2024

select
    nsp.nspname as schemaname, -- schema name
    case
        when increment_by > 0
        then
            100.0 * (max_value - coalesce(last_value, start_value)) / (max_value - min_value)
        else
            100.0 * (coalesce(last_value, start_value) - min_value) / (max_value - min_value)
    end :: numeric(5, 2) as remaining_percentage -- percentage of remaining values
    pg_get_serial_sequence(col.attrelid::regclass::text, col.attname) as sequence_name, -- check sequence growth direction (increment or decrement)
from pg_catalog.pg_sequences
join
    pg_catalog.pg_class t
    join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace
    join pg_catalog.pg_attribute col on col.attrelid = t.oid
where
    not cycle -- exclude cyclic sequences
    and nsp.nspname = :schema_name_param::text
order by schemaname, sequencename;

Does this code satisfy request?

@mfvanek
Copy link
Owner

mfvanek commented May 5, 2024

Does this code satisfy request?
It doesn't work. :(

It should be

create sequence if not exists demo.seq1; -- bigint by default
create sequence if not exists demo.seq2 as smallint;
create sequence if not exists demo.seq3 as smallint increment by -200;
select nextval('demo.seq3'); -- call several times

with all_sequences as (
    select
        s.seqrelid::regclass::text as sequence_name,
        s.seqtypid::regtype as data_type,
        s.seqstart as start_value,
        s.seqmin as min_value,
        s.seqmax as max_value,
        s.seqincrement as increment_by,
        case when has_sequence_privilege(c.oid, 'select,usage'::text)
        then pg_sequence_last_value(c.oid::regclass)
        else null::bigint end as last_value
    from
        pg_sequence s
        join pg_class c on c.oid = s.seqrelid
        left join pg_namespace n on n.oid = c.relnamespace
    where
        not pg_is_other_temp_schema(n.oid) -- not temporary
        and c.relkind = 'S'::char -- sequence object
        and not s.seqcycle -- skip cycle sequences
         -- and n.nspname = :schema_name_param::text
        and n.nspname = 'demo'::text
),
sequence_state as (
    select
        t.sequence_name,
        t.data_type,
        case when t.increment_by > 0 -- ascending or descending sequence
        then 100.0 * (t.max_value - coalesce(t.last_value, t.start_value)) / (t.max_value - t.min_value)
        else 100.0 * (coalesce(t.last_value, t.start_value) - t.min_value) / (t.max_value - t.min_value)
        end ::numeric(5, 2) as remaining_percentage -- percentage of remaining values
    from all_sequences as t
)
select *
from sequence_state as s
where
    --s.remaining_percentage <= :remaining_percentage_threshold::numeric(5, 2)
    s.remaining_percentage <= '99.99'::numeric(5, 2)
order by s.sequence_name;

Prints

demo.seq3	smallint	96.34

@mfvanek
Copy link
Owner

mfvanek commented May 5, 2024

@BLoHny
You'd better to revert your last commit because the query is wrong now.
Please retest the query before requesting review again.

There was only one issue with query

  == [/github/workspace/sql/check_sequence_overflow.sql] FAIL
  L:  42 | P:   5 | RF03 | Qualified reference 's.remaining_percentage' found in
                         | single table select which is inconsistent with previous
                         | references. [references.consistent]

https://github.com/mfvanek/pg-index-health-sql/pull/42/checks?check_run_id=24604476669

I guess we can fix it with s.*

select s.*
from sequence_state as s

@mfvanek mfvanek merged commit 1bb1bc5 into mfvanek:master May 15, 2024
1 check passed
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

2 participants