On 07/07/2010 12:59 PM, John wrote:
> I am the only developer, DBA etc.. for a small project.  Today (yesterday was 
> everything was perfect) many of the sequence numbers fell behind what is the 
> actual PK value.   For example the invoice PK sequence current value = 1056 
> but the table PK was 1071.  Nobody (other than myself) knows how to 
> edit/access the postgres server.  So
> 
> 1. Does anyone know how this could have happened?????? Other than human 
> interaction.

I've never heard of this happening. Are you certain nothing bypassed the
sequence and directly inserted a PK value?

> 2. Does anyone have a script to reset the sequences to match the tables? 

Not heavily tested, but something like this might do the trick:

8<----------------------
CREATE OR REPLACE FUNCTION adjust_seqs(namespace text)
  RETURNS text AS $$
DECLARE
  rec         record;
  startval    bigint;
  sql         text;
  seqname     text;
BEGIN
  FOR rec in EXECUTE 'select table_name, column_name, column_default
                      from information_schema.columns
                      where table_schema = ''' || namespace || '''
                      and column_default like ''nextval%''' LOOP

    seqname := pg_get_serial_sequence(rec.table_name, rec.column_name);
    sql := 'select max(' || rec.column_name || ') + 1 from ' ||
                                                        rec.table_name;
    EXECUTE sql INTO startval;
    IF startval IS NOT NULL THEN
      sql := 'ALTER SEQUENCE ' || seqname || ' RESTART WITH ' ||
                                                              startval;
      EXECUTE sql;
      RAISE NOTICE '%', sql;
    END IF;
  END LOOP;
  RETURN 'OK';
END;
$$ LANGUAGE plpgsql STRICT;

select adjust_seqs('public');
8<----------------------

HTH,

Joe

-- 
Joe Conway
credativ LLC: http://www.credativ.us
Linux, PostgreSQL, and general Open Source
Training, Service, Consulting, & Support

Attachment: signature.asc
Description: OpenPGP digital signature

Reply via email to