Excel.DataValidation class

Represents the data validation applied to the current range. To learn more about the data validation object model, read Add data validation to Excel ranges.

Extends

Remarks

[ API set: ExcelApi 1.8 ]

Properties

context

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

errorAlert

Error alert when user enters invalid data.

ignoreBlanks

Specifies if data validation will be performed on blank cells. Default is true.

prompt

Prompt when users select a cell.

rule

Data validation rule that contains different type of data validation criteria.

type

Type of the data validation, see Excel.DataValidationType for details.

valid

Represents if all cell values are valid according to the data validation rules. Returns true if all cell values are valid, or false if all cell values are invalid. Returns null if there are both valid and invalid cell values within the range.

Methods

clear()

Clears the data validation from the current range.

getInvalidCells()

Returns a RangeAreas object, comprising one or more rectangular ranges, with invalid cell values. If all cell values are valid, this function will throw an ItemNotFound error.

getInvalidCellsOrNullObject()

Returns a RangeAreas object, comprising one or more rectangular ranges, with invalid cell values. If all cell values are valid, this function will return null.

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.

set(properties, options)

Sets multiple properties of an object at the same time. You can pass either a plain object with the appropriate properties, or another API object of the same type.

set(properties)

Sets multiple properties on the object at the same time, based on an existing loaded object.

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.DataValidation object is an API object, the toJSON method returns a plain JavaScript object (typed as Excel.Interfaces.DataValidationData) that contains shallow copies of any loaded child properties from the original object.

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

errorAlert

Error alert when user enters invalid data.

errorAlert: Excel.DataValidationErrorAlert;

Property Value

Remarks

[ API set: ExcelApi 1.8 ]

Examples

// Link to full sample: https://raw.githubusercontent.com/OfficeDev/office-js-snippets/prod/samples/excel/22-data-validation/data-validation.yaml

await Excel.run(async (context) => {
    const sheet = context.workbook.worksheets.getItem("Decision");
    const commentsRange = 
        sheet.tables.getItem("NameOptionsTable").columns.getItem("Comments").getDataBodyRange();

    // When you are developing, it is a good practice to
    // clear the dataValidation object with each run of your code.
    commentsRange.dataValidation.clear();   

    // If the value of A2 is contained in the value of C2, then 
    // SEARCH(A2,C2) returns the number where it begins. Otherwise,
    // it does not return a number.
    let redundantStringRule = {
        custom: {
            formula: "=NOT(ISNUMBER(SEARCH(A2,C2)))"
        }
    };
    commentsRange.dataValidation.rule = redundantStringRule;
    commentsRange.dataValidation.errorAlert = {
        message: "It is redundant to include the baby name in the comment.",
        showAlert: true,
        style: "Information",
        title: "Baby Name in Comment"
    };

    await context.sync();
});

ignoreBlanks

Specifies if data validation will be performed on blank cells. Default is true.

ignoreBlanks: boolean;

Property Value

boolean

Remarks

[ API set: ExcelApi 1.8 ]

prompt

Prompt when users select a cell.

prompt: Excel.DataValidationPrompt;

Property Value

Remarks

[ API set: ExcelApi 1.8 ]

Examples

// Link to full sample: https://raw.githubusercontent.com/OfficeDev/office-js-snippets/prod/samples/excel/22-data-validation/data-validation.yaml

await Excel.run(async (context) => {
    const sheet = context.workbook.worksheets.getItem("Decision");
    const rankingRange = sheet.tables.getItem("NameOptionsTable").columns.getItem("Ranking").getDataBodyRange();

    // When you are developing, it is a good practice to
    // clear the dataValidation object with each run of your code.
    rankingRange.dataValidation.clear();

    let greaterThanZeroRule = {
        wholeNumber: {
            formula1: 0,
            operator: Excel.DataValidationOperator.greaterThan
        }
    };
    rankingRange.dataValidation.rule = greaterThanZeroRule;

    rankingRange.dataValidation.prompt = {
        message: "Please enter a positive number.",
        showPrompt: true,
        title: "Positive numbers only."
    };

    rankingRange.dataValidation.errorAlert = {
        message: "Sorry, only positive numbers are allowed",
        showAlert: true,
        style: "Stop",
        title: "Negative Number Entered"
    };

    await context.sync();
});

rule

Data validation rule that contains different type of data validation criteria.

rule: Excel.DataValidationRule;

Property Value

Remarks

[ API set: ExcelApi 1.8 ]

Examples

// Link to full sample: https://raw.githubusercontent.com/OfficeDev/office-js-snippets/prod/samples/excel/22-data-validation/data-validation.yaml

await Excel.run(async (context) => {
    const sheet = context.workbook.worksheets.getItem("Decision");
    const nameRange = 
        sheet.tables.getItem("NameOptionsTable").columns.getItem("Baby Name").getDataBodyRange();

    // When you are developing, it is a good practice to
    // clear the dataValidation object with each run of your code.
    nameRange.dataValidation.clear();

    const nameSourceRange = context.workbook.worksheets.getItem("Names").getRange("A1:A3");

    let approvedListRule = {
        list: {
            inCellDropDown: true,
            source: nameSourceRange
        }
    };
    nameRange.dataValidation.rule = approvedListRule;

    await context.sync();
});

type

Type of the data validation, see Excel.DataValidationType for details.

readonly type: Excel.DataValidationType | "None" | "WholeNumber" | "Decimal" | "List" | "Date" | "Time" | "TextLength" | "Custom" | "Inconsistent" | "MixedCriteria";

Property Value

Excel.DataValidationType | "None" | "WholeNumber" | "Decimal" | "List" | "Date" | "Time" | "TextLength" | "Custom" | "Inconsistent" | "MixedCriteria"

Remarks

[ API set: ExcelApi 1.8 ]

valid

Represents if all cell values are valid according to the data validation rules. Returns true if all cell values are valid, or false if all cell values are invalid. Returns null if there are both valid and invalid cell values within the range.

readonly valid: boolean;

Property Value

boolean

Remarks

[ API set: ExcelApi 1.8 ]

Method Details

clear()

Clears the data validation from the current range.

clear(): void;

Returns

void

Remarks

[ API set: ExcelApi 1.8 ]

getInvalidCells()

Returns a RangeAreas object, comprising one or more rectangular ranges, with invalid cell values. If all cell values are valid, this function will throw an ItemNotFound error.

getInvalidCells(): Excel.RangeAreas;

Returns

Remarks

[ API set: ExcelApi 1.9 ]

getInvalidCellsOrNullObject()

Returns a RangeAreas object, comprising one or more rectangular ranges, with invalid cell values. If all cell values are valid, this function will return null.

getInvalidCellsOrNullObject(): Excel.RangeAreas;

Returns

Remarks

[ API set: ExcelApi 1.9 ]

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.DataValidationLoadOptions): Excel.DataValidation;

Parameters

options
Excel.Interfaces.DataValidationLoadOptions

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

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?: {
            select?: string;
            expand?: string;
        }): Excel.DataValidation;

Parameters

propertyNamesAndPaths

{ select?: string; expand?: string; }

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

set(properties, options)

Sets multiple properties of an object at the same time. You can pass either a plain object with the appropriate properties, or another API object of the same type.

set(properties: Interfaces.DataValidationUpdateData, options?: OfficeExtension.UpdateOptions): void;

Parameters

properties
Excel.Interfaces.DataValidationUpdateData

A JavaScript object with properties that are structured isomorphically to the properties of the object on which the method is called.

options
OfficeExtension.UpdateOptions

Provides an option to suppress errors if the properties object tries to set any read-only properties.

Returns

void

set(properties)

Sets multiple properties on the object at the same time, based on an existing loaded object.

set(properties: Excel.DataValidation): void;

Parameters

Returns

void

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.DataValidation object is an API object, the toJSON method returns a plain JavaScript object (typed as Excel.Interfaces.DataValidationData) that contains shallow copies of any loaded child properties from the original object.

toJSON(): Excel.Interfaces.DataValidationData;

Returns