Answering another top request: data validation in Apps Script

Google Apps Script is, first and foremost, a tool for making Google Apps more powerful — and today’s addition of programmatic control over data-validation rules in Google Sheets is a perfect example. For a quick demo, make a copy of this spreadsheet, then follow the instructions provided.


For the last few months, scriptable access to the data validation feature in Sheets has been the most requested feature on the Apps Script issue tracker. A common use for data-validation rules is to require that a cell’s value match one of the values in a different range. The following example shows how to achieve that goal with Apps Script. First, we use the newDataValidation() method to construct a DataValidationBuilder, then set the appropriate options and apply the final DataValidation with setDataValidation().


// Set the data-validation rule for cell A1 to require a value from B1:B10.
var cell = SpreadsheetApp.getActive().getRange('A1');
var range = SpreadsheetApp.getActive().getRange('B1:B10');
var rule = SpreadsheetApp.newDataValidation().requireValueInRange(range)
.build();
cell.setDataValidation(rule);

It’s also possible to modify existing data-validation rules. The next example changes rules that require a date in 2013 to require a date in 2014 instead. You’ll see that the script calls getDataValidations() to retrieve the existing rules, then uses getCriteriaType(), getCriteriaValues(), and the DataValidationCriteria enum to examine the rules before applying the new date restriction via the advanced withCriteria() method.


// Change existing data-validation rules that require a date in 2013
// to require a date in 2014.
var oldDates = [new Date('1/1/2013'), new Date('12/31/2013')];
var newDates = [new Date('1/1/2014'), new Date('12/31/2014')];
var sheet = SpreadsheetApp.getActiveSheet();
var range = sheet.getRange(1, 1, sheet.getMaxRows(), sheet.getMaxColumns());
var rules = range.getDataValidations();

for (var i = 0; i < rules.length; i++) {
for (var j = 0; j < rules[i].length; j++) {
var rule = rules[i][j];

if (rule != null) {
var criteria = rule.getCriteriaType();
var args = rule.getCriteriaValues();

if (criteria == SpreadsheetApp.DataValidationCriteria.DATE_BETWEEN
&& args[0].getTime() == oldDates[0].getTime()
&& args[1].getTime() == oldDates[1].getTime()) {
rules[i][j] = rule.copy().withCriteria(criteria, newDates).build();
}
}
}
}
range.setDataValidations(rules);

With this new feature in Apps Script, you should find it much easier to manage complex data-validation scenarios. Please keep the feature requests coming!


Asim Fazal   profile

Asim is a software engineer on the Google Sheets team in New York — and an enthusiastic occasional contributor to the Apps Script team.