Excel.WorksheetCollection class

Represents a collection of worksheet objects that are part of the workbook.

[ API set: ExcelApi 1.1 ]

Extends

Properties

context

The request context associated with the object. This connects the add-in's process to the Office host application's process.

items

Gets the loaded child items in this collection.

Methods

add(name)

Adds a new worksheet to the workbook. The worksheet will be added at the end of existing worksheets. If you wish to activate the newly added worksheet, call ".activate() on it.

[ API set: ExcelApi 1.1 ]

addFromBase64(base64File, sheetNamesToInsert, positionType, relativeTo)

Inserts the specified worksheets of a workbook into the current workbook.

[ API set: ExcelApi BETA (PREVIEW ONLY) ]

addFromBase64(base64File, sheetNamesToInsert, positionTypeString, relativeTo)

Inserts the specified worksheets of a workbook into the current workbook.

[ API set: ExcelApi BETA (PREVIEW ONLY) ]

getActiveWorksheet()

Gets the currently active worksheet in the workbook.

[ API set: ExcelApi 1.1 ]

getCount(visibleOnly)

Gets the number of worksheets in the collection.

[ API set: ExcelApi 1.4 ]

getFirst(visibleOnly)

Gets the first worksheet in the collection.

[ API set: ExcelApi 1.5 ]

getItem(key)

Gets a worksheet object using its Name or ID.

[ API set: ExcelApi 1.1 ]

getItemOrNullObject(key)

Gets a worksheet object using its Name or ID. If the worksheet does not exist, will return a null object.

[ API set: ExcelApi 1.4 ]

getLast(visibleOnly)

Gets the last worksheet in the collection.

[ API set: ExcelApi 1.5 ]

load(option)

Queues up a command to load the specified properties of the object. You must call "context.sync()" before reading the properties.

load(propertyNames)

Queues up a command to load the specified properties of the object. You must call context.sync() before reading the properties.

load(option)
toJSON()

Overrides the JavaScript toJSON() method in order to provide more useful output when an API object is passed to JSON.stringify(). (JSON.stringify, in turn, calls the toJSON method of the object that is passed to it.) Whereas the original Excel.WorksheetCollection object is an API object, the toJSON method returns a plain JavaScript object (typed as Excel.Interfaces.WorksheetCollectionData) that contains an "items" array with shallow copies of any loaded properties from the collection's items.

Events

onActivated

Occurs when any worksheet in the workbook is activated.

[ API set: ExcelApi 1.7 ]

onAdded

Occurs when a new worksheet is added to the workbook.

[ API set: ExcelApi 1.7 ]

onCalculated

Occurs when any worksheet in the workbook is calculated.

[ API set: ExcelApi 1.8 ]

onChanged

Occurs when any worksheet in the workbook is changed.

[ API set: ExcelApi BETA (PREVIEW ONLY) ]

onDeactivated

Occurs when any worksheet in the workbook is deactivated.

[ API set: ExcelApi 1.7 ]

onDeleted

Occurs when a worksheet is deleted from the workbook.

[ API set: ExcelApi 1.7 ]

onFiltered

Occurs when any worksheet's filter is applied in the workbook.

[ API set: ExcelApi BETA (PREVIEW ONLY) ]

onFormatChanged

Occurs when any worksheet in the workbook has format changed.

[ API set: ExcelApi BETA (PREVIEW ONLY) ]

onSelectionChanged

Occurs when the selection changes on any worksheet.

[ API set: ExcelApi BETA (PREVIEW ONLY) ]

Property Details

context

The request context associated with the object. This connects the add-in's process to the Office host application's process.

context: RequestContext;

Property Value

RequestContext

items

Gets the loaded child items in this collection.

readonly items: Excel.Worksheet[];

Property Value

Excel.Worksheet[]

Method Details

add(name)

Adds a new worksheet to the workbook. The worksheet will be added at the end of existing worksheets. If you wish to activate the newly added worksheet, call ".activate() on it.

[ API set: ExcelApi 1.1 ]

add(name?: string): Excel.Worksheet;

Parameters

name
string

Optional. The name of the worksheet to be added. If specified, name should be unqiue. If not specified, Excel determines the name of the new worksheet.

Returns

Examples

Excel.run(function (ctx) { 
    var wSheetName = 'Sample Name';
    var worksheet = ctx.workbook.worksheets.add(wSheetName);
    worksheet.load('name');
    return ctx.sync().then(function() {
        console.log(worksheet.name);
    });
}).catch(function(error) {
    console.log("Error: " + error);
    if (error instanceof OfficeExtension.Error) {
        console.log("Debug info: " + JSON.stringify(error.debugInfo));
    }
});

addFromBase64(base64File, sheetNamesToInsert, positionType, relativeTo)

Note

This API is provided as a preview for developers and may change based on feedback that we receive. Do not use this API in a production environment.

Inserts the specified worksheets of a workbook into the current workbook.

[ API set: ExcelApi BETA (PREVIEW ONLY) ]

addFromBase64(base64File: string, sheetNamesToInsert?: string[], positionType?: Excel.WorksheetPositionType, relativeTo?: Worksheet | string): OfficeExtension.ClientResult<string[]>;

Parameters

base64File
string

Required. Base64 string representing the source workbook.

sheetNamesToInsert
string[]

Optional. The speified worksheet names to insert. By default it will insert all worksheets from the source workbook.

positionType
Excel.WorksheetPositionType

Optional. Insert position type, see Excel.WorksheetPositionType for details. Default is "Start".

relativeTo
Worksheet | string

Optional. The referencing worksheet object or worksheet name/id in the current workbook. Default is null and based on the postionType parameter it will insert worksheets at the start or end of the current workbook.

Returns

OfficeExtension.ClientResult<string[]>

An array where each item represents the Id of the new inserted worksheet.

addFromBase64(base64File, sheetNamesToInsert, positionTypeString, relativeTo)

Note

This API is provided as a preview for developers and may change based on feedback that we receive. Do not use this API in a production environment.

Inserts the specified worksheets of a workbook into the current workbook.

[ API set: ExcelApi BETA (PREVIEW ONLY) ]

addFromBase64(base64File: string, sheetNamesToInsert?: string[], positionTypeString?: "None" | "Before" | "After" | "Beginning" | "End", relativeTo?: Worksheet | string): OfficeExtension.ClientResult<string[]>;

Parameters

base64File
string

Required. Base64 string representing the source workbook.

sheetNamesToInsert
string[]

Optional. The speified worksheet names to insert. By default it will insert all worksheets from the source workbook.

positionTypeString
"None" | "Before" | "After" | "Beginning" | "End"

Optional. Insert position type, see Excel.WorksheetPositionType for details. Default is "Start".

relativeTo
Worksheet | string

Optional. The referencing worksheet object or worksheet name/id in the current workbook. Default is null and based on the postionType parameter it will insert worksheets at the start or end of the current workbook.

Returns

OfficeExtension.ClientResult<string[]>

An array where each item represents the Id of the new inserted worksheet.

getActiveWorksheet()

Gets the currently active worksheet in the workbook.

[ API set: ExcelApi 1.1 ]

getActiveWorksheet(): Excel.Worksheet;

Returns

Examples

Excel.run(function (ctx) {  
    var activeWorksheet = ctx.workbook.worksheets.getActiveWorksheet();
    activeWorksheet.load('name');
    return ctx.sync().then(function() {
            console.log(activeWorksheet.name);
    });
}).catch(function(error) {
    console.log("Error: " + error);
    if (error instanceof OfficeExtension.Error) {
        console.log("Debug info: " + JSON.stringify(error.debugInfo));
    }
});

getCount(visibleOnly)

Gets the number of worksheets in the collection.

[ API set: ExcelApi 1.4 ]

getCount(visibleOnly?: boolean): OfficeExtension.ClientResult<number>;

Parameters

visibleOnly
boolean

Optional. If true, considers only visible worksheets, skipping over any hidden ones.

Returns

OfficeExtension.ClientResult<number>

getFirst(visibleOnly)

Gets the first worksheet in the collection.

[ API set: ExcelApi 1.5 ]

getFirst(visibleOnly?: boolean): Excel.Worksheet;

Parameters

visibleOnly
boolean

Optional. If true, considers only visible worksheets, skipping over any hidden ones.

Returns

Examples

await Excel.run(async (context) => {
    const sheets = context.workbook.worksheets;

    // We don't want to include the default worksheet that was created
    // when the workbook was created, so our "firstSheet" will be the one
    // after the literal first. Note chaining of navigation methods.
    const firstSheet = sheets.getFirst().getNext();
    const lastSheet = sheets.getLast();
    const firstTaxRateRange = firstSheet.getRange("B2");
    const lastTaxRateRange = lastSheet.getRange("B2");

    firstSheet.load("name");
    lastSheet.load("name");
    firstTaxRateRange.load("text");
    lastTaxRateRange.load("text");

    await context.sync();

    let firstYear = firstSheet.name.substr(5, 4);
    let lastYear = lastSheet.name.substr(5, 4);
    console.log(`Tax Rate change from ${firstYear} to ${lastYear}`, `Tax rate for ${firstYear}: ${firstTaxRateRange.text[0][0]}\nTax rate for ${lastYear}: ${lastTaxRateRange.text[0][0]}`)

    await context.sync();
});

getItem(key)

Gets a worksheet object using its Name or ID.

[ API set: ExcelApi 1.1 ]

getItem(key: string): Excel.Worksheet;

Parameters

key
string

The Name or ID of the worksheet.

Returns

getItemOrNullObject(key)

Gets a worksheet object using its Name or ID. If the worksheet does not exist, will return a null object.

[ API set: ExcelApi 1.4 ]

getItemOrNullObject(key: string): Excel.Worksheet;

Parameters

key
string

The Name or ID of the worksheet.

Returns

getLast(visibleOnly)

Gets the last worksheet in the collection.

[ API set: ExcelApi 1.5 ]

getLast(visibleOnly?: boolean): Excel.Worksheet;

Parameters

visibleOnly
boolean

Optional. If true, considers only visible worksheets, skipping over any hidden ones.

Returns

Examples

await Excel.run(async (context) => {
    const sheets = context.workbook.worksheets;

    // We don't want to include the default worksheet that was created
    // when the workbook was created, so our "firstSheet" will be the one
    // after the literal first. Note chaining of navigation methods.
    const firstSheet = sheets.getFirst().getNext();
    const lastSheet = sheets.getLast();
    const firstTaxRateRange = firstSheet.getRange("B2");
    const lastTaxRateRange = lastSheet.getRange("B2");

    firstSheet.load("name");
    lastSheet.load("name");
    firstTaxRateRange.load("text");
    lastTaxRateRange.load("text");

    await context.sync();

    let firstYear = firstSheet.name.substr(5, 4);
    let lastYear = lastSheet.name.substr(5, 4);
    console.log(`Tax Rate change from ${firstYear} to ${lastYear}`, `Tax rate for ${firstYear}: ${firstTaxRateRange.text[0][0]}\nTax rate for ${lastYear}: ${lastTaxRateRange.text[0][0]}`)

    await context.sync();
});

load(option)

Queues up a command to load the specified properties of the object. You must call "context.sync()" before reading the properties.

load(option?: Excel.Interfaces.WorksheetCollectionLoadOptions & Excel.Interfaces.CollectionLoadOptions): Excel.WorksheetCollection;

Parameters

option
Excel.Interfaces.WorksheetCollectionLoadOptions & Excel.Interfaces.CollectionLoadOptions

Returns

Remarks

In addition to this signature, this method has the following signatures:

load(option?: string | string[]): Excel.WorksheetCollection - Where option is a comma-delimited string or an array of strings that specify the properties to load.

load(option?: { select?: string; expand?: string; }): Excel.WorksheetCollection - Where option.select is a comma-delimited string that specifies the properties to load, and options.expand is a comma-delimited string that specifies the navigation properties to load.

load(option?: { select?: string; expand?: string; top?: number; skip?: number }): Excel.WorksheetCollection - Only available on collection types. It is similar to the preceding signature. Option.top specifies the maximum number of collection items that can be included in the result. Option.skip specifies the number of items that are to be skipped and not included in the result. If option.top is specified, the result set will start after skipping the specified number of items.

load(propertyNames)

Queues up a command to load the specified properties of the object. You must call context.sync() before reading the properties.

load(propertyNames?: string | string[]): Excel.WorksheetCollection;

Parameters

propertyNames
string | string[]

A comma-delimited string or an array of strings that specify the properties to load.

Returns

Examples

Excel.run(function (ctx) { 
    var worksheets = ctx.workbook.worksheets;
    worksheets.load('items');
    return ctx.sync().then(function() {
        for (var i = 0; i < worksheets.items.length; i++)
        {
            console.log(worksheets.items[i].name);
            console.log(worksheets.items[i].index);
        }
    });
}).catch(function(error) {
    console.log("Error: " + error);
    if (error instanceof OfficeExtension.Error) {
        console.log("Debug info: " + JSON.stringify(error.debugInfo));
    }
});

load(option)

load(option?: OfficeExtension.LoadOption): Excel.WorksheetCollection;

Parameters

Returns

toJSON()

Overrides the JavaScript toJSON() method in order to provide more useful output when an API object is passed to JSON.stringify(). (JSON.stringify, in turn, calls the toJSON method of the object that is passed to it.) Whereas the original Excel.WorksheetCollection object is an API object, the toJSON method returns a plain JavaScript object (typed as Excel.Interfaces.WorksheetCollectionData) that contains an "items" array with shallow copies of any loaded properties from the collection's items.

toJSON(): Excel.Interfaces.WorksheetCollectionData;

Returns

Event Details

onActivated

Occurs when any worksheet in the workbook is activated.

[ API set: ExcelApi 1.7 ]

readonly onActivated: OfficeExtension.EventHandlers<Excel.WorksheetActivatedEventArgs>;

Returns

OfficeExtension.EventHandlers<Excel.WorksheetActivatedEventArgs>

Examples

await Excel.run(async (context) => {
    let sheets = context.workbook.worksheets;
    sheets.onActivated.add(onActivate);

    await context.sync();
    console.log("A handler has been registered for the OnActivate event.");
});

onAdded

Occurs when a new worksheet is added to the workbook.

[ API set: ExcelApi 1.7 ]

readonly onAdded: OfficeExtension.EventHandlers<Excel.WorksheetAddedEventArgs>;

Returns

OfficeExtension.EventHandlers<Excel.WorksheetAddedEventArgs>

Examples

await Excel.run(async (context) => {
    let sheet = context.workbook.worksheets;
    sheet.onAdded.add(onWorksheetAdd);

    await context.sync();
    console.log("A handler has been registered for the OnAdded event.");
});

onCalculated

Occurs when any worksheet in the workbook is calculated.

[ API set: ExcelApi 1.8 ]

readonly onCalculated: OfficeExtension.EventHandlers<Excel.WorksheetCalculatedEventArgs>;

Returns

OfficeExtension.EventHandlers<Excel.WorksheetCalculatedEventArgs>

onChanged

Note

This API is provided as a preview for developers and may change based on feedback that we receive. Do not use this API in a production environment.

Occurs when any worksheet in the workbook is changed.

[ API set: ExcelApi BETA (PREVIEW ONLY) ]

readonly onChanged: OfficeExtension.EventHandlers<Excel.WorksheetChangedEventArgs>;

Returns

OfficeExtension.EventHandlers<Excel.WorksheetChangedEventArgs>

onDeactivated

Occurs when any worksheet in the workbook is deactivated.

[ API set: ExcelApi 1.7 ]

readonly onDeactivated: OfficeExtension.EventHandlers<Excel.WorksheetDeactivatedEventArgs>;

Returns

OfficeExtension.EventHandlers<Excel.WorksheetDeactivatedEventArgs>

Examples

await Excel.run(async (context) => {
    let sheets = context.workbook.worksheets;
    sheets.onDeactivated.add(onDeactivate);

    await context.sync();
    console.log("A handler has been registered for the OnDeactivate event.");
});

onDeleted

Occurs when a worksheet is deleted from the workbook.

[ API set: ExcelApi 1.7 ]

readonly onDeleted: OfficeExtension.EventHandlers<Excel.WorksheetDeletedEventArgs>;

Returns

OfficeExtension.EventHandlers<Excel.WorksheetDeletedEventArgs>

onFiltered

Note

This API is provided as a preview for developers and may change based on feedback that we receive. Do not use this API in a production environment.

Occurs when any worksheet's filter is applied in the workbook.

[ API set: ExcelApi BETA (PREVIEW ONLY) ]

readonly onFiltered: OfficeExtension.EventHandlers<Excel.WorksheetFilteredEventArgs>;

Returns

OfficeExtension.EventHandlers<Excel.WorksheetFilteredEventArgs>

onFormatChanged

Note

This API is provided as a preview for developers and may change based on feedback that we receive. Do not use this API in a production environment.

Occurs when any worksheet in the workbook has format changed.

[ API set: ExcelApi BETA (PREVIEW ONLY) ]

readonly onFormatChanged: OfficeExtension.EventHandlers<Excel.WorksheetFormatChangedEventArgs>;

Returns

OfficeExtension.EventHandlers<Excel.WorksheetFormatChangedEventArgs>

onSelectionChanged

Note

This API is provided as a preview for developers and may change based on feedback that we receive. Do not use this API in a production environment.

Occurs when the selection changes on any worksheet.

[ API set: ExcelApi BETA (PREVIEW ONLY) ]

readonly onSelectionChanged: OfficeExtension.EventHandlers<Excel.WorksheetSelectionChangedEventArgs>;

Returns

OfficeExtension.EventHandlers<Excel.WorksheetSelectionChangedEventArgs>