Cross Apply not summing correctly

  • I have a group of records that I can sort of get working  but the inner cross apply is doubling the amounts.  I assume that is because it is doing it once for each record in the outer select.

    I also want to get the inner count in the outer select but can't figure out how to get it out as it would need to be part of the Group By clause which would not work.

    Here is my schema and code:

    Declare @test-2 TABLE 
    (
     FullName varchar(20),
     AdjType int,
     Adjustment int
    )

    INSERT @test-2 values('Tom Jones', 2, 10)
    INSERT @test-2 values('Tom Jones', 2, 15)
    INSERT @test-2 values('Tom Jones', 3, 100)
    INSERT @test-2 values('Tom Jones', 3, 150)
    INSERT @test-2 values('Ron Olsen', 2, 1000)
    INSERT @test-2 values('Ron Olsen', 2, 1500)
    INSERT @test-2 values('Ron Olsen', 3, 10000)
    INSERT @test-2 values('Ron Olsen', 3, 15000)


    SELECT baDental.FullName, COUNT(*) AS AdjustmentDentalCount, SUM(baDental.Adjustment) AS AdjustmentDental, SUM(baVision.Adjustment) AS AdjustmentVision
    FROM @test-2 baDental
    CROSS APPLY
    (
     SELECT FullName, COUNT(*) AS AdjustmentVisionCount, SUM(Adjustment) AS Adjustment
     FROM @test-2 ba2
     WHERE ba2.AdjType = 3 AND    -- Vision
        baDental.FullName = ba2.FullName
     GROUP BY FullName
    ) baVision
    WHERE baDental.AdjType = 2   -- Dental
    GROUP BY baDental.FullName

    The results are:

    data:image/png;base64,iVBORw0KGgoAAAANSUhEUgAAAYQAAAA3CAYAAAAMlD28AAAAAXNSR0IArs4c6QAAAARnQU1BAACxjwv8YQUAAAAJcEhZcwAADsQAAA7EAZUrDhsAAAz+SURBVHhe7Z3BixvXHce/ai89NYFcQk52M7Mm8lwCNhjpFpbEuxvC4oMCgSJ6kUhCkTDZYojIwagQuiZIbWNHewmiUIiamsWtpMaY3laYeqEXWSarSe1TyCWwyR8Q9f3ePGlH2hnNjDSzq9X8Pni8ozdv3nvz+83M7/3ek94v8be//2MAhmEYJvYkBgK1H2u+/fZbvPTSS+oTEydY94sD6+J0+Zn6yzAMw8QcNggMwzCMhA0CwzAMIxk3CGYV6UQCCduWrprq4ASUN12FOfw7TEukMXaK/fhZpp0X8pi4Njtn5Tqljuw6TiPfjrDVE3Ixq/mj+tMR1x0WrPvZiEIuS6ELE9V0QshefRyyAG0/7iGkKugPBqC5Ztr2Cpo64JcOitkz8HAEpL3bRS5noNH0uLJZlBrljeBUtl3H/RKSZd3d8E8jYLvNahp6I4lSX9VdLwHrWfeHOygRyZF170CU7Z7CcuhCw0Ymhe7BeE1mswEYPWTd2nACMg9/yEjccBWjge1J63emMXHQNbBZ24TRaE5XiFbA3l5BqPyMoK2hUK9APGGR3mgkQ7rfK/UC1obCEXXXBnsI3Oc4UVj3i8Py6ELbyEzI3Xo+Mls193afwDV5G4RJq+TDSm1sZdAtO+QR7t6Ry0ruqkiT5eWRz6dlerraRlXu29xZkScvXCxrmCEfXo/SL2YTDWMTa9CRRAOjzomtXelsQ/hGVpqUz6ScbJ+ppzySAV1vtohOpwh9dN4M8lDnWXlV2SL/WNnW2cfRVmB0eujT/jxlO+l3CMkQGWy43c0T9cpTZb0OMvTbnjBg3fsre5ruw2KZdKFtiKfBfg3q+YBb+0SK/Vom6j56XibrpgP+OW4QqNGyMNpURUERlqzk5CWsCes3cldtRqPTRXJrT6SJ3kqxDMh9Ok4WlITZQLKuzquLW+GEh6TIlTM218QeuXpk2KW6pJJR6st21UuGzOtNG9tFA62hDIq7WBG9tBS58kPrP6s8xHm9zbqV3jJk/o3Jsh0RD1iqiwNzzrLd9OvJuCz7mS7Wve7kma81GKx7QaS6989y6cJ+Dda1IbOhjhGT7du2vYvHr3nseTlWdzA9eMwh1IQ1no21WgmYbIy0asp66cJiqmSkbD1H+z5BlrPTQVFXRorO69gsa+SQK9fBzrpVv17soEOunrToFWyp8Q9NTyIl97ygB3AH6zSh2lxBve8g41nkQV08kXfYHoj2+KePXsfACuYs202/XkzKUjwpqe7B9Bt55msNAus+ct37Zvl0cTRspIaLxiqY0r5pz8vM94FF+HMII9awlWkgu91Tn9vI68KilpT1ElbXn+KInGUpR9sJjjuT8I2Wre6+UIVS/ExoKOyJcuolJHtl6PosXpiDPHR1aBbMA3RTSXELErOW7aHfSRf5LMC6D0f3YbCMuhg9E/SCnzA4obQvON4GQY0xDh9ksz98wXujFUowdnZsvQXhzunWVZvNnr9eBAlNWMpdOUAnkONk4bujbkhXLmnXsnL1DlaECovYVuOJlG/selzlJh6eRBpVYTALtToq5K4HuanDlodpjZ0aJeHKzl32NP1acqNvoA2HYKluSxb0YEzI0lgR7Zn93gsD1n1Yup+f5dSFuobs5HARMaV9VLfT8yI/zYcPD0H09Ctd5Rqlsb2rkn1B5w77CrQvLl6Wk0C20VXpXghLWW/RiZZrlu0hUx+Ow0WNkytH+pB3ohwX7K5b7RLNmugVucmN0g0lBx2NTB2FNeum1n3N2QSUh3ggjpVtnyfSy+iV+qhJf3Sesr31qxX20M/0UFZ5qG60xPVrVK84uWzVqzcy6MsGucnQBadrnRnWfZi6n48l1YVAXoOwYJPX5ti+kT10e17mhxe3U4S2qBb1FLJAfepEHrNIsO4XB9bF6RLhHEIMoV9R6kUH949Zelj3iwPrYmbYQ1DwsrvxhXW/OLAuThf2EBiGYRgJGwSGYRhGkhDb4PDwEM8//zz476ElFYZhmBiS+O77H3kOQfCLn/+E5557Tn1i4sQPP/zAul8QWBenCw8ZKchDYBiGiTNsEBQ8XMQwTNxhg6BgD4EJHdOkf8dxS2fmJ6jMg6YvOc4G4eltvPnCL/Hi2LaKrQfq+Jw8e1A4Kv9qATtP1QGq9+ptPFMfTxI/HkJ7tM44rY/OT3SccNY9rTdjpVlb2loTn45Qfj2LrC7y25bydktn/BKezFlHx3H3EC5/jIff/4jv1Pbwi4t4ciuEl7UwBlfeBq7vq7LvXMC9S6tHRuGU8PQQ2nmsI6OWBu8j09CjCQLCLB5TdW9f8XLPWoXXrKLcpfx72KP83fIoeIpjOhOQEGTOOnLE95DRudUNvPLoa/xPfZ6Nb7Bz6zFu7lfx2nmVdP49/FMYm4/+dF8lnA6eHsJaDYPacF0UWqXweExUZklx0/3Y0tE2+j3b6pMaVowOerRSpVs645+wZM46csS3QXj2oIknly/gV/Th6W1sXT0a8vm3SnuThn+ur7oPMT39CvceXYQ2NAZDXr6AS/WmVY7i2We2cj77xkqcqFd6FX7q9UGwOQQrWIexYt02TJyY0H2ngewwfKPqSpoHXaRsSzXrScuAuKUzAQlB5qwjZ9wNwqMbuCJfsNZ25RZw/c57OEe9/HdvAB/81xpK2nyMd66r3v2jx+iv16yhILchpqFRsXNewytq1+I+Pv3wIv5K5exfw5MP/yiMBdV7F/od21DTu6p8P/V6EORbRmY1i6KMWKQSmNhwTPepDEoURrHfgsHDiCcDyzwy/M0h7H+Jm3iMNnXUqZePj/H+6ssy27k3ruFSz7RewJevjdKp1++I07DTUxNP1K7Fy9Avf453rore/lca/kxDTNK7+A8+uqSM1KUb2H90F/epTX7q9cCvh0CBr7O0/jgvqxs7juleK2BP7MuIhdoatngYMXpY5pHib8jo/OvIfXARf2nNOc5//g28dfkxzMkJ5G++xn52A6+pj2QQcv8iL+B30A/+gCuX1LAUfmN5DaPtAXLKDsyLHw+BXggUjILXWI8fQXSvrRjo2Aae+z1riMktnZmfoDJnHTnjew4Bqxv4NY3z00sdN/DpA2tc/9lXd7Gf1HBOfvJCvOiFYfmIXvDKKDx7cBtvvv0YN3/7upUguY+tF1axA2GIPqnhJhkRkDH5HG3bfEKYX1H19BDMKrJFAy02BvHDRfdkJBL5trg36UMb23IJfpGDAr0Pg56L/w+6KSv6o1s645vQZM46csS/QZDDONS7Fy/1Ox8Dt1615hZ2r+HhJ/aXuQerVTz8AvhEDf1cufU13toXPf2xiebX8f7vL+KezPMq7m3WxHGq90tg16r3xXfFeXJOIxy8PIS2uPM6wkSt274Dzb9FiAduutcKdbRQtkJSUjjQCoUDFSdoBZSMhkhPI03hD43S9HTGN6HJnHXkCC9upyAjw7GC4klkC6rRr12FT6FNvlDc0pn5dRFU5qyjMdggKHi10/jCK2wuDqyL0yXAkNFyw2sZMQwTd9ggKIL8DoFhGGYZYYOgYA+BYZi4kxA94wG9DKmHHPe/DMMwcSYx4K/WSHgyK76w7hcH1sXpwkNGDMMwjIQNAsMwDCNhg8AwzPJAPyhzWkDALZ0Zw9EgtPNHP9Ef28JeZ9asIp2u4qzoSYbWU7LgZSvihbPu3cM5MlHBYUujxNEgrNWG4elayNnD1dViHACAQ2jGl6AhNJmI4bClUcFDRn7hEJrxJWgITSY6OGxppAQ3CMLi5lX4ukQ6Lxw4Ky0t9vPKrU5X26jK/bToSfl8aU4p1yrLcg9HPbOJ/EOrL5fHHeaNrCvAITTji3cITSZiOGxpZAQ0CCaq2SJQ6kt3rZ/pYn34hu50kdzaw6BfAYplQO5n0C03fcwRTC+3t1m33MOWIcqjOQfK30CSwuhRej2JRpbSaX10w3Inqe7itmVYQoZDaMYXDqG5ALDMIyOYQTCbaMiHQTlgG5mjYBJCSRSnQmLf94NHucN0Cl4hofydDoq68hD0Ijqi19A0dSRTO1hPC++guYJ6v4aw39nkgXAIzXhyTPcah3M8cVjmkXLycwhyGCiMbxbZJ5Zoo8klDYU9sV8vIdkrQ9fV0FNI0AuBQ2jGE9b9YsMhMcMhmEHQNpARDvO2mhcwmw3bhI1PtBUYsjcv9mnCR6YFLJfyC09g92jiQBkZ+kpaGlXhFxRqdVRSXYTWeRB1cAjNmOKiezlflXcI58hEhqvMOSRmOIje9RRagxxy4n8b/coglwKtfzRAqjLoq7SU176dVm6QovORGlSGB73KJcbKFm0b5c+NyulXhmVjkBoV7s3h4aHac6aVU3XZtiDlM4vL7Lrvi2MplZYa5Ph+mBsvXUyTuZWeks9/Knf01nJLZ47Di9speFGt+MK6Xxzm1oVb6Eu3dGYMNggKfinEF9b94sC6OF1OflKZYRiGWUCA/wMYzPsDBzPG1wAAAABJRU5ErkJggg==

    Thanks

  • You did the 1st part right by posting the sample data. Now can post us the desired results. Then what version of  sql server are you using? because higher version of sql server doesn't requires sum with group by function.. Rather we can usesum with partition by

    Saravanan

  • You can simplify this query, no need to use cross apply or a CTE.
    😎


    USE TEEST;
    GO
    SET NOCOUNT ON

    Declare @test-2 TABLE
    (
    FullName varchar(20),
    AdjType int,
    Adjustment int
    )
    INSERT @test-2 values('Tom Jones', 2, 10)
    INSERT @test-2 values('Tom Jones', 2, 15)
    INSERT @test-2 values('Tom Jones', 3, 100)
    INSERT @test-2 values('Tom Jones', 3, 150)
    INSERT @test-2 values('Ron Olsen', 2, 1000)
    INSERT @test-2 values('Ron Olsen', 2, 1500)
    INSERT @test-2 values('Ron Olsen', 3, 10000)
    INSERT @test-2 values('Ron Olsen', 3, 15000)

    SELECT
     T.FullName
    ,SUM(CASE WHEN T.AdjType = 2 THEN T.Adjustment END) AS AdjustmentDental
    ,SUM(CASE WHEN T.AdjType = 3 THEN T.Adjustment END) AS AdjustmentVision
    ,SUM(CASE WHEN T.AdjType = 2 THEN 1 END) AS AdjustmentDentalCount
    ,SUM(CASE WHEN T.AdjType = 3 THEN 1 END) AS AdjustmentVisionCount
    FROM  @test-2 T
    GROUP BY T.FullName
    ORDER BY T.FullName;

    Output

    FullName  AdjustmentDental AdjustmentVision AdjustmentDentalCount AdjustmentVisionCount
    ----------- ---------------- ---------------- --------------------- ---------------------
    Ron Olsen 2500     25000    2       2
    Tom Jones 25     250     2       2

  • Eirikur Eiriksson - Friday, June 8, 2018 11:22 PM

    You can simplify this query, no need to use cross apply or a CTE.
    😎


    USE TEEST;
    GO
    SET NOCOUNT ON

    Declare @test-2 TABLE
    (
    FullName varchar(20),
    AdjType int,
    Adjustment int
    )
    INSERT @test-2 values('Tom Jones', 2, 10)
    INSERT @test-2 values('Tom Jones', 2, 15)
    INSERT @test-2 values('Tom Jones', 3, 100)
    INSERT @test-2 values('Tom Jones', 3, 150)
    INSERT @test-2 values('Ron Olsen', 2, 1000)
    INSERT @test-2 values('Ron Olsen', 2, 1500)
    INSERT @test-2 values('Ron Olsen', 3, 10000)
    INSERT @test-2 values('Ron Olsen', 3, 15000)

    SELECT
     T.FullName
    ,SUM(CASE WHEN T.AdjType = 2 THEN T.Adjustment END) AS AdjustmentDental
    ,SUM(CASE WHEN T.AdjType = 3 THEN T.Adjustment END) AS AdjustmentVision
    ,SUM(CASE WHEN T.AdjType = 2 THEN 1 END) AS AdjustmentDentalCount
    ,SUM(CASE WHEN T.AdjType = 3 THEN 1 END) AS AdjustmentVisionCount
    FROM  @test-2 T
    GROUP BY T.FullName
    ORDER BY T.FullName;

    Output

    FullName  AdjustmentDental AdjustmentVision AdjustmentDentalCount AdjustmentVisionCount
    ----------- ---------------- ---------------- --------------------- ---------------------
    Ron Olsen 2500     25000    2       2
    Tom Jones 25     250     2       2

    Sorry didn't see the desired results on OP post.  Great solution😊😊😊

    Saravanan

  • I was able to use this in the actual select statement and it worked perfectly.

    Thanks.

  • tshad - Monday, June 11, 2018 1:32 AM

    I was able to use this in the actual select statement and it worked perfectly.

    Thanks.

    You are very welcome.
    😎

    Question, do you know how it works?

  • saravanatn - Friday, June 8, 2018 11:42 PM

    Eirikur Eiriksson - Friday, June 8, 2018 11:22 PM

    You can simplify this query, no need to use cross apply or a CTE.
    😎


    USE TEEST;
    GO
    SET NOCOUNT ON

    Declare @test-2 TABLE
    (
    FullName varchar(20),
    AdjType int,
    Adjustment int
    )
    INSERT @test-2 values('Tom Jones', 2, 10)
    INSERT @test-2 values('Tom Jones', 2, 15)
    INSERT @test-2 values('Tom Jones', 3, 100)
    INSERT @test-2 values('Tom Jones', 3, 150)
    INSERT @test-2 values('Ron Olsen', 2, 1000)
    INSERT @test-2 values('Ron Olsen', 2, 1500)
    INSERT @test-2 values('Ron Olsen', 3, 10000)
    INSERT @test-2 values('Ron Olsen', 3, 15000)

    SELECT
     T.FullName
    ,SUM(CASE WHEN T.AdjType = 2 THEN T.Adjustment END) AS AdjustmentDental
    ,SUM(CASE WHEN T.AdjType = 3 THEN T.Adjustment END) AS AdjustmentVision
    ,SUM(CASE WHEN T.AdjType = 2 THEN 1 END) AS AdjustmentDentalCount
    ,SUM(CASE WHEN T.AdjType = 3 THEN 1 END) AS AdjustmentVisionCount
    FROM  @test-2 T
    GROUP BY T.FullName
    ORDER BY T.FullName;

    Output

    FullName  AdjustmentDental AdjustmentVision AdjustmentDentalCount AdjustmentVisionCount
    ----------- ---------------- ---------------- --------------------- ---------------------
    Ron Olsen 2500     25000    2       2
    Tom Jones 25     250     2       2

    Sorry didn't see the desired results on OP post.  Great solution😊😊😊

    Dear Admin,
    Why my response is marked as answer. When Eirikur Eiriksson gives the perfect solution. Kindly remove it and mark his response as answer.

    Saravanan

  • saravanatn - Monday, June 11, 2018 4:00 AM

    saravanatn - Friday, June 8, 2018 11:42 PM

    Eirikur Eiriksson - Friday, June 8, 2018 11:22 PM

    You can simplify this query, no need to use cross apply or a CTE.
    😎


    USE TEEST;
    GO
    SET NOCOUNT ON

    Declare @test-2 TABLE
    (
    FullName varchar(20),
    AdjType int,
    Adjustment int
    )
    INSERT @test-2 values('Tom Jones', 2, 10)
    INSERT @test-2 values('Tom Jones', 2, 15)
    INSERT @test-2 values('Tom Jones', 3, 100)
    INSERT @test-2 values('Tom Jones', 3, 150)
    INSERT @test-2 values('Ron Olsen', 2, 1000)
    INSERT @test-2 values('Ron Olsen', 2, 1500)
    INSERT @test-2 values('Ron Olsen', 3, 10000)
    INSERT @test-2 values('Ron Olsen', 3, 15000)

    SELECT
     T.FullName
    ,SUM(CASE WHEN T.AdjType = 2 THEN T.Adjustment END) AS AdjustmentDental
    ,SUM(CASE WHEN T.AdjType = 3 THEN T.Adjustment END) AS AdjustmentVision
    ,SUM(CASE WHEN T.AdjType = 2 THEN 1 END) AS AdjustmentDentalCount
    ,SUM(CASE WHEN T.AdjType = 3 THEN 1 END) AS AdjustmentVisionCount
    FROM  @test-2 T
    GROUP BY T.FullName
    ORDER BY T.FullName;

    Output

    FullName  AdjustmentDental AdjustmentVision AdjustmentDentalCount AdjustmentVisionCount
    ----------- ---------------- ---------------- --------------------- ---------------------
    Ron Olsen 2500     25000    2       2
    Tom Jones 25     250     2       2

    Sorry didn't see the desired results on OP post.  Great solution😊😊😊

    Dear Admin,
    Why my response is marked as answer. When Eirikur Eiriksson gives the perfect solution. Kindly remove it and mark his response as answer.

    Don't worry about it Saravanan, tshad just made a mistake there, but it is clear what the correct answer is and your post contains that answer then is's all fine.
    😎

  • Eirikur Eiriksson - Monday, June 11, 2018 4:33 AM

    saravanatn - Monday, June 11, 2018 4:00 AM

    saravanatn - Friday, June 8, 2018 11:42 PM

    Eirikur Eiriksson - Friday, June 8, 2018 11:22 PM

    You can simplify this query, no need to use cross apply or a CTE.
    😎


    USE TEEST;
    GO
    SET NOCOUNT ON

    Declare @test-2 TABLE
    (
    FullName varchar(20),
    AdjType int,
    Adjustment int
    )
    INSERT @test-2 values('Tom Jones', 2, 10)
    INSERT @test-2 values('Tom Jones', 2, 15)
    INSERT @test-2 values('Tom Jones', 3, 100)
    INSERT @test-2 values('Tom Jones', 3, 150)
    INSERT @test-2 values('Ron Olsen', 2, 1000)
    INSERT @test-2 values('Ron Olsen', 2, 1500)
    INSERT @test-2 values('Ron Olsen', 3, 10000)
    INSERT @test-2 values('Ron Olsen', 3, 15000)

    SELECT
     T.FullName
    ,SUM(CASE WHEN T.AdjType = 2 THEN T.Adjustment END) AS AdjustmentDental
    ,SUM(CASE WHEN T.AdjType = 3 THEN T.Adjustment END) AS AdjustmentVision
    ,SUM(CASE WHEN T.AdjType = 2 THEN 1 END) AS AdjustmentDentalCount
    ,SUM(CASE WHEN T.AdjType = 3 THEN 1 END) AS AdjustmentVisionCount
    FROM  @test-2 T
    GROUP BY T.FullName
    ORDER BY T.FullName;

    Output

    FullName  AdjustmentDental AdjustmentVision AdjustmentDentalCount AdjustmentVisionCount
    ----------- ---------------- ---------------- --------------------- ---------------------
    Ron Olsen 2500     25000    2       2
    Tom Jones 25     250     2       2

    Sorry didn't see the desired results on OP post.  Great solution😊😊😊

    Dear Admin,
    Why my response is marked as answer. When Eirikur Eiriksson gives the perfect solution. Kindly remove it and mark his response as answer.

    Don't worry about it Saravanan, tshad just made a mistake there, but it is clear what the correct answer is and your post contains that answer then is's all fine.
    😎

    Just curious to know how it mark it as answer for a post

    Saravanan

  • saravanatn - Monday, June 11, 2018 4:50 AM

    Just curious to know how it mark it as answer for a post

    Only the original poster can do that.

    Steve (aka sgmunson) 🙂 🙂 🙂
    Rent Servers for Income (picks and shovels strategy)

  • tshad - Monday, June 11, 2018 1:32 AM

    I was able to use this in the actual select statement and it worked perfectly.

    Thanks.

    Like Eirikur asked, though.... do you know how it works?  After all, you're the one that will need to support it and you'll also need to do it again many times in your career.

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

  • My mistake.

    You're right. I just marked the latest one.  Didn't notice that the answer was right above it.

    And yes, I do understand how it works.  Was able to quickly add it to my actual query.

    Thanks

Viewing 12 posts - 1 through 11 (of 11 total)

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