Login     Register

        Contact Us     Search

XLeratorDB/financial Documentation

SQL Server constant principal rate amortization


ConstantPrincipalRate

Updated: 18 September 2014

Use the table-valued function ConstantPrincipalRate to return the cash flow schedule for a loan with no fixed maturity date where the principal is reduced on using a fixed rate. ConstantPrincipalRate computes the periodic interest and principal amounts until the loan balance has been brought to zero. ConstantPrincipalRate supports separate interest and principal repayment schedules.
The interest and principal payment periods are entered in ConstantPrincipalRate as the number of months between payments. For example, a loan with monthly payments of interest would have an interest frequency of 1. If principal is to be repaid every months, then it would have a principal payment frequency of 6.
ConstantPrincipalRate supports both an initial grace period and an additional grace period during the life of the loan, for principal and/or interest. 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 interest grace period is entered in ConstantPrincipalRate and it is greater than the reference date, then it becomes the first interest payment date and subsequent interest payments are calculated from that date forward. The same principle applies for principal payments.
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 respective 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 respective 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 respective 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 respective 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 rate is calculated as:

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

I
=
InterestRate
R
=
@InterestRate
F
=
@Frequency
T
=
Time, in years, from the previous interest payment date to PaymentDate

In the case where there are one or more principal payments between interest payment dates, the interest payment amount is calculated using the outstanding principal balances during the interest payment period.
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].[ConstantPrincipalRate](
  <@OutstandingAmount, float,>
 ,<@InterestBasis, nvarchar(4000),>
 ,<@InterestRate, float,>
 ,<@FreqPayPrincipal, int,>
 ,<@FreqPayInterest, int,>
 ,<@AmortizationRate, float,>
 ,<@MinimumPayment, float,>
 ,<@ReferenceDate, datetime,>
 ,<@PrevPrincipalPayDate, datetime,>
 ,<@PrevInterestPayDate, datetime,>
 ,<@StartDate, datetime,>
 ,<@FirstPrincipalPayDate, datetime,>
 ,<@FirstInterestPayDate, datetime,>
 ,<@PrincipalGracePeriodStartDate, datetime,>
 ,<@PrincipalGracePeriodEndDate, datetime,>
 ,<@InterestGracePeriodStartDate, datetime,>
 ,<@InterestGracePeriodEndDate, 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
@FreqPayPrincipal
the number of months between principal payments. @ FreqPayPrincipal is an expression of type int or of a type that can be implicitly converted to int.
@FreqPayInterest
the number of months in a regular interest payment. @ FreqPayInterest is an expression of type int or of a type that can be implicitly converted to int.
@AmortizationRate
the percentage, as a decimal (1% = .01), of the outstanding principal amount due on a principal payment date. @AmortizationRate is an expression of type float or of a type that can be implicitly converted to float.
@MinimumPayment
the specified smallest payment amount prior to the last payment. @MinimumPayment is an expression of type float or of a type that can be implicitly converted to float.
@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. 
@PrevPrincipalPayDate
the last principal payment date prior to the reference date. @PrevPrincipalPayDate is an expression that returns a datetime or smalldatetime value, or a character string in date format. 
@PrevInterestPayDate
the last interest payment date prior to the reference date. @PrevPrincipalPayDate 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. 
@FirstPrincipalPayDate
the first principal payment date of the loan if other than a regular periodic payment. @FirstPrincipalPayDate is an expression that returns a datetime or smalldatetime value, or a character string in date format. 
@FirstInterestPayDate
the first interest payment date of the loan if other than a regular periodic payment. @FirstInterestPayDate is an expression that returns a datetime or smalldatetime value, or a character string in date format. 
@PrincipalGracePeriodStartDate
the date on which the (interim) principal grace period commences. @PrincipalGracePeriodStartDate is an expression that returns a datetime or smalldatetime value, or a character string in date format. 
@PrincipalGracePeriodEndDate
the date on which the (interim) principal grace period concludes. @PrincipalGracePeriodEndDate is an expression that returns a datetime or smalldatetime value, or a character string in date format. 
 
@InterestGracePeriodStartDate
the date on which the (interim) interest grace period commences. @InterestGracePeriodStartDate is an expression that returns a datetime or smalldatetime value, or a character string in date format. 
@PrincipalGracePeriodEndDate
the date on which the (interim) interest 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 @FirstInterestPayDate and @InterestGracePeriodEndDate.
·         GraceInterest is only calculated if length of the grace interest period is greater than @FreqPayInterest.
·         GraceInterest is the difference between the interest for the period from the previous interest payment to PaymentDate and interest that would have been calculated for a period with length equal to @FreqPayInterest.
·         PrincipalPayment = MIN(MAX(@AmortizationRate * CapitalAmountInDebt(Period-1), @MinimumPayment), CapitalAmountInDebt(Period-1).
·         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 @FreqPayInterest.
Examples
This is a 100,000 loan with quarterly payments of principal and interest and an interest rate of 3.0%. The principal payments are calculated as 13.0% of the outstanding principal balance, with a minimum payment of 2,500.00.
SELECT
       *
FROM wct.ConstantPrincipalRate(
  100000            --@OutstandingAmount
 ,'Actual/365'      --@InterestBasis
 ,.03               --@InterestRate
 ,3                 --@FreqPayPrincipal
 ,3                 --@FreqPayInterest
 ,.13               --@AmortizationRate
 ,2500              --@MinimumPayment
 ,'2014-10-01'      --@ReferenceDate
 ,NULL              --@PrevPrincipalPayDate
 ,NULL              --@PrevInterestPayDate
 ,NULL              --@StartDate
 ,NULL              --@FirstPrincipalPayDate
 ,NULL              --@FirstInterestPayDate
 ,NULL              --@PrincipalGracePeriodStartDate
 ,NULL              --@PrincipalGracePeriodEndDate
 ,NULL              --@InterestGracePeriodStartDate
 ,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
100000.00
100000.00
100000.00
0
2014-10-31
0.00
0.000000
1
13000.00
756.19
13756.19
100756.19
87000.00
100756.19
3
2015-01-31
0.00
0.007562
2
11310.00
636.35
11946.35
101392.54
75690.00
87636.35
6
2015-04-30
0.00
0.007314
3
9839.70
572.36
10412.06
101964.90
65850.30
76262.36
9
2015-07-31
0.00
0.007562
4
8560.54
497.95
9058.49
102462.85
57289.76
66348.25
12
2015-10-31
0.00
0.007562
5
7447.67
433.22
7880.89
102896.07
49842.09
57722.98
15
2016-01-31
0.00
0.007562
6
6479.47
368.68
6848.15
103264.74
43362.62
50210.77
18
2016-04-30
0.00
0.007397
7
5637.14
327.90
5965.04
103592.65
37725.48
43690.52
21
2016-07-31
0.00
0.007562
8
4904.31
285.28
5189.59
103877.92
32821.17
38010.75
24
2016-10-31
0.00
0.007562
9
4266.75
248.19
4514.94
104126.11
28554.42
33069.36
27
2017-01-31
0.00
0.007562
10
3712.07
208.86
3920.93
104334.97
24842.34
28763.27
30
2017-04-30
0.00
0.007314
11
3229.50
187.85
3417.36
104522.83
21612.84
25030.20
33
2017-07-31
0.00
0.007562
12
2809.67
163.43
2973.10
104686.26
18803.17
21776.27
36
2017-10-31
0.00
0.007562
13
2500.00
142.19
2642.19
104828.45
16303.17
18945.36
39
2018-01-31
0.00
0.007562
14
2500.00
119.25
2619.25
104947.69
13803.17
16422.42
42
2018-04-30
0.00
0.007314
15
2500.00
104.38
2604.38
105052.07
11303.17
13907.55
45
2018-07-31
0.00
0.007562
16
2500.00
85.47
2585.47
105137.54
8803.17
11388.64
48
2018-10-31
0.00
0.007562
17
2500.00
66.57
2566.57
105204.11
6303.17
8869.74
51
2019-01-31
0.00
0.007562
18
2500.00
46.10
2546.10
105250.22
3803.17
6349.27
54
2019-04-30
0.00
0.007314
19
2500.00
28.76
2528.76
105278.98
1303.17
3831.93
57
2019-07-31
0.00
0.007562
20
1303.17
9.85
1313.02
105288.83
0.00
1313.02
60
2019-10-31
0.00
0.007562

The same basic SQL with monthly payments of principal and semi-annual payments of interest.
SELECT
       *
FROM wct.ConstantPrincipalRate(
  100000            --@OutstandingAmount
 ,'Actual/365'      --@InterestBasis
 ,.03               --@InterestRate
 ,1                 --@FreqPayPrincipal
 ,6                 --@FreqPayInterest
 ,.13               --@AmortizationRate
 ,2500              --@MinimumPayment
 ,'2014-10-01'      --@ReferenceDate
 ,NULL              --@PrevPrincipalPayDate
 ,NULL              --@PrevInterestPayDate
 ,NULL              --@StartDate
 ,NULL              --@FirstPrincipalPayDate
 ,NULL              --@FirstInterestPayDate
 ,NULL              --@PrincipalGracePeriodStartDate
 ,NULL              --@PrincipalGracePeriodEndDate
 ,NULL              --@InterestGracePeriodStartDate
 ,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
100000.00
100000.00
100000.00
0
2014-10-31
0.00
0.000000
1
13000.00
0.00
13000.00
100000.00
87000.00
100000.00
1
2014-11-30
0.00
0.002450
2
11310.00
0.00
11310.00
100000.00
75690.00
87000.00
2
2014-12-31
0.00
0.004989
3
9839.70
0.00
9839.70
100000.00
65850.30
75690.00
3
2015-01-31
0.00
0.007534
4
8560.54
0.00
8560.54
100000.00
57289.76
65850.30
4
2015-02-28
0.00
0.009838
5
7447.67
0.00
7447.67
100000.00
49842.09
57289.76
5
2015-03-31
0.00
0.012395
6
6479.47
1082.52
7561.99
101082.52
43362.62
50924.61
6
2015-04-30
0.00
0.014876
7
5637.14
0.00
5637.14
101082.52
37725.48
43362.62
7
2015-05-31
0.00
0.002532
8
4904.31
0.00
4904.31
101082.52
32821.17
37725.48
8
2015-06-30
0.00
0.004989
9
4266.75
0.00
4266.75
101082.52
28554.42
32821.17
9
2015-07-31
0.00
0.007534
10
3712.07
0.00
3712.07
101082.52
24842.34
28554.42
10
2015-08-31
0.00
0.010085
11
3229.50
0.00
3229.50
101082.52
21612.84
24842.34
11
2015-09-30
0.00
0.012560
12
2809.67
476.72
3286.39
101559.24
18803.17
22089.56
12
2015-10-31
0.00
0.015124
13
2500.00
0.00
2500.00
101559.24
16303.17
18803.17
13
2015-11-30
0.00
0.002450
14
2500.00
0.00
2500.00
101559.24
13803.17
16303.17
14
2015-12-31
0.00
0.004989
15
2500.00
0.00
2500.00
101559.24
11303.17
13803.17
15
2016-01-31
0.00
0.007534
16
2500.00
0.00
2500.00
101559.24
8803.17
11303.17
16
2016-02-29
0.00
0.009920
17
2500.00
0.00
2500.00
101559.24
6303.17
8803.17
17
2016-03-31
0.00
0.012478
18
2500.00
188.25
2688.25
101747.49
3803.17
6491.42
18
2016-04-30
0.00
0.014959
19
2500.00
0.00
2500.00
101747.49
1303.17
3803.17
19
2016-05-31
0.00
0.002532
20
1303.17
12.85
1316.02
101760.34
0.00
1316.02
20
2016-06-30
0.00
0.004989

In this example, we modify the SQL so that first interest payment isn't due until January of 2015 and the first principal payment isn't due until March of 2015.
SELECT
       *
FROM wct.ConstantPrincipalRate(
  100000            --@OutstandingAmount
 ,'Actual/365'      --@InterestBasis
 ,.03               --@InterestRate
 ,1                 --@FreqPayPrincipal
 ,6                 --@FreqPayInterest
 ,.13               --@AmortizationRate
 ,2500              --@MinimumPayment
 ,'2014-10-01'      --@ReferenceDate
 ,NULL              --@PrevPrincipalPayDate
 ,NULL              --@PrevInterestPayDate
 ,NULL              --@StartDate
 ,'2015-03-01'      --@FirstPrincipalPayDate
 ,'2015-01-01'      --@FirstInterestPayDate
 ,NULL              --@PrincipalGracePeriodStartDate
 ,NULL              --@PrincipalGracePeriodEndDate
 ,NULL              --@InterestGracePeriodStartDate
 ,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
100000.00
100000.00
100000.00
0
2014-10-31
0.00
0.000000
1
0.00
753.37
753.37
100753.37
100000.00
100753.37
3
2015-01-31
0.00
0.007534
2
13000.00
0.00
13000.00
100753.37
87000.00
100000.00
5
2015-03-31
0.00
0.004825
3
11310.00
0.00
11310.00
100753.37
75690.00
87000.00
6
2015-04-30
0.00
0.007287
4
9839.70
0.00
9839.70
100753.37
65850.30
75690.00
7
2015-05-31
0.00
0.009838
5
8560.54
0.00
8560.54
100753.37
57289.76
65850.30
8
2015-06-30
0.00
0.012312
6
7447.67
1201.57
8649.24
101954.95
49842.09
58491.33
9
2015-07-31
0.00
0.014876
7
6479.47
0.00
6479.47
101954.95
43362.62
49842.09
10
2015-08-31
0.00
0.002532
8
5637.14
0.00
5637.14
101954.95
37725.48
43362.62
11
2015-09-30
0.00
0.004989
9
4904.31
0.00
4904.31
101954.95
32821.17
37725.48
12
2015-10-31
0.00
0.007534
10
4266.75
0.00
4266.75
101954.95
28554.42
32821.17
13
2015-11-30
0.00
0.010003
11
3712.07
0.00
3712.07
101954.95
24842.34
28554.42
14
2015-12-31
0.00
0.012560
12
3229.50
547.60
3777.11
102502.55
21612.84
25389.95
15
2016-01-31
0.00
0.015124
13
2809.67
0.00
2809.67
102502.55
18803.17
21612.84
16
2016-02-29
0.00
0.002369
14
2500.00
0.00
2500.00
102502.55
16303.17
18803.17
17
2016-03-31
0.00
0.004907
15
2500.00
0.00
2500.00