How to compare parent child data in SQL

  • Hi;

    I have two SQL tables like below;

    T1: relationID, meterID, parentID, childID

    T2: dataID, meterID, date, amount

    Sample data of tables;

    T1 T2

    ----------------- -------------------------

    1 | 1 | null | 2 * 1 | 1 | 01,01,2013 | 100 *

    2 | 1 | null | 3 * 2 | 2 | 01,01,2013 | 60 *

    3 | 2 | 1 | 4 3 | 3 | 01,01,2013 | 40 *

    4 | 2 | 1 | 5 4 | 4 | 01,01,2013 | 35

    5 | 3 | 1 | 6 5 | 5 | 01,01,2013 | 25

    6 | 3 | 1 | 7 6 | 6 | 01,01,2013 | 15

    7 | 4 | 2 | null 7 | 7 | 01,01,2013 | 25

    8 | 5 | 2 | null

    9 | 6 | 3 | null

    10 | 7 | 3 | null

    I want to compare if the sum of the children's amount is equal to parent's amount.

    For example; meter1 is parent of meter2 and meter3 (lines with *). I want to check if 100 = 60 + 40.

    How can i do this with SQL query.

    You can see the relation between the meters at the image below.

    Sorry for my poor English.

  • Here is the raw form of the query using CTE's. Please tweak it to suit your requirement....I hope this helps

    ;WITH tblCTE_1

    AS

    (

    SELECT T2.MeterID AS CMeterID, T1.MeterID AS PMeterID, Amount

    FROM dbo.T2

    LEFT JOIN dbo.T1

    ON T2.MeterID = T1.ChildID

    ),

    tblCTE_2 AS

    (

    SELECT PMeterID, SUM(Amount) AS Amount

    FROM tblCTE_1

    GROUP BY PMeterID

    )

    SELECT C1.CMeterID AS MeterID

    FROM tblCTE_1 C1

    INNER JOIN tblCTE_2 C2

    ON C1.CMeterID = C2.PMeterID

    WHERE C2.PMeterID IS NOT NULL

    AND C1.Amount = C2.Amount -- C1.Amount <> C2.Amount -- in case you want those ID's whose SUM(Amount) do not match

  • AhmetEmre90 (2/20/2013)


    Hi;

    I have two SQL tables like below;

    T1: relationID, meterID, parentID, childID

    T2: dataID, meterID, date, amount

    Sample data of tables;

    T1 T2

    ----------------- -------------------------

    1 | 1 | null | 2 * 1 | 1 | 01,01,2013 | 100 *

    2 | 1 | null | 3 * 2 | 2 | 01,01,2013 | 60 *

    3 | 2 | 1 | 4 3 | 3 | 01,01,2013 | 40 *

    4 | 2 | 1 | 5 4 | 4 | 01,01,2013 | 35

    5 | 3 | 1 | 6 5 | 5 | 01,01,2013 | 25

    6 | 3 | 1 | 7 6 | 6 | 01,01,2013 | 15

    7 | 4 | 2 | null 7 | 7 | 01,01,2013 | 25

    8 | 5 | 2 | null

    9 | 6 | 3 | null

    10 | 7 | 3 | null

    I want to compare if the sum of the children's amount is equal to parent's amount.

    For example; meter1 is parent of meter2 and meter3 (lines with *). I want to check if 100 = 60 + 40.

    How can i do this with SQL query.

    You can see the relation between the meters at the image below.

    Sorry for my poor English.

    I believe that the following article will give you what you want and much more.

    http://www.sqlservercentral.com/articles/T-SQL/94570/

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

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • A couple of quick points:

    1. Since you're a first time poster, you should understand that to get better, faster and more accurate help you should follow the first link in Jeff signature to learn forum etiquette for providing DDL and consumable sample data (like in my first SQL shown below).

    2. Jeff's article on Hierarchies on Steroids is incredibly useful for complex hiearchies were a lot of information between nodes must be retained. However I think it may be a bit overkill in this case where all you need to do is sum the children of a parent to one level deep (assuming this is right).

    DDL and consumable sample data:

    DECLARE @T1 TABLE

    (relationID INT, meterID INT, parentID INT, childID INT)

    DECLARE @T2 TABLE

    (dataID INT, meterID INT, [date] DATE, amount INT)

    INSERT INTO @T1

    SELECT 1 , 1 , null , 2

    UNION ALL SELECT 2 , 1 , null , 3

    UNION ALL SELECT 3 , 2 , 1 , 4

    UNION ALL SELECT 4 , 2 , 1 , 5

    UNION ALL SELECT 5 , 3 , 1 , 6

    UNION ALL SELECT 6 , 3 , 1 , 7

    UNION ALL SELECT 7 , 4 , 2 , null

    UNION ALL SELECT 8 , 5 , 2 , null

    UNION ALL SELECT 9 , 6 , 3 , null

    UNION ALL SELECT 10 , 7 , 3 , null

    INSERT INTO @T2

    SELECT 1 , 1 , '2013-01-01' , 100

    UNION ALL SELECT 2 , 2 , '2013-01-01' , 60

    UNION ALL SELECT 3 , 3 , '2013-01-01' , 40

    UNION ALL SELECT 4 , 4 , '2013-01-01' , 35

    UNION ALL SELECT 5 , 5 , '2013-01-01' , 25

    UNION ALL SELECT 6 , 6 , '2013-01-01' , 15

    UNION ALL SELECT 7 , 7 , '2013-01-01' , 25

    A possibly simpler solution than the one provided by Mr. AsiaIndian, made possible because you keep all of your child nodes in the relations table:

    SELECT a.meterID, b.[date]

    ,MeterAmt=MAX(b.amount)

    ,SumOfChildren=SUM(c.amount)

    FROM @T1 a

    INNER JOIN @T2 b ON a.meterID = b.meterID

    LEFT JOIN @T2 c ON a.childID = c.meterID

    GROUP BY a.meterID, b.[date]

    Change the LEFT JOIN to an INNER JOIN if you don't want leaf nodes displayed in the results.


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    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?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

  • dwain.c (2/27/2013)


    However I think it may be a bit overkill in this case where all you need to do is sum the children of a parent to one level deep (assuming this is right).

    If that's all they'll EVER want to do, then I agree. While it’s true that I tend to “over” plan by making such "simple" things bullet proof to scope changes, scale changes, and future requirements, let's hope that the complexity of the doubly-linked (each row has the parent and child listed) hierarchical Adjacency List in T1 isn't the foreboding of more complex requests that I think it will be.

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

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • Jeff Moden (2/27/2013)


    dwain.c (2/27/2013)


    However I think it may be a bit overkill in this case where all you need to do is sum the children of a parent to one level deep (assuming this is right).

    If that's all they'll EVER want to do, then I agree. While it’s true that I tend to “over” plan by making such "simple" things bullet proof to scope changes, scale changes, and future requirements, let's hope that the complexity of the doubly-linked (each row has the parent and child listed) hierarchical Adjacency List in T1 isn't the foreboding of more complex requests that I think it will be.

    The thought did occur to me that maintaining those child nodes in the relations table was probably going to incur some overhead (and headaches).

    But I also figured that you need to learn to crawl before you can learn to run.


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    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?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

Viewing 6 posts - 1 through 5 (of 5 total)

You must be logged in to reply to this topic. Login to reply