0

I need a sequential number sequence for the rows in a table and I need to ensure that it is always sequential with no gaps on insert , when deleted I can leave the row gap, but on insert I must fill the gaps with the new rows. The reason for this is a different system must line up one for one with the row records. Yet the db can be manipulated by others in both the sql end and also via an application ; I am thinking a trigger will allow me to accomplish the something changed part - but how to actually determine if I have gaps and perform the insert of this sequence number - even if I have to maintain the deleted sequences in a separate table and manage is fine - I am required to line up one for one with this other system no matter how the table gets manipulated .

Auto Increment field will not work as a row gets deleted the next insert will be the last auto Increment value. I would need an insert at .. or perhaps keep the row and add a field IsDeleted and force the table as read only or no more inserts / deletes ..but how to do that? Perhaps when row is inserted I could set sequence number at gap if found or at end if not.

Does somebody have experience doing this kind of thing ?

Ken
  • 2,518
  • 2
  • 27
  • 35
  • Using the event scheduler, you can create an event which will go through your table, check what's the last value of the sequence (let's call that column `sequence_value`) and it will update records on predefined interval. Why this approach? You need to have only a single process doing this task and event is the perfect candidate. Creating such a query should be trivial. You can do this every few minutes in order to save up on sever resources (that's why you don't want to do it on every query, plus it can lead to undesirable effects which I can't explain in a single comment). – N.B. Sep 09 '16 at 23:36
  • Why would an uninterrupted sequence help your system to line up with another system one to one? If you insert a record, I would expect your system to communicate this fact to the other system along with the id of the newly created record. – Shadow Sep 10 '16 at 01:10
  • See this INNODB Gap Anomaly answer of mine [Here](http://stackoverflow.com/a/38363271) and you will get a flavor for a few of the cases that cause gaps (not including the obvious case of deletes). They are everyday occurrences for many systems. And http://stackoverflow.com/a/39362042. – Drew Sep 10 '16 at 01:15
  • So, shown above are 5 cases, the last link being rollbacks. Deletes make 6. Trust me there are many more cases. Your data will be littered with gaps. Just because a boss says "Let's do this thing" doesn't mean it needs to be implemented that way. Calm rational reasonable minds need to come together and craft a different solution. – Drew Sep 10 '16 at 01:30
  • @Shadow the other system is almost always fixed, changeable with a lot of effort; it runs live equipment. it can't query it cant order by it knows only that row 1 through 20 of the list it gets must be 1 through 20 and not some others. The management side of the system is accessible by people who may have no understanding of what they do whether via the application or sql script. I need to ensure that it is matched up to the nth degree or bad things can happen. I am not dealing with simple db operations that affect a website or an application / data store. – Ken Sep 10 '16 at 01:51
  • @Drew I am not concerned about the identity column - I just need to make sure that I have a sequential number in a column and if that row is deleted I need to insert the new row with the missing sequence number. If there is not a missing sequence number I just need to insert the row at the end with the next sequence number. – Ken Sep 10 '16 at 02:06
  • Oh that is much better news then. My brain went off on autoinc as there was no mention of it not being there. How you allocate your sequence # prior to the insert (that put it there in the first place or failed) may fall prey to the same problems though. You would just be doing what the engine does, assuming success, and all those fail reasons still apply ? So watch out for that for then there would be no difference. – Drew Sep 10 '16 at 02:10

1 Answers1

2

I know there is a lot here. I tried to document it rather well inside the code and here and there. It uses Stored Procedures. You can naturally pull the code out and not use that method. It uses a main table that houses next available incrementors. It uses safe INNODB Intention Locks for concurrency. It has a reuse table and stored procs to support it.

It does not in anyway use the table myTable. It is shown there for your own imagination based on comments under your question. The summary of that is that you know that you will have gaps upon DELETE. You want some orderly fashion to reuse those slots, those sequence numbers. So, when you DELETE a row, use the stored procs accordingly to add that number. Naturally there is a stored proc to get the next sequence number for reuse and other things.

For the purposes of testing, your sectionType = 'devices'

And best of all it is tested!

Schema:

create table myTable
(   -- your main table, the one you cherish
    `id` int auto_increment primary key, -- ignore this
    `seqNum` int not null, -- FOCUS ON THIS
    `others` varchar(100) not null
) ENGINE=InnoDB;

create table reuseMe
(   -- table for sequence numbers to reuse
    `seqNum` int not null primary key, -- FOCUS ON THIS
    `reused` int not null -- 0 upon entry, 1 when used up (reused)
    -- the primary key enforces uniqueness
) ENGINE=InnoDB;;

CREATE TABLE `sequences` (
    -- table of sequence numbers system-wide
    -- this is the table that allocates the incrementors to you
    `id` int NOT NULL AUTO_INCREMENT,
    `sectionType` varchar(200) NOT NULL,
    `nextSequence` int NOT NULL,
    PRIMARY KEY (`id`),
    UNIQUE KEY `sectionType` (`sectionType`)
) ENGINE=InnoDB;
INSERT sequences(sectionType,nextSequence) values ('devices',1); -- this is the focus
INSERT sequences(sectionType,nextSequence) values ('plutoSerialNum',1); -- not this
INSERT sequences(sectionType,nextSequence) values ('nextOtherThing',1); -- not this
-- the other ones are conceptuals for multi-use of a sequence table

Stored Proc: uspGetNextSequence

DROP PROCEDURE IF EXISTS uspGetNextSequence;
DELIMITER $$
CREATE PROCEDURE uspGetNextSequence(p_sectionType varchar(200))
BEGIN
    -- a stored proc to manage next sequence numbers handed to you.
    -- driven by the simple concept of a name. So we call it a section type.
    -- uses SAFE INNODB Intention Locks to support concurrency
    DECLARE valToUse INT;

    START TRANSACTION;
    SELECT nextSequence into valToUse from sequences where sectionType=p_sectionType FOR UPDATE;
    IF valToUse is null THEN
        SET valToUse=-1;
    END IF;
    UPDATE sequences set nextSequence=nextSequence+1 where sectionType=p_sectionType;
    COMMIT; -- get it and release INTENTION LOCK ASAP
    SELECT valToUse as yourSeqNum; -- return as a 1 column, 1 row resultset
END$$
DELIMITER ;
-- ****************************************************************************************
-- test:
call uspGetNextSequence('devices'); -- your section is 'devices'

After you call uspGetNextSequence() it is your RESPONSIBILITY to ensure that that sequence #

is either added into myTable (by confirming it), or that if it fails, you insert it into

the reuse table with a call to uspAddToReuseList(). Not all inserts succeed. Focus on this part.

Because with this code you cannot "put" it back into the sequences table because of

concurrency, other users, and the range already passed by. So, simply, if the insert fails,

put the number into reuseMe via uspAddToReuseList()

. . .

Stored Proc: uspAddToReuseList:

DROP PROCEDURE IF EXISTS uspAddToReuseList;
DELIMITER $$
CREATE PROCEDURE uspAddToReuseList(p_reuseNum INT)
BEGIN
    -- a stored proc to insert a sequence num into the reuse list
    -- marks it available for reuse (a status column called `reused`)
    INSERT reuseMe(seqNum,reused) SELECT p_reuseNum,0; -- 0 means it is avail, 1 not
END$$
DELIMITER ;
-- ****************************************************************************************
-- test:
call uspAddToReuseList(701); -- 701 needs to be reused

Stored Proc: uspGetOneToReuse:

DROP PROCEDURE IF EXISTS uspGetOneToReuse;
DELIMITER $$
CREATE PROCEDURE uspGetOneToReuse()
BEGIN
    -- a stored proc to get an available sequence num for reuse
    -- a return of -1 means there aren't any
    -- the slot will be marked as reused, the row will remain
    DECLARE retNum int; -- the seq number to return, to reuse, -1 means there isn't one

    START TRANSACTION;

    -- it is important that 0 or 1 rows hit the following condition
    -- also note that FOR UPDATE is the innodb Intention Lock
    -- The lock is for concurrency (multiple users at once)
    SELECT seqNum INTO retNum 
    FROM reuseMe WHERE reused=0 ORDER BY seqNum LIMIT 1 FOR UPDATE;

    IF retNum is null THEN
        SET retNum=-1;
    ELSE 
        UPDATE reuseMe SET reused=1 WHERE seqNum=retNum; -- slot used
    END IF;
    COMMIT; -- release INTENTION LOCK ASAP

    SELECT retNum as yoursToReuse; -- >0 or -1 means there is none
END$$
DELIMITER ;
-- ****************************************************************************************
-- test:
call uspGetOneToReuse();

Stored Proc: uspCleanReuseList:

DROP PROCEDURE IF EXISTS uspCleanReuseList;
DELIMITER $$
CREATE PROCEDURE uspCleanReuseList()
BEGIN
    -- a stored proc to remove rows that have been successfully reused
    DELETE FROM reuseMe where reused=1;
END$$
DELIMITER ;
-- ****************************************************************************************
-- test:
call uspCleanReuseList();

Stored Proc: uspOoopsResetToAvail:

DROP PROCEDURE IF EXISTS uspOoopsResetToAvail;
DELIMITER $$
CREATE PROCEDURE uspOoopsResetToAvail(p_reuseNum INT)
BEGIN
    -- a stored proc to deal with a reuse attempt (sent back to you)
    -- that you need to reset the number as still available, 
    -- perhaps because of a failed INSERT when trying to reuse it
    UPDATE reuseMe SET reused=0 WHERE seqNum=p_reuseNum;
END$$
DELIMITER ;
-- ****************************************************************************************
-- test:
call uspOoopsResetToAvail(701);

Workflow ideas:

Let GNS mean a call to uspGetNextSequence().

Let RS mean Reuse Sequence via a call to uspGetOneToReuse()

When a new INSERTis desired, call RS:

A. If RS returns -1 then nothing is to be reused so call GNS which returns N. If you can successfully INSERT with myTable.seqNum=N with a confirm, you are done. If you cannot successfully INSERT it, then call uspAddToReuseList(N).

B. If RS returns > 0, note in your head that slot has reuseMe.reused=1, a good thing to remember. So it is assumed to be in the process of being successfully reused. Let's call that sequence number N. If you can successfully INSERT with myTable.seqNum=N with a confirm, you are done. If you cannot successfully INSERT it, then call uspOoopsResetToAvail(N).

When you deem it safe to call uspCleanReuseList() do so. Adding a DATETIME to the reuseMe table might be a good idea, denoting when a row from myTable was orignally deleting and causing the reuseMe row to get its original INSERT.

Drew
  • 24,851
  • 10
  • 43
  • 78
  • I will look at this more tomorrow when I have a more clear mind but it looks like what I need. – Ken Sep 10 '16 at 05:28