Multiple Selection from Data Validation Drop Down
In google sheets, how to add multiple values in same cell using drop down
This is exactly what I was looking for. Eamonn Cottrell did a great job - thank you so much!
Additionally, I made a few changes to meet my needs:
It won't show empty values.
- When I needed more than 30 values in the drop-down, it showed empty cells, so I removed them.
I added a search box to filter the values.
- As mentioned, it was difficult to choose many values from the drop-down, so I added this feature.
Drop-down
Code.gs
use this code and run & give the permission
function onOpen(e) {
SpreadsheetApp.getUi()
.createMenu('Multiple Select Data Validation')
.addItem('Show dialog', 'showDialog')
.addToUi();
}
function showDialog() {
var html = HtmlService.createTemplateFromFile('Page').evaluate();
SpreadsheetApp.getUi()
.showSidebar(html);
}
var valid = function() {
try {
var values = SpreadsheetApp.getActiveRange().getDataValidation().getCriteriaValues()[0].getValues();
// Filter out empty values
var filteredValues = values.filter(function(row) {
return row.some(function(cell) {
return cell && cell.trim() !== '';
});
});
return filteredValues;
} catch (e) {
return null;
}
}
function fillCell(e) {
var s = [];
for (var i in e) {
if (i.substr(0, 2) == 'ch') s.push(e[i]);
}
if (s.length) SpreadsheetApp.getActiveRange().setValue(s.join(', '));
}
Page.html
<div>
<? var data = valid(); ?>
<style>
form input[type="text"] {
padding: 5px;
margin-bottom: 10px;
width: 100%;
}
form input[type="checkbox"] {
background-color: powderblue;
padding: 5px 15px;
border: none;
border-radius: 100px;
}
form input[type="checkbox"]:hover {
background-color: lightgrey;
transform: scale(1.05);
}
</style>
<form id="form" name="form">
<input type="text" id="search" placeholder="Type to search..." oninput="filterCheckboxes()" />
<div id="checkboxContainer">
<? if (Object.prototype.toString.call(data) === '[object Array]') { ?>
<? for (var i = 0; i < data.length; i++) { ?>
<? for (var j = 0; j < data[i].length; j++) { ?>
<? if (data[i][j] && data[i][j].trim() !== '') { ?>
<div class="checkbox-item">
<input type="checkbox" id="ch<?= '' + i + j ?>" name="ch<?= '' + i + j ?>" value="<?= data[i][j] ?>">
<label for="ch<?= '' + i + j ?>"><?= data[i][j] ?></label>
</div>
<? } ?>
<? } ?>
<? } ?>
<? } else { ?>
<p>Maybe current cell doesn't have <a href="https://support.google.com/drive/answer/139705?hl=en">Data validation...</a></p>
<? } ?>
</div>
<br>
<input type="button" value="fill current" onclick="google.script.run.fillCell(this.parentNode)" />
<br>
<br>
<input type="button" value="get validation from current" onclick="google.script.run.showDialog()" />
<br>
<br>
<input type="reset" value="reset checkbox selections" />
</form>
<script>
function filterCheckboxes() {
var searchValue = document.getElementById('search').value.toLowerCase();
var checkboxes = document.querySelectorAll('#checkboxContainer .checkbox-item');
checkboxes.forEach(function(item) {
var label = item.querySelector('label').textContent.toLowerCase();
if (label.includes(searchValue)) {
item.style.display = '';
} else {
item.style.display = 'none';
}
});
}
</script>
</div>
Reference:
Multiple Selection Data Validation in Google Sheets - YouTube
ย