Apportion amounts between account holders when amount is uneven

  • I have a T-SQL problem I need to sort and need help as my grey matter is hurting!

    CREATE TABLE #CustomerAccount

    (

    AccountNoINT,

    Customer1IDINT,

    Customer2IDINT,

    Customer3IDINT,

    Customer4IDINT,

    AccountHoldersTinyInt

    )

    CREATE TABLE #AccountBalance

    (

    AccountNoINT,

    BalanceMONEY,

    InterestMONEY

    )

    INSERT INTO #CustomerAccount(AccountNo, Customer1ID, Customer2ID, Customer3ID, Customer4ID, AccountHolders)

    VALUES(10001,1,0,0,0,1), (20002,2,3,0,0,2), (30003,4,5,6,0,3), (40004, 7,8,9,10,4), (50005,11,12,0,0,2), (60006,13,14,15,0,3), (70007,16,17,18,19,4)

    INSERT INTO #AccountBalance(AccountNo, Balance, Interest)

    VALUES(10001,500,0.54), (20002,459,0.34), (30003, 333, 0.33), (40004, 100, 0.4), (50005, 101, 0.33), (60006, 100, 1), (70007, 112, 0.55)

    SELECT *,

    CASE WHEN Customer1ID != 0 THEN (AB.Balance + AB.Interest) / CA.AccountHolders ELSE 0 END AS AccountHolder1Balance,

    CASE WHEN Customer2ID != 0 THEN (AB.Balance + AB.Interest) / CA.AccountHolders ELSE 0 END AS AccountHolder2Balance,

    CASE WHEN Customer3ID != 0 THEN (AB.Balance + AB.Interest) / CA.AccountHolders ELSE 0 END AS AccountHolder3Balance,

    CASE WHEN Customer4ID != 0 THEN (AB.Balance + AB.Interest) / CA.AccountHolders ELSE 0 END AS AccountHolder4Balance

    FROM #CustomerAccount CA INNER JOIN #AccountBalance AB ON CA.AccountNo = AB.AccountNo

    From the results of the select statement you can see that each of the first four accounts are ok, the balance is equally divisible by the number of account holders for that account and each account holder is apportioned an equal amount.

    The next three accounts however don't divide equally between the number of account holders and spill over into 3+ decimal places which is not acceptable. What I need to be able to do is apportion the primary account holder(s) with a slightly higher amount and subsequent account holders with a rounded down amount which when totalled would equal the balance + interest.

    So, say an account existed with two account holders and the total balance was 1.11 the first account holder would have a balance of 0.56 and the second a balance of 0.55. Again three account holders with 100.00 would equal the first account holder with 33.34 which account holders 2 and 3 would each have 33.33.

    Another scenario would be four account holders a total balance of 1.02, account holders one and two would each be apportioned 0.26 while account holders three and four would each have 0.25 - NOT account holder one with 0.27 and two, three and four with 0.25.

    Is there a way I can do this with SQL and return the appropriate amounts to each of the customer IDs in the CustomerAccount table?

    Any help greatly appreciated.

    Keep the rubber side down and the shiny side up.

  • Here is something that works:CREATE TABLE #CustomerAccount

    (

    AccountNoINT,

    Customer1IDINT,

    Customer2IDINT,

    Customer3IDINT,

    Customer4IDINT,

    AccountHoldersTinyInt

    )

    CREATE TABLE #AccountBalance

    (

    AccountNoINT,

    Balance MONEY,

    InterestMONEY

    )

    INSERT INTO #CustomerAccount(AccountNo, Customer1ID, Customer2ID, Customer3ID, Customer4ID, AccountHolders)

    VALUES(10001,1,0,0,0,1), (20002,2,3,0,0,2), (30003,4,5,6,0,3), (40004, 7,8,9,10,4), (50005,11,12,0,0,2), (60006,13,14,15,0,3), (70007,16,17,18,19,4)

    INSERT INTO #AccountBalance(AccountNo, Balance, Interest)

    VALUES(10001,500,0.54), (20002,459,0.34), (30003, 333, 0.33), (40004, 100, 0.4), (50005, 101, 0.33), (60006, 100, 1), (70007, 112, 0.55)

    SELECT *,

    round(CASE WHEN Customer1ID != 0 THEN (AB.Balance + AB.Interest) / CA.AccountHolders ELSE 0 END,2)

    + (case when Customer2ID = 0 then (AB.Balance + AB.Interest) - ((round((AB.Balance + AB.Interest) / CA.AccountHolders,2)) * CA.AccountHolders) else 0 end) AS AccountHolder1Balance,

    round(CASE WHEN Customer2ID != 0 THEN (AB.Balance + AB.Interest) / CA.AccountHolders ELSE 0 END,2)

    + (case when Customer3ID = 0 and Customer2ID != 0 then (AB.Balance + AB.Interest) - ((round((AB.Balance + AB.Interest) / CA.AccountHolders,2)) * CA.AccountHolders) else 0 end) AS AccountHolder2Balance,

    round(CASE WHEN Customer3ID != 0 THEN (AB.Balance + AB.Interest) / CA.AccountHolders ELSE 0 END,2)

    + (case when Customer4ID = 0 and Customer3ID != 0 then (AB.Balance + AB.Interest) - ((round((AB.Balance + AB.Interest) / CA.AccountHolders,2)) * CA.AccountHolders) else 0 end) AS AccountHolder3Balance,

    round(CASE WHEN Customer4ID != 0 THEN (AB.Balance + AB.Interest) / CA.AccountHolders ELSE 0 END,2)

    + (case when Customer4ID != 0 then (AB.Balance + AB.Interest) - ((round((AB.Balance + AB.Interest) / CA.AccountHolders,2)) * CA.AccountHolders) else 0 end) AS AccountHolder4Balance,

    (AB.Balance + AB.Interest) - ((round((AB.Balance + AB.Interest) / CA.AccountHolders,2)) * CA.AccountHolders) as diff

    FROM #CustomerAccount CA INNER JOIN #AccountBalance AB ON CA.AccountNo = AB.AccountNo You can delete the diff column, but wanted to leave it to show you what it is doing to determine the round issue.



    Microsoft Certified Master - SQL Server 2008
    Follow me on twitter: @keith_tate

    Forum Etiquette: How to post data/code on a forum to get the best help[/url]

  • If Keith's solution won't work for you, this looks like something I covered in my first SSC article:

    Financial Rounding of Allocations [/url]


    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

  • Thank you both! You've both been a great help.

    Apologies for my late reply, only just got back in the office.

    Keep the rubber side down and the shiny side up.

Viewing 4 posts - 1 through 3 (of 3 total)

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