Grouping a String by everything other than the last numbers considering they exist

  • Hey Guys,

    Our database has Unique SKU's for each product, however when it comes to Jewelry every size needs its own SKU.

    Something along the following lines:

    1/2CT-RDHL-FGI1-AMD7

    1/2CT-RDHL-FGI1-AMD8

    1/2-FG-I1-ATT

    1/2PR-RNG-ATT-10

    1/2PR-RNG-ATT-5

    1/2PR-RNG-ATT-6

    1/2PR-RNG-ATT-7

    1/2PR-RNG-ATT-8

    1/2PR-RNG-ATT-9

    1/2RDSL-HISI2-AMD-5

    1/2RDSL-HISI2-AMD-6

    1CT-LDB-SRNG/10

    1CT-LDB-SRNG/11

    1CT-LDB-SRNG/5

    1CT-LDB-SRNG/6

    1CT-LDB-SRNG/7

    1CT-LDB-SRNG/8

    1CT-LDB-SRNG/9

    I'd like to tally the stock by each product so I'd like to Group the SKU's if they are the same besides the last charachters, where they are numbers.

    Resulting with something along the following lines:

    1/2CT-RDHL-FGI1-AMD

    1/2-FG-I1-ATT

    1/2PR-RNG-ATT

    1/2RDSL-HISI2-AMD

    1CT-LDB-SRNG

    Any help would be greatly appreciated??

  • As you're new to SSC, I'd like to suggest that to get better and faster help, it helps your helpers if you'll post DDL and consumable sample data like this:

    CREATE TABLE #Products (ID VARCHAR(100))

    INSERT INTO #Products

    SELECT '1/2CT-RDHL-FGI1-AMD7'

    UNION ALL SELECT '1/2CT-RDHL-FGI1-AMD8'

    UNION ALL SELECT '1/2-FG-I1-ATT'

    UNION ALL SELECT '1/2PR-RNG-ATT-10'

    UNION ALL SELECT '1/2PR-RNG-ATT-5'

    UNION ALL SELECT '1/2PR-RNG-ATT-6'

    UNION ALL SELECT '1/2PR-RNG-ATT-7'

    UNION ALL SELECT '1/2PR-RNG-ATT-8'

    UNION ALL SELECT '1/2PR-RNG-ATT-9'

    UNION ALL SELECT '1/2RDSL-HISI2-AMD-5'

    UNION ALL SELECT '1/2RDSL-HISI2-AMD-6'

    UNION ALL SELECT '1CT-LDB-SRNG/10'

    UNION ALL SELECT '1CT-LDB-SRNG/11'

    UNION ALL SELECT '1CT-LDB-SRNG/5'

    UNION ALL SELECT '1CT-LDB-SRNG/6'

    UNION ALL SELECT '1CT-LDB-SRNG/7'

    UNION ALL SELECT '1CT-LDB-SRNG/8'

    UNION ALL SELECT '1CT-LDB-SRNG/9'

    This makes it much easier for us volunteers to focus on possible solutions, such as this one:

    SELECT [NewID]

    FROM #Products

    CROSS APPLY (

    SELECT LEFT(ID, 1+LEN(ID)-PATINDEX('%[A-Za-z]%', REVERSE(ID)))) a([NewID])

    GROUP BY [NewID]

    DROP TABLE #Products


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

  • Thanks Dwain,

    That was perfect.

    I really appreciate your help.

Viewing 3 posts - 1 through 2 (of 2 total)

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