Sorting issue when meet there is ASCII

  • Hi there, I am facing a sorting issue explained as below and looking for help please,

    Result from first query,

    Select part_code from s_stkmst

    WHERE part_code>='RKS0516'

    ORDER BY part_code collate SQL_Latin1_General_Cp1251_CS_AS

    RKS0516-W

    RKS0516-W-Z

    RKS0516A-W

    RKS0516A-W-Z

    RKS0530-A

    RKS0530-A-SP

    RKS0530-A-Z

    RKS0530-A1

    Result from second query,

    Select part_code from s_stkmst

    WHERE part_code>='RKS0516-W'

    ORDER BY part_code collate SQL_Latin1_General_Cp1251_CS_AS

    RKS0516-W

    RKS0516-W-Z

    RKS0530-A

    RKS0530-A-SP

    RKS0530-A-Z

    RKS0530-A1

    The second result from the query is missing 2 records 'RKS0516A-W' and 'RKS0516A-W-Z'. I had tries other collate and couldn't get it right.

    Together, we can make wonders!
  • That'll be because "A" comes after "-" in SQL_Latin1_General_Cp1251_CS_AS and all the other collations you've tried. Here's a few options I can think of:

    (1) Find a collation that has "-" after all the alphanumeric characters

    (2) Change your database design so that you store the separate parts of your codes in separate columns

    (3) Use a string splitter (search this site to find one) to split your codes into their separate parts before you do your ORDER BY

    (4) Use REPLACE to replace "-" with some other character that comes after all alphanumeric characters in the collation and that does not appear in any of the codes. Replace that character with "-" again once you've done your sorting.

    (5) Use a more generalised form of the query to make sure you return all the data you need and then have your presentation layer do the customised sorting and filtering

    John

    Edit: added option 5

  • John Mitchell-245523 (7/25/2013)


    That'll be because "A" comes after "-" in SQL_Latin1_General_Cp1251_CS_AS and all the other collations you've tried. Here's a few options I can think of:

    (1) Find a collation that has "-" after all the alphanumeric characters

    (2) Change your database design so that you store the separate parts of your codes in separate columns

    (3) Use a string splitter (search this site to find one) to split your codes into their separate parts before you do your ORDER BY

    (4) Use REPLACE to replace "-" with some other character that comes after all alphanumeric characters in the collation and that does not appear in any of the codes. Replace that character with "-" again once you've done your sorting.

    (5) Use a more generalised form of the query to make sure you return all the data you need and then have your presentation layer do the customised sorting and filtering

    John

    Edit: added option 5

    Thank you so much for your fast reply.

    Certainly, option 2 is not possible because it may affect system design. I had found a similar example in this forum as your option 4 as below but result is the same,

    SELECT part_code,

    REPLACE(REPLACE(part_code,'-',' Z'),' ',' ')

    FROM s_stkmst

    WHERE part_code >= 'RKS0516-W'

    ORDER BY REPLACE(REPLACE(part_code,'-',' Z'),' ',' ') collate SQL_Latin1_General_Cp1251_CS_AS

    Together, we can make wonders!
  • I think this is because you're putting a space before your "Z". And the outer REPLACE doesn't do anything - it just replaces a space with a space.

    John

  • John Mitchell-245523 (7/25/2013)


    I think this is because you're putting a space before your "Z". And the outer REPLACE doesn't do anything - it just replaces a space with a space.

    John

    I have tried and playing around the REPLACE but no luck. Can you please show an example of how to resolve this scenario? TQ

    Together, we can make wonders!
  • If removing the space before the Z doesn't do it, please post table DDL in the form of CREATE TABLE statements, sample data in the form of INSERT statements, and the results you expect to see given the sample data.

    John

  • John Mitchell-245523 (7/25/2013)


    If removing the space before the Z doesn't do it, please post table DDL in the form of CREATE TABLE statements, sample data in the form of INSERT statements, and the results you expect to see given the sample data.

    John

    Hi John,

    Thanks again.

    I reproduce the scenario from same SQL 2008 R2 server and here below is as per your request,

    CREATE TABLE [dbo].[A_Test] (

    [part_code] varchar(50) COLLATE Chinese_PRC_Stroke_90_CI_AS NOT NULL

    )

    ON [PRIMARY]

    GO

    INSERT INTO [dbo].[A_Test] ([part_code])

    VALUES (N'RKS0516-W')

    GO

    INSERT INTO [dbo].[A_Test] ([part_code])

    VALUES (N'RKS0516-W-Z')

    GO

    INSERT INTO [dbo].[A_Test] ([part_code])

    VALUES (N'RKS0516A-W')

    GO

    INSERT INTO [dbo].[A_Test] ([part_code])

    VALUES (N'RKS0516A-W-Z')

    GO

    INSERT INTO [dbo].[A_Test] ([part_code])

    VALUES (N'RKS0530-A')

    GO

    INSERT INTO [dbo].[A_Test] ([part_code])

    VALUES (N'RKS0530-A-SP')

    GO

    1) Result from this query is correct,

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

    Select part_code,

    from A_Test

    WHERE part_code>='RKS0516'

    ORDER BY part_code collate SQL_Latin1_General_Cp437_BIN

    RKS0516-W

    RKS0516-W-Z

    RKS0516A-W

    RKS0516A-W-Z

    RKS0530-A

    RKS0530-A-SP

    But, when I change the filter value from 'RKS0516' to 'RKS0516-W', the result shows missing of 2 records

    RKS0516-W

    RKS0516-W-Z

    RKS0530-A

    RKS0530-A-SP

    I am expecting the result should like the first query.

    Together, we can make wonders!
  • OK, you seem to have changed your collation, so here's what to do in general:

    (1) Go on to Wikipedia and search for "code page xxxx" where xxxx is the three or four digits that follow "Cp" in the name of the collation you are using. You'll come to a page like this.

    (2) Find a character in the character set that comes after every character that is used in your part_code.

    (3) Replace "-" in your part_codes with that character. Do that with a REPLACE function similar to the inner REPLACE you used before, but with the new character instead of Z and without a space before it. Put the REPLACE on both sides of the ">=". You don't need the outer REPLACE that you tried in your previous example.

    (4) You should end up with something like this:

    Select part_code

    from A_Test

    WHERE REPLACE(part_code,'-','~') COLLATE SQL_Latin1_General_Cp437_BIN >= REPLACE('RKS0516','-','~') COLLATE SQL_Latin1_General_Cp437_BIN

    ORDER BY part_code collate SQL_Latin1_General_Cp437_BIN

    John

  • John, sorry for the confusion. I was trying many ways and mixed up the original code page I posted initially. Thanks for your tips and I will try it.

    Together, we can make wonders!
  • Seems like this works for me so far,

    Select part_code, REPLACE(part_code,'-','#')

    from A_Test

    WHERE REPLACE(part_code,'-','#') COLLATE SQL_Latin1_General_Cp437_BIN >= REPLACE('RKS0516-W-Z','-','#') COLLATE SQL_Latin1_General_Cp437_BIN

    ORDER BY REPLACE(part_code,'-','#') collate SQL_Latin1_General_Cp437_BIN

    Thanks John

    Together, we can make wonders!

Viewing 10 posts - 1 through 9 (of 9 total)

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