Click here to Skip to main content
13,772,600 members
Click here to Skip to main content
Add your own
alternative version

Stats

284.7K views
1.7K downloads
55 bookmarked
Posted 15 Sep 2014
Licenced CPOL

SQL queries to manage hierarchical or parent-child relational rows in SQL Server

, 15 Sep 2014
Rate this:
Please Sign up or sign in to vote.
Some queries to find generation of each row, all possible children’s, all possible parents, managing recursion

Introduction

Here in this post we will try to manage data’s with hierarchical relation or parent-child relation of a specific table in SQL server. Our special concentration would be over,

  • Show Generations of each row
  • Find all possible parents of a specific row
  • Find all possible child’s of a specific row
  • Show all possible parents at a column with a separator
  • Show all possible child’s at a column with a separator

Background

Let’s pretend

  • A row can have only one parent or Null as no parent
  • There is at least a row, without parent (parentId is null)
  • And at least a row, without any child

Here is our table schema.

/*drop the tbl*/
--DROP TABLE UserType

/*create the tbl*/
CREATE TABLE UserType(
    Id BIGINT NOT NULL,
    Name VARCHAR(100) NOT NULL,
    ParentId BIGINT NULL    
)

Let’s populate the table with data’s

/*insert data into table*/
DECLARE @maxCount BIGINT,
        @count BIGINT,
        @parentId BIGINT;        
SET @maxCount = 10;        /*change to input more*/
SET @count = 1;

WHILE @count <= @maxCount
BEGIN
    If @count = 1
        SET @parentId = NULL;
    ELSE
        SET @parentId = @count - 1;
        
    INSERT INTO UserType(Id, Name, ParentId)
        VALUES (@count, 'User_' + CONVERT(VARCHAR(400), @count), @parentId)
    SET @count = @count + 1;
END

So our populated table would be like

/*show inserted datas*/
SELECT *
    FROM UserType;

Check in live http://www.sqlfiddle.com/#!3/f50a6/1

Now how to find all this generations, parents or child’s using SQL for a specific row …!!!

The answer is using recursion. But to use this recursion we need some Thing Called CTE (Common Table Expressions) or in syntax “WITH” in SQL. If we don’t have any idea about it, we can start with the links or Google for few moments.

http://msdn.microsoft.com/en-us/library/ms175972.aspx

http://technet.microsoft.com/en-us/library/ms190766%28v=sql.105%29.aspx

http://www.codeproject.com/Articles/265371/Common-Table-Expressions-CTE-in-SQL-SERVER

So let’s start with pretty basics.

Regular Join

Joining table with itself based on condition, where ones parentId is equal to another’s Id

/*regular join to get detail*/    
SELECT ChildUserType.Id, ChildUserType.Name, ParentUserType.Id, ParentUserType.Name
    FROM UserType AS ChildUserType
    LEFT JOIN UserType AS ParentUserType ON ChildUserType.ParentId = ParentUserType.Id;

Check in live http://www.sqlfiddle.com/#!3/f50a6/2

Row Generation

The procedure is something like

  • All rows with no parent (NULL), assign generation 0 to them
  • Find rows where parent belongs to the generation 0, and assign increased generation to itself
  • Do until the recursion is finished.
/*row generations*/
WITH Hierarchy(ChildId, ChildName, Generation, ParentId)
AS
(
    SELECT Id, Name, 0, ParentId
        FROM UserType AS FirtGeneration
        WHERE ParentId IS NULL        
    UNION ALL
    SELECT NextGeneration.Id, NextGeneration.Name, Parent.Generation + 1, Parent.ChildId
        FROM UserType AS NextGeneration
        INNER JOIN Hierarchy AS Parent ON NextGeneration.ParentId = Parent.ChildId    
)
SELECT *
    FROM Hierarchy
    OPTION(MAXRECURSION 32767)

Check in live http://www.sqlfiddle.com/#!3/f50a6/3

All Possible Parents

check http://stackoverflow.com/a/21233413/2948523

Here we are trying to find all possible parents of a row where it's Id = 5

  • Starts with selecting the row where Id = 5
  • Find other rows where its id is equal to previously selected’s ParentId
  • And continue reduction
--all posible parents of @id
DECLARE @id BIGINT;
SET @id = 5;
WITH tblParent AS
(
    SELECT *
        FROM UserType WHERE Id = @id
    UNION ALL
    SELECT UserType.*
        FROM UserType  JOIN tblParent  ON UserType.Id = tblParent.ParentId
)
SELECT * FROM  tblParent
    WHERE Id <> @id
OPTION(MAXRECURSION 32767)

Check in live http://www.sqlfiddle.com/#!3/f50a6/5

All Possible Childs

check http://stackoverflow.com/a/21233413/2948523

Here we are trying to find all possible child’s of a row where it’s Id = 5

  • Starts with selecting the row where Id = 5
  • Find other rows where its ParentId is equal to previously selected’s Id
  • And continue reduction
-- all posible childs of @userTypeId
DECLARE @userTypeId BIGINT;
SET @userTypeId = 5;
WITH tblChild AS
(
    SELECT *
        FROM UserType WHERE ParentId = @userTypeId
    UNION ALL
    SELECT UserType.* FROM UserType  JOIN tblChild  ON UserType.ParentId = tblChild.Id
)
SELECT *
    FROM tblChild
OPTION(MAXRECURSION 32767)

Check in live http://www.sqlfiddle.com/#!3/f50a6/6

All Possible Parents In A Column

Here we are showing all the possible parents Ids at the column with a specific separator ‘.’

/*row posible parents in a column*/
WITH Hierarchy(ChildId, ChildName, ParentId, Parents)
AS
(
    SELECT Id, Name, ParentId, CAST('' AS VARCHAR(MAX))
        FROM UserType AS FirtGeneration
        WHERE ParentId IS NULL    
    UNION ALL
    SELECT NextGeneration.Id, NextGeneration.Name, Parent.ChildId,
    CAST(CASE WHEN Parent.Parents = ''
        THEN(CAST(NextGeneration.ParentId AS VARCHAR(MAX)))
        ELSE(Parent.Parents + '.' + CAST(NextGeneration.ParentId AS VARCHAR(MAX)))
    END AS VARCHAR(MAX))
        FROM UserType AS NextGeneration
        INNER JOIN Hierarchy AS Parent ON NextGeneration.ParentId = Parent.ChildId    
)
SELECT *
    FROM Hierarchy
OPTION(MAXRECURSION 32767)

Check in live http://www.sqlfiddle.com/#!3/f50a6/7

All Possible Childs In A Column

Here we are showing all the possible child’s Ids at the column with a specific separator ‘.’

/*row posible childs in a column*/
WITH Hierarchy(ChildId, ChildName, ParentId, Childs)
AS
(
    SELECT Id, Name, ParentId, CAST('' AS VARCHAR(MAX))
        FROM UserType AS LastGeneration
        WHERE Id NOT IN (SELECT COALESCE(ParentId, 0) FROM UserType)     
    UNION ALL
    SELECT PrevGeneration.Id, PrevGeneration.Name, PrevGeneration.ParentId,
    CAST(CASE WHEN Child.Childs = ''
        THEN(CAST(Child.ChildId AS VARCHAR(MAX)))
        ELSE(Child.Childs + '.' + CAST(Child.ChildId AS VARCHAR(MAX)))
    END AS VARCHAR(MAX))
        FROM UserType AS PrevGeneration
        INNER JOIN Hierarchy AS Child ON PrevGeneration.Id = Child.ParentId    
)
SELECT *
    FROM Hierarchy
OPTION(MAXRECURSION 32767)

Check in live http://www.sqlfiddle.com/#!3/f50a6/8

Recursion limit !!!

In all of the previous queries we have used syntax like

OPTION(MAXRECURSION 32767)

This specifies the maximum number of recursions in CTE. Now if we don’t use this OPTION(MAXRECURSION 32767) , by default it is 100.

We need to specify this number depending on the recursion requirement.

If More Recursion Needed !!!

With MAXRECURSION value equal to 0 means that no limit is applied to the recursion level, but remember a recursion should end at some level.

OPTION(MAXRECURSION 0)

To increase the recursion number, excluding CTE’s maximum Limit. We can follow some instruction like the links, or Google for some time.

http://www.sql-server-helper.com/error-messages/msg-310.aspx

http://stackoverflow.com/questions/15080922/infinite-loop-cte-with-option-maxrecursion-0

Limitations

Yes, there could be something which I misunderstood or presented. So if you find anything, just let me know.

Find the SQL file at the attachment.

License

This article, along with any associated source code and files, is licensed under The Code Project Open License (CPOL)

Share

About the Author

DiponRoy
Bangladesh Bangladesh
No Biography provided

You may also be interested in...

Pro
Pro

Comments and Discussions

 
Questioncount all possible childs Pin
drcza15-Aug-18 0:17
memberdrcza15-Aug-18 0:17 
QuestionWhat if the parent child relationships are not defined by an interger Pin
Cameron Stewart18-Jan-18 17:41
memberCameron Stewart18-Jan-18 17:41 
QuestionRe: What if the parent child relationships are not defined by an interger Pin
DiponRoy21-Jan-18 6:13
memberDiponRoy21-Jan-18 6:13 
AnswerRe: What if the parent child relationships are not defined by an interger Pin
Cameron Stewart21-Jan-18 13:37
memberCameron Stewart21-Jan-18 13:37 
Questionhow to convert " -- all posible childs of @userTypeId " to LINQ query Pin
Member 2627173(Sina Taghizadeh))23-Nov-17 9:27
memberMember 2627173(Sina Taghizadeh))23-Nov-17 9:27 
QuestionTHANK YOU SO MUCH Pin
JesseCamron25-May-17 23:22
memberJesseCamron25-May-17 23:22 
AnswerRe: THANK YOU SO MUCH Pin
DiponRoy29-May-17 7:10
memberDiponRoy29-May-17 7:10 
GeneralMany Thanks Pin
Boony Developer3-May-17 22:26
memberBoony Developer3-May-17 22:26 
GeneralRe: Many Thanks Pin
DiponRoy4-May-17 21:49
memberDiponRoy4-May-17 21:49 
QuestionMillion Thanks Pin
EYO191923-Nov-16 5:31
memberEYO191923-Nov-16 5:31 
AnswerRe: Million Thanks Pin
DiponRoy23-Nov-16 7:05
memberDiponRoy23-Nov-16 7:05 
GeneralGreat Article Pin
Alireza_136223-Sep-16 12:02
memberAlireza_136223-Sep-16 12:02 
GeneralRe: Great Article Pin
DiponRoy25-Sep-16 20:02
memberDiponRoy25-Sep-16 20:02 
SuggestionI can recommend... (Hierarchies on Steroids) Pin
Paw Jershauge14-Apr-16 21:31
memberPaw Jershauge14-Apr-16 21:31 
QuestionParent Name Pin
Nagaraju Dasari2-Aug-15 17:46
memberNagaraju Dasari2-Aug-15 17:46 
QuestionHow to find the depth of the child efficiently?? Pin
Member 118158015-Jul-15 22:52
memberMember 118158015-Jul-15 22:52 
AnswerRe: How to find the depth of the child efficiently?? Pin
DiponRoy6-Jul-15 16:54
memberDiponRoy6-Jul-15 16:54 
Questiongood one Pin
Arkadeep De18-May-15 21:13
professionalArkadeep De18-May-15 21:13 
AnswerRe: good one Pin
DiponRoy18-May-15 22:09
memberDiponRoy18-May-15 22:09 
Questionthat was exactly what I need but ... Pin
stelios19849-Nov-14 21:57
memberstelios19849-Nov-14 21:57 
AnswerRe: that was exactly what I need but ... Pin
DiponRoy18-May-15 22:16
memberDiponRoy18-May-15 22:16 
QuestionCheck this link! Pin
Paw Jershauge28-Sep-14 22:39
memberPaw Jershauge28-Sep-14 22:39 
AnswerRe: Check this link! Pin
DiponRoy29-Sep-14 8:07
memberDiponRoy29-Sep-14 8:07 
SuggestionOther resources for trees and hierarchies Pin
Gringo Gordo22-Sep-14 10:37
memberGringo Gordo22-Sep-14 10:37 
GeneralRe: Other resources for trees and hierarchies Pin
DiponRoy22-Sep-14 10:48
memberDiponRoy22-Sep-14 10:48 

General General    News News    Suggestion Suggestion    Question Question    Bug Bug    Answer Answer    Joke Joke    Praise Praise    Rant Rant    Admin Admin   

Use Ctrl+Left/Right to switch messages, Ctrl+Up/Down to switch threads, Ctrl+Shift+Left/Right to switch pages.

Permalink | Advertise | Privacy | Cookies | Terms of Use | Mobile
Web06 | 2.8.181119.1 | Last Updated 16 Sep 2014
Article Copyright 2014 by DiponRoy
Everything else Copyright © CodeProject, 1999-2018
Layout: fixed | fluid