Welcome to Software Development on Codidact!
Will you help us build our independent community of developers helping developers? We're small and trying to grow. We welcome questions about all aspects of software development, from design to code to QA and more. Got questions? Got answers? Got code you'd like someone to review? Please join us.
How to break infinite loop in CTE
I have a parent-child relation in my table, with possibly circular cases. Is it possible to break the infinite recursion in CTE checking values of all previous rows? I would need something like this:
with my_cte(childId, parentId, col1)
AS (
SELECT r.childId, r.parentId, r.col1
FROM My_Table r WHERE r.childId = 'x' AND (r.col1 = 1 or r.col1 = 2)
UNION ALL
SELECT rel.childId, rel.parentId, rel.col1
FROM My_Table rel INNER JOIN my_cte sd ON rel.childId = sd.parentId where (rel.col1 = 1 OR rel.col1 = 2) AND ...
-- check that rel.childId, rel.parentId not in previous rows
)
SELECT DISTINCT * from shared_documents
How can I achieve this? Or how to approach this?
Example table with records would be:
childId | parentId | col1 |
---|---|---|
1 | 3 | 1 |
1 | 4 | 1 |
3 | 5 | 1 |
5 | 1 | 1 -- circular case |
6 | 2 | 1 |
5 | 7 | 1 |
If I ask for hierarchy related to 1, I should get
childId | parentId | col1 |
---|---|---|
1 | 3 | 1 |
1 | 4 | 1 |
3 | 5 | 1 |
5 | 1 | 1 -- circular case |
5 | 7 | 1 |
- 1 has two parents: 3 and 4.
- 3 has 1 parent: 5
- 5 has 2 parents: 1 and 7. But 1 brings the infinite loop, so the query should ignore this. And continue to the next row.
3 answers
I have not managed to make an answer with standard SQL. I've had to resort to using arrays. And I don't have a Microsoft SQL Server RDBMS at hand. So I've done it instead in PostgreSQL. You'll just need to use whatever equivalent array functions sql-server has.
- ARRAY(SELECT XX) : constructs an array with a single element XX
- ARRAY_CAT( a1, a2) : concatenates two arrays
- ARRAY_POSITION(a, e) : returns the position of e in array a. NULL if e is not in array a.
This is half the answer: how to get the hierarchy for all descendants (children, grandchildren, etc).
For the full answer you just need to do the same for ascendants and then perform a union.
WITH RECURSIVE cte AS (
SELECT
childid,
parentid,
ARRAY(SELECT XX) a
FROM my_table
WHERE parentid=XX
UNION ALL
SELECT
m.childid,
m.parentid,
ARRAY_CAT( cte.a, ARRAY(SELECT m.parentid))
FROM
my_table m
INNER JOIN cte
ON cte.childid = m.parentid
WHERE ARRAY_POSITION(cte.a, m.parentid) is null
)
SELECT DISTINCT childid, parentid FROM cte;
Replace XX by the id for which you are querying its descendants.
This works by storing in an extra colum an array with all parent ids which have been processed. When doing the recursive CTE we only select rows with a parentid which is not contained in such array. This way we break the loop.
The code as such is hard to understand. I suggest to run the following code and check the result. Which will help in understanding the previous code.
WITH RECURSIVE cte AS (
SELECT
1 as iteration,
childid,
parentid,
ARRAY(SELECT XX) a
FROM my_table
WHERE parentid=XX
UNION ALL
SELECT
iteration+1,
m.childid,
m.parentid,
ARRAY_CAT( cte.a, ARRAY(SELECT m.parentid))
FROM
my_table m
INNER JOIN cte
ON cte.childid = m.parentid
WHERE ARRAY_POSITION(cte.a, m.parentid) is null
)
SELECT iteration, childid, parentid, a FROM cte ORDER BY iteration;
Which, for XX=1, returns the following table:
iteration | childid | parentid | a
--------------------------------------------
1 | 5 | 1 | {1}
2 | 3 | 5 | {1,5}
3 | 1 | 3 | {1,5,3}
Which are the descendants of 1, as expected. With their immediate parents and the array of checked parents as it grows.
Estela's answer provides great insight about how to do it also in SQL Server. Unfortunately, there does not seem to be a build-in array functionality, so one way is to rely on strings as shown here.
Basically, instead of accumulating values in an array, a string does this (way less efficiently for many records, I would say).
In this case, a query that seems to provide the results you are looking for is the following (some security check does not allow to post the query, so I am using SQL fiddle for sharing it):
http://sqlfiddle.com/#!18/a50101/1
Note: considering how complex things might get (edge cases might add up to the logic), this type of query might be better be done in a language/framework like C++, Java or .NET, unless there is a very strong reason to remain in SQL. These allow for much more flexibility, considering the iterative nature of the algorithm (not so suitable for set based operations) and also provide way better-debugging capabilities.
For small tables you can bound the recursion depth:
WITH my_cte(childId, parentId, depth, max_depth)
AS (
SELECT r.childId, r.parentId, 1, (SELECT COUNT(*) FROM My_Table)
FROM My_Table r
WHERE r.childId = 1
UNION ALL
SELECT rel.childId, rel.parentId, sd.depth + 1, sd.max_depth
FROM My_Table rel INNER JOIN my_cte sd ON rel.childId = sd.parentId
WHERE sd.depth < sd.max_depth
)
SELECT DISTINCT childId, parentId
FROM my_cte
This approach is limited by the bound that MAXRECURSION <= 32767
.
1 comment thread