Login     Register

        Contact Us     Search

XLeratorDB/financial Documentation

SQL Server amortization for constant payment amount loans


ConstantPaymentAmount

Updated: 18 September 2014

Use the table-valued function ConstantPaymentAmount to return the cash flow schedule for a loan with a fixed payment amount but no fixed maturity date. ConstantPaymentAmount computes the periodic interest and principal amounts until the loan balance has been brought to zero.
The payment period is entered in ConstantPaymentAmount as the number of months between payments. For example, a loan with monthly payments would have a frequency of 1. A loan with quarterly payments would have frequency of 3. A loan with annual payments would have a frequency of 12.
ConstantPaymentAmount supports both an initial grace period and an additional grace period during the life of the loan. All payments and their associated dates are calculated with respect to the reference date supplied to the function (which should not be confused with the start date). If an initial grace period is entered in ConstantPaymentAmount and it is greater than the reference rate, then it becomes the first interest payment date and subsequent interest payments are calculated from that date forward.
If any payments would otherwise occur in the specified grace period, then that payment is moved to the end of the grace period and all remaining payments are calculated from the end of the grace period.
If no initial grace period is specified then the first payment date is calculated using the interest payment frequency. If the start date has been entered and the number of months between the start date and the reference date is less than the frequency, then the first payment date is calculated by adding the frequency (as a number of months) to the start date.
If no start date has been entered but a previous payment date has been entered and the number of months between the previous payment date and the reference date is less than the frequency, then the first payment date is calculated by adding the frequency (as a number of months) to the previous payment date.
If there is no start date and previous payment dates or the number of months between those dates and the reference date is greater than the frequency, then the first payment date is calculated by adding the frequency (as a number of months) to the reference date.
All payments in the resultant table are moved to the end of the month and interest is calculated using these end-of-month dates.
The interest payment is calculated as:

Formula for XLeratorDB ConstantPaymentAmount loan schedule function for SQL Server
Where:

I
=
InterestPayment
P
=
@OutstandingAmount
R
=
@InterestRate
F
=
@Frequency
T
=
Time, in years, from PaymentDate(Period-1) to PaymentDate

If the irregular period is longer than the regular period then the interest amount is broken out into the regular interest amount and a 'grace' interest amount.
Syntax
SELECT * FROM [wct].[ConstantPaymentAmount](
  <@OutstandingAmount, float,>
 ,<@InterestBasis, nvarchar(4000),>
 ,<@InterestRate, float,>
 ,<@PaymentFrequency, int,>
 ,<@PaymentAmount, float,>
 ,<@ReferenceDate, datetime,>
 ,<@PrevPayDate, datetime,>
 ,<@StartDate, datetime,>
 ,<@FirstPayDate, datetime,>
 ,<@GracePeriodStartDate, datetime,>
 ,<@GracePeriodEndDate, datetime,>)
Arguments
@OutstandingAmount
the principal amount of the loan. @OutstandingAmount is an expression of type float or of a type that can be implicitly converted to float.
@InterestBasis
the day count convention used to calculate the interest amount. @InterestBasis can be 30/360, Actual/360, Actual/365, or Actual/Actual. @InterestBasis is an expression of the character string data type category.
@InterestRate
the annual rate of interest for the loan. @InterestRate is an expression of type float or of a type that can be implicitly converted to float
@PaymentFrequency
the number of months in a regular interest payment. @PaymentFrequency is an expression of type int or of a type that can be implicitly converted to int.
@PaymentAmount
the amount of the periodic payment. @PaymentAmount is an expression that returns a float or float value, or a character string in date format. 
@ReferenceDate
the starting date for the number of months with respect to all other dates. @ReferenceDate is an expression that returns a datetime or smalldatetime value, or a character string in date format. 
@PrevPayDate
the last interest payment date prior to the reference date. @PrevPayDate is an expression that returns a datetime or smalldatetime value, or a character string in date format. 
@StartDate
the start date of the loan. @StartDate is an expression that returns a datetime or smalldatetime value, or a character string in date format. 
@FirstPayDate
the first payment date of the loan if other than a regular periodic payment. @FirstPayDate is an expression that returns a datetime or smalldatetime value, or a character string in date format. 
@GracePeriodStartDate
the date on which the (interim) grace period commences. @GracePeriodStartDate is an expression that returns a datetime or smalldatetime value, or a character string in date format. 
@GracePeriodEndDate
the date on which the (interim) grace period concludes. @GracePeriodEndDate is an expression that returns a datetime or smalldatetime value, or a character string in date format. 
Return Type
RETURNS TABLE (
       [Period] [int] NULL,
       [PrincipalPayment] [float] NULL,
       [InterestPayment] [float] NULL,
       [CashFlow] [float] NULL,
       [OutstandingExposure] [float] NULL,
       [CapitalAmountInDebt] [float] NULL,
       [TotalExposure] [float] NULL,
       [NumberOfMonth] [int] NULL,
       [PaymentDate] [datetime] NULL,
       [GraceInterest] [float] NULL,
       [InterestRate] [float] NULL
)

Column
Description
Period
A reference number uniquely identifying a row in the resultant table.
PrincipalPayment
The amount of the principal payment.
InterestPayment
The amount of the regular interest payment.
CashFlow
PrincipalPayment + InterestPayment + GraceInterest.
OutstandingExposure
When Period = 0 then @OutstandingAmount. For Period > 0 then OutstandingExposure(Period-1) + InterestPayment.
CapitalAmountInDebt
When Period = 0, @OutstandingAmount. For Period > 0 then CapitalAmountInDebt(Period-1) – PrincipalPayment
TotalExposure
When Period = 0, @OutstandingAmount. For Period > 0 then CapitalAmountInDebt(Period-1) + InterestPayment
NumberOfMonth
The number of months between the @ReferenceDate and the PaymentDate.
PaymentDate
The end-of-month date of the payment.
GraceInterest
The amount of the grace interest
InterestRate
The interest amount from PaymentDate(Period-1) to PaymentDate assuming a principal amount of 1

 
Remarks
·         The PaymentDate for all rows is generated as the last day of the month.
·         For Period = 0, PrincipalPayment, InterestPayment, CashFlow, NumberOfMonth, GraceInterest, and InterestRate are set to 0.
·         If @Frequency is NULL then @Frequency = 1
·         If @InterestRate is NULL then @InterestRate = 0
·         If @ReferenceDate is NULL then @ReferenceDate = GETDATE()
·         GraceInterest is only calculated on @FirstPayDate and @GracePeriodEndDate.
·         GraceInterest is only calculated if NumberOfMonth – NumberOfMonth(Period-1) > @PaymentFrequency
·         GraceInterest is the difference between the interest for the period from the previous row to the current row minus interest that would have been calculated for a period with length equal to @PaymentFrequency
·         CashFlow may not equal PaymentAmount on @FirstPayDate or @GracePeriodEndDate due to GraceInterest.
·         The final payment is adjusted for CapitalAmountInDebt(Period-1) and the length of the period if it is less than @PaymentFrequency.
·         The last row returned will always be for the maturity date and may be shorter than a regular period depending on the combination of dates and @PaymentFrequency
Examples
This is a simple 300,000 loan with quarterly payments of 17,500 and an interest rate of 5%.
SELECT
       *
FROM wct.ConstantPaymentAmount(
  300000            --@OutstandingAmount
 ,'Actual/360'      --@InterestBasis
 ,.05               --@InterestRate
 ,3                 --@PaymentFrequency
 ,17500             --@PaymentAmount
 ,'2014-12-15'      --@ReferenceDate
 ,NULL              --@PrevPayDate
 ,NULL              --@StartDate
 ,NULL              --@FirstPayDate
 ,NULL              --@GracePeriodStartDate
 ,NULL              --@InterestGracePeriodEndDate
)
This produces the following result (which has been reformatted for ease of viewing).

 Period
Principal Payment
Interest Payment
Cash Flow
Outstanding Exposure
Capital Amount In Debt
Total Exposure
Number Of Month
Payment Date
Grace Interest
Interest Rate
0
0.00
0.00
0.00
300000.00
300000.00
300000.00
0
2014-12-31
0.00
0.000000
1
13750.00
3750.00
17500.00
303750.00
286250.00
303750.00
3
2015-03-31
0.00
0.012500
2
13881.87
3618.13
17500.00
307368.13
272368.13
289868.13
6
2015-06-30
0.00
0.012640
3
14019.26
3480.74
17500.00
310848.87
258348.87
275848.87
9
2015-09-30
0.00
0.012780
4
14198.42
3301.58
17500.00
314150.45
244150.45
261650.45
12
2015-12-31
0.00
0.012780
5
14414.00
3086.00
17500.00
317236.46
229736.46
247236.46
15
2016-03-31
0.00
0.012640
6
14596.19
2903.81
17500.00
320140.27
215140.27
232640.27
18
2016-06-30
0.00
0.012640
7
14750.61
2749.39
17500.00
322889.67
200389.67
217889.67
21
2016-09-30
0.00
0.012780
8
14939.11
2560.89
17500.00
325450.56
185450.56
202950.56
24
2016-12-31
0.00
0.012780
9
15181.87
2318.13
17500.00
327768.69
170268.69
187768.69
27
2017-03-31
0.00
0.012500
10
15347.84
2152.16
17500.00
329920.84
154920.84
172420.84
30
2017-06-30
0.00
0.012640
11
15520.18
1979.82
17500.00
331900.66
139400.66
156900.66
33
2017-09-30
0.00
0.012780
12
15718.52
1781.48
17500.00
333682.14
123682.14
141182.14
36
2017-12-31
0.00
0.012780
13
15953.97
1546.03
17500.00
335228.17
107728.17
125228.17
39
2018-03-31
0.00
0.012500
14
16138.34
1361.66
17500.00
336589.82
91589.82
109089.82
42
2018-06-30
0.00
0.012640
15
16329.52
1170.48
17500.00
337760.30
75260.30
92760.30
45
2018-09-30
0.00
0.012780
16
16538.21
961.79
17500.00
338722.09
58722.09
76222.09
48
2018-12-31
0.00
0.012780
17
16765.97
734.03
17500.00
339456.12
41956.12
59456.12
51
2019-03-31
0.00
0.012500
18
16969.68
530.32
17500.00
339986.43
24986.43
42486.43
54
2019-06-30
0.00
0.012640
19
17180.68
319.32
17500.00
340305.75
7805.75
25305.75
57
2019-09-30
0.00
0.012780
20
7805.75
99.75
7905.50
340405.50
0.00
7905.50
60
2019-12-31
0.00
0.012780

In this example, using the same basic SQL, we add a first payment date so that the first payment will not be paid until 30-June-2015.
SELECT
       *
FROM wct.ConstantPaymentAmount(
  300000            --@OutstandingAmount
 ,'Actual/360'      --@InterestBasis
 ,.05               --@InterestRate
 ,3                 --@PaymentFrequency
 ,17500             --@PaymentAmount
 ,'2014-12-15'      --@ReferenceDate
 ,NULL              --@PrevPayDate
 ,NULL              --@StartDate
 ,'2015-06-30'      --@FirstPayDate
 ,NULL              --@GracePeriodStartDate
 ,NULL              --@InterestGracePeriodEndDate
)
This produces the following result.

Period
Principal Payment
Interest Payment
Cash Flow
Outstanding Exposure
Capital Amount In Debt
Total Exposure
Number Of Month
Payment Date
Grace Interest
Interest Rate
0
0.00
0.00
0.00
300000.00
300000.00
300000.00
0
2014-12-31
0.00
0.000000
1
13708.07
3791.93
21297.40
303791.93
286291.93
303791.93
6
2015-06-30
3797.40
0.025298
2
13841.32
3658.68
17500.00
307450.61
272450.61
289950.61
9
2015-09-30
0.00
0.012780
3
14018.21
3481.79
17500.00
310932.40
258432.40
275932.40
12
2015-12-31
0.00
0.012780
4
14233.48
3266.52
17500.00
314198.93
244198.93
261698.93
15
2016-03-31
0.00
0.012640
5
14413.38
3086.62
17500.00
317285.55
229785.55
247285.55
18
2016-06-30
0.00
0.012640
6
14563.45
2936.55
17500.00
320222.10
215222.10
232722.10
21
2016-09-30
0.00
0.012780
7
14749.56
2750.44
17500.00
322972.54
200472.54
217972.54
24
2016-12-31
0.00
0.012780
8
14994.09
2505.91
17500.00
325478.45
185478.45
202978.45
27
2017-03-31
0.00
0.012500
9
15155.60
2344.40
17500.00
327822.85
170322.85
187822.85
30
2017-06-30
0.00
0.012640
10
15323.35
2176.65
17500.00
329999.50
154999.50
172499.50
33
2017-09-30
0.00
0.012780
11
15519.18
1980.82
17500.00
331980.32
139480.32
156980.32
36
2017-12-31
0.00
0.012780
12
15756.50
1743.50
17500.00
333723.83
123723.83
141223.83
39
2018-03-31
0.00
0.012500
13
15936.16
1563.84
17500.00
335287.67
107787.67
125287.67
42
2018-06-30
0.00
0.012640
14
16122.52
1377.48
17500.00
336665.14
91665.14
109165.14
45
2018-09-30
0.00
0.012780
15
16328.56
1171.44
17500.00
337836.58
75336.58
92836.58
48
2018-12-31
0.00
0.012780
16
16558.29
941.71
17500.00
338778.29
58778.29
76278.29
51
2019-03-31
0.00
0.012500
17
16757.06
742.94
17500.00
339521.23
42021.23
59521.23
54
2019-06-30
0.00
0.012640
18
16962.99
537.01
17500.00
340058.25
25058.25
42558.25
57
2019-09-30
0.00
0.012780
19
17179.77
320.23
17500.00
340378.48
7878.48
25378.48
60
2019-12-31
0.00
0.012780
20
7878.48
99.58
7978.06
340478.06
0.00
7978.06
63
2020-03-31
0.00
0.012640

We modify the SQL so that there are no payments in 2018.
SELECT
       *
FROM wct.ConstantPaymentAmount(
  300000            --@OutstandingAmount
 ,'Actual/360'      --@InterestBasis
 ,.05               --@InterestRate
 ,3                 --@PaymentFrequency
 ,17500             --@PaymentAmount
 ,'2014-12-15'      --@ReferenceDate
 ,NULL              --@PrevPayDate
 ,NULL              --@StartDate
 ,'2015-06-30'      --@FirstPayDate
 ,'2018-01-01'      --@GracePeriodStartDate
 ,'2019-01-01'      --@GracePeriodEndDate
)
This produces the following result.

Period
Principal Payment
Interest Payment
Cash Flow
Outstanding Exposure
Capital Amount In Debt
Total Exposure
Number Of Month
Payment Date
Grace Interest
Interest Rate
0
0.00
0.00
0.00
300000.00
300000.00
300000.00
0
2014-12-31
0.00
0.000000
1
13708.07
3791.93
21297.40
303791.93
286291.93
303791.93
6
2015-06-30
3797.40
0.025298
2
13841.32
3658.68
17500.00
307450.61
272450.61
289950.61
9
2015-09-30
0.00
0.012780
3
14018.21
3481.79
17500.00
310932.40
258432.40
275932.40
12
2015-12-31
0.00
0.012780
4
14233.48
3266.52
17500.00
314198.93
244198.93
261698.93
15
2016-03-31
0.00
0.012640
5
14413.38
3086.62
17500.00
317285.55
229785.55
247285.55
18
2016-06-30
0.00
0.012640
6
14563.45
2936.55
17500.00
320222.10
215222.10
232722.10
21
2016-09-30
0.00
0.012780
7
14749.56
2750.44
17500.00
322972.54
200472.54
217972.54
24
2016-12-31
0.00
0.012780
8
14994.09
2505.91
17500.00
325478.45
185478.45
202978.45
27
2017-03-31
0.00
0.012500
9
15155.60
2344.40
17500.00
327822.85
170322.85
187822.85
30
2017-06-30
0.00
0.012640
10
15323.35
2176.65
17500.00
329999.50
154999.50
172499.50
33
2017-09-30
0.00
0.012780
11
15519.18
1980.82
17500.00
331980.32
139480.32
156980.32
36
2017-12-31
0.00
0.012780
12
15717.50
1782.50
23553.58
333762.82
123762.82
141262.82
49
2019-01-31
6053.58
0.056180
13
15970.26
1529.74
17500.00
335292.56
107792.56
125292.56
52
2019-04-30
0.00
0.012360
14
16122.46
1377.54
17500.00
336670.10
91670.10
109170.10
55
2019-07-31
0.00
0.012780
15
16328.50
1171.50
17500.00
337841.60
75341.60
92841.60
58
2019-10-31
0.00
0.012780
16
16537.17
962.83
17500.00
338804.43
58804.43
76304.43
61
2020-01-31
0.00
0.012780
17
16764.94
735.06
17500.00
339539.49
42039.49
59539.49
64
2020-04-30
0.00
0.012500
18
16962.75
537.25
17500.00
340076.73
25076.73
42576.73
67
2020-07-31
0.00
0.012780
19
17179.53
320.47
17500.00
340397.20
7897.20
25397.20
70
2020-10-31
0.00
0.012780
20
7897.20
100.92
7998.12
340498.12
0.00
7998.12
73
2021-01-31
0.00
0.012780

Using the same basic SQL, we get rid of the first payment date and calculate the first interest payment using the previous payment date.
SELECT
       *
FROM wct.ConstantPaymentAmount(
  300000            --@OutstandingAmount
 ,'Actual/360'      --@InterestBasis
 ,.05               --@InterestRate
 ,3                 --@PaymentFrequency
 ,17500             --@PaymentAmount
 ,'2014-12-15'      --@ReferenceDate
 ,'2014-11-15'      --@PrevPayDate
 ,NULL              --@StartDate
 ,NULL              --@FirstPayDate
 ,'2018-01-01'      --@GracePeriodStartDate
 ,'2019-01-01'      --@GracePeriodEndDate
)
This produces the following result.

Period
Principal Payment
Interest Payment
Cash Flow
Outstanding Exposure
Capital Amount In Debt
Total Exposure
Number Of Month
Payment Date
Grace Interest
Interest Rate
0
0.00
0.00
0.00
300000.00
300000.00
300000.00
0
2014-12-31
0.00
0.000000
1
15046.93
2453.07
17500.00
302453.07
284953.07
302453.07
2
2015-02-28
0.00
0.008177
2
13858.43
3641.57
17500.00
306094.64
271094.64
288594.64
5
2015-05-31
0.00
0.012780
3
14035.53
3464.47
17500.00
309559.11
257059.11
274559.11
8
2015-08-31
0.00
0.012780
4
14250.83
3249.17
17500.00
312808.27
242808.27
260308.27
11
2015-11-30
0.00
0.012640
5
14430.96
3069.04
17500.00
315877.31
228377.31
245877.31
14
2016-02-29
0.00
0.012640
6
14581.44
2918.56
17500.00
318795.87
213795.87
231295.87
17
2016-05-31
0.00
0.012780
7
14767.79
2732.21
17500.00
321528.08
199028.08
216528.08
20
2016-08-31
0.00
0.012780
8
14984.33
2515.67
17500.00
324043.75
184043.75
201543.75
23
2016-11-30
0.00
0.012640
9
15199.45
2300.55
17500.00
326344.30
168844.30
186344.30
26
2017-02-28
0.00
0.012500
10
15342.25
2157.75
17500.00
328502.05
153502.05
171002.05
29
2017-05-31
0.00
0.012780
11
15538.31
1961.69
17500.00
330463.74
137963.74
155463.74
32
2017-08-31
0.00
0.012780
12
15756.17
1743.83
17500.00
332207.57
122207.57
139707.57
35
2017-11-30
0.00
0.012640
13
15938.24
1561.76
23357.39
333769.33
106269.33
123769.33
49
2019-01-31
5857.39
0.060709
14
16186.48
1313.52
17500.00
335082.84
90082.84
107582.84
52
2019-04-30
0.00
0.012360
15
16348.78
1151.22
17500.00
336234.06
73734.06
91234.06
55
2019-07-31
0.00
0.012780
16
16557.71
942.29
17500.00
337176.35
57176.35
74676.35
58
2019-10-31
0.00
0.012780
17
16769.31
730.69
17500.00
337907.03
40407.03
57907.03
61
2020-01-31
0.00
0.012780
18
16994.91
505.09
17500.00
338412.12
23412.12
40912.12
64
2020-04-30
0.00
0.012500
19
17200.80
299.20
17500.00
338711.32
6211.32
23711.32
67
2020-07-31
0.00
0.012780
20
6211.32
79.38
6290.70
338790.70
0.00
6290.70
70
2020-10-31
0.00
0.012780

In this example, we eliminate the grace period and the previous payment date and add a start date.
SELECT
       *
FROM wct.ConstantPaymentAmount(
  300000            --@OutstandingAmount
 ,'Actual/360'      --@InterestBasis
 ,.05               --@InterestRate
 ,3                 --@PaymentFrequency
 ,17500             --@PaymentAmount
 ,'2014-12-15'      --@ReferenceDate
 ,NULL              --@PrevPayDate
 ,'2014-10-15'      --@StartDate
 ,NULL              --@FirstPayDate
 ,NULL              --@GracePeriodStartDate
 ,NULL              --@GracePeriodEndDate
)
This produces the following result.

Period
Principal Payment
Interest Payment
Cash Flow
Outstanding Exposure
Capital Amount In Debt
Total Exposure
Number Of Month
Payment Date
Grace Interest
Interest Rate
0
0.00
0.00
0.00
300000.00
300000.00
300000.00
0
2014-12-31
0.00
0.000000
1
16213.59
1286.41
17500.00
301286.41
283786.41
301286.41
1
2015-01-31
0.00
0.004288
2
13992.33
3507.67
17500.00
304794.08
269794.08
287294.08
4
2015-04-30
0.00
0.012360
3
14052.15
3447.85
17500.00
308241.93
255741.93
273241.93
7
2015-07-31
0.00
0.012780
4
14231.73
3268.27
17500.00
311510.19
241510.19
259010.19
10
2015-10-31
0.00
0.012780
5
14413.61
3086.39
17500.00
314596.59
227096.59
244596.59
13
2016-01-31
0.00
0.012780
6
14661.29
2838.71
17500.00
317435.29
212435.29
229935.29
16
2016-04-30
0.00
0.012500
7
14785.17
2714.83
17500.00
320150.12
197650.12
215150.12
19
2016-07-31
0.00
0.012780
8
14974.12
2525.88
17500.00
322676.00
182676.00
200176.00
22
2016-10-31
0.00
0.012780
9
15165.48
2334.52
17500.00
325010.51
167510.51
185010.51
25
2017-01-31
0.00
0.012780
10
15429.53
2070.47
17500.00
327080.99
152080.99
169580.99
28
2017-04-30
0.00
0.012360
11
15556.47
1943.53
17500.00
329024.51
136524.51
154024.51
31
2017-07-31
0.00
0.012780
12
15755.28
1744.72
17500.00
330769.23
120769.23
138269.23
34
2017-10-31
0.00
0.012780
13
15956.62
1543.38
17500.00
332312.61
104812.61
122312.61
37
2018-01-31
0.00
0.012780
14
16204.49
1295.51
17500.00
333608.12
88608.12
106108.12
40
2018-04-30
0.00
0.012360
15
16367.63
1132.37
17500.00
334740.49
72240.49
89740.49
43
2018-07-31
0.00
0.012780
16
16576.80
923.20
17500.00
335663.69
55663.69
73163.69
46
2018-10-31
0.00
0.012780
17
16788.64
711.36
17500.00
336375.05
38875.05
56375.05
49
2019-01-31
0.00
0.012780
18
17019.49
480.51
17500.00
336855.55
21855.55
39355.55
52
2019-04-30
0.00
0.012360
19
17220.70
279.30
17500.00
337134.86
4634.86
22134.86
55
2019-07-31
0.00
0.012780
20
4634.86
59.23
4694.09
337194.09
0.00
4694.09
58
2019-10-31
0.00
0.012780

 

See Also

 



Copyright 2008-2024 Westclintech LLC         Privacy Policy        Terms of Service