Excel.Table class

Represents an Excel table.

[ API set: ExcelApi 1.1 ]

Extends
OfficeExtension.ClientObject

Remarks

Our how-to guide on working with tables has detailed walkthroughs, images, and code samples.

Properties

columns

Represents a collection of all the columns in the table. Read-only.

[ API set: ExcelApi 1.1 ]

highlightFirstColumn

Indicates whether the first column contains special formatting.

[ API set: ExcelApi 1.3 ]

highlightLastColumn

Indicates whether the last column contains special formatting.

[ API set: ExcelApi 1.3 ]

id

Returns a value that uniquely identifies the table in a given workbook. The value of the identifier remains the same even when the table is renamed. Read-only.

[ API set: ExcelApi 1.1 ]

legacyId

Returns a numeric id.

[ API set: ExcelApi 1.8 ]

name

Name of the table.

[ API set: ExcelApi 1.1 ]

rows

Represents a collection of all the rows in the table. Read-only.

[ API set: ExcelApi 1.1 ]

showBandedColumns

Indicates whether the columns show banded formatting in which odd columns are highlighted differently from even ones to make reading the table easier.

[ API set: ExcelApi 1.3 ]

showBandedRows

Indicates whether the rows show banded formatting in which odd rows are highlighted differently from even ones to make reading the table easier.

[ API set: ExcelApi 1.3 ]

showFilterButton

Indicates whether the filter buttons are visible at the top of each column header. Setting this is only allowed if the table contains a header row.

[ API set: ExcelApi 1.3 ]

showHeaders

Indicates whether the header row is visible or not. This value can be set to show or remove the header row.

[ API set: ExcelApi 1.1 ]

showTotals

Indicates whether the total row is visible or not. This value can be set to show or remove the total row.

[ API set: ExcelApi 1.1 ]

sort

Represents the sorting for the table. Read-only.

[ API set: ExcelApi 1.2 ]

style

Constant value that represents the Table style. Possible values are: TableStyleLight1 thru TableStyleLight21, TableStyleMedium1 thru TableStyleMedium28, TableStyleStyleDark1 thru TableStyleStyleDark11. A custom user-defined style present in the workbook can also be specified.

[ API set: ExcelApi 1.1 ]

worksheet

The worksheet containing the current table. Read-only.

[ API set: ExcelApi 1.2 ]

Methods

clearFilters()

Clears all the filters currently applied on the table.

[ API set: ExcelApi 1.2 ]

convertToRange()

Converts the table into a normal range of cells. All data is preserved.

[ API set: ExcelApi 1.2 ]

delete()

Deletes the table.

[ API set: ExcelApi 1.1 ]

getDataBodyRange()

Gets the range object associated with the data body of the table.

[ API set: ExcelApi 1.1 ]

getHeaderRowRange()

Gets the range object associated with header row of the table.

[ API set: ExcelApi 1.1 ]

getRange()

Gets the range object associated with the entire table.

[ API set: ExcelApi 1.1 ]

getTotalRowRange()

Gets the range object associated with totals row of the table.

[ API set: ExcelApi 1.1 ]

load(option)

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

reapplyFilters()

Reapplies all the filters currently on the table.

[ API set: ExcelApi 1.2 ]

toJSON()

Events

onChanged

Occurs when data in cells changes on a specific table.

[ API set: ExcelApi 1.7 ]

onSelectionChanged

Occurs when the selection changes on a specific table.

[ API set: ExcelApi 1.7 ]

Property Details

columns

Represents a collection of all the columns in the table. Read-only.

[ API set: ExcelApi 1.1 ]

readonly columns: Excel.TableColumnCollection;
Property Value

highlightFirstColumn

Indicates whether the first column contains special formatting.

[ API set: ExcelApi 1.3 ]

highlightFirstColumn: boolean;
Property Value
boolean

highlightLastColumn

Indicates whether the last column contains special formatting.

[ API set: ExcelApi 1.3 ]

highlightLastColumn: boolean;
Property Value
boolean

id

Returns a value that uniquely identifies the table in a given workbook. The value of the identifier remains the same even when the table is renamed. Read-only.

[ API set: ExcelApi 1.1 ]

readonly id: string;
Property Value
string

legacyId

Returns a numeric id.

[ API set: ExcelApi 1.8 ]

readonly legacyId: string;
Property Value
string

name

Name of the table.

[ API set: ExcelApi 1.1 ]

name: string;
Property Value
string

rows

Represents a collection of all the rows in the table. Read-only.

[ API set: ExcelApi 1.1 ]

readonly rows: Excel.TableRowCollection;
Property Value

showBandedColumns

Indicates whether the columns show banded formatting in which odd columns are highlighted differently from even ones to make reading the table easier.

[ API set: ExcelApi 1.3 ]

showBandedColumns: boolean;
Property Value
boolean

showBandedRows

Indicates whether the rows show banded formatting in which odd rows are highlighted differently from even ones to make reading the table easier.

[ API set: ExcelApi 1.3 ]

showBandedRows: boolean;
Property Value
boolean

showFilterButton

Indicates whether the filter buttons are visible at the top of each column header. Setting this is only allowed if the table contains a header row.

[ API set: ExcelApi 1.3 ]

showFilterButton: boolean;
Property Value
boolean

showHeaders

Indicates whether the header row is visible or not. This value can be set to show or remove the header row.

[ API set: ExcelApi 1.1 ]

showHeaders: boolean;
Property Value
boolean

showTotals

Indicates whether the total row is visible or not. This value can be set to show or remove the total row.

[ API set: ExcelApi 1.1 ]

showTotals: boolean;
Property Value
boolean

sort

Represents the sorting for the table. Read-only.

[ API set: ExcelApi 1.2 ]

readonly sort: Excel.TableSort;
Property Value

style

Constant value that represents the Table style. Possible values are: TableStyleLight1 thru TableStyleLight21, TableStyleMedium1 thru TableStyleMedium28, TableStyleStyleDark1 thru TableStyleStyleDark11. A custom user-defined style present in the workbook can also be specified.

[ API set: ExcelApi 1.1 ]

style: string;
Property Value
string

worksheet

The worksheet containing the current table. Read-only.

[ API set: ExcelApi 1.2 ]

readonly worksheet: Excel.Worksheet;
Property Value

Method Details

clearFilters()

Clears all the filters currently applied on the table.

[ API set: ExcelApi 1.2 ]

clearFilters(): void;
Returns
void

convertToRange()

Converts the table into a normal range of cells. All data is preserved.

[ API set: ExcelApi 1.2 ]

convertToRange(): Excel.Range;
Returns

Examples

Excel.run(function (ctx) { 
    var tableName = 'Table1';
    var table = ctx.workbook.tables.getItem(tableName);
    table.convertToRange();
    return ctx.sync(); 
}).catch(function(error) {
    console.log("Error: " + error);
    if (error instanceof OfficeExtension.Error) {
        console.log("Debug info: " + JSON.stringify(error.debugInfo));
    }
});

delete()

Deletes the table.

[ API set: ExcelApi 1.1 ]

delete(): void;
Returns
void

Examples

Excel.run(function (ctx) { 
    var tableName = 'Table1';
    var table = ctx.workbook.tables.getItem(tableName);
    table.delete();
    return ctx.sync(); 
}).catch(function(error) {
    console.log("Error: " + error);
    if (error instanceof OfficeExtension.Error) {
        console.log("Debug info: " + JSON.stringify(error.debugInfo));
    }
});

getDataBodyRange()

Gets the range object associated with the data body of the table.

[ API set: ExcelApi 1.1 ]

getDataBodyRange(): Excel.Range;
Returns

Examples

Excel.run(function (ctx) { 
    var tableName = 'Table1';
    var table = ctx.workbook.tables.getItem(tableName);
    var tableDataRange = table.getDataBodyRange();
    tableDataRange.load('address')
    return ctx.sync().then(function() {
            console.log(tableDataRange.address);
    });
}).catch(function(error) {
    console.log("Error: " + error);
    if (error instanceof OfficeExtension.Error) {
        console.log("Debug info: " + JSON.stringify(error.debugInfo));
    }
});

getHeaderRowRange()

Gets the range object associated with header row of the table.

[ API set: ExcelApi 1.1 ]

getHeaderRowRange(): Excel.Range;
Returns

Examples

Excel.run(function (ctx) { 
    var tableName = 'Table1';
    var table = ctx.workbook.tables.getItem(tableName);
    var tableHeaderRange = table.getHeaderRowRange();
    tableHeaderRange.load('address');
    return ctx.sync().then(function() {
        console.log(tableHeaderRange.address);
    });
}).catch(function(error) {
    console.log("Error: " + error);
    if (error instanceof OfficeExtension.Error) {
        console.log("Debug info: " + JSON.stringify(error.debugInfo));
    }
});

getRange()

Gets the range object associated with the entire table.

[ API set: ExcelApi 1.1 ]

getRange(): Excel.Range;
Returns

Examples

Excel.run(function (ctx) { 
    var tableName = 'Table1';
    var table = ctx.workbook.tables.getItem(tableName);
    var tableRange = table.getRange();
    tableRange.load('address');    
    return ctx.sync().then(function() {
            console.log(tableRange.address);
    });
}).catch(function(error) {
    console.log("Error: " + error);
    if (error instanceof OfficeExtension.Error) {
        console.log("Debug info: " + JSON.stringify(error.debugInfo));
    }
});

getTotalRowRange()

Gets the range object associated with totals row of the table.

[ API set: ExcelApi 1.1 ]

getTotalRowRange(): Excel.Range;
Returns

Examples

Excel.run(function (ctx) { 
    var tableName = 'Table1';
    var table = ctx.workbook.tables.getItem(tableName);
    var tableTotalsRange = table.getTotalRowRange();
    tableTotalsRange.load('address');    
    return ctx.sync().then(function() {
            console.log(tableTotalsRange.address);
    });
}).catch(function(error) {
    console.log("Error: " + error);
    if (error instanceof OfficeExtension.Error) {
        console.log("Debug info: " + JSON.stringify(error.debugInfo));
    }
});

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.Table;
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.Table - 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.Table - 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

// Get a table by name. 
Excel.run(function (ctx) { 
    var tableName = 'Table1';
    var table = ctx.workbook.tables.getItem(tableName);
    table.load('index')
    return ctx.sync().then(function() {
            console.log(table.index);
    });
}).catch(function(error) {
    console.log("Error: " + error);
    if (error instanceof OfficeExtension.Error) {
        console.log("Debug info: " + JSON.stringify(error.debugInfo));
    }
});
// Get a table by index.
Excel.run(function (ctx) { 
    var index = 0;
    var table = ctx.workbook.tables.getItemAt(0);
    table.load('id')
    return ctx.sync().then(function() {
            console.log(table.id);
    });
}).catch(function(error) {
    console.log("Error: " + error);
    if (error instanceof OfficeExtension.Error) {
        console.log("Debug info: " + JSON.stringify(error.debugInfo));
    }
});
// Set table style. 
Excel.run(function (ctx) { 
    var tableName = 'Table1';
    var table = ctx.workbook.tables.getItem(tableName);
    table.name = 'Table1-Renamed';
    table.showTotals = false;
    table.style = 'TableStyleMedium2';
    table.load('tableStyle');
    return ctx.sync().then(function() {
            console.log(table.style);
    });
}).catch(function(error) {
    console.log("Error: " + error);
    if (error instanceof OfficeExtension.Error) {
        console.log("Debug info: " + JSON.stringify(error.debugInfo));
    }
});

reapplyFilters()

Reapplies all the filters currently on the table.

[ API set: ExcelApi 1.2 ]

reapplyFilters(): void;
Returns
void

toJSON()

toJSON(): Excel.Interfaces.TableData;
Returns

Event Details

onChanged

Occurs when data in cells changes on a specific table.

[ API set: ExcelApi 1.7 ]

readonly onChanged: OfficeExtension.EventHandlers<Excel.TableChangedEventArgs>;
Returns
OfficeExtension.EventHandlers<Excel.TableChangedEventArgs>

Examples

await Excel.run(async (context) => {
    let table = context.workbook.tables.getItemAt(0);
    table.onChanged.add(onChange);

    await context.sync();

    OfficeHelpers.UI.notify("A handler has been registered for the onChanged event",
        "Try changing a cell value in the table, and watch the console output.");
});

onSelectionChanged

Occurs when the selection changes on a specific table.

[ API set: ExcelApi 1.7 ]

readonly onSelectionChanged: OfficeExtension.EventHandlers<Excel.TableSelectionChangedEventArgs>;
Returns
OfficeExtension.EventHandlers<Excel.TableSelectionChangedEventArgs>

Examples

await Excel.run(async (context) => {
    let table = context.workbook.tables.getItemAt(0);
    table.onSelectionChanged.add(onSelectionChange);

    await context.sync();

    OfficeHelpers.UI.notify("A handler has been registered for table onSelectionChanged event",
        "Try changing a range selection in the table, and watch the console output.");
});