By: Alex Tocitu | Updated: 2011-03-04 | Comments | Related: > Functions User Defined UDF
Problem
You need to use financial functions as a tool to aid you in making business decisions and sometimes to run "what if" scenarios. Although there are numerous packages in the market offering this ability, they may be more than you actually need. Simply using the CLR feature in SQL Server, you are now able to develop your own set of financial functions to calculate, and possibly immediately store your results in the database.
Solution
The .NET Base Class Library provides the Microsoft.VisualBasic namespace which contains the Financial class. Listed below are some of the names of the static methods (13 in total) in the Financial class, used to perform financial operations:
- FV: future value
- IPmt: interest payment
- NPer: number of periods
- Pmt: payment
- PV: present value
- Rate: interest rate
Describing how these financial functions are built, or work internally, is beyond the scope of this article.
In the tip presented here we will show the code necessary to develop SQL CLR C# functions that can be used in scenarios of interest. For example, you may wish to calculate the payment for an annuity based on periodic, fixed payments and a fixed interest rate. (To learn more about creating a CLR function, refer to this tip.)
To be more concrete, the function takes the following input parameters:
- Rate: specifies the interest rate per period. For example, if you get a car loan at an annual percentage rate (APR) of 6 percent and make monthly payments, the rate per period is 0.06/12, or 0.005.
- NPer: specifies the total number of payment periods in the annuity. For example, if you make monthly payments on a five-year car loan, your loan has a total of 5 × 12 (or 60) payment periods.
- PV: specifies the present value (or lump sum) that a series of payments to be paid in the future is worth now. For example, when you borrow money to buy a car, the loan amount is the present value to the lender of the monthly car payments you will make.
- FV: specifies the future value or cash balance you want after you have made the final payment. For example, the future value of a loan is $0 because that is its value after the final payment. However, if you want to save $54,000 during 18 years for your child's education, then $54,000 is the future value.
- EndOfPeriod: specifies when payments are due. This argument must be either 1 if payments are due at the end of the payment period, or 0 if payments are due at the beginning of the period.
Notice that because SQL CLR functions can't take optional parameters, all inputs are required. Also, the EndOfPeriod parameter represents a conversion from the DueDate enumeration in .NET.
And now our function becomes pretty straightforward, with the code sample below having comments to improve clarity:
using System; using System.Data.SqlTypes; using Microsoft.SqlServer.Server; public class FinancialFunctions { [SqlFunction] public static SqlDouble FinancialPayment(SqlDouble rate, SqlDouble nper, SqlDouble pv, SqlDouble fv, SqlBoolean endOfPeriod) { // Returns the payment for an annuity based on periodic, // fixed payments and a fixed interest rate. try { // Test for null values and NPer = 0. if (!rate.IsNull && !nper.IsNull && nper != 0 && !pv.IsNull && !fv.IsNull && !endOfPeriod.IsNull) return Microsoft.VisualBasic.Financial.Pmt( rate.Value, nper.Value, pv.Value, fv.Value, endOfPeriod.Value == true ? Microsoft.VisualBasic.DueDate.EndOfPeriod : Microsoft.VisualBasic.DueDate.BegOfPeriod); else // if any input paramater is NULL, return NULL return SqlDouble.Null; } catch (Exception ex) { // on any error, return NULL return SqlDouble.Null; } } };
A sample SQL Server run is shown in the script below.
The first example shows what the payment would be for a loan of $5,000.00 at 6% for 60 payments.
---------------------------------------- declare @Rate as float = 0.06 / 12 declare @NPer as float = 60 declare @PV as float = - 5000 declare @FV as float = 0 declare @EndOfPeriod as bit = 1 -- select dbo.FinancialPayment( @Rate, @NPer, @PV, @FV, @EndOfPeriod) go; -- returned value: 96.66 ---------------------------------------- declare @Rate as float = 0.05 / 12 declare @NPer as float = 0 declare @PV as float = 0 declare @FV as float = - 54000 declare @EndOfPeriod as bit = 1 -- select dbo.FinancialPayment( @Rate, @NPer, @PV, @FV, @EndOfPeriod) go; -- returned value: NULL ---------------------------------------- declare @Rate as float = 0.05 / 12 declare @NPer as float = 18 * 12 declare @PV as float = 0 declare @FV as float = - 54000 declare @EndOfPeriod as bit = 1 -- select dbo.FinancialPayment( @Rate, @NPer, @PV, @FV, @EndOfPeriod) go; -- returned value: 154.65 ----------------------------------------
The advantages of implementing the basic financial functions are straightforward as they can be used inline of SQL statements as well as to fill computed (and persisted) table columns within your SQL Server database environment.
Financial modules provide a very powerful functionality that every Developer/DBA should attempt to implement if requirements arise.
Our tip discussed here just gets you started writing your own SQL CLR objects embedding this attractive alternative in your BI solutions.
Next Steps
- Compile, deploy, and use the FinancialPayment function; enhance it to suit your needs.
- Explore uses of other financial functions with variable input / output parameters.
- Use complex mathematics in your SQL Server CLR development toolkit.
- Read these other SQL CLR tips on this site.
About the author
This author pledges the content of this article is based on professional experience and not AI generated.
View all my tips
Article Last Updated: 2011-03-04