Calculating interest query

  • I'm currently in the process of trying to calculate interest we need to pay out to our customers. I have calculated refunds for all of our customers that returns the data in the following format:

    acct_no , refund, month, year

    I have another table that contains interest rate information for each month that has the following format:

    interest rate, month, year

    I need a way to calculate the compound interest and so far I am having no luck. Thank you in advance for any help.

  • Nathan,

    My recommendation would be for you to read the article at the first link in my signature line below. Following the recommendations for how to post in that article will probably get you a fully tested answer in the form of code and in very short order. Help us help you.

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

  • as already mentioned, pls provide create table, insert data and expected results.

  • Thank you for pointing out proper posting etiquette. I had not seen that article before and I apologize.

    IF OBJECT_ID('TempDB..#InterestRates','U') IS NOT NULL

    DROP TABLE #InterestRates

    CREATE TABLE #InterestRates

    (

    [InterestRate] [float] NULL,

    [Month] [int] NULL,

    [year] [int] NULL

    )

    INSERT INTO #InterestRates

    (InterestRate,[Month],[Year])

    SELECT '0.105','8','2007' UNION ALL

    SELECT '0.105','9','2007' UNION ALL

    SELECT '0.105','10','2007' UNION ALL

    SELECT '0.105','11','2007' UNION ALL

    SELECT '0.105','12','2007' UNION ALL

    SELECT '0.105','1','2008' UNION ALL

    SELECT '0.105','2','2008' UNION ALL

    SELECT '0.105','3','2008' UNION ALL

    SELECT '0.105','4','2008' UNION ALL

    SELECT '0.105','5','2008' UNION ALL

    SELECT '0.105','6','2008' UNION ALL

    SELECT '0.105','7','2008' UNION ALL

    SELECT '0.105','8','2008' UNION ALL

    SELECT '0.105','9','2008' UNION ALL

    SELECT '0.105','10','2008' UNION ALL

    SELECT '0.105','11','2008' UNION ALL

    SELECT '0.105','12','2008' UNION ALL

    SELECT '0.105','1','2009' UNION ALL

    SELECT '0.105','2','2009' UNION ALL

    SELECT '0.105','3','2009' UNION ALL

    SELECT '0.105','4','2009' UNION ALL

    SELECT '0.105','5','2009' UNION ALL

    SELECT '0.105','6','2009' UNION ALL

    SELECT '0.0067','7','2009' UNION ALL

    SELECT '0.0067','8','2009' UNION ALL

    SELECT '0.0067','9','2009' UNION ALL

    SELECT '0.0055','10','2009' UNION ALL

    SELECT '0.0055','11','2009' UNION ALL

    SELECT '0.0055','12','2009' UNION ALL

    SELECT '0.0055','1','2010' UNION ALL

    SELECT '0.0055','2','2010'

    IF OBJECT_ID('TempDB..#Refunds','U') IS NOT NULL

    DROP TABLE #Refunds

    CREATE TABLE #Refunds

    (

    [Acct_no] [varchar(20)] NULL,

    [Amount] [float] NULL,

    [Month] [int] NULL,

    [year] [int] NULL

    )

    INSERT INTO #Refunds

    (Acct_no,Amount, [Month],[year])

    SELECT '1271003600','333.107456586203','1','2008' UNION ALL

    SELECT '1271003600','87.6816131178288','1','2009' UNION ALL

    SELECT '1271003600','103.602002310821','2','2008' UNION ALL

    SELECT '1271003600','81.9722910242125','2','2009' UNION ALL

    SELECT '1271003600','72.3401647559977','3','2008' UNION ALL

    SELECT '1271003600','86.1625895742832','3','2009' UNION ALL

    SELECT '1271003600','103.361218989159','4','2008' UNION ALL

    SELECT '1271003600','84.6065155612006','4','2009' UNION ALL

    SELECT '1271003600','92.2834655375568','5','2008' UNION ALL

    SELECT '1271003600','84.6688365382596','5','2009' UNION ALL

    SELECT '1271003600','89.0687598341003','6','2008' UNION ALL

    SELECT '1271003600','79.1241550533365','6','2009' UNION ALL

    SELECT '1271003600','123.131877952709','7','2008' UNION ALL

    SELECT '1271003600','89.3938505146093','7','2009' UNION ALL

    SELECT '1271003600','87.2510378856992','8','2007' UNION ALL

    SELECT '1271003600','94.0687846832911','8','2008' UNION ALL

    SELECT '1271003600','340.381691069552','8','2009' UNION ALL

    SELECT '1271003600','80.3632310400272','9','2007' UNION ALL

    SELECT '1271003600','121.96840107118','9','2008' UNION ALL

    SELECT '1271003600','87.1037670414245','10','2007' UNION ALL

    SELECT '1271003600','94.9861134399298','10','2008' UNION ALL

    SELECT '1271003600','73.8008470324637','11','2007' UNION ALL

    SELECT '1271003600','78.537373182859','11','2008' UNION ALL

    SELECT '1271003600','90.7988754111144','12','2007' UNION ALL

    SELECT '1271003600','88.4954811818565','12','2008' UNION ALL

    SELECT '1271005700 ','651.764','1','2008' UNION ALL

    SELECT '1271005700 ','650.766','1','2009' UNION ALL

    SELECT '1271005700 ','897.994','2','2008' UNION ALL

    SELECT '1271005700 ','688.486','2','2009' UNION ALL

    SELECT '1271005700 ','721.466','3','2008' UNION ALL

    SELECT '1271005700 ','718.654','3','2009' UNION ALL

    SELECT '1271005700 ','913.072','4','2008' UNION ALL

    SELECT '1271005700 ','863.224','4','2009' UNION ALL

    SELECT '1271005700 ','735.081','5','2008' UNION ALL

    SELECT '1271005700 ','647.368','5','2009' UNION ALL

    SELECT '1271005700 ','607.721','6','2008' UNION ALL

    SELECT '1271005700 ','580.359','6','2009' UNION ALL

    SELECT '1271005700 ','718.969','7','2008' UNION ALL

    SELECT '1271005700 ','693.378','7','2009' UNION ALL

    SELECT '1271005700 ','734.005','8','2007' UNION ALL

    SELECT '1271005700 ','591.788','8','2008' UNION ALL

    SELECT '1271005700 ','679.773','8','2009' UNION ALL

    SELECT '1271005700 ','560.296','9','2007' UNION ALL

    SELECT '1271005700 ','685.047','9','2008' UNION ALL

    SELECT '1271005700 ','682.834','10','2007' UNION ALL

    SELECT '1271005700 ','608.706','10','2008' UNION ALL

    SELECT '1271005700 ','586.172','11','2007' UNION ALL

    SELECT '1271005700 ','650.191','11','2008' UNION ALL

    SELECT '1271005700 ','858.672','12','2007' UNION ALL

    SELECT '1271005700 ','711.708','12','2008'

    The formula I am using to calculate interest is

    Interest(month) =( Refund(PreviousMonth) + Interest(Previous Month) ) * (1+ InterestRate(Month)/12)

    For Example

    Interest(August 2008) = ( 0 + 0)*(1+.105/12) = 0

    Interest(September 2008) = ( 87.25 + 0 )*(1+.105/12) = 88.01

    Interest(October 2008) = (80.36 + 88.01)*(1+.105/12) = 169.851

    There are no more refunds to add after August 2009 but we continue to accrue interest until February 2010

    For the account above I get a Final balance of 3011.41

    If anything above is unclear please let me know and thank you for your help.

  • Hi Nathan

    Thanks for posting the sample data and expected results, it doesn't half make a difference. Top work.

    Here you go.

    ;WITH CTEdata AS (

    SELECT ExecSeq = ROW_NUMBER() OVER (ORDER BY Dates.[year], Dates.[Month]),

    r.Acct_no, r.Amount, Dates.[Month], Dates.[year], i.InterestRate, CAST(0 AS float) AS Interest

    FROM (

    SELECT [Year], [month]

    FROM (

    (SELECT TOP 12 [month] = ROW_NUMBER() OVER(ORDER BY [name]) FROM master.sys.columns) m

    CROSS JOIN

    (SELECT 2007 AS [Year] UNION ALL SELECT 2008 UNION ALL SELECT 2009 UNION ALL SELECT 2010) y

    )

    WHERE NOT ([Year] = 2010 AND [month] > 2) AND NOT ([Year] = 2007 AND [month] < 8)

    ) Dates

    LEFT JOIN #Refunds r ON r.[year] = Dates.[year] AND r.[Month] = Dates.[Month]

    LEFT JOIN #InterestRates i ON i.[year] = Dates.[year] AND i.[Month] = Dates.[Month]),

    Calculator AS (

    SELECT ExecSeq,

    Acct_no,

    Amount,

    [Month],

    [year],

    InterestRate,

    Interest

    FROM CTEdata WHERE ExecSeq = 1

    UNION ALL

    SELECT cr.ExecSeq,

    ISNULL(cr.Acct_no, lr.Acct_no),

    ISNULL(cr.Amount, 0),

    cr.[Month],

    cr.[year],

    cr.InterestRate,

    Interest = (lr.Amount + lr.Interest) * (1 + (cr.InterestRate/12))

    FROM Calculator lr

    INNER JOIN CTEdata cr ON cr.ExecSeq = lr.ExecSeq+1

    )

    SELECT * FROM Calculator ORDER BY ExecSeq


    [font="Arial"]Low-hanging fruit picker and defender of the moggies[/font]

    For better assistance in answering your questions, please read this[/url].


    Understanding and using APPLY, (I)[/url] and (II)[/url] Paul White[/url]

    Hidden RBAR: Triangular Joins[/url] / The "Numbers" or "Tally" Table: What it is and how it replaces a loop[/url] Jeff Moden[/url]

  • nathan 7372 (2/26/2010)


    Thank you for pointing out proper posting etiquette. I had not seen that article before and I apologize.

    Absolutely no problem and no need to apologize. You're new and I figured you needed a leg up to get a good answer. Looks like Chris jumped right in there as soon as you posted the data. Very well done.

    If I have time tonight after I get home from work, I'll try to show you a different way.

    --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/26/2010)


    nathan 7372 (2/26/2010)


    Thank you for pointing out proper posting etiquette. I had not seen that article before and I apologize.

    Absolutely no problem and no need to apologize. You're new and I figured you needed a leg up to get a good answer. Looks like Chris jumped right in there as soon as you posted the data. Very well done.

    If I have time tonight after I get home from work, I'll try to show you a different way.

    Absolutely. Excellent description of the problem, easily-consumable data - what more could you ask for? 😎

    Jeff, apologies if you feel I was treading on your toes here - I figured you'd come up with a quirky update solution, so the OP will have choice. The obvious third alternative (correlated subquery/triangular join) will likely appear too - they're all yours, mate :Whistling:

    Cheers

    ChrisM


    [font="Arial"]Low-hanging fruit picker and defender of the moggies[/font]

    For better assistance in answering your questions, please read this[/url].


    Understanding and using APPLY, (I)[/url] and (II)[/url] Paul White[/url]

    Hidden RBAR: Triangular Joins[/url] / The "Numbers" or "Tally" Table: What it is and how it replaces a loop[/url] Jeff Moden[/url]

  • ChrisM@home (2/26/2010)


    Jeff, apologies if you feel I was treading on your toes here - I figured you'd come up with a quirky update solution, so the OP will have choice. The obvious third alternative (correlated subquery/triangular join) will likely appear too - they're all yours, mate :Whistling:

    Oh no... please don't feel that way. Absolutely no offense taken over here and no apologies required. You did great, Chris. In fact, I don't feel pressured now because someone did have the time to produce a coded answer to some great data.

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

  • Besides the method of calculating and updating, you'll want to reconsider the datatype choices. Generally, FLOAT is inappropriate for financial calculations due to rounding issues. Microsoft recommends DECIMAL instead.

    See http://msdn.microsoft.com/en-us/library/system.decimal.aspx

    To quote the "remarks" in that article:

    The Decimal value type is appropriate for financial calculations requiring large numbers of significant integral and fractional digits and no round-off errors. The Decimal type does not eliminate the need for rounding. Rather, it minimizes errors due to rounding.

  • Thank you very much for your help. I only have a very basic understanding of CTEs but I'm sure I will be able to puzzle out exactly what's happening after a bit of studying. I'm sure it's much better than the only solution I was able to imagine which involved a cursor and some temporary tables. I will let you know how it works once it finishes running. I had to raise the recursion limit and the query has been running for over an hour so far. Thankfully it only has to be run once assuming the numbers come out right. 🙂

    I look forward to seeing some other solutions if anyone has any. I always like to learn more and this problem really stumped me.

  • Well after 1 hour and 11 minutes it reached the maximum recursion of 32767 and terminated. I'm going to try and figure out what exactly this query is doing because it works beautifully when there is only one account but when you add more than one account it breaks. I'm going to edit the sample data to include another account. Sorry about that.

  • nathan 7372 (2/26/2010)


    Well after 1 hour and 11 minutes it reached the maximum recursion of 32767 and terminated. I'm going to try and figure out what exactly this query is doing because it works beautifully when there is only one account but when you add more than one account it breaks. I'm going to edit the sample data to include another account. Sorry about that.

    I was afraid of that when I saw the recursive CTE. They actually tend to be a bit slower than even a cursor. How many rows in total are you processing?

    Also, what do you mean by "Refund"? Are you talking about the Amount column?

    If all goes well, the example I'm writing should give you what you want at a rate of about a million rows every 7 seconds or so. Nope... that's not a misprint.

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

  • Yeah I'm working with refunds so refund=amount. I have 222K rows of data which comes out to about 11K accounts. I will definatly be interested to see your query especially if it puts out the performance you claim. Thanks

  • nathan 7372 (2/26/2010)


    Yeah I'm working with refunds so refund=amount. I have 222K rows of data which comes out to about 11K accounts. I will definatly be interested to see your query especially if it puts out the performance you claim. Thanks

    Do you have a running balance column in your real table that you need to have filled in? If so, I need you to post the create statement including all indexes for the real refund table, please. It's important.

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

  • Currently there is no running balance column in the table. If I need to add one let me know. I also have no indexes at this point. I probably should add some but I'm not entirely sure what would be a useful index at this point.

Viewing 15 posts - 1 through 15 (of 67 total)

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