Increment a string

  • Comments posted to this topic are about the item Increment a string

  • How do you plan on handling when you need to increment 'ZZ'?

    Toni

  • Here is a stab at this issue as a function. If you pad the input with your zero symbol, you will get padded output, but it will grow the "number" beyond the bounds of the padding up to the length defined for the @Ticket input. Thus, 'ZZ' in returns '100' while '00ZZ' in returns '0100'.

    CREATE FUNCTION dbo.NextTicket( @Ticket VARCHAR(128) ) RETURNS VARCHAR(128) AS

    BEGIN

    DECLARE @digits TABLE( value INT IDENTITY(0,1) NOT NULL PRIMARY KEY, symbol CHAR(1) NOT NULL UNIQUE );

    DECLARE @place INT, @zero_digit CHAR(1), @highest_digit CHAR(1);

    -- 1. build a table of symbols that compose the "digits" of our ticket numbers

    -- Note that you could impose artifical order, it just happens that sorting by

    -- the value gives me the order I want.

    INSERT INTO @digits ( symbol )

    SELECT ch

    FROM (

    SELECT '0' AS ch UNION SELECT '1' UNION SELECT '2' UNION SELECT '3' UNION SELECT '4' UNION SELECT '5'

    UNION SELECT '6' UNION SELECT '7' UNION SELECT '8' UNION SELECT '9' UNION SELECT 'A' UNION SELECT 'B'

    UNION SELECT 'C' UNION SELECT 'D' UNION SELECT 'E' UNION SELECT 'F' UNION SELECT 'G' UNION SELECT 'H'

    UNION SELECT 'I' UNION SELECT 'J' UNION SELECT 'K' UNION SELECT 'L' UNION SELECT 'M' UNION SELECT 'N'

    UNION SELECT 'O' UNION SELECT 'P' UNION SELECT 'Q' UNION SELECT 'R' UNION SELECT 'S' UNION SELECT 'T'

    UNION SELECT 'U' UNION SELECT 'V' UNION SELECT 'W' UNION SELECT 'X' UNION SELECT 'Y' UNION SELECT 'Z'

    ) AS symbols

    ORDER BY ch ASC;

    SELECT @zero_digit = symbol FROM @digits WHERE value = 0;

    SELECT TOP 1 @highest_digit = symbol FROM @digits ORDER BY value DESC;

    -- 2. assume valid input (functions can't throw errors) -----------------------

    SET @Ticket = RTRIM(LTRIM(@Ticket));

    -- 3. carry the 1 -------------------------------------------------------------

    SET @place = LEN(@Ticket);

    WHILE @place > 0 AND SUBSTRING(@Ticket, @place, 1) = @highest_digit

    BEGIN

    SET @Ticket = STUFF(@Ticket, @place, 1, @zero_digit);

    SET @place = @place -1;

    END

    -- 4. final increment ---------------------------------------------------------

    IF @place = 0 BEGIN

    DECLARE @one_digit CHAR(1), @length INT;

    SELECT @one_digit = symbol FROM @digits WHERE value = 1;

    SET @length = LEN(@Ticket);

    SET @Ticket = @one_digit + @Ticket; -- if this overflows, it will truncate the right most "digit"

    IF @length = LEN(@Ticket) -- still the same length only if overflowed...

    SET @Ticket = REPLICATE(@zero_digit, @length); -- roll over back to zero

    END ELSE BEGIN

    DECLARE @next_digit CHAR(1);

    SET @next_digit = (

    SELECT symbol FROM @digits WHERE value = (

    SELECT value +1 FROM @digits WHERE symbol = SUBSTRING(@Ticket, @place, 1)));

    SET @Ticket = STUFF(@Ticket, @place, 1, @next_digit);

    END

    -- 5. Return the new Ticket number

    RETURN @Ticket;

    END

  • Hi Dennis. Interesting way to carry the digits. I had done another one that had a fixed length for the string to be increment (e.g. 2 chars). If overflow occurred, it returns '**' (the pseudo-standard overflow chars) or if any invalid characters (not in the set of incrementable characters) were passed, a

    '--' is returned.

    The function I built used strings and indexes into them versus creating and working through a table. In a simple comparison from using the below statements while executing the code within your and my functions, not using a table yields much better performance (particularly if the function were invoked with any regularity).

    DBCC DROPCLEANBUFFERS

    GO

    SET STATISTICS IO ON

    SET STATISTICS TIME ON

    -----------------------------------------------------------------------------------------

    RESULTS Elapsed | Statements Run | Logical Read | Scans | CPU

    -----------------------------------------------------------------------------------------

    Using table 126 ms | 23 | 118 | 4 | 48

    Using string 0 ms | 11 | 0 | 0 | 0

    The function I created is here:

    /* Remove any prior version of function */

    IF EXISTS (SELECT * FROM dbo.sysobjects WHERE id = OBJECT_ID(N'[dbo].[fn_NextSerial]')

    AND xtype IN (N'FN', N'IF', N'TF'))

    DROP FUNCTION [dbo].[fn_NextSerial]

    GO

    CREATE FUNCTION fn_NextSerial (@currentboth CHAR(2))

    RETURNS char(2)

    AS

    /* Given the current value of a two-character string (@currentboth),

    return the next higher value based on the string of valid chars (@alphas)

    Example: fn_NextSerial('AZ') will return 'BA'

    Note: If the string can not be incremented any further, '**' is returned

    If the string contains invalid characters, '--' is returned

    */

    BEGIN

    DECLARE @alphas CHAR(36) -- valid alpha values (length must match that of string assigned below)

    SET @alphas = '0123456789ABCDEFGHIJKLMNOPQRSTUVWXYZ' -- valid chars for incrementing string

    DECLARE @current1 INT -- index in valid alpha values of 1st char in string

    DECLARE @current2 INT -- index in valid alpha values of 2nd char in string

    SET @current1 = CHARINDEX(SUBSTRING(@currentboth,1,1),@alphas)

    SET @current2 = CHARINDEX(SUBSTRING(@currentboth,2,1),@alphas)

    /* If any invalid or null input, return '--' */

    IF @current1 = 0 OR @current2 = 0 OR @currentboth IS NULL

    SET @currentboth = '--'

    ELSE

    BEGIN

    IF @current2 = LEN(@alphas) -- Is the 2nd char at the last valid string position?

    BEGIN

    IF @current1 <> LEN(@alphas) -- Can the 1st char still be incremented?

    BEGIN

    /* Increment the 1st char position and set the 2nd char to starting char */

    SET @currentboth = SUBSTRING(@alphas,(@current1+1),1)+

    SUBSTRING(@alphas,1,1)

    END

    ELSE

    SET @currentboth = '**' -- return '**' to show no more incrementing possible

    END

    ELSE

    /* Leave 1st char unchanged and increment the 2nd char of the string */

    SET @currentboth= SUBSTRING(@currentboth,1,1) + SUBSTRING(@alphas,@current2+1,1)

    END

    RETURN @currentboth -- return the next value or

    -- '**' if already at highest value or

    -- '--' if invalid chars passed

    END

    GO

    Select 'Next after 00 is:' + dbo.fn_NextSerial('00') -- '01'

    Select 'Next after 0Y is:' + dbo.fn_NextSerial('0Y') -- '0Z'

    Select 'Next after 0Z is:' + dbo.fn_NextSerial('0Z') -- '10'

    Select 'Next after ZY is:' + dbo.fn_NextSerial('ZY') -- 'ZZ'

    Select 'Next after ZZ is:' + dbo.fn_NextSerial('ZZ') -- '**'

    Select 'Next after '' Z'' is:' + dbo.fn_NextSerial(' Z') -- '--'

    Select 'Next after @0 is:' + dbo.fn_NextSerial('@0') -- '--'

    Select 'Next after A$ is:' + dbo.fn_NextSerial('A$') -- '--'

    Select 'Next after null is:' + dbo.fn_NextSerial(NULL) -- '--'

    I modified your function to use the string and it brought the usage back comparable to what my function had achieved for CPU, IO and elapsed time. The statements that were changed are commented out and the replacements are right next to them.

    If you would want to adopt returning a '**' for overflow or '--' for invalid chars, then you could use code similar to the checks in mine. Here is the heart of your function (my interpretation) using the string versus a table:

    --DBCC DROPCLEANBUFFERS -- clear the buffers

    --go

    /* Prep as if we are calling the function */

    declare @Ticket varchar(128)

    set statistics io on

    set statistics time on

    set @Ticket = 'ZZZ' -- change this and rerun to test different cases

    select 'Input is ' + @Ticket

    /* Invoke the statements from the body of the function */

    -- DECLARE @digits TABLE( value INT IDENTITY(0,1) NOT NULL PRIMARY KEY, symbol CHAR(1) NOT NULL UNIQUE );

    DECLARE @place INT, @zero_digit CHAR(1), @highest_digit CHAR(1);

    -- 1. build a table of symbols that compose the "digits" of our ticket numbers

    -- Note that you could impose artifical order, it just happens that sorting by

    -- the value gives me the order I want.

    /* INSERT INTO @digits ( symbol )

    SELECT ch

    FROM (

    SELECT '0' AS ch UNION SELECT '1' UNION SELECT '2' UNION SELECT '3' UNION SELECT '4' UNION SELECT '5'

    UNION SELECT '6' UNION SELECT '7' UNION SELECT '8' UNION SELECT '9' UNION SELECT 'A' UNION SELECT 'B'

    UNION SELECT 'C' UNION SELECT 'D' UNION SELECT 'E' UNION SELECT 'F' UNION SELECT 'G' UNION SELECT 'H'

    UNION SELECT 'I' UNION SELECT 'J' UNION SELECT 'K' UNION SELECT 'L' UNION SELECT 'M' UNION SELECT 'N'

    UNION SELECT 'O' UNION SELECT 'P' UNION SELECT 'Q' UNION SELECT 'R' UNION SELECT 'S' UNION SELECT 'T'

    UNION SELECT 'U' UNION SELECT 'V' UNION SELECT 'W' UNION SELECT 'X' UNION SELECT 'Y' UNION SELECT 'Z'

    ) AS symbols

    ORDER BY ch ASC;

    */

    DECLARE @digits CHAR(36) -- valid alpha values (length must match that of string assigned below)

    SET @digits = '0123456789ABCDEFGHIJKLMNOPQRSTUVWXYZ' -- valid chars for incrementing string

    -- SELECT @zero_digit = symbol FROM @digits WHERE value = 0;

    SET @zero_digit = SUBSTRING(@digits,1,1)

    -- SELECT TOP 1 @highest_digit = symbol FROM @digits ORDER BY value DESC;

    SET @highest_digit = SUBSTRING(@digits,LEN(@digits),1)

    -- 2. assume valid input (functions can't throw errors) -----------------------

    SET @Ticket = RTRIM(LTRIM(@Ticket));

    -- 3. carry the 1 -------------------------------------------------------------

    SET @place = LEN(@Ticket);

    WHILE @place > 0 AND SUBSTRING(@Ticket, @place, 1) = @highest_digit

    BEGIN

    SET @Ticket = STUFF(@Ticket, @place, 1, @zero_digit);

    SET @place = @place -1;

    END

    -- 4. final increment ---------------------------------------------------------

    IF @place = 0 BEGIN

    DECLARE @one_digit CHAR(1), @length INT;

    -- SELECT @one_digit = symbol FROM @digits WHERE value = 1;

    SET @one_digit = SUBSTRING(@digits,2,1)

    SET @length = LEN(@Ticket);

    SET @Ticket = @one_digit + @Ticket; -- if this overflows, it will truncate the right most "digit"

    IF @length = LEN(@Ticket) -- still the same length only if overflowed...

    SET @Ticket = REPLICATE(@zero_digit, @length); -- roll over back to zero

    END

    ELSE BEGIN

    DECLARE @next_digit CHAR(1);

    --SET @next_digit =

    -- (SELECT symbol FROM @digits WHERE value = (

    -- SELECT value +1 FROM @digits WHERE symbol = SUBSTRING(@Ticket, @place, 1)));

    SET @next_digit =

    SUBSTRING(@digits,CHARINDEX(SUBSTRING(@Ticket,@place,1),@digits)+1,1)

    SET @Ticket = STUFF(@Ticket, @place, 1, @next_digit);

    END

    /* Put out the result */

    select 'Answer is ' + @Ticket

    set statistics io off

    set statistics time off

    Toni

  • Nice, pulling out the table is a big improvement. In looking at that, I was thinking about doing more than just adding one. So I created an addition function that allows upto 128 digit numbers in base 36, and then a separate function to constrain it to ZZ max value for Tickets.

    Your solution still beats mine (4ms on my test machine verses 9ms for my solution).

    Function for base36 addition

    ALTER FUNCTION dbo.Base36Add( @value1 varchar(128), @value2 varchar(128) ) RETURNS varchar(128) AS

    BEGIN

    DECLARE @digits char(36); SET @digits = '0123456789ABCDEFGHIJKLMNOPQRSTUVWXYZ';

    DECLARE @sum varchar(16), @i int, @s-2 int, @d1 int, @d2 int, @r int;

    -- 1. null values are invalid -------------------------------------------------

    IF @value1 IS NULL OR @value2 IS NULL

    GOTO Exit_Error;

    -- 2. pad so they are the same length -----------------------------------------

    IF len(@value1) < len(@value2)

    SET @value1 = replicate( substring(@digits,1,1), len(@value2)-len(@value1) ) + @value1;

    ELSE IF len(@value2) < len(@value1)

    SET @value2 = replicate( substring(@digits,1,1), len(@value1)-len(@value2) ) + @value2;

    -- 3. sum and carry -----------------------------------------------------------

    SELECT

    @sum = '', /* init string for prepending */

    @i = len(@value1), /* start at least signifigant place */

    @r = 0; /* start with no remainder */

    WHILE 0 < @i BEGIN /* for each place */

    -- a. convert the sum of the remainder plus the current place in both values to an integer

    SELECT

    @d1 = charindex( substring(@value1,@i,1), @digits ) - 1,

    @d2 = charindex( substring(@value2,@i,1), @digits ) - 1;

    IF (coalesce(@d1,-1) = -1 OR coalesce(@d2,-1) = -1)

    GOTO Exit_Error;

    SET @s-2 = @r + @d1 + @d2;

    -- b. find the resulting total for this place

    SET @sum = substring(@digits, (@s % 36) + 1, 1)

    + @sum;

    -- c. find the remainder to carry forward

    SET @r = (@s / 36);

    -- d. next place...

    SET @i = @i - 1;

    END

    -- 4. final remainder?

    IF 0 < @r BEGIN

    IF len(@sum) < 128 /* defined return value size */

    SET @sum = substring(@digits, @r + 1, 1) + @sum;

    ELSE

    SET @sum = '**'; /* overflow */

    END

    Exit_Success:

    RETURN @sum;

    Exit_Error:

    RETURN '--'; /* invalid input */

    END

    Function to constrict Ticket numbers to 00 through ZZ (0 to 1296)

    CREATE FUNCTION [dbo].[NextTicket]( @Ticket varchar(2) ) RETURNS varchar(2) AS

    BEGIN

    IF @Ticket = 'ZZ'

    RETURN '**';

    RETURN dbo.Base36Add( @Ticket, '1' );

    END

    Test queries for timing

    SELECT

    dbo.NextTicket('00') AS Expect_01,

    dbo.NextTicket('0Y') AS Expect_0Z,

    dbo.NextTicket('0Z') AS Expect_10,

    dbo.NextTicket('ZY') AS Expect_ZZ,

    dbo.NextTicket('ZZ') AS Expect_Overflow,

    dbo.NextTicket(' Z') AS Expect_Invalid_01,

    dbo.NextTicket('@0') AS Expect_Invalid_02,

    dbo.NextTicket('A$') AS Expect_Invalid_03,

    dbo.NextTicket(NULL) AS Expect_Invalid_04

    SELECT

    dbo.fn_NextSerial('00') AS Expect_01,

    dbo.fn_NextSerial('0Y') AS Expect_0Z,

    dbo.fn_NextSerial('0Z') AS Expect_10,

    dbo.fn_NextSerial('ZY') AS Expect_ZZ,

    dbo.fn_NextSerial('ZZ') AS Expect_Overflow,

    dbo.fn_NextSerial(' Z') AS Expect_Invalid_01,

    dbo.fn_NextSerial('@0') AS Expect_Invalid_02,

    dbo.fn_NextSerial('A$') AS Expect_Invalid_03,

    dbo.fn_NextSerial(NULL) AS Expect_Invalid_04

Viewing 5 posts - 1 through 4 (of 4 total)

You must be logged in to reply to this topic. Login to reply