Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 Development Tools
 Reporting Services Development
 Get Last Parent Row

Author  Topic 

bo0tl3ss
Starting Member

20 Posts

Posted - 2011-02-14 : 22:45:54
hi there. good morning!

table

id desc parent

1 This null
2 is 1
3 a sample 2
4 table 3


sql param is 4 then how will i get the 1 row...thanks guys! more power...

AndrewMurphy
Master Smack Fu Yak Hacker

2916 Posts

Posted - 2011-02-15 : 05:45:35
start with below - and experiment. you will have issues if there is not always a 4-level structure.

select * from mytable a
inner join mytable b on b.id = a.parent
..
..
where a.id = 4
Go to Top of Page

Transact Charlie
Master Smack Fu Yak Hacker

3451 Posts

Posted - 2011-02-15 : 06:01:16
I think you may have been looking for something more like

DECLARE @foo TABLE (
[fooID] INT PRIMARY KEY
, [fooDesc] VARCHAR(10)
, [parentID] INT
)

INSERT @foo ([fooId], [fooDesc], [parentID])
SELECT 1, 'This', NULL
UNION SELECT 2, 'is', 1
UNION SELECT 3, 'a sample', 2
UNION SELECT 4, 'table', 3
-- Another Sentance
UNION SELECT 5, 'I', NULL
UNION SELECT 6, 'Recurse', 5
UNION SELECT 7, 'Therefore', 6
UNION SELECT 8, 'I', 7
UNION SELECT 9, 'Recurse!', 8


DECLARE @startID INT SET @startId = 9

; WITH

hierarchy AS (
-- Anchor
SELECT
f.[fooID] AS [fooID]
, CAST(f.[fooDesc] AS VARCHAR(MAX)) AS [DESC_Chain]
, CAST(f.[fooID] AS VARCHAR(MAX)) AS [ID_Chain]
, f.[parentID] AS [parentID]
FROM
@foo AS f
WHERE
f.[fooID] = @startId

-- Recursive
UNION ALL SELECT
parent.[fooID] AS [fooID]
, CAST(child.[DESC_Chain] + ' -> ' + parent.[fooDesc] AS VARCHAR(MAX))
, CAST(child.[ID_Chain] + ' -> ' + CAST(parent.[fooID] AS VARCHAR(10)) AS VARCHAR(MAX))
, parent.[parentID]
FROM
hierarchy AS child
JOIN @foo AS parent ON parent.[fooID] = child.[parentID]
)

SELECT * FROM hierarchy WHERE [parentID] IS NULL

Results:

fooID DESC_Chain ID_Chain parentID
----------- -------------------------------------------------- ------------------------------ -----------
5 Recurse! -> I -> Therefore -> Recurse -> I 9 -> 8 -> 7 -> 6 -> 5 NULL



Charlie
===============================================================
Msg 3903, Level 16, State 1, Line 1736
The ROLLBACK TRANSACTION request has no corresponding BEGIN TRANSACTION
Go to Top of Page
   

- Advertisement -