Excel.ConditionalFormatCollection class

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

Extends

Remarks

[ API set: ExcelApi 1.6 ]

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.

add(typeString)

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

clearAll()

Clears all conditional formats active on the current specified range.

getCount()

Returns the number of conditional formats in the workbook.

getItem(id)

Returns a conditional format for the given ID.

getItemAt(index)

Returns a conditional format at the given index.

getItemOrNullObject(id)

Returns a conditional format identified by its ID. If the conditional format object does not exist, then this method returns an object with its isNullObject property set to true. For further information, see *OrNullObject methods and properties.

load(options)

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

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

items

Gets the loaded child items in this collection.

readonly items: Excel.ConditionalFormat[];

Property Value

Method Details

add(type)

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

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

Parameters

type
Excel.ConditionalFormatType

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

Returns

Remarks

[ API set: ExcelApi 1.6 ]

Examples

// Link to full sample: https://raw.githubusercontent.com/OfficeDev/office-js-snippets/prod/samples/excel/14-conditional-formatting/conditional-formatting-basic.yaml

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

add(typeString)

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

add(typeString: "Custom" | "DataBar" | "ColorScale" | "IconSet" | "TopBottom" | "PresetCriteria" | "ContainsText" | "CellValue"): Excel.ConditionalFormat;

Parameters

typeString

"Custom" | "DataBar" | "ColorScale" | "IconSet" | "TopBottom" | "PresetCriteria" | "ContainsText" | "CellValue"

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

Returns

Remarks

[ API set: ExcelApi 1.6 ]

clearAll()

Clears all conditional formats active on the current specified range.

clearAll(): void;

Returns

void

Remarks

[ API set: ExcelApi 1.6 ]

Examples

// Link to full sample: https://raw.githubusercontent.com/OfficeDev/office-js-snippets/prod/samples/excel/14-conditional-formatting/conditional-formatting-basic.yaml

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.

getCount(): OfficeExtension.ClientResult<number>;

Returns

Remarks

[ API set: ExcelApi 1.6 ]

Examples

await Excel.run(async (context) => {
    const sheetName = "Sheet1";
    const rangeAddress = "A1:C3";
    const range = context.workbook.worksheets.getItem(sheetName).getRange(rangeAddress);
    const conditionalFormat = range.conditionalFormats.add(Excel.ConditionalFormatType.iconSet);
    conditionalFormat.iconSetOrNullObject.style = Excel.IconSet.fourTrafficLights;
    const cfCount = range.conditionalFormats.getCount(); 

    await context.sync()
    console.log("Count: " + cfCount.value);
});

getItem(id)

Returns a conditional format for the given ID.

getItem(id: string): Excel.ConditionalFormat;

Parameters

id

string

The ID of the conditional format.

Returns

Conditional format object.

Remarks

[ API set: ExcelApi 1.6 ]

Examples

await Excel.run(async (context) => {
    const sheetName = "Sheet1";
    const rangeAddress = "A1:C3";
    const range = context.workbook.worksheets.getItem(sheetName).getRange(rangeAddress);
    const conditionalFormats = range.conditionalFormats;
    const conditionalFormat = conditionalFormats.getItemAt(3);
    await context.sync()

    console.log("Conditional Format at Item 3 Loaded");
});

getItemAt(index)

Returns a conditional format at the given index.

getItemAt(index: number): Excel.ConditionalFormat;

Parameters

index

number

Index of the conditional formats to be retrieved.

Returns

Remarks

[ API set: ExcelApi 1.6 ]

Examples

// Link to full sample: https://raw.githubusercontent.com/OfficeDev/office-js-snippets/prod/samples/excel/14-conditional-formatting/conditional-formatting-basic.yaml

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

getItemOrNullObject(id)

Returns a conditional format identified by its ID. If the conditional format object does not exist, then this method returns an object with its isNullObject property set to true. For further information, see *OrNullObject methods and properties.

getItemOrNullObject(id: string): Excel.ConditionalFormat;

Parameters

id

string

The ID of the conditional format.

Returns

Remarks

[ API set: ExcelApi 1.14 ]

load(options)

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

load(options?: Excel.Interfaces.ConditionalFormatCollectionLoadOptions & Excel.Interfaces.CollectionLoadOptions): Excel.ConditionalFormatCollection;

Parameters

options

Excel.Interfaces.ConditionalFormatCollectionLoadOptions & Excel.Interfaces.CollectionLoadOptions

Provides options for which properties of the object to load.

Returns

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

Parameters

propertyNames

string | string[]

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

Returns

load(propertyNamesAndPaths)

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

load(propertyNamesAndPaths?: OfficeExtension.LoadOption): Excel.ConditionalFormatCollection;

Parameters

propertyNamesAndPaths
OfficeExtension.LoadOption

propertyNamesAndPaths.select is a comma-delimited string that specifies the properties to load, and propertyNamesAndPaths.expand is a comma-delimited string that specifies the navigation properties to load.

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