SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


sort by serialcode


sort by serialcode

Author
Message
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (84K reputation)SSC Guru (84K reputation)SSC Guru (84K reputation)SSC Guru (84K reputation)SSC Guru (84K reputation)SSC Guru (84K reputation)SSC Guru (84K reputation)SSC Guru (84K reputation)

Group: General Forum Members
Points: 84677 Visits: 41069
The following will handle more levels than you can shake a stick at with numbers as large as 99999999. You'll need the DelimitedSplit8K function for this and I've included a link to that article after the code below.

--===== Build the test data
DECLARE @Result TABLE (Serial nvarchar(10),Title varchar(20))
INSERT INTO @Result
SELECT '1.1','a' UNION ALL
SELECT '1.2.1','b' UNION ALL
SELECT '1.2.2','C' UNION ALL
SELECT '1.2.3','G' UNION ALL
SELECT '1.11','B' UNION ALL
SELECT '2.3','B' UNION ALL
SELECT '2.11','B' UNION ALL
SELECT '2.2','C' UNION ALL
SELECT '1.5','E' UNION ALL
SELECT '1.3','E'
;
--===== Solve the problem by creating a hierarchical sort path using a very high speed
-- method for the right alignment of integer data (thanks, Dwaine)
WITH
cteBuildPath AS
(
SELECT r.Serial
,r.Title
,SortPath =
(--==== Split the parts of each Serial and reassemble as a hierarchical path
SELECT RIGHT(split.Item+100000000,8) --Converts each # to a zero filled right aligned number of 8 digits.
FROM @Result r1
CROSS APPLY dbo.DelimitedSplit8K(Serial,'.') split
WHERE r1.Serial = r.Serial
FOR XML PATH('')
)
FROM @Result r
)
SELECT Serial,Title
FROM cteBuildPath
ORDER BY SortPath
;




The DelimitedSplit8K function may be found at the following URL...
http://www.sqlservercentral.com/articles/Tally+Table/72993/

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
sayedkhalid99
sayedkhalid99
Valued Member
Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)

Group: General Forum Members
Points: 70 Visits: 533
thanks jeff for your reply , i will check this
sayedkhalid99
sayedkhalid99
Valued Member
Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)

Group: General Forum Members
Points: 70 Visits: 533
ChrisM@Work (1/3/2014)
DECLARE @Result TABLE (Serial nvarchar(10),Title varchar(20))
INSERT INTO @Result
SELECT '1.1','a' UNION ALL
SELECT '1.2.1','b' UNION ALL
SELECT '1.2.2','C' UNION ALL
SELECT '1.2.3.4','G' UNION ALL
SELECT '1.11','B' UNION ALL
SELECT '1.2.33.4.5','Extra row' UNION ALL
SELECT '2.3','B' UNION ALL
SELECT '2.11','B' UNION ALL
SELECT '2.2','C' UNION ALL
SELECT '1.5','E' UNION ALL
SELECT '1.1','E'

SELECT r.*

FROM @Result r

CROSS APPLY (SELECT n = CHARINDEX('.',Serial,0)) p1
CROSS APPLY (SELECT n = NULLIF(CHARINDEX('.',Serial,p1.n+1),0)) p2
CROSS APPLY (SELECT n = NULLIF(CHARINDEX('.',Serial,p2.n+1),0)) p3
CROSS APPLY (SELECT n = NULLIF(CHARINDEX('.',Serial,p3.n+1),0)) p4
CROSS APPLY (
SELECT
Elem1 = LEFT(Serial, p1.n-1),
Elem2 = SUBSTRING(Serial, p1.n+1, ISNULL(p2.n-(p1.n+1),8000)),
Elem3 = SUBSTRING(Serial, p2.n+1, ISNULL(p3.n-(p2.n+1),8000)),
Elem4 = SUBSTRING(Serial, p3.n+1, ISNULL(p4.n-(p3.n+1),8000)),
Elem5 = SUBSTRING(Serial, p4.n+1, 8000)
) x

ORDER BY CAST(x.Elem1 AS INT), CAST(x.Elem2 AS INT), CAST(x.Elem3 AS INT), CAST(x.Elem4 AS INT), CAST(x.Elem5 AS INT)


what change shall i bring in here so that if the serial don't have any decimal point say , it gives error in left function.
DECLARE @Result TABLE (Serial nvarchar(10),Title varchar(20))
INSERT INTO @Result
SELECT '1.1','a' UNION ALL
SELECT '1.2.1','b' UNION ALL
SELECT '1.2.2','C' UNION ALL
SELECT '1.2.3.4','G' UNION ALL
SELECT '1.11','B' UNION ALL
SELECT '1.2.33.4.5','Extra row' UNION ALL
SELECT '2.3','B' UNION ALL
SELECT '2.11','B' UNION ALL
SELECT '2.2','C' UNION ALL
SELECT '1.5','E' UNION ALL
SELECT '1','E'
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (84K reputation)SSC Guru (84K reputation)SSC Guru (84K reputation)SSC Guru (84K reputation)SSC Guru (84K reputation)SSC Guru (84K reputation)SSC Guru (84K reputation)SSC Guru (84K reputation)

Group: General Forum Members
Points: 84677 Visits: 41069
sayedkhalid99 (1/3/2014)

what change shall i bring in here so that if the serial don't have any decimal point say , it gives error in left function.
DECLARE @Result TABLE (Serial nvarchar(10),Title varchar(20))
INSERT INTO @Result
SELECT '1.1','a' UNION ALL
SELECT '1.2.1','b' UNION ALL
SELECT '1.2.2','C' UNION ALL
SELECT '1.2.3.4','G' UNION ALL
SELECT '1.11','B' UNION ALL
SELECT '1.2.33.4.5','Extra row' UNION ALL
SELECT '2.3','B' UNION ALL
SELECT '2.11','B' UNION ALL
SELECT '2.2','C' UNION ALL
SELECT '1.5','E' UNION ALL
SELECT '1','E'


With absolutely no disrespect intended or implied towards anyones fine work on this thread, my recommendation would be to not do it in any way that has such a small limit on the number of levels because there will be a drop-everything panic if a 6th or 7th level ever shows up. Don't say it won't happen. Make your code bullet proof and scalable and just assume that it will happen when you can least afford it to.

As a bit of a sidebar, if it were me, I'd stop recaclulating things that won't change over and over again. I'd turn my code into a function and add a persisted computed column that contains the function to the table so that I don't ever have to worry about calculating a sort order on something that's almost perfectly static.

As a hidden benefit of using the code I posted, you'll also have the DelimitedSplit8K function, which you find dozens of other uses for.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
sayedkhalid99
sayedkhalid99
Valued Member
Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)Valued Member (70 reputation)

Group: General Forum Members
Points: 70 Visits: 533
thanks for your feed back jeff, since i already implemented the first solution provided when i received the code in my project just wanted to change that rather then new code due to shortage of time and deadlines, later on i decided to use your solution and worked perfectly.
i will take your suggestion on
Make your code bullet proof and scalable and just assume that it will happen when you can least afford it to.
And I'd stop recaclulating things that won't change over and over again.

thanks for your continuous support to community members.
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (84K reputation)SSC Guru (84K reputation)SSC Guru (84K reputation)SSC Guru (84K reputation)SSC Guru (84K reputation)SSC Guru (84K reputation)SSC Guru (84K reputation)SSC Guru (84K reputation)

Group: General Forum Members
Points: 84677 Visits: 41069
sayedkhalid99 (1/4/2014)
thanks for your feed back jeff, since i already implemented the first solution provided when i received the code in my project just wanted to change that rather then new code due to shortage of time and deadlines, later on i decided to use your solution and worked perfectly.
i will take your suggestion on
Make your code bullet proof and scalable and just assume that it will happen when you can least afford it to.
And I'd stop recaclulating things that won't change over and over again.

thanks for your continuous support to community members.


Thanks for the feedback. Heh... yeah. I do understand deadlines and I believe you've done it the right way. You "got out of the woods" by doing something that would meet the deadline. Most people make the mistake of stopping there. You didn't. You're taking it to the next step and made it so it wouldn't become an emergency deadline in the future. Well done.

Just as a follow up, I have to ask... will there ever be the possibility that the "serial" will ever contain letters? If so, post back and we'll take it to the next level.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
ChrisM@Work
ChrisM@Work
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16016 Visits: 19524
Jeff Moden (1/4/2014)
sayedkhalid99 (1/3/2014)

what change shall i bring in here so that if the serial don't have any decimal point say , it gives error in left function.
DECLARE @Result TABLE (Serial nvarchar(10),Title varchar(20))
INSERT INTO @Result
SELECT '1.1','a' UNION ALL
SELECT '1.2.1','b' UNION ALL
SELECT '1.2.2','C' UNION ALL
SELECT '1.2.3.4','G' UNION ALL
SELECT '1.11','B' UNION ALL
SELECT '1.2.33.4.5','Extra row' UNION ALL
SELECT '2.3','B' UNION ALL
SELECT '2.11','B' UNION ALL
SELECT '2.2','C' UNION ALL
SELECT '1.5','E' UNION ALL
SELECT '1','E'


With absolutely no disrespect intended or implied towards anyones fine work on this thread, my recommendation would be to not do it in any way that has such a small limit on the number of levels because there will be a drop-everything panic if a 6th or 7th level ever shows up. Don't say it won't happen. Make your code bullet proof and scalable and just assume that it will happen when you can least afford it to.

As a bit of a sidebar, if it were me, I'd stop recaclulating things that won't change over and over again. I'd turn my code into a function and add a persisted computed column that contains the function to the table so that I don't ever have to worry about calculating a sort order on something that's almost perfectly static.

As a hidden benefit of using the code I posted, you'll also have the DelimitedSplit8K function, which you find dozens of other uses for.


There are compelling reasons for using the DelimitedSplit8K function in this case and I have to agree with Jeff that it's the best tool for the job - but I have a question: what is the source of this data? Is it persisted over time as a permanent table, or is it the output of another query, as the older post from 2011 might suggest?

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search