October 29, 2013 at 10:53 am
I have 2 tables "Category & Item" .. In the first table "Category" .. I have a self join Relation.
*The First Table Represent Main Categories which allow user to access items which are related to specific category
*The Second Table Represent The Items which is related to each category
*Each Category may be a child or parent for other categories
--I want to know how can I get the full items count for specific category and his child items hierarchy tree .. (not only the items which is related to that category only .. we shall get the count for the items which related to his child also = Indirect Relation)
Examples :
#The Items Count for "Electronic" Category will be 8
#The Items Count for "TV" Category will be 4
#The Items Count for "Cell Phones" Category will be 4
#The Items Count for "LCD" Category will be 1
#The Items Count for "LED" Category will be 1
#The Items Count for "Smart Phone" Category will be 1
#The Items Count for "3G Phone" Category will be 1
First Table (Category) :
ID , Name , ParentID
1 , Electronics , 0
2 , TV , 1
3 , Cell Phones , 1
4 , LCD , 2
5 , LED , 2
6 , Smart Phone , 3
7 , 3G Phone , 3
8 , Clothes , 0
Second Table (Item) :
ID , Name , CategoryID
1 , item1 , 2
2 , item2 , 4
3 , item3 , 5
4 , item4 , 7
5 , item5 , 6
6 , item6 , 3
7 , item7 , 8
8 , item8 , 3
9 , item9 , 2
So any Ideas for how can i get the above query result for these 2 tables ???
Notes :
-I can have many levels in the tree hierarchy
-Items can be linked to any category levl
October 29, 2013 at 11:43 am
There might be several ways to go, but here's an option using a recursive query on a table-valued function. Before implementing this solution, be sure to understand what's going on and feel free to ask anything.
DDL & Sample Data
CREATE TABLE Category(
IDint,
Namevarchar(20),
ParentIDint)
INSERT INTO Category VALUES
(1 , 'Electronics' , 0),
(2 , 'TV' , 1),
(3 , 'Cell Phones' , 1),
(4 , 'LCD' , 2),
(5 , 'LED' , 2),
(6 , 'Smart Phone' , 3),
(7 , '3G Phone' , 3),
(8 , 'Clothes' , 0)
GO
CREATE TABLE Item(
IDint,
Namechar(5),
CategoryIDint)
INSERT INTO Item VALUES
(1 , 'item1' , 2),
(2 , 'item2' , 4),
(3 , 'item3' , 5),
(4 , 'item4' , 7),
(5 , 'item5' , 6),
(6 , 'item6' , 3),
(7 , 'item7' , 8),
(8 , 'item8' , 3),
(9 , 'item9' , 2)
GO
Function declaration
CREATE FUNCTION Categories_List( @Category int)
RETURNS TABLE
AS
RETURN
(
WITH rCTE AS(
SELECT *
FROM Category
WHERE id = @Category
UNION ALL
SELECT c.*
FROM Category c
JOIN rCTE r ON c.ParentID = r.ID
)
SELECT ID
FROM rCTE
)
GO
Final query
SELECT c.ID, c.Name, COUNT(*)
FROM Category c
CROSS APPLY dbo.Categories_List( c.ID) l
JOIN Item i ON l.ID = i.CategoryID
GROUP BY c.ID, c.Name
October 30, 2013 at 5:35 am
Thanks a lot Luis .. Can I handle it without functions ?? is there any other alternative way ??
October 30, 2013 at 8:56 am
ahmedhussein874 (10/30/2013)
Thanks a lot Luis .. Can I handle it without functions ?? is there any other alternative way ??
Why do you want to do it without the use of high performance, easy to use, inline table valued functions like Luis used?
--Jeff Moden
Change is inevitable... Change for the better is not.
October 30, 2013 at 9:19 am
ahmedhussein874 (10/30/2013)
Thanks a lot Luis .. Can I handle it without functions ?? is there any other alternative way ??
There might be, but it might take me a while to find something with good performance and I have work of my own. Is there any good reason to find a different way?
October 30, 2013 at 12:41 pm
Luis Cazares (10/30/2013)
ahmedhussein874 (10/30/2013)
Thanks a lot Luis .. Can I handle it without functions ?? is there any other alternative way ??There might be, but it might take me a while to find something with good performance and I have work of my own. Is there any good reason to find a different way?
Luis, that's impressive. You essentially wrote the equivalent of Oracle's START WITH...CONNECT BY in SQL Server. As a bonus, you did it in a high-performance, compact and cool way. Seriously great work.
October 30, 2013 at 1:02 pm
Ed Wagner (10/30/2013)
Luis Cazares (10/30/2013)
ahmedhussein874 (10/30/2013)
Thanks a lot Luis .. Can I handle it without functions ?? is there any other alternative way ??There might be, but it might take me a while to find something with good performance and I have work of my own. Is there any good reason to find a different way?
Luis, that's impressive. You essentially wrote the equivalent of Oracle's START WITH...CONNECT BY in SQL Server. As a bonus, you did it in a high-performance, compact and cool way. Seriously great work.
:blush: A good inspiration moment got me a great compliment. Thak you, Ed.
October 31, 2013 at 5:33 am
Its Great .. I will use Function Solution Luis ..Thanks a lot for your help 🙂
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply