Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase ««12

Build menu with CTE .... Expand / Collapse
Author
Message
Posted Monday, September 23, 2013 3:22 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: 2 days ago @ 4:14 AM
Points: 3,618, Visits: 5,254
hunchback (9/22/2013)
One way to accomplish this is using a varbinary column to concatenate the sequence of numbers based on the position value.

WITH C1 AS (
SELECT
Id, IdRoot, Name, Position,
CAST(ROW_NUMBER() OVER(ORDER BY position) AS varbinary(900)) AS order_val,
0 AS lvl
FROM
menu
WHERE
IdRoot = 0

UNION ALL

SELECT
C.Id, C.IdRoot, C.Name, C.Position,
CAST(P.[path] + CAST(ROW_NUMBER() OVER(PARTITION BY P.IdRoot ORDER BY C.Position) AS BINARY(8)) AS varbinary(900)),
P.lvl + 1
FROM
C1 AS p
INNER JOIN
menu AS C
ON p.Id = C.IdRoot
)
SELECT REPLICATE(SPACE(4), 2 * lvl) + [name] AS menu
FROM C1
ORDER BY order_val;
GO

/*

menu
ERP
ACC
HR
PAYMENT
PROCESS
CANCEL
VACATIONS
ABSENTS
SALES

*/


To generate the numbers in specific order we can use a ranking function like ROW_NUMBER, where you can use multiple columns to drive the sort order (by name or position or whatever other combination).

You can read more about other uses of he ranking functions in the last book from Itzik Ben-Gan about T-SQL Querying.

Inside Microsoft® SQL Server® 2008: T-SQL Querying

Microsoft SQL Server 2012 High-Performance T-SQL Using Window Functions


As Jeff said, NM=Nice Method (?).

Except I think that P.[Path] should be p.Order_val in the recursive leg of your CTE.



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

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?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1497303
Posted Monday, September 23, 2013 3:26 AM


Mr or Mrs. 500

Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500

Group: General Forum Members
Last Login: Thursday, June 12, 2014 9:30 AM
Points: 513, Visits: 1,129
dwain.c (9/23/2013)
As Jeff said, NM=Nice Method (?).

Except I think that P.[Path] should be p.Order_val in the recursive leg of your CTE.


Yes, had to change it to work but it's just fine...

Pedro




If you need to work better, try working less...
Post #1497305
Posted Monday, September 23, 2013 3:29 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: 2 days ago @ 4:14 AM
Points: 3,618, Visits: 5,254
PiMané (9/23/2013)
dwain.c (9/23/2013)
As Jeff said, NM=Nice Method (?).

Except I think that P.[Path] should be p.Order_val in the recursive leg of your CTE.


Yes, had to change it to work but it's just fine...

Pedro


Figured you must've.

I looked at this in the morning but didn't have time, so I came back to study it. Any time Jeff approves of something it makes me want to understand.

Now I think I do so I'm probably the better for it.



My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

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?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1497306
Posted Monday, September 23, 2013 5:40 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Tuesday, August 19, 2014 11:57 AM
Points: 114, Visits: 611
I changed [path] by order_val in the recursive part and now it should run flawless.

A recursive CTE is still an iterative approach so I do not hold my breath hoping for better performance.

You can add a clustered index by ID and a nonclustered by IdRoot.



Post #1497334
Posted Monday, September 23, 2013 5:43 AM


Mr or Mrs. 500

Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500Mr or Mrs. 500

Group: General Forum Members
Last Login: Thursday, June 12, 2014 9:30 AM
Points: 513, Visits: 1,129
hunchback (9/23/2013)
I changed [path] by order_val in the recursive part and now it should run flawless.

A recursive CTE is still an iterative approach so I do not hold my breath hoping for better performance.

You can add a clustered index by ID and a nonclustered by IdRoot.


It's better than the recursive cursor it's currently using...
Instead of 7ms and 530reads, for 28 rows, takes 3ms and 321 reads.
And for bigger menus the difference is even greater.

Pedro




If you need to work better, try working less...
Post #1497336
Posted Monday, September 23, 2013 7:51 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 8:33 AM
Points: 36,958, Visits: 31,465
The "NM" stands for "Never Mind". I had posted a rebuttal saying that the code didn't sort alphabetically, which seemed logical to me at the time. Then I realized that it did sort by the given ID using the same sort method that I had in my first article on hierarchies, compared it to the order the OP was looking for, and realized my mistake. I removed my mistaken post and, since we can't delete posts, just put in a quick "NM".

Still, it is a nice method... especially since I've used the same method in the past.


--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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1497391
Posted Monday, September 23, 2013 7:56 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 8:33 AM
Points: 36,958, Visits: 31,465
hunchback (9/23/2013)
I changed [path] by order_val in the recursive part and now it should run flawless.

A recursive CTE is still an iterative approach so I do not hold my breath hoping for better performance.

You can add a clustered index by ID and a nonclustered by IdRoot.


Well said. Oddly enough, a well constructed WHILE loop that iterates over the Levels of the menu in a manner similar to the rCTE would probably do as well. In either case, the recursion is necessary and isn't as bad as an rCTE that counts because the rCTE method that we both used (and a similar WHILE loop would use) processes an entire set (all nodes at a given level) instead of just individual rows.


--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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1497393
« Prev Topic | Next Topic »

Add to briefcase ««12

Permissions Expand / Collapse