Excel.ConditionalFormatCollection class

Represents a collection of all the conditional formats that are overlap the range.

[ API set: ExcelApi 1.6 ]

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

Adds a new conditional format to the collection at the first/top priority.

[ API set: ExcelApi 1.6 ]

clearAll()

Clears all conditional formats active on the current specified range.

[ API set: ExcelApi 1.6 ]

getCount()

Returns the number of conditional formats in the workbook. Read-only.

[ API set: ExcelApi 1.6 ]

getItem(id)

Returns a conditional format for the given ID.

[ API set: ExcelApi 1.6 ]

getItemAt(index)

Returns a conditional format at the given index.

[ API set: ExcelApi 1.6 ]

load(option)

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

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.ConditionalFormatCollection object is an API object, the toJSON method returns a plain JavaScript object (typed as Excel.Interfaces.ConditionalFormatCollectionData) that contains an "items" array with shallow copies of any loaded properties from the collection's items.

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.ConditionalFormat[];

Property Value

Excel.ConditionalFormat[]

Method Details

add(type)

Adds a new conditional format to the collection at the first/top priority.

[ API set: ExcelApi 1.6 ]

add(type: Excel.ConditionalFormatType): Excel.ConditionalFormat;

Parameters

type
Excel.ConditionalFormatType

The type of conditional format being added. See Excel.ConditionalFormatType for details.

Returns

Examples

Excel.run(function (ctx) {
    var sheetName = "Sheet1";
    var rangeAddress = "A1:C3";
    var range = ctx.workbook.worksheets.getItem(sheetName).getRange(rangeAddress);
    var conditionalFormat = range.conditionalFormats.add(Excel.ConditionalFormatType.iconSet);
    conditionalFormat.iconOrNull.style = "YellowThreeArrows";
    return ctx.sync().then(function () {
        console.log("Added new yellow three arrow icon set.");
    });
}).catch(function (error) {
    console.log("Error: " + error);
    if (error instanceof OfficeExtension.Error) {
        console.log("Debug info: " + JSON.stringify(error.debugInfo));
    }
});
await Excel.run(async (context) => {
    const sheet = context.workbook.worksheets.getItem("Sample");
    const range = sheet.getRange("B2:M5");
    const conditionalFormat = range.conditionalFormats
        .add(Excel.ConditionalFormatType.colorScale);
    const criteria = {
        minimum: { formula: null, type: Excel.ConditionalFormatColorCriterionType.lowestValue, color: "blue" },
        midpoint: { formula: "50", type: Excel.ConditionalFormatColorCriterionType.percent, color: "yellow" },
        maximum: { formula: null, type: Excel.ConditionalFormatColorCriterionType.highestValue, color: "red" }
    };
    conditionalFormat.colorScale.criteria = criteria;

    await context.sync();
});

clearAll()

Clears all conditional formats active on the current specified range.

[ API set: ExcelApi 1.6 ]

clearAll(): void;

Returns

void

Examples

Excel.run(function (ctx) {
    var sheetName = "Sheet1";
    var rangeAddress = "A1:C3";
    var range = ctx.workbook.worksheets.getItem(sheetName).getRange(rangeAddress);
    var conditionalFormats = range.conditionalFormats;
    var conditionalFormat = conditionalFormats.clearAll();
    return ctx.sync().then(function () {
        console.log("Cleared all conditional formats from this range.");
    });
}).catch(function (error) {
    console.log("Error: " + error);
    if (error instanceof OfficeExtension.Error) {
        console.log("Debug info: " + JSON.stringify(error.debugInfo));
    }
});
await Excel.run(async (context) => {
    const sheet = context.workbook.worksheets.getItem("Sample");
    const range = sheet.getRange();
    range.conditionalFormats.clearAll();

    await context.sync();

    $(".conditional-formats").hide();
});

getCount()

Returns the number of conditional formats in the workbook. Read-only.

[ API set: ExcelApi 1.6 ]

getCount(): OfficeExtension.ClientResult<number>;

Returns

OfficeExtension.ClientResult<number>

Examples

Excel.run(function (ctx) {
    var sheetName = "Sheet1";
    var rangeAddress = "A1:C3";
    var range = ctx.workbook.worksheets.getItem(sheetName).getRange(rangeAddress);
    var conditionalFormat = range.conditionalFormats.add(Excel.ConditionalFormatType.iconSet);
    conditionalFormat.iconOrNull.style = Excel.IconSet.fourTrafficLights;
    var cfCount = range.conditionalFormats.getCount(); 

    return ctx.sync().then(function () {
        console.log("Count: " + cfCount.value);
    });
}).catch(function (error) {
    console.log("Error: " + error);
    if (error instanceof OfficeExtension.Error) {
        console.log("Debug info: " + JSON.stringify(error.debugInfo));
    }
});

getItem(id)

Returns a conditional format for the given ID.

[ API set: ExcelApi 1.6 ]

getItem(id: string): Excel.ConditionalFormat;

Parameters

id
string

The id of the conditional format.

Returns

Conditional Format object.

Examples

Excel.run(function (ctx) {
    var sheetName = "Sheet1";
    var rangeAddress = "A1:C3";
    var range = ctx.workbook.worksheets.getItem(sheetName).getRange(rangeAddress);
    var conditionalFormats = range.conditionalFormats;
    var conditionalFormat = conditionalFormats.getItemAt(3);
    return ctx.sync().then(function () {
        console.log("Conditional Format at Item 3 Loaded");
    });
}).catch(function (error) {
    console.log("Error: " + error);
    if (error instanceof OfficeExtension.Error) {
        console.log("Debug info: " + JSON.stringify(error.debugInfo));
    }
});

getItemAt(index)

Returns a conditional format at the given index.

[ API set: ExcelApi 1.6 ]

getItemAt(index: number): Excel.ConditionalFormat;

Parameters

index
number

Index of the conditional formats to be retrieved.

Returns

Examples

Excel.run(function (ctx) {
    var sheetName = "Sheet1";
    var rangeAddress = "A1:C3";
    var range = ctx.workbook.worksheets.getItem(sheetName).getRange(rangeAddress);
    var conditionalFormats = range.conditionalFormats;
    var conditionalFormat = conditionalFormats.getItemAt(3);
    return ctx.sync().then(function () {
        console.log("Conditional Format at Item 3 Loaded");
    });
}).catch(function (error) {
    console.log("Error: " + error);
    if (error instanceof OfficeExtension.Error) {
        console.log("Debug info: " + JSON.stringify(error.debugInfo));
    }
});
await Excel.run(async (context) => {
    const sheet = context.workbook.worksheets.getItem("Sample");
    const worksheetRange = sheet.getRange();
    worksheetRange.conditionalFormats.load("type");

    await context.sync();

    let cfRangePairs: { cf: Excel.ConditionalFormat, range: Excel.Range }[] = [];
    worksheetRange.conditionalFormats.items.forEach(item => {
        cfRangePairs.push({
            cf: item,
            range: item.getRange().load("address")
        });
    });

    await context.sync();

    if (cfRangePairs.length > 0) {
        cfRangePairs.forEach(item => {
            console.log(item.cf.type);
        });
    } else {
        console.log("No conditional formats applied.");
    }
});

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

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.ConditionalFormatCollection - 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.ConditionalFormatCollection - 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.

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.ConditionalFormatCollection object is an API object, the toJSON method returns a plain JavaScript object (typed as Excel.Interfaces.ConditionalFormatCollectionData) that contains an "items" array with shallow copies of any loaded properties from the collection's items.

toJSON(): Excel.Interfaces.ConditionalFormatCollectionData;

Returns