Query to increment an alpha character suffix

  • Need some help from the TSQL gurus. The situation is that given data in the column a table, data in another column of another table needs incremented by an alpha character. For example, if 12345 is in ColA of TblA and 12345 is in ColB of TblB, then append A to ColB in TblB. However, there's a date field in TblB that determines whether alpha character suffix in ColB should be incremented further. Ultimately, these are PO numbers, but the exact situation I don't think is relevant.

    CREATE TABLE #PONUMBERTEST (PONUMBER VARCHAR(MAX))

    INSERT INTO #PONUMBERTEST
    SELECT '12345'
    UNION
    SELECT '12345A'

    CREATE TABLE #PONUMBERTESTIMPORT (PONUMBER VARCHAR(MAX),PODATE DATE)

    INSERT INTO #PONUMBERTESTIMPORT
    SELECT '12345','20180224'
    UNION
    SELECT '12345','20180225'
    UNION
    SELECT '12345','20180226'

    SELECT * FROM #PONUMBERTEST

    SELECT *,
        CASE
            WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER)=0 THEN PONUMBER
            WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'A')=0 THEN PONUMBER+'A'
            WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'B')=0 THEN PONUMBER+'B'
            WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'C')=0 THEN PONUMBER+'C'
            WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'D')=0 THEN PONUMBER+'D'
            WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'E')=0 THEN PONUMBER+'E'
            WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'F')=0 THEN PONUMBER+'F'
            WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'G')=0 THEN PONUMBER+'G'
        END PONUMBERTOUSE
    FROM #PONUMBERTESTIMPORT A

    Results of the above gives 3 rows:

    12345    2018-02-24    12345B
    12345    2018-02-25    12345B
    12345    2018-02-26    12345B

    The results should be as below since the dates are different:

    12345 2018-02-24 12345B
    12345 2018-02-25 12345C
    12345 2018-02-26 12345D

    If 2nd row was 2-24, then the results should be as follows (with the 3rd column being the same for rows 1 and 2):

    12345 2018-02-24 12345B
    12345 2018-02-24 12345B
    12345 2018-02-26 12345C

    Any help would be much appreciated.

  • lbrigham - Monday, February 26, 2018 12:56 PM

    Need some help from the TSQL gurus. The situation is that given data in the column a table, data in another column of another table needs incremented by an alpha character. For example, if 12345 is in ColA of TblA and 12345 is in ColB of TblB, then append A to ColB in TblB. However, there's a date field in TblB that determines whether alpha character suffix in ColB should be incremented further. Ultimately, these are PO numbers, but the exact situation I don't think is relevant.

    CREATE TABLE #PONUMBERTEST (PONUMBER VARCHAR(MAX))

    INSERT INTO #PONUMBERTEST
    SELECT '12345'
    UNION
    SELECT '12345A'

    CREATE TABLE #PONUMBERTESTIMPORT (PONUMBER VARCHAR(MAX),PODATE DATE)

    INSERT INTO #PONUMBERTESTIMPORT
    SELECT '12345','20180224'
    UNION
    SELECT '12345','20180225'
    UNION
    SELECT '12345','20180226'

    SELECT * FROM #PONUMBERTEST

    SELECT *,
        CASE
            WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER)=0 THEN PONUMBER
            WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'A')=0 THEN PONUMBER+'A'
            WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'B')=0 THEN PONUMBER+'B'
            WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'C')=0 THEN PONUMBER+'C'
            WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'D')=0 THEN PONUMBER+'D'
            WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'E')=0 THEN PONUMBER+'E'
            WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'F')=0 THEN PONUMBER+'F'
            WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'G')=0 THEN PONUMBER+'G'
        END PONUMBERTOUSE
    FROM #PONUMBERTESTIMPORT A

    Results of the above gives 3 rows:

    12345    2018-02-24    12345B
    12345    2018-02-25    12345B
    12345    2018-02-26    12345B

    The results should be as below since the dates are different:

    12345 2018-02-24 12345B
    12345 2018-02-25 12345C
    12345 2018-02-26 12345D

    If 2nd row was 2-24, then the results should be as follows (with the 3rd column being the same for rows 1 and 2):

    12345 2018-02-24 12345B
    12345 2018-02-24 12345B
    12345 2018-02-26 12345C

    Any help would be much appreciated.

    Have you tried working with RANK()?

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • Yeah, I think that's it. Well, using DENSE_RANK() to handle date ties along with CHAR() + 64 to convert results of DENSE_RANK from numeric to alpha equivalent starting with A. Thanks for pointing me in this direction. For some reason hadn't thought of that. This is what I have now (main query from above) and seems to handle the scenarios I've thrown at it:

    SELECT *,
      CASE
       WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER)=0 THEN PONUMBER
       WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'A')=0 THEN PONUMBER+char(DENSE_RANK() OVER (PARTITION BY PONUMBER ORDER BY PODATE) + 64)
       WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'B')=0 THEN PONUMBER+char((DENSE_RANK() OVER (PARTITION BY PONUMBER ORDER BY PODATE) + 1) + 64)
       WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'C')=0 THEN PONUMBER+char((DENSE_RANK() OVER (PARTITION BY PONUMBER ORDER BY PODATE) + 2) + 64)
       WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'D')=0 THEN PONUMBER+char((DENSE_RANK() OVER (PARTITION BY PONUMBER ORDER BY PODATE) + 3) + 64)
       WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'E')=0 THEN PONUMBER+char((DENSE_RANK() OVER (PARTITION BY PONUMBER ORDER BY PODATE) + 4) + 64)
       WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'F')=0 THEN PONUMBER+char((DENSE_RANK() OVER (PARTITION BY PONUMBER ORDER BY PODATE) + 5) + 64)
       WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'G')=0 THEN PONUMBER+char((DENSE_RANK() OVER (PARTITION BY PONUMBER ORDER BY PODATE) + 6) + 64)
      END PONUMBERTOUSE
       ,DENSE_RANK() OVER (PARTITION BY PONUMBER ORDER BY PODATE) DenseRank
    FROM #PONUMBERTESTIMPORT A

  • On this small scale test, this solution performs better.  I haven't had a chance to test on a larger scale.


    SELECT *, pni.PONUMBER + REPLACE(CHAR(DENSE_RANK() OVER(PARTITION BY pni.PONUMBER ORDER BY PODATE) +
        CASE
            WHEN pn.PONumberSequence IS NULL THEN 63
            WHEN pn.PONumberSequence BETWEEN '0' AND '9' THEN 64
            ELSE ASCII(PONumberSequence)
        END), '@', '')
    FROM #PONUMBERTESTIMPORT pni
    OUTER APPLY
    (
        SELECT RIGHT(MAX(PONUMBER), 1)
        FROM #PONUMBERTEST pn
        WHERE pn.PONUMBER LIKE pni.PONUMBER + '%'
    ) pn(PONumberSequence)

    Drew

    J. Drew Allen
    Business Intelligence Analyst
    Philadelphia, PA

  • lbrigham - Monday, February 26, 2018 1:30 PM

    Yeah, I think that's it. Well, using DENSE_RANK() to handle date ties along with CHAR() + 64 to convert results of DENSE_RANK from numeric to alpha equivalent starting with A. Thanks for pointing me in this direction. For some reason hadn't thought of that. This is what I have now (main query from above) and seems to handle the scenarios I've thrown at it:

    SELECT *,
      CASE
       WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER)=0 THEN PONUMBER
       WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'A')=0 THEN PONUMBER+char(DENSE_RANK() OVER (PARTITION BY PONUMBER ORDER BY PODATE) + 64)
       WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'B')=0 THEN PONUMBER+char((DENSE_RANK() OVER (PARTITION BY PONUMBER ORDER BY PODATE) + 1) + 64)
       WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'C')=0 THEN PONUMBER+char((DENSE_RANK() OVER (PARTITION BY PONUMBER ORDER BY PODATE) + 2) + 64)
       WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'D')=0 THEN PONUMBER+char((DENSE_RANK() OVER (PARTITION BY PONUMBER ORDER BY PODATE) + 3) + 64)
       WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'E')=0 THEN PONUMBER+char((DENSE_RANK() OVER (PARTITION BY PONUMBER ORDER BY PODATE) + 4) + 64)
       WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'F')=0 THEN PONUMBER+char((DENSE_RANK() OVER (PARTITION BY PONUMBER ORDER BY PODATE) + 5) + 64)
       WHEN (SELECT COUNT(*) FROM #PONUMBERTEST WHERE PONUMBER=A.PONUMBER+'G')=0 THEN PONUMBER+char((DENSE_RANK() OVER (PARTITION BY PONUMBER ORDER BY PODATE) + 6) + 64)
      END PONUMBERTOUSE
       ,DENSE_RANK() OVER (PARTITION BY PONUMBER ORDER BY PODATE) DenseRank
    FROM #PONUMBERTESTIMPORT A

    Here's something that might be more efficient.

    SELECT *,
       A.PONUMBER
      + REPLACE( CHAR( ISNULL(ASCII((SELECT CASE WHEN RIGHT(MAX(T.PONUMBER), 1) LIKE '[0-9]' THEN '@' ELSE RIGHT(MAX(T.PONUMBER), 1) END
                         FROM #PONUMBERTEST AS T
                         WHERE T.PONUMBER LIKE A.PONUMBER + '%'
                         AND T.PONUMBER NOT LIKE A.PONUMBER + '[0-9]')), 63)
      + DENSE_RANK() OVER( PARTITION BY A.PONUMBER ORDER BY PODATE)), '@', '') PONUMBERTOUSE
    FROM #PONUMBERTESTIMPORT A

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • You guys are awesome. Thanks!

  • I prefer this alternative.  Not for performance reasons, mostly that it allows easier customization of the suffix chars to be assigned.  Sometimes certain chars, such as I and O, are skipped because they look too much like numbers.  Also, the logic below is clearer to me, although that could just be me.

    ;WITH cte_suffix_chars AS (
      SELECT 'ABCDEFGHIJKLMNOPQRSTUVWXYZ' AS suffix_chars
    )
    SELECT A.PONUMBER, A.PODATE,
      A.PONUMBER + SUBSTRING(suffix_chars, ISNULL(CHARINDEX(POSUFFIX, suffix_chars) + rank_num, 1), 1) AS PONUMBERTOUSE
    FROM (
      SELECT *, DENSE_RANK() OVER(PARTITION BY PONUMBER ORDER BY PODATE) AS rank_num
      FROM #PONUMBERTESTIMPORT
    ) AS A
    CROSS JOIN cte_suffix_chars
    LEFT OUTER JOIN (
      SELECT LEFT(PONUMBER, LEN(PONUMBER) - 1) AS PONUMBER, MAX(RIGHT(PONUMBER, 1)) AS POSUFFIX  
      FROM #PONUMBERTEST
      WHERE RIGHT(PONUMBER, 1) NOT LIKE '[0-9]'
      GROUP BY LEFT(PONUMBER, LEN(PONUMBER) - 1)
    ) AS T ON T.PONUMBER = A.PONUMBER

    SQL DBA,SQL Server MVP(07, 08, 09) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".

  • ScottPletcher - Monday, February 26, 2018 4:54 PM

    I prefer this alternative.  Not for performance reasons, mostly that it allows easier customization of the suffix chars to be assigned.  Sometimes certain chars, such as I and O, are skipped because they look too much like numbers.  Also, the logic below is clearer to me, although that could just be me.

    ;WITH cte_suffix_chars AS (
      SELECT 'ABCDEFGHIJKLMNOPQRSTUVWXYZ' AS suffix_chars
    )
    SELECT A.PONUMBER, A.PODATE,
      A.PONUMBER + SUBSTRING(suffix_chars, ISNULL(CHARINDEX(POSUFFIX, suffix_chars) + rank_num, 1), 1) AS PONUMBERTOUSE
    FROM (
      SELECT *, DENSE_RANK() OVER(PARTITION BY PONUMBER ORDER BY PODATE) AS rank_num
      FROM #PONUMBERTESTIMPORT
    ) AS A
    CROSS JOIN cte_suffix_chars
    LEFT OUTER JOIN (
      SELECT LEFT(PONUMBER, LEN(PONUMBER) - 1) AS PONUMBER, MAX(RIGHT(PONUMBER, 1)) AS POSUFFIX  
      FROM #PONUMBERTEST
      WHERE RIGHT(PONUMBER, 1) NOT LIKE '[0-9]'
      GROUP BY LEFT(PONUMBER, LEN(PONUMBER) - 1)
    ) AS T ON T.PONUMBER = A.PONUMBER

    I considered an approach similar to this, but decided to retain the as much of the original solution as possible while improving the functionality.

    Your group by in your subquery is wrong.  It will produce two groups from the data when it should only produce 1.

    Your query does not appear to handle situations where PONUMBERTEST does not already contain a suffix, i.e., when the table is empty or contains only '12345'.  It produces three rows with '12345A' in both cases, because you replace the null value AFTER adding the dense rank instead of before adding the dense rank.

    I also don't understand why you use a CTE for the constant suffix string instead of declaring a variable.

    I've rewritten your query to correct each of these issues.


    DECLARE @suffixes CHAR(26) = 'ABCDEFGHIJKLMNOPQRSTUVWXYZ';

    SELECT *, i.PONUMBER + SUBSTRING(@suffixes, DENSE_RANK() OVER(PARTITION BY i.PONUMBER ORDER BY i.PODATE) + ISNULL(n.BasePosition,-1), 1)
    FROM #PONUMBERTESTIMPORT i
    OUTER APPLY
    (
        SELECT CHARINDEX(RIGHT(MAX(PONUMBER), 1), @suffixes) AS BasePosition
        FROM #PONUMBERTEST n
        WHERE n.PONUMBER LIKE i.PONUMBER + '%'
    ) n

    Drew

    J. Drew Allen
    Business Intelligence Analyst
    Philadelphia, PA

  • I have a little more time today, corrected version below. 
    The cte is to (1) make it easier to use in a function and (2) to make it easier to pull from a permanent table -- this is not the kind of thing you'd want to have to recreate in multiple places in code in case it changed later.  If you want max performance, replace the cte with the static string
    ' ABCDEFGHIJKLMNOPQRSTUVWXYZ'.
    Btw, I believe your last version of the code will still add 'A' to the first non-suffixed entry.


    ;WITH cte_suffix_chars AS (
        SELECT ' ABCDEFGHIJKLMNOPQRSTUVWXYZ' AS suffix_chars
    )
    SELECT A.PONUMBER, A.PODATE,
        A.PONUMBER + RTRIM(SUBSTRING(suffix_chars, ISNULL(POSUFFIX_Byte, 0) + rank_num, 1)) AS PONUMBERTOUSE
    FROM (
        SELECT *, DENSE_RANK() OVER(PARTITION BY PONUMBER ORDER BY PODATE) AS rank_num
        FROM #PONUMBERTESTIMPORT
    ) AS A
    CROSS JOIN cte_suffix_chars
    LEFT OUTER JOIN (
        SELECT LEFT(PONUMBER, LEN(PONUMBER) - 1) AS PONUMBER,
              CHARINDEX(MAX(RIGHT(PONUMBER, 1)), MAX(suffix_chars)) AS POSUFFIX_Byte
        FROM #PONUMBERTEST
        CROSS JOIN cte_suffix_chars
        WHERE RIGHT(PONUMBER, 1) NOT LIKE '[0-9]'
        GROUP BY LEFT(PONUMBER, LEN(PONUMBER) - 1)
    ) AS T ON T.PONUMBER = A.PONUMBER

    SQL DBA,SQL Server MVP(07, 08, 09) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".

  • ScottPletcher - Tuesday, February 27, 2018 12:07 PM

    Btw, I believe your last version of the code will still add 'A' to the first non-suffixed entry.

    It actually doesn't.  SUBSTRING(<any string>, 0, 1) returns the empty string.  I tested it before posting.

    Drew

    J. Drew Allen
    Business Intelligence Analyst
    Philadelphia, PA

  • drew.allen - Tuesday, February 27, 2018 12:23 PM

    ScottPletcher - Tuesday, February 27, 2018 12:07 PM

    Btw, I believe your last version of the code will still add 'A' to the first non-suffixed entry.

    It actually doesn't.  SUBSTRING(<any string>, 0, 1) returns the empty string.  I tested it before posting.

    Drew

    I think that's just if there is no entry in the other table.  But if a non-suffixed the number is there, '12346', then it return 12345A for the first detail row.  I don't know the detailed requirements, so I'm not sure which is the correct method, but it's easy enough to adjust any code accordingly.

    SQL DBA,SQL Server MVP(07, 08, 09) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".

  • ScottPletcher - Tuesday, February 27, 2018 1:00 PM

    drew.allen - Tuesday, February 27, 2018 12:23 PM

    ScottPletcher - Tuesday, February 27, 2018 12:07 PM

    Btw, I believe your last version of the code will still add 'A' to the first non-suffixed entry.

    It actually doesn't.  SUBSTRING(<any string>, 0, 1) returns the empty string.  I tested it before posting.

    Drew

    I think that's just if there is no entry in the other table.  But if a non-suffixed the number is there, '12346', then it return 12345A for the first detail row.  I don't know the detailed requirements, so I'm not sure which is the correct method, but it's easy enough to adjust any code accordingly.

    I think that's what the OP wanted.

    For example, if 12345 is in ColA of TblA and 12345 is in ColB of TblB, then append A to ColB in TblB.

    Drew

    J. Drew Allen
    Business Intelligence Analyst
    Philadelphia, PA

Viewing 12 posts - 1 through 11 (of 11 total)

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