Call built-in Excel worksheet functions

This article explains how to call built-in Excel worksheet functions such as VLOOKUP and SUM using the Excel JavaScript API. It also provides the full list of built-in Excel worksheet functions that can be called using the Excel JavaScript API.

Note

For information about how to create custom functions in Excel using the Excel JavaScript API, see Create custom functions in Excel.

Calling a worksheet function

The following code snippet shows how to call a worksheet function, where sampleFunction() is a placeholder that should be replaced with the name of the function to call and the input parameters that the function requires. The value property of the FunctionResult object that's returned by a worksheet function contains the result of the specified function. As this example shows, you must load the value property of the FunctionResult object before you can read it. In this example, the result of the function is simply being written to the console.

await Excel.run(async (context) => {
    let functionResult = context.workbook.functions.sampleFunction();
    functionResult.load('value');

    await context.sync();
    console.log('Result of the function: ' + functionResult.value);
});

Tip

See the Supported worksheet functions section of this article for a list of functions that can be called using the Excel JavaScript API.

Sample data

The following image shows a table in an Excel worksheet that contains sales data for various types of tools over a three month period. Each number in the table represents the number of units sold for a specific tool in a specific month. The examples that follow will show how to apply built-in worksheet functions to this data.

Sales data in Excel for Hammer, Wrench, and Saw in months November, December, and January.

Example 1: Single function

The following code sample applies the VLOOKUP function to the sample data described previously to identify the number of wrenches sold in November.

await Excel.run(async (context) => {
    let range = context.workbook.worksheets.getItem("Sheet1").getRange("A1:D4");
    let unitSoldInNov = context.workbook.functions.vlookup("Wrench", range, 2, false);
    unitSoldInNov.load('value');

    await context.sync();
    console.log(' Number of wrenches sold in November = ' + unitSoldInNov.value);
});

Example 2: Nested functions

The following code sample applies the VLOOKUP function to the sample data described previously to identify the number of wrenches sold in November and the number of wrenches sold in December, and then applies the SUM function to calculate the total number of wrenches sold during those two months.

As this example shows, when one or more function calls are nested within another function call, you only need to load the final result that you subsequently want to read (in this example, sumOfTwoLookups). Any intermediate results (in this example, the result of each VLOOKUP function) will be calculated and used to calculate the final result.

await Excel.run(async (context) => {
    let range = context.workbook.worksheets.getItem("Sheet1").getRange("A1:D4");
    let sumOfTwoLookups = context.workbook.functions.sum(
        context.workbook.functions.vlookup("Wrench", range, 2, false),
        context.workbook.functions.vlookup("Wrench", range, 3, false)
    );
    sumOfTwoLookups.load('value');

    await context.sync();
    console.log(' Number of wrenches sold in November and December = ' + sumOfTwoLookups.value);
});

Supported worksheet functions

The following built-in Excel worksheet functions can be called using the Excel JavaScript API.

Function Description
ABS function Returns the absolute value of a number
ACCRINT function Returns the accrued interest for a security that pays periodic interest
ACCRINTM function Returns the accrued interest for a security that pays interest at maturity
ACOS function Returns the arccosine of a number
ACOSH function Returns the inverse hyperbolic cosine of a number
ACOT function Returns the arccotangent of a number
ACOTH function Returns the hyperbolic arccotangent of a number
AMORDEGRC function Returns the depreciation for each accounting period by using a depreciation coefficient
AMORLINC function Returns the depreciation for each accounting period
AND function Returns TRUE if all of its arguments are true
ARABIC function Converts a Roman number to Arabic, as a number
AREAS function Returns the number of areas in a reference
ASC function Changes full-width (double-byte) English letters or katakana within a character string to half-width (single-byte) characters
ASIN function Returns the arcsine of a number
ASINH function Returns the inverse hyperbolic sine of a number
ATAN function Returns the arctangent of a number
ATAN2 function Returns the arctangent from x- and y-coordinates
ATANH function Returns the inverse hyperbolic tangent of a number
AVEDEV function Returns the average of the absolute deviations of data points from their mean
AVERAGE function Returns the average of its arguments
AVERAGEA function Returns the average of its arguments, including numbers, text, and logical values
AVERAGEIF function Returns the average (arithmetic mean) of all the cells in a range that meet a given criteria
AVERAGEIFS function Returns the average (arithmetic mean) of all cells that meet multiple criteria
BAHTTEXT function Converts a number to text, using the ß (baht) currency format
BASE function Converts a number into a text representation with the given radix (base)
BESSELI function Returns the modified Bessel function In(x)
BESSELJ function Returns the Bessel function Jn(x)
BESSELK function Returns the modified Bessel function Kn(x)
BESSELY function Returns the Bessel function Yn(x)
BETA.DIST function Returns the beta cumulative distribution function
BETA.INV function Returns the inverse of the cumulative distribution function for a specified beta distribution
BIN2DEC function Converts a binary number to decimal
BIN2HEX function Converts a binary number to hexadecimal
BIN2OCT function Converts a binary number to octal
BINOM.DIST function Returns the individual term binomial distribution probability
BINOM.DIST.RANGE function Returns the probability of a trial result using a binomial distribution
BINOM.INV function Returns the smallest value for which the cumulative binomial distribution is less than or equal to a criterion value
BITAND function Returns a 'Bitwise And' of two numbers
BITLSHIFT function Returns a value number shifted left by shift_amount bits
BITOR function Returns a bitwise OR of 2 numbers
BITRSHIFT function Returns a value number shifted right by shift_amount bits
BITXOR function Returns a bitwise 'Exclusive Or' of two numbers
CEILING.MATH, ECMA_CEILING functions Rounds a number up, to the nearest integer or to the nearest multiple of significance
CEILING.PRECISE function Rounds a number the nearest integer or to the nearest multiple of significance. Regardless of the sign of the number, the number is rounded up.
CHAR function Returns the character specified by the code number
CHISQ.DIST function Returns the cumulative beta probability density function
CHISQ.DIST.RT function Returns the one-tailed probability of the chi-squared distribution
CHISQ.INV function Returns the cumulative beta probability density function
CHISQ.INV.RT function Returns the inverse of the one-tailed probability of the chi-squared distribution
CHOOSE function Chooses a value from a list of values
CLEAN function Removes all nonprintable characters from text
CODE function Returns a numeric code for the first character in a text string
COLUMNS function Returns the number of columns in a reference
COMBIN function Returns the number of combinations for a given number of objects
COMBINA function Returns the number of combinations with repetitions for a given number of items
COMPLEX function Converts real and imaginary coefficients into a complex number
CONCATENATE function Joins several text items into one text item
CONFIDENCE.NORM function Returns the confidence interval for a population mean
CONFIDENCE.T function Returns the confidence interval for a population mean, using a Student's t distribution
CONVERT function Converts a number from one measurement system to another
COS function Returns the cosine of a number
COSH function Returns the hyperbolic cosine of a number
COT function Returns the cotangent of an angle
COTH function Returns the hyperbolic cotangent of a number
COUNT function Counts how many numbers are in the list of arguments
COUNTA function Counts how many values are in the list of arguments
COUNTBLANK function Counts the number of blank cells within a range
COUNTIF function Counts the number of cells within a range that meet the given criteria
COUNTIFS function Counts the number of cells within a range that meet multiple criteria
COUPDAYBS function Returns the number of days from the beginning of the coupon period to the settlement date
COUPDAYS function Returns the number of days in the coupon period that contains the settlement date
COUPDAYSNC function Returns the number of days from the settlement date to the next coupon date
COUPNCD function Returns the next coupon date after the settlement date
COUPNUM function Returns the number of coupons payable between the settlement date and maturity date
COUPPCD function Returns the previous coupon date before the settlement date
CSC function Returns the cosecant of an angle
CSCH function Returns the hyperbolic cosecant of an angle
CUMIPMT function Returns the cumulative interest paid between two periods
CUMPRINC function Returns the cumulative principal paid on a loan between two periods
DATE function Returns the serial number of a particular date
DATEVALUE function Converts a date in the form of text to a serial number
DAVERAGE function Returns the average of selected database entries
DAY function Converts a serial number to a day of the month
DAYS function Returns the number of days between two dates
DAYS360 function Calculates the number of days between two dates based on a 360-day year
DB function Returns the depreciation of an asset for a specified period by using the fixed-declining balance method
DBCS function Changes half-width (single-byte) English letters or katakana within a character string to full-width (double-byte) characters
DCOUNT function Counts the cells that contain numbers in a database
DCOUNTA function Counts nonblank cells in a database
DDB function Returns the depreciation of an asset for a specified period by using the double-declining balance method or some other method that you specify
DEC2BIN function Converts a decimal number to binary
DEC2HEX function Converts a decimal number to hexadecimal
DEC2OCT function Converts a decimal number to octal
DECIMAL function Converts a text representation of a number in a given base into a decimal number
DEGREES function Converts radians to degrees
DELTA function Tests whether two values are equal
DEVSQ function Returns the sum of squares of deviations
DGET function Extracts from a database a single record that matches the specified criteria
DISC function Returns the discount rate for a security
DMAX function Returns the maximum value from selected database entries
DMIN function Returns the minimum value from selected database entries
DOLLAR, USDOLLAR functions Converts a number to text, using the $ (dollar) currency format
DOLLARDE function Converts a dollar price, expressed as a fraction, into a dollar price, expressed as a decimal number
DOLLARFR function Converts a dollar price, expressed as a decimal number, into a dollar price, expressed as a fraction
DPRODUCT function Multiplies the values in a particular field of records that match the criteria in a database
DSTDEV function Estimates the standard deviation based on a sample of selected database entries
DSTDEVP function Calculates the standard deviation based on the entire population of selected database entries
DSUM function Adds the numbers in the field column of records in the database that match the criteria
DURATION function Returns the annual duration of a security with periodic interest payments
Dlet function Estimates variance based on a sample from selected database entries
DVARP function Calculates variance based on the entire population of selected database entries
EDATE function Returns the serial number of the date that is the indicated number of months before or after the start date
EFFECT function Returns the effective annual interest rate
EOMONTH function Returns the serial number of the last day of the month before or after a specified number of months
ERF function Returns the error function
ERF.PRECISE function Returns the error function
ERFC function Returns the complementary error function
ERFC.PRECISE function Returns the complementary ERF function integrated between x and infinity
ERROR.TYPE function Returns a number corresponding to an error type
EVEN function Rounds a number up to the nearest even integer
EXACT function Checks to see if two text values are identical
EXP function Returns e raised to the power of a given number
EXPON.DIST function Returns the exponential distribution
F.DIST function Returns the F probability distribution
F.DIST.RT function Returns the F probability distribution
F.INV function Returns the inverse of the F probability distribution
F.INV.RT function Returns the inverse of the F probability distribution
FACT function Returns the factorial of a number
FACTDOUBLE function Returns the double factorial of a number
FALSE function Returns the logical value FALSE
FIND, FINDB functions Finds one text value within another (case-sensitive)
FISHER function Returns the Fisher transformation
FISHERINV function Returns the inverse of the Fisher transformation
FIXED function Formats a number as text with a fixed number of decimals
FLOOR.MATH function Rounds a number down, to the nearest integer or to the nearest multiple of significance
FLOOR.PRECISE function Rounds a number down to the nearest integer or to the nearest multiple of significance. Regardless of the sign of the number, the number is rounded down.
FV function Returns the future value of an investment
FVSCHEDULE function Returns the future value of an initial principal after applying a series of compound interest rates
GAMMA function Returns the Gamma function value
GAMMA.DIST function Returns the gamma distribution
GAMMA.INV function Returns the inverse of the gamma cumulative distribution
GAMMALN function Returns the natural logarithm of the gamma function, Γ(x)
GAMMALN.PRECISE function Returns the natural logarithm of the gamma function, Γ(x)
GAUSS function Returns 0.5 less than the standard normal cumulative distribution
GCD function Returns the greatest common divisor
GEOMEAN function Returns the geometric mean
GESTEP function Tests whether a number is greater than a threshold value
HARMEAN function Returns the harmonic mean
HEX2BIN function Converts a hexadecimal number to binary
HEX2DEC function Converts a hexadecimal number to decimal
HEX2OCT function Converts a hexadecimal number to octal
HLOOKUP function Looks in the top row of an array and returns the value of the indicated cell
HOUR function Converts a serial number to an hour
HYPERLINK function Creates a shortcut or jump that opens a document stored on a network server, an intranet, or the Internet
HYPGEOM.DIST function Returns the hypergeometric distribution
IF function Specifies a logical test to perform
IMABS function Returns the absolute value (modulus) of a complex number
IMAGINARY function Returns the imaginary coefficient of a complex number
IMARGUMENT function Returns the argument theta, an angle expressed in radians
IMCONJUGATE function Returns the complex conjugate of a complex number
IMCOS function Returns the cosine of a complex number
IMCOSH function Returns the hyperbolic cosine of a complex number
IMCOT function Returns the cotangent of a complex number
IMCSC function Returns the cosecant of a complex number
IMCSCH function Returns the hyperbolic cosecant of a complex number
IMDIV function Returns the quotient of two complex numbers
IMEXP function Returns the exponential of a complex number
IMLN function Returns the natural logarithm of a complex number
IMLOG10 function Returns the base-10 logarithm of a complex number
IMLOG2 function Returns the base-2 logarithm of a complex number
IMPOWER function Returns a complex number raised to an integer power
IMPRODUCT function Returns the product of from 2 to 255 complex numbers
IMREAL function Returns the real coefficient of a complex number
IMSEC function Returns the secant of a complex number
IMSECH function Returns the hyperbolic secant of a complex number
IMSIN function Returns the sine of a complex number
IMSINH function Returns the hyperbolic sine of a complex number
IMSQRT function Returns the square root of a complex number
IMSUB function Returns the difference between two complex numbers
IMSUM function Returns the sum of complex numbers
IMTAN function Returns the tangent of a complex number
INT function Rounds a number down to the nearest integer
INTRATE function Returns the interest rate for a fully invested security
IPMT function Returns the interest payment for an investment for a given period
IRR function Returns the internal rate of return for a series of cash flows
ISERR function Returns TRUE if the value is any error value except #N/A
ISERROR function Returns TRUE if the value is any error value
ISEVEN function Returns TRUE if the number is even
ISFORMULA function Returns TRUE if there is a reference to a cell that contains a formula
ISLOGICAL function Returns TRUE if the value is a logical value
ISNA function Returns TRUE if the value is the #N/A error value
ISNONTEXT function Returns TRUE if the value is not text
ISNUMBER function Returns TRUE if the value is a number
ISO.CEILING function Returns a number that is rounded up to the nearest integer or to the nearest multiple of significance
ISODD function Returns TRUE if the number is odd
ISOWEEKNUM function Returns the number of the ISO week number of the year for a given date
ISPMT function Calculates the interest paid during a specific period of an investment
ISREF function Returns TRUE if the value is a reference
ISTEXT function Returns TRUE if the value is text
KURT function Returns the kurtosis of a data set
LARGE function Returns the k-th largest value in a data set
LCM function Returns the least common multiple
LEFT, LEFTB functions Returns the leftmost characters from a text value
LEN, LENB functions Returns the number of characters in a text string
LN function Returns the natural logarithm of a number
LOG function Returns the logarithm of a number to a specified base
LOG10 function Returns the base-10 logarithm of a number
LOGNORM.DIST function Returns the cumulative lognormal distribution
LOGNORM.INV function Returns the inverse of the lognormal cumulative distribution
LOOKUP function Looks up values in a vector or array
LOWER function Converts text to lowercase
MATCH function Looks up values in a reference or array
MAX function Returns the maximum value in a list of arguments
MAXA function Returns the maximum value in a list of arguments, including numbers, text, and logical values
MDURATION function Returns the Macauley modified duration for a security with an assumed par value of $100
MEDIAN function Returns the median of the given numbers
MID, MIDB functions Returns a specific number of characters from a text string starting at the position you specify
MIN function Returns the minimum value in a list of arguments
MINA function Returns the smallest value in a list of arguments, including numbers, text, and logical values
MINUTE function Converts a serial number to a minute
MIRR function Returns the internal rate of return where positive and negative cash flows are financed at different rates
MOD function Returns the remainder from division
MONTH function Converts a serial number to a month
MROUND function Returns a number rounded to the desired multiple
MULTINOMIAL function Returns the multinomial of a set of numbers
N function Returns a value converted to a number
NA function Returns the error value #N/A
NEGBINOM.DIST function Returns the negative binomial distribution
NETWORKDAYS function Returns the number of whole workdays between two dates
NETWORKDAYS.INTL function Returns the number of whole workdays between two dates using parameters to indicate which and how many days are weekend days
NOMINAL function Returns the annual nominal interest rate
NORM.DIST function Returns the normal cumulative distribution
NORM.INV function Returns the inverse of the normal cumulative distribution
NORM.S.DIST function Returns the standard normal cumulative distribution
NORM.S.INV function Returns the inverse of the standard normal cumulative distribution
NOT function Reverses the logic of its argument
NOW function Returns the serial number of the current date and time
NPER function Returns the number of periods for an investment
NPV function Returns the net present value of an investment based on a series of periodic cash flows and a discount rate
NUMBERVALUE function Converts text to number in a locale-independent manner
OCT2BIN function Converts an octal number to binary
OCT2DEC function Converts an octal number to decimal
OCT2HEX function Converts an octal number to hexadecimal
ODD function Rounds a number up to the nearest odd integer
ODDFPRICE function Returns the price per $100 face value of a security with an odd first period
ODDFYIELD function Returns the yield of a security with an odd first period
ODDLPRICE function Returns the price per $100 face value of a security with an odd last period
ODDLYIELD function Returns the yield of a security with an odd last period
OR function Returns TRUE if any argument is true
PDURATION function Returns the number of periods required by an investment to reach a specified value
PERCENTILE.EXC function Returns the k-th percentile of values in a range, where k is in the range 0..1, exclusive
PERCENTILE.INC function Returns the k-th percentile of values in a range
PERCENTRANK.EXC function Returns the rank of a value in a data set as a percentage (0..1, exclusive) of the data set
PERCENTRANK.INC function Returns the percentage rank of a value in a data set
PERMUT function Returns the number of permutations for a given number of objects
PERMUTATIONA function Returns the number of permutations for a given number of objects (with repetitions) that can be selected from the total objects
PHI function Returns the value of the density function for a standard normal distribution
PI function Returns the value of pi
PMT function Returns the periodic payment for an annuity
POISSON.DIST function Returns the Poisson distribution
POWER function Returns the result of a number raised to a power
PPMT function Returns the payment on the principal for an investment for a given period
PRICE function Returns the price per $100 face value of a security that pays periodic interest
PRICEDISC function Returns the price per $100 face value of a discounted security
PRICEMAT function Returns the price per $100 face value of a security that pays interest at maturity
PRODUCT function Multiplies its arguments
PROPER function Capitalizes the first letter in each word of a text value
PV function Returns the present value of an investment
QUARTILE.EXC function Returns the quartile of the data set, based on percentile values from 0..1, exclusive
QUARTILE.INC function Returns the quartile of a data set
QUOTIENT function Returns the integer portion of a division
RADIANS function Converts degrees to radians
RAND function Returns a random number between 0 and 1
RANDBETWEEN function Returns a random number between the numbers you specify
RANK.AVG function Returns the rank of a number in a list of numbers
RANK.EQ function Returns the rank of a number in a list of numbers
RATE function Returns the interest rate per period of an annuity
RECEIVED function Returns the amount received at maturity for a fully invested security
REPLACE, REPLACEB functions Replaces characters within text
REPT function Repeats text a given number of times
RIGHT, RIGHTB functions Returns the rightmost characters from a text value
ROMAN function Converts an Arabic numeral to Roman, as text
ROUND function Rounds a number to a specified number of digits
ROUNDDOWN function Rounds a number down, toward zero
ROUNDUP function Rounds a number up, away from zero
ROWS function Returns the number of rows in a reference
RRI function Returns an equivalent interest rate for the growth of an investment
SEC function Returns the secant of an angle
SECH function Returns the hyperbolic secant of an angle
SECOND function Converts a serial number to a second
SERIESSUM function Returns the sum of a power series based on the formula
SHEET function Returns the sheet number of the referenced sheet
SHEETS function Returns the number of sheets in a reference
SIGN function Returns the sign of a number
SIN function Returns the sine of the given angle
SINH function Returns the hyperbolic sine of a number
SKEW function Returns the skewness of a distribution
SKEW.P function Returns the skewness of a distribution based on a population: a characterization of the degree of asymmetry of a distribution around its mean
SLN function Returns the straight-line depreciation of an asset for one period
SMALL function Returns the k-th smallest value in a data set
SQRT function Returns a positive square root
SQRTPI function Returns the square root of (number * pi)
STANDARDIZE function Returns a normalized value
STDEV.P function Calculates standard deviation based on the entire population
STDEV.S function Estimates standard deviation based on a sample
STDEVA function Estimates standard deviation based on a sample, including numbers, text, and logical values
STDEVPA function Calculates standard deviation based on the entire population, including numbers, text, and logical values
SUBSTITUTE function Substitutes new text for old text in a text string
SUBTOTAL function Returns a subtotal in a list or database
SUM function Adds its arguments
SUMIF function Adds the cells specified by a given criteria
SUMIFS function Adds the cells in a range that meet multiple criteria
SUMSQ function Returns the sum of the squares of the arguments
SYD function Returns the sum-of-years' digits depreciation of an asset for a specified period
T function Converts its arguments to text
T.DIST function Returns the Percentage Points (probability) for the Student t-distribution
T.DIST.2T function Returns the Percentage Points (probability) for the Student t-distribution
T.DIST.RT function Returns the Student's t-distribution
T.INV function Returns the t-value of the Student's t-distribution as a function of the probability and the degrees of freedom
T.INV.2T function Returns the inverse of the Student's t-distribution
TAN function Returns the tangent of a number
TANH function Returns the hyperbolic tangent of a number
TBILLEQ function Returns the bond-equivalent yield for a Treasury bill
TBILLPRICE function Returns the price per $100 face value for a Treasury bill
TBILLYIELD function Returns the yield for a Treasury bill
TEXT function Formats a number and converts it to text
TIME function Returns the serial number of a particular time
TIMEVALUE function Converts a time in the form of text to a serial number
TODAY function Returns the serial number of today's date
TRIM function Removes spaces from text
TRIMMEAN function Returns the mean of the interior of a data set
TRUE function Returns the logical value TRUE
TRUNC function Truncates a number to an integer
TYPE function Returns a number indicating the data type of a value
UNICHAR function Returns the Unicode character that is references by the given numeric value
UNICODE function Returns the number (code point) that corresponds to the first character of the text
UPPER function Converts text to uppercase
VALUE function Converts a text argument to a number
VAR.P function Calculates variance based on the entire population
VAR.S function Estimates variance based on a sample
VARA function Estimates variance based on a sample, including numbers, text, and logical values
VARPA function Calculates variance based on the entire population, including numbers, text, and logical values
VDB function Returns the depreciation of an asset for a specified or partial period by using a declining balance method
VLOOKUP function Looks in the first column of an array and moves across the row to return the value of a cell
WEEKDAY function Converts a serial number to a day of the week
WEEKNUM function Converts a serial number to a number representing where the week falls numerically with a year
WEIBULL.DIST function Returns the Weibull distribution
WORKDAY function Returns the serial number of the date before or after a specified number of workdays
WORKDAY.INTL function Returns the serial number of the date before or after a specified number of workdays using parameters to indicate which and how many days are weekend days
XIRR function Returns the internal rate of return for a schedule of cash flows that is not necessarily periodic
XNPV function Returns the net present value for a schedule of cash flows that is not necessarily periodic
XOR function Returns a logical exclusive OR of all arguments
YEAR function Converts a serial number to a year
YEARFRAC function Returns the year fraction representing the number of whole days between start_date and end_date
YIELD function Returns the yield on a security that pays periodic interest
YIELDDISC function Returns the annual yield for a discounted security; for example, a Treasury bill
YIELDMAT function Returns the annual yield of a security that pays interest at maturity
Z.TEST function Returns the one-tailed probability-value of a z-test

See also