A mate reached out to me last week asking if there was a way to monitor the times any article in a Google Sheet list goes through an editing stage before being published. From there, he wanted to report the number of edits on the article in an adjacent cell.
Take a look at the example:
As you can see in the example, whenever “NEEDS EDIT” is selected from the dropdown menu, then the counter column for the selected row item is updated automatically.
In this tutorial, we will cover how to create this for a single Google Sheet tab or for multiple selected tabs. I’ll also wrap up with a script to calculate just the aggregate count of changes to all the rows in the selected range and report it in a single cell.
Check out the video tutorial that covers the basics and grab the Starter Sheet to play along:
The Video
Scheduled release 6 Dec 2022 9am GMT+10
Generally better to view it from YouTube.
Starter Sheet
Here is a link to the starter sheet copy the sheet and head to Extensions > Apps Script in the menu.
The onEdit(e) Simple Trigger
Everything starts with the onEdit(e) simple trigger. This is a special trigger in Google Apps Script called a Simple Trigger that will run every time you edit your Google Sheet. If Apps Script sees the onEdit() function in your project it runs automatically.
Every time onEdit() is executed, it will retrieve an event parameter that is commonly referenced as "e"
(onEdit(e)
). The event object can return things like:
- The current value
- The previous value
- The edited range
- The source spreadsheet
- The trigger id
- The authorisation mode
We will be using a few of these in our code below.
Unless you have a very short coding task, it is generally good practice to reference another function that will be executed when onEdit() is run rather than coding directing within the onEdit() function.
Take a look at the three examples I added for my test project for this tutorial:
1 2 3 4 5 6 7 8 |
function onEdit(e) { countTimesSpecificCellValSelected_v1_(e); // Count each row in a single col countTimesSpecificCellValSelected_v2_(e); // Count for multiple Sheet Tabs countTimesSpecificCellValSelected_v3_(e); // Count Aggregate }; |
You can see that each one of these functions will be run one after the other when a cell is edited and calls onEdit()
.
Count Every Time The Cell Changes
In this example, we add a count to our adjacent counter cell each time the cell is edited.
Note that we take the event (e
) as our parameter for our countEveryTimeCellIsChanged(e)
function.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 |
/** * @OnlyCurrentDoc */ /** * Simple trigger function that runs after each change in the sheet. */ function onEdit(e) { countEveryTimeCellIsChanged(e) }; /** * Counts the times a cell is edited in a specified column and displays * the count in the selected adjacent column. * @param {Object} e - The event object from the onEdit trigger event. */ function countEveryTimeCellIsChanged(e){ // ### VARIABLES ### // Update these const tgtSheet = "Single List"; // The sheet name the data is on. const tgtCol = 3; // The column to search for a change. const counterCol = 4; // The column to update the counter. // ### --- ### const range = e.range const sheet = range.getSheet(); const column = range.getColumn(); // check if on the correct sheet and in the correct column. if(sheet.getName() === tgtSheet && column === tgtCol){ const row = range.getRow() // Get the counter cell; const counterCellRange = sheet.getRange(row, counterCol); const counterCellVal = counterCellRange.getValue(); const updateCounterCell = (counterCellVal < 0)? 1 : counterCellVal + 1; counterCellRange.setValue(updateCounterCell) }; }; |
Set the Variables
First, let’s assign all our variables at the top of our function to make it easier for us to change should we need to down the track.
We have 3 variables that we need to include here. They won’t change so we will make them a constant variable:
tgtSheet
– This is the target sheet tab name. For our example, this is assigned to “Single List”.tgtCol
– This is the target column or the column that has the values that will need to be monitored for changes. In our example, this is the status column, column 3.counterCol
– This is the column where we display our change count. For us, this is column 4, but it could be any selected column in the sheet.
You can stop here if you want to copy and paste the script into your own project and update the variables for your own purposes. Or continue to learn how it all works.
Need help with Google Workspace development?
My team of experts can help you with all of your needs, from custom app development to integrations and security. We have a proven track record of success in helping businesses of all sizes get the most out of Google Workspace.
Schedule a free consultation today to discuss your needs and get started or learn more about our services here.
Get the Correct Sheet Tab and Column
Lines 33-38
We don’t want to end up counting the wrong column or updating a completely different sheet tab by mistake. This means we need a way to check if we are in the right spot.
The first thing we need to do is check the range we are currently editing. This can be done by grabbing the range object in our event parameter. Line 33
We now have access to the Google Apps Script range class. From this class, we can get the sheet class and also the range column number. Line 34-35
Using the JavaScript ‘if’ statement we first check that the sheets name (sheet.getName())
is equal to our assigned target sheet name and if it is, then check that the selected column is equal to the target column. Line 38
Update the Counter Cell
Lines 40 – 48
We need to update the adjacent counter cell in the same row that was changed when edited.
We can use the range class again with the getRow() method. This will give us a row number. Line 40
const row = range.getRow();
Next, using the sheet variable we created earlier we can call the getRange() method to get the counter cell. For a single cell, this method can take two variables the row and the column number. Here, we add in these two variables we collected earlier.
const counterCellRange = sheet.getRange(row, counterCol);
Now we need to add one to the current count in our counter cell. This means that we first need to collect the current value in the cell, which we do with the getValue() method.
We need a way to check if the value in the counter cell is empty. If it is then we want to give it a value of 1 otherwise we want to add 1 to the current value.
const counterCellVal = counterCellRange.getValue();
This can be achieved with a ternary operation. Think of a JavaScript ternary operator as a single line if statement in a way.
The ternary operator below states that if the value is less than zero (empty) then add one otherwise add one to the counter cell value.
const updateCounterCell = (counterCellVal < 0)? 1 : counterCellVal + 1;
Finally, we update the counter cell:
counterCellRange.setValue(updateCounterCell);
Done!
The following scripts will modify this code. We will touch on the changes only in the code discussion of each script.
Count Every Time The Cell Changes To the Selected Value
In this scenario, we only want to count when a cell changes to a specific value. For our example, this value is “NEEDS EDIT”.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 |
/** * @OnlyCurrentDoc */ /** * Simple trigger function that runs after each change in the sheet. */ function onEdit(e) { countTimesSpecificCellValSelected_v1_(e); // Count each row in a single col }; /** * Counts the number of times a cell value is change to a specfic item * from a dropdown in a specified column and displays the count in the * selected adjacent column. * @param {Object} e - The event object from the onEdit trigger event. */ function countTimesSpecificCellValSelected_v1_(e){ // ### VARIABLES ### // Update these const tgtSheet = "Single List"; // The sheet name the data is on. const tgtCol = 3; // The column to search for a change. const counterCol = 4; // The column to update the counter. const tgtVal = "NEEDS EDIT" // ### --- ### const range = e.range const sheet = range.getSheet(); const column = range.getColumn(); // check if on the correct sheet and in the correct column. if(sheet.getName() === tgtSheet && column === tgtCol){ // Check if the cell value matches the target value we need to count. const cellVal = e.value; if(cellVal === tgtVal){ const row = range.getRow() // Get the counter cell; const counterCellRange = sheet.getRange(row, counterCol); const counterCellVal = counterCellRange.getValue(); const updateCounterCell = (counterCellVal < 0)? 1 : counterCellVal + 1; counterCellRange.setValue(updateCounterCell) }; }; }; |
First off, we need to store a target value that we want to monitor for and if that value appears add one to our counter cell. Here on line 29, we set our target value to “NEEDS EDIT”.
const tgtVal = "NEEDS EDIT"
You can change this to the value that you need for your project.
Next, we need to check if the cell that was edited was edited to the new target value before we update the counter cell.
To do this we first get the value of the selected range (Line 42):
const cellVal = range.getValue();
Then we create an if statement checking that the cell value matches the target value on line 43 and closes on line 54.
if(cellVal === tgtVal){
Apply The Script to Multiple Selected Google Sheets
What if we have different editorial teams or genres handled by different editors? We might want to put the data for each team in a different sheet tab to make it easy for monitoring. Here we will need to check all the selected sheets for any changes.
In our example now we want the “Team 1” and “Team 2” sheet tabs. Both tabs are identical in format.
Let’s see how our code works now:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 |
/** * @OnlyCurrentDoc */ /** * Simple trigger function that runs after each change in the sheet. */ function onEdit(e) { countTimesSpecificCellValSelected_v2_(e); // Count for multiple Sheet Tabs }; /** * Counts the number of times a cell value is change to a specfic item * from a dropdown in a specified column for selected sheets and displays * the count in the selected adjacent column. * @param {Object} e - The event object from the onEdit trigger event. */ function countTimesSpecificCellValSelected_v2_(e){ // ### VARIABLES ### // Update these const tgtSheets = ["Team 1", "Team 2"]; // The sheet names the data is on. const tgtCol = 3; // The column to search for a change. const counterCol = 4; // The column to update the counter. const tgtVal = "NEEDS EDIT" // ### --- ### const range = e.range const sheet = range.getSheet(); const column = range.getColumn(); // check if on the correct sheet and in the correct column. if(tgtSheets.includes(sheet.getName()) && column === tgtCol){ // Check if the cell value matches the target value we need to count. const cellVal = e.value; if(cellVal === tgtVal){ const row = range.getRow() // Get the counter cell; const counterCellRange = sheet.getRange(row, counterCol); const counterCellVal = counterCellRange.getValue(); const updateCounterCell = (counterCellVal < 0)? 1 : counterCellVal + 1; counterCellRange.setValue(updateCounterCell) }; }; }; |
Two changes need to be made to the script here.
On line 25, we need to change the tgtSheet
variable to tgtSheets
and include an array of all the Google Sheet tabs we need to monitor with our Apps Script code.
const tgtSheets = ["Team 1", "Team 2"]; // The sheet names the data is on.
Then on line 38, we need to replace the first part of the if statement with a way that will look through our array of sheets and check if the current sheet contains the selected name.
This can be achieved with the JavaScript includes function. This function appends a selected array (In our case, the target sheets array) and takes a target value as an argument. Our target value is the select sheet that this being edited.
... tgtSheets.includes(sheet.getName()) ...
Get the Aggregate Count of the Changes
This final script checks all the cells in the target column in a single Google Sheet tab and checks if they have been changed to “NEEDS EDIT”. Then records the aggregate count of all the cells in a single counter cell in a separate sheet tab.
In our example, we will monitor the “Single List” sheet tab for our desired change and record the total count of changes for all rows in the “Aggregate” sheet tab.
Check out the code:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 |
/** * @OnlyCurrentDoc */ /** * Simple trigger function that runs after each change in the sheet. */ function onEdit(e) { countTimesSpecificCellValSelected_v3_(e); // Count Aggregate }; /** * Gets the aggregate of all the times each cell item changes to the * selected cell value in a given row and reprots in a selecte cell. * @param {Object} e - The event object from the onEdit trigger event. */ function countTimesSpecificCellValSelected_v3_(e){ // ### VARIABLES ### // Update these const tgtSheet = "Single List"; // The sheet name the data is on. const tgtCol = 3; // The column to search for a change. const counterCell = 'Aggregate!A2'; // The column to update the counter. const tgtVal = "NEEDS EDIT" // ### --- ### const range = e.range const sheet = range.getSheet(); const column = range.getColumn(); // check if on the correct sheet and in the correct column. if(sheet.getName() === tgtSheet && column === tgtCol){ // Check if the cell value matches the target value we need to count. const cellVal = e.value; if(cellVal === tgtVal){ const counterCellRange = e.source.getRange(counterCell); const counterCellVal = counterCellRange.getValue(); const updateCounterCell = (counterCellVal < 0)? 1 : counterCellVal + 1; counterCellRange.setValue(updateCounterCell) }; }; }; |
First, we have replaced the counterCol
variable with the counterCell
variable and set that to cell A2 of the ‘Aggregate’ sheet tab.
const counterCell = 'Aggregate!A2'; // The column to update the counter.
Next, we don’t need to get the row number this time so we have deleted this variable.
Lastly, on line 44, we use the source property of the event (e
) object to grab the current spreadsheet. This allows us to use the getRange() method to select our counter cell.
Conclusion
There should be enough samples there for you to work out your own combinations. If you want to test your new skills out, try to:
- Create an aggregate count of multiple sheet tabs.
- Move the counter column to another location in the sheet.
- Check for different target values in different sheets with different locations.
If you get stuck check out some of the other popular tutorials on using onEdit():
- Add the Current Date to a Sheet When Data Is Added So That The Date Does Not Change(Static) – Google Sheets (Updated January 2022)
- How to Hide a Row based on a Cell Value in Google Sheets with Filter or Google Apps Script.
- Google Apps Script – How to Automatically Generate a Time From a Four Digit 24 hour Time in Google Sheets.
- Google Apps Script – Adding a Unique ID in a Cell on Edit of an Adjacent Cell Using Time
- Google Apps Script – Create Custom Unique IDs in Google Sheets [Update December 2021]
- Google Apps Script – When I add a value to a cell in a selected column, I want it to move to another Google Sheet [update Feb 2022]
- Google Apps Script: Create a Select All Checkbox to Tick Checkboxes in Any Desired Range in Google Sheets
It’s always nice to hear how people use these scripts in their own projects and it can be inspiring to share your use cases with others. Feel free to share your experience and examples in the comments below.
Finally a big thanks to Mike Kanert for the inspiration for this post. Editor, writer, artist, actor, educator, polymath and all-around nice fella, you can find Mike on Instagram @Unremarkable_Us for his latest comic series made by parents for parents:
If you have found the tutorial helpful, why not shout me a coffee ☕? I'd really appreciate it.
~Yagi