Excel.WorksheetCollection class

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

[ API set: ExcelApi 1.1 ]

Extends
OfficeExtension.ClientObject

Properties

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 ]

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.

toJSON()

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 ]

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 ]

Property Details

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));
    }
});

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);
    OfficeHelpers.UI.notify(`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);
    OfficeHelpers.UI.notify(`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?: string | string[]): Excel.WorksheetCollection;
Parameters
option
string | string[]

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

Returns
Remarks

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

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.

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));
    }
});

toJSON()

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();

    OfficeHelpers.UI.notify("A handler has been registered for the OnActivate event",
        "Try selecting a different worksheet, and watch the console output.");   
});

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();

    OfficeHelpers.UI.notify("A handler has been registered for the OnAdded event",
        "Try adding a worksheet, and watch the console output.");
});

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();

    OfficeHelpers.UI.notify("A handler has been registered for the OnDeactivate event",
        "Try selecting a different worksheet, and watch the console output.");   
});

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>