Financial Functions Part One

This category contains the mathematical finance functions of Collabora Office Calc.

ACCRINT

Calculates the accrued interest of a security in the case of periodic payments.

Syntax

ACCRINT(Issue; FirstInterest; Settlement; Rate; [Par]; Frequency [; Basis])

Issue (required) is the issue date of the security.

FirstInterest (required) is the first interest date of the security.

Settlement (required) is the date at which the interest accrued up until then is to be calculated.

Rate (required) is the annual nominal rate of interest (coupon interest rate)

Par (optional) is the par value of the security. If omitted, a default value of 1000 is used.

note

We recommend that you always specify the value that you require for ACCRINT’s Par argument, rather than allowing Calc to apply an arbitrary default. This will make your formula easier to understand and easier to maintain.


Frequency (required) is the number of interest payments per year (1, 2 or 4).

Basis (optional) is chosen from a list of options and indicates how the year is to be calculated.

Basis

Calculation

0 or missing

US method (NASD), 12 months of 30 days each

1

Exact number of days in months, exact number of days in year

2

Exact number of days in month, year has 360 days

3

Exact number of days in month, year has 365 days

4

European method, 12 months of 30 days each


Example

A security is issued on 2001-02-28. First interest is set for 2001-08-31. The settlement date is 2001-05-01. The Rate is 0.1 or 10% and Par is 1000 currency units. Interest is paid half-yearly (frequency is 2). The basis is the US method (0). How much interest has accrued?

=ACCRINT("2001-02-28";"2001-08-31";"2001-05-01";0.1;1000;2;0) returns 16.94444.

ACCRINTM

Calculates the accrued interest of a security in the case of one-off payment at the settlement date.

Syntax

ACCRINTM(Issue; Settlement; Rate [; Par [; Basis]])

Issue (required) is the issue date of the security.

Settlement (required) is the date at which the interest accrued up until then is to be calculated.

Rate (required) is the annual nominal rate of interest (coupon interest rate).

Par (optional) is the par value of the security. If omitted, a default value of 1000 is used.

note

We recommend that you always specify the value that you require for ACCRINTM’s Par argument, rather than allowing Calc to apply an arbitrary default. This will make your formula easier to understand and easier to maintain.


Basis (optional) is chosen from a list of options and indicates how the year is to be calculated.

Basis

Calculation

0 or missing

US method (NASD), 12 months of 30 days each

1

Exact number of days in months, exact number of days in year

2

Exact number of days in month, year has 360 days

3

Exact number of days in month, year has 365 days

4

European method, 12 months of 30 days each


Example

A security is issued on 2001-04-01. The maturity date is set for 2001-06-15. The Rate is 0.1 or 10% and Par is 1000 currency units. The basis of the daily/annual calculation is the daily balance (3). How much interest has accrued?

=ACCRINTM("2001-04-01";"2001-06-15";0.1;1000;3) returns 20.54795.

AMORDEGRC

Calculates the amount of depreciation for a settlement period as degressive amortization. Unlike AMORLINC, a depreciation coefficient that is independent of the depreciable life is used here.

Syntax

AMORDEGRC(Cost; DatePurchased; FirstPeriod; Salvage; Period; Rate [; Basis])

Cost is the acquisition costs.

DatePurchased is the date of acquisition.

FirstPeriod is the end date of the first settlement period.

Salvage is the salvage value of the capital asset at the end of the depreciable life.

Period is the settlement period to be considered.

Rate is the rate of depreciation.

Basis (optional) is chosen from a list of options and indicates how the year is to be calculated.

Basis

Calculation

0 or missing

US method (NASD), 12 months of 30 days each

1

Exact number of days in months, exact number of days in year

2

Exact number of days in month, year has 360 days

3

Exact number of days in month, year has 365 days

4

European method, 12 months of 30 days each


Example

An asset was acquired on 2020-02-01 at a cost of 2000 currency units. The end date of the first settlement period was 2020-12-31. The salvage value of the asset at the end of its depreciable life will be 10 currency units. The rate of depreciation is 0.1 (10%) and the year is calculated using the US method (Basis 0). Assuming degressive depreciation, what is the amount of depreciation in the fourth depreciation period?

=AMORDEGRC(2000; "2020-02-01"; "2020-12-31"; 10; 4; 0.1; 0) returns a depreciation amount of 163 currency units.

note

Be aware that Basis 2 is not supported by Microsoft Excel. Hence, if you use Basis 2 and export your document to XLSX format, it will return an error when opened in Excel.


AMORLINC

Calculates the amount of depreciation for a settlement period as linear amortization. If the capital asset is purchased during the settlement period, the proportional amount of depreciation is considered.

Syntax

AMORLINC(Cost; DatePurchased; FirstPeriod; Salvage; Period; Rate [; Basis])

Cost means the acquisition costs.

DatePurchased is the date of acquisition.

FirstPeriod is the end date of the first settlement period.

Salvage is the salvage value of the capital asset at the end of the depreciable life.

Period is the settlement period to be considered.

Rate is the rate of depreciation.

Basis (optional) is chosen from a list of options and indicates how the year is to be calculated.

Basis

Calculation

0 or missing

US method (NASD), 12 months of 30 days each

1

Exact number of days in months, exact number of days in year

2

Exact number of days in month, year has 360 days

3

Exact number of days in month, year has 365 days

4

European method, 12 months of 30 days each


Example

An asset was acquired on 2020-02-01 at a cost of 2000 currency units. The end date of the first settlement period was 2020-12-31. The salvage value of the asset at the end of its depreciable life will be 10 currency units. The rate of depreciation is 0.1 (10%) and the year is calculated using the US method (Basis 0). Assuming linear depreciation, what is the amount of depreciation in the fourth depreciation period?

=AMORLINC(2000; "2020-02-01"; "2020-12-31"; 10; 4; 0.1; 0) returns a depreciation amount of 200 currency units.

note

Be aware that Basis 2 is not supported by Microsoft Excel. Hence, if you use Basis 2 and export your document to XLSX format, it will return an error when opened in Excel.


DB

Returns the depreciation of an asset for a specified period using the fixed-declining balance method.

This form of depreciation is used if you want to get a higher depreciation value at the beginning of the depreciation (as opposed to linear depreciation). The depreciation value is reduced with every depreciation period by the depreciation already deducted from the initial cost.

Syntax

DB(Cost; Salvage; Life; Period [; Month])

Cost is the initial cost of an asset.

Salvage is the value of an asset at the end of the depreciation.

Life defines the period over which an asset is depreciated.

Period is the length of each period. The length must be entered in the same date unit as the depreciation period.

Month (optional) denotes the number of months for the first year of depreciation. If an entry is not defined, 12 is used as the default.

Example

A computer system with an initial cost of 25,000 currency units is to be depreciated over a three-year period. The salvage value is to be 1,000 currency units. The first period of depreciation comprises 6 months. What is the fixed-declining balance depreciation of the computer system in the second period, which is a full year starting from the end of the first six-month period?

=DB(25000; 1000; 3; 2; 6) returns 11,037.95 currency units.

DDB

Returns the depreciation of an asset for a specified period using the arithmetic-declining method.

Use this form of depreciation if you require a higher initial depreciation value as opposed to linear depreciation. The depreciation value gets less with each period and is usually used for assets whose value loss is higher shortly after purchase (for example, vehicles, computers). Please note that the book value will never reach zero under this calculation type.

Syntax

DDB(Cost; Salvage; Life; Period [; Factor])

Cost fixes the initial cost of an asset.

Salvage fixes the value of an asset at the end of its life.

Life is the number of periods (for example, years or months) defining how long the asset is to be used.

Period states the period for which the value is to be calculated.

Factor (optional) is the factor by which depreciation decreases. If a value is not entered, the default is factor 2.

Example

A computer system with an initial cost of 75,000 currency units is to be depreciated monthly over 5 years. The value at the end of the depreciation is to be 1 currency unit. The factor is 2.

=DDB(75000;1;60;12;2) = 1,721.81 currency units. Therefore, the double-declining depreciation in the twelfth month after purchase is 1,721.81 currency units.

DISC

Calculates the allowance (discount) of a security as a percentage.

Syntax

DISC(Settlement; Maturity; Price; Redemption [; Basis])

Settlement is the date of purchase of the security.

Maturity is the date on which the security matures (expires).

Price is the price of the security per 100 currency units of par value.

Redemption is the redemption value of the security per 100 currency units of par value.

Basis (optional) is chosen from a list of options and indicates how the year is to be calculated.

Basis

Calculation

0 or missing

US method (NASD), 12 months of 30 days each

1

Exact number of days in months, exact number of days in year

2

Exact number of days in month, year has 360 days

3

Exact number of days in month, year has 365 days

4

European method, 12 months of 30 days each


Example

A security is purchased on 2001-01-25; the maturity date is 2001-11-15. The price (purchase price) is 97, the redemption value is 100. Using daily balance calculation (basis 3) how high is the settlement (discount)?

=DISC("2001-01-25";"2001-11-15";97;100;3) returns about 0.0372 or 3.72 per cent.

DURATION

Calculates the duration of a fixed interest security in years.

Syntax

DURATION(Settlement; Maturity; Coupon; Yield; Frequency [; Basis])

Settlement is the date of purchase of the security.

Maturity is the date on which the security matures (expires).

Coupon is the annual coupon interest rate (nominal rate of interest)

Yield is the annual yield of the security.

Frequency is the number of interest payments per year (1, 2 or 4).

Basis (optional) is chosen from a list of options and indicates how the year is to be calculated.

Basis

Calculation

0 or missing

US method (NASD), 12 months of 30 days each

1

Exact number of days in months, exact number of days in year

2

Exact number of days in month, year has 360 days

3

Exact number of days in month, year has 365 days

4

European method, 12 months of 30 days each


Example

A security is purchased on 2001-01-01; the maturity date is 2006-01-01. The Coupon rate of interest is 8%. The yield is 9.0%. Interest is paid half-yearly (frequency is 2). Using daily balance interest calculation (basis 3) how long is the duration?

=DURATION("2001-01-01";"2006-01-01";0.08;0.09;2;3) returns 4.2 years.

EFFECT

Returns the net annual interest rate for a nominal interest rate.

Nominal interest refers to the amount of interest due at the end of a calculation period. Effective interest increases with the number of payments made. In other words, interest is often paid in installments (for example, monthly or quarterly) before the end of the calculation period.

Syntax

EFFECT(Nom; P)

Nom is the nominal interest.

P is the number of interest payment periods per year.

Example

If the annual nominal interest rate is 9.75% and four interest calculation periods are defined, what is the actual interest rate (effective rate)?

=EFFECT(9.75%;4) = 10.11% The annual effective rate is therefore 10.11%.

EFFECT_ADD

Calculates the effective annual rate of interest on the basis of the nominal interest rate and the number of interest payments per annum.

note

The functions whose names end with _ADD or _EXCEL2003 return the same results as the corresponding Microsoft Excel 2003 functions without the suffix. Use the functions without suffix to get results based on international standards.


Syntax

EFFECT_ADD(NominalRate; NPerY)

NominalRate is the annual nominal rate of interest.

NPerY is the number of interest payments per year.

Example

What is the effective annual rate of interest for a 5.25% nominal rate and quarterly payment.

=EFFECT_ADD(0.0525;4) returns 0.053543 or 5.3543%.

IRR

Calculates the internal rate of return for an investment. The values represent cash flow values at regular intervals, at least one value must be negative (payments), and at least one value must be positive (income).

If the payments take place at irregular intervals, use the XIRR function.

Syntax

IRR(Values [; Guess])

Values represents an array containing the values.

Guess (optional) is the estimated value. An iterative method is used to calculate the internal rate of return. If you can provide only few values, you should provide an initial guess to enable the iteration.

note

This function ignores any text or empty cell within a data range. If you suspect wrong results from this function, look for text in the data ranges. To highlight text contents in a data range, use the value highlighting feature.


Example

Under the assumption that cell contents are A1=-10000, A2=3500, A3=7600 and A4=1000, the formula =IRR(A1:A4) gives a result of 11,33%.

warning

Because of the iterative method used, it is possible for IRR to fail and return Error 523, with "Error: Calculation does not converge" in the status bar. In that case, try another value for Guess.


ISPMT

Calculates the level of interest for unchanged amortization installments.

Syntax

ISPMT(Rate; Period; TotalPeriods; Invest)

Rate sets the periodic interest rate.

Period is the number of installments for calculation of interest.

TotalPeriods is the total number of installment periods.

Invest is the amount of the investment.

Example

For a credit amount of 120,000 currency units with a two-year term and monthly installments, at a yearly interest rate of 12% the level of interest after 1.5 years is required.

=ISPMT(1%;18;24;120000) = -300 currency units. The monthly interest after 1.5 years amounts to 300 currency units.

PV

Returns the present value of an investment resulting from a series of regular payments.

Use this function to calculate the amount of money needed to be invested at a fixed rate today, to receive a specific amount, an annuity, over a specified number of periods. You can also determine how much money is to remain after the elapse of the period. Specify as well if the amount is to be paid out at the beginning or at the end of each period.

Enter these values either as numbers, expressions or references. If, for example, interest is paid annually at 8%, but you want to use month as your period, enter 8%/12 under Rate and Collabora Office Calc with automatically calculate the correct factor.

Syntax

PV(Rate; NPer; Pmt [; FV [; Type]])

Rate defines the interest rate per period.

NPer is the total number of periods (payment period).

Pmt is the regular payment made per period.

FV (optional) defines the future value remaining after the final installment has been made.

Type (optional) denotes due date for payments. Type = 1 means due at the beginning of a period and Type = 0 (default) means due at the end of the period.

In the Collabora Office Calc functions, parameters marked as "optional" can be left out only when no parameter follows. For example, in a function with four parameters, where the last two parameters are marked as "optional", you can leave out parameter 4 or parameters 3 and 4, but you cannot leave out parameter 3 alone.

Example

What is the present value of an investment, if 500 currency units are paid out monthly and the annual interest rate is 8%? The payment period is 48 months and 20,000 currency units are to remain at the end of the payment period.

=PV(8%/12;48;500;20000) = -35,019.37 currency units. Under the named conditions, you must deposit 35,019.37 currency units today, if you want to receive 500 currency units per month for 48 months and have 20,000 currency units left over at the end. Cross-checking shows that 48 x 500 currency units + 20,000 currency units = 44,000 currency units. The difference between this amount and the 35,000 currency units deposited represents the interest paid.

If you enter references instead of these values into the formula, you can calculate any number of "If-then" scenarios. Please note: references to constants must be defined as absolute references. Examples of this type of application are found under the depreciation functions.

RECEIVED

Calculates the amount received that is paid for a fixed-interest security at a given point in time.

Syntax

RECEIVED(Settlement; Maturity; Investment; Discount [; Basis])

Settlement is the date of purchase of the security.

Maturity is the date on which the security matures (expires).

Investment is the purchase sum.

Discount is the percentage discount on acquisition of the security.

Basis (optional) is chosen from a list of options and indicates how the year is to be calculated.

Basis

Calculation

0 or missing

US method (NASD), 12 months of 30 days each

1

Exact number of days in months, exact number of days in year

2

Exact number of days in month, year has 360 days

3

Exact number of days in month, year has 365 days

4

European method, 12 months of 30 days each


Example

Settlement date: February 15 1999, maturity date: May 15 1999, investment sum: 1000 currency units, discount: 5.75 per cent, basis: Daily balance/360 = 2.

The amount received on the maturity date is calculated as follows:

=RECEIVED("1999-02-15";"1999-05-15";1000;0.0575;2) returns 1014.420266.

SYD

Returns the arithmetic-declining depreciation rate.

Use this function to calculate the depreciation amount for one period of the total depreciation span of an object. Arithmetic declining depreciation reduces the depreciation amount from period to period by a fixed sum.

Syntax

SYD(Cost; Salvage; Life; Period)

Cost is the initial cost of an asset.

Salvage is the value of an asset after depreciation.

Life is the period fixing the time span over which an asset is depreciated.

Period defines the period for which the depreciation is to be calculated.

Example

A video system initially costing 50,000 currency units is to be depreciated annually for the next 5 years. The salvage value is to be 10,000 currency units. You want to calculate depreciation for the first year.

=SYD(50000;10000;5;1)=13,333.33 currency units. The depreciation amount for the first year is 13,333.33 currency units.

To have an overview of depreciation rates per period, it is best to define a depreciation table. By entering the different depreciation formulas available in Collabora Office Calc next to each other, you can see which depreciation form is the most appropriate. Enter the table as follows:

A

B

C

D

E

1

Initial Cost

Salvage Value

Useful Life

Time Period

Deprec. SYD

2

50,000 currency units

10,000 currency units

5

1

13,333.33 currency units

3

2

10,666.67 currency units

4

3

8,000.00 currency units

5

4

5,333.33 currency units

6

5

2,666.67 currency units

7

6

0.00 currency units

8

7

9

8

10

9

11

10

12

13

>0

Total

40,000.00 currency units


The formula in E2 is as follows:

=SYD($A$2;$B$2;$C$2;D2)

This formula is duplicated in column E down to E11 (select E2, then drag down the lower right corner with the mouse).

Cell E13 contains the formula used to check the total of the depreciation amounts. It uses the SUMIF function as the negative values in E8:E11 must not be considered. The condition >0 is contained in cell A13. The formula in E13 is as follows:

=SUMIF(E2:E11;A13)

Now view the depreciation for a 10 year period, or at a salvage value of 1 currency unit, or enter a different initial cost, and so on.

Financial Functions Part Two

Financial Functions Part Three

Functions by Category

Please support us!