Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
2 changes: 1 addition & 1 deletion snippets/sheets/filters_samples/readme.md
Original file line number Diff line number Diff line change
@@ -1,3 +1,3 @@
# Filters samples

![alt](./000.png)
![alt](000.png)
3 changes: 2 additions & 1 deletion snippets/sheets/reset_sheet_data/appsscript.json
Original file line number Diff line number Diff line change
Expand Up @@ -3,5 +3,6 @@
"dependencies": {
"libraries": []
},
"exceptionLogging": "STACKDRIVER"
"exceptionLogging": "STACKDRIVER",
"runtimeVersion": "V8"
}
142 changes: 6 additions & 136 deletions snippets/sheets/reset_sheet_data/index.js
Original file line number Diff line number Diff line change
@@ -1,144 +1,13 @@
/**
* @file A snippet for .
* Examples of the snippet {@link https://support.google.com/docs/thread/5809954?msgid=5809954}
* @file A snippet for reset the sheet/sheets data to its original state
* Samples for {@link https://support.google.com/docs/thread/5809954?msgid=5809954}
*/

/**
* Runs the snippet.
* Removes rows by condition 'B:B=10'. Appends deleted rows to the 'Archive' sheet.
*/
function onOpen() {
SpreadsheetApp.getUi()
.createMenu('Reset sheet')
.addItem(
'Reset active sheet (ContactPrice example)',
'userActionResetActiveSheetByRangesAddresses'
)
.addItem('Reset ranges', 'userActionResetRangesByRangesAddresses')
.addItem(
'Reset multiple sheets',
'userActionResetMultipleSheetsByRangesAddresses'
)
.addItem(
'Reset "GSM" columns',
'userActionResetMultipleSheetsBySpecialColumns'
)
.addItem('Reset to a specific value', 'userActionResetToSpecificValue')
.addItem('Make a copy before reset', 'userActionMakeCopyBeforeReset')
.addToUi();
}

/**
* Clear specifing cells on the active sheet
*/
function userActionResetActiveSheetByRangesAddresses() {
var sheet = SpreadsheetApp.getActiveSheet();
if (sheet.getName() !== 'ContactPrice') {
SpreadsheetApp.getActive().toast('Please, activate "ContactPrice" sheet');
return;
}
var rangesAddressesList = ['B5', 'B7', 'B9', 'B11', 'B15', 'B19'];
resetByRangesList_(sheet, rangesAddressesList);
}

/**
* Clear specifing ranges
*/
function userActionResetRangesByRangesAddresses() {
var sheet = SpreadsheetApp.getActive().getSheetByName('Reset ranges example');
sheet.activate();
var rangesAddressesList = ['B5:B15', 'B19'];
resetByRangesList_(sheet, rangesAddressesList);
}

/**
* Clear specifing sheets
*/
function userActionResetMultipleSheetsByRangesAddresses() {
var sheetNames = [
{ name: 'Sheet1', rangesAddressesList: ['B5:B15', 'B19'] },
{ name: 'Sheet2', rangesAddressesList: ['A1:Z20'] },
];
sheetNames.forEach(function(sn) {
var sheet = SpreadsheetApp.getActive().getSheetByName(sn.name);
if (sheet) {
resetByRangesList_(sheet, sn.rangesAddressesList);
}
});
}

/**
* Clear specifing sheets by color
*/
function userActionResetMultipleSheetsByColor() {
var fColor = '#fa7d00';
var sheetNames = [
// { name: 'Sheet1' },
{ name: 'Reset by color (click the image)' },
];
sheetNames.forEach(function(sn) {
var sheet = SpreadsheetApp.getActive().getSheetByName(sn.name);
if (sheet) {
var rangesAddressesList = sheet
.getDataRange()
.getFontColors()
.reduce(function(p, row, i) {
var colors = row.reduce(function(p2, color, j) {
if (color === fColor)
p2.push(Utilities.formatString('R%sC%s', i + 1, j + 1));
return p2;
}, []);
if (colors.length) p = p.concat(colors);
return p;
}, []);
if (rangesAddressesList.length)
resetByRangesList_(sheet, rangesAddressesList);
}
});
}

/**
* Cleaning the sheet and special columns
*/
function userActionResetMultipleSheetsBySpecialColumns() {
SpreadsheetApp.getActive()
.getSheets()
.forEach(function(sheet) {
var lastRow = sheet.getLastRow();
var rangesAddressesList = sheet
.getRange('2:2')
.getValues()[0]
.reduce(function(p, cell, i) {
if (cell === 'GSA')
p.push(
Utilities.formatString('R3C%s:R%sC%s', i + 1, lastRow, i + 1)
);
return p;
}, []);
if (rangesAddressesList.length) {
sheet.activate(); // Please remove this
resetByRangesList_(sheet, rangesAddressesList);
}
});
}

/**
* Reset to specific values
*/
function userActionResetToSpecificValue() {
var sheet = SpreadsheetApp.getActiveSheet();
if (sheet.getName() !== 'ContactPrice') {
SpreadsheetApp.getActive().toast('Please, activate "ContactPrice" sheet');
return;
}
var rangesAddressesList = ['B5', 'B7', 'B9', 'B11', 'B15', 'B19'];
resetByRangesListToValue_(sheet, rangesAddressesList, 'CLEARED');
}

/**
* Clear the sheet by the range list
* @param {GoogleAppsScript.Spreadsheet.Sheet} sheet The sheet
* @param {Array.<string>} rangesAddressesList The list of ranges to return, as specified in A1 notation or R1C1 notation.
* @param {Array.<string>} rangesAddressesList The list of ranges to return,
* as specified in A1 notation or R1C1 notation.
*/
function resetByRangesList_(sheet, rangesAddressesList) {
sheet.getRangeList(rangesAddressesList).clearContent();
Expand All @@ -147,7 +16,8 @@ function resetByRangesList_(sheet, rangesAddressesList) {
/**
* Reset the sheet by the range list to a value
* @param {GoogleAppsScript.Spreadsheet.Sheet} sheet The sheet
* @param {Array.<string>} rangesAddressesList The list of ranges to return, as specified in A1 notation or R1C1 notation.
* @param {Array.<string>} rangesAddressesList The list of ranges to return,
* as specified in A1 notation or R1C1 notation.
*/
function resetByRangesListToValue_(sheet, rangesAddressesList, value) {
value = value || '';
Expand Down
Original file line number Diff line number Diff line change
@@ -1,15 +1,13 @@
/* global resetByRangesList_ */

/**
*
* The user action
*/
function userActionMakeCopyBeforeReset() {
// Don't copy this part. It's just for sample === START
const __checkvar__ = 'Make copy before reset';
if (SpreadsheetApp.getActiveSheet().getName() !== __checkvar__) {
SpreadsheetApp.getActive()
.getSheetByName(__checkvar__)
.activate();
SpreadsheetApp.getActive().getSheetByName(__checkvar__).activate();
SpreadsheetApp.getUi().alert(
'OK. The original sheet will activated. Please, fill data and try again!'
);
Expand Down
50 changes: 43 additions & 7 deletions snippets/sheets/reset_sheet_data/readme.md
Original file line number Diff line number Diff line change
@@ -1,13 +1,49 @@
---
title: Reset sheets
status: init
url: snippets/spreadsheet_reset-sheets
title: 'Reset a sheet'
date: '2021-06-23'
description: 'Resets the sheet/sheets data to its original state. Cleans the sheet(s)'
tags: ['sheets']
categories: ['snippets']
images: ['./snippets/sheets/reset_sheet_data/screenshot.png']
---

## Reset sheets
## Resets the sheet/sheets data to its original state. Cleans the sheet(s)

Based on [I need a script to clear certain cells in sheets when a button is pressed](https://support.google.com/docs/thread/5809954?msgid=5809954)
{{< toc >}}

[Sample sheet](https://docs.google.com/spreadsheets/d/1g8cCxofljFhq_J72sT5tvZZbeMTD5Wc8akHeXetCeDw/edit?usp=sharing)
<video controls width="100%" height="350px" autoplay="true" loop="true">
<source src="./screenrecord.mp4" type="video/mp4">
Sorry, your browser doesn't support embedded videos.
</video>

![Google Apps Script reset a sheet](https://raw.githubusercontent.com/contributorpw/google-apps-script-snippets/master/snippets/spreadsheet_reset-sheets/screenrecord.gif)
### Snippet

- {{< externalLink >}}
- {{< commentLink >}}
- {{< scrvizLink >}}

{{< codeFromFile "index.js" >}}

### Run it

Copy the full sample of the Spreadsheet [Reset sheet data](https://docs.google.com/spreadsheets/d/1g8cCxofljFhq_J72sT5tvZZbeMTD5Wc8akHeXetCeDw/edit?usp=sharing).

You have to decide how you want to reset your sheet. This is expressed in individual user actions.

{{< codeFromFile "userActions.js" >}}

### Additional

{{< codeFromFile "triggerActions.js" >}}

#### Make copy before reset

<video controls width="100%" height="350px" autoplay="true" loop="true">
<source src="./screenrecord2.mp4" type="video/mp4">
Sorry, your browser doesn't support embedded videos.
</video>


{{< codeFromFile "makeCopyBeforeReset.js" >}}

{{< clipboard >}}
13 changes: 0 additions & 13 deletions snippets/sheets/reset_sheet_data/readme.ru.md

This file was deleted.

Binary file removed snippets/sheets/reset_sheet_data/screenrecord.gif
Binary file not shown.
Binary file removed snippets/sheets/reset_sheet_data/screenrecord2.gif
Binary file not shown.
Binary file added snippets/sheets/reset_sheet_data/screenshot.png
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
23 changes: 23 additions & 0 deletions snippets/sheets/reset_sheet_data/triggerActions.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@
/**
* Creates the user menu for handy use.
*/
function onOpen() {
SpreadsheetApp.getUi()
.createMenu('Reset sheet')
.addItem(
'Reset active sheet (ContactPrice example)',
'userActionResetActiveSheetByRangesAddresses'
)
.addItem('Reset ranges', 'userActionResetRangesByRangesAddresses')
.addItem(
'Reset multiple sheets',
'userActionResetMultipleSheetsByRangesAddresses'
)
.addItem(
'Reset "GSM" columns',
'userActionResetMultipleSheetsBySpecialColumns'
)
.addItem('Reset to a specific value', 'userActionResetToSpecificValue')
.addItem('Make a copy before reset', 'userActionMakeCopyBeforeReset')
.addToUi();
}
108 changes: 108 additions & 0 deletions snippets/sheets/reset_sheet_data/userActions.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,108 @@
/* global resetByRangesList_, resetByRangesListToValue_ */

/**
* Clear specifing cells on the active sheet
*/
function userActionResetActiveSheetByRangesAddresses() {
var sheet = SpreadsheetApp.getActiveSheet();
if (sheet.getName() !== 'ContactPrice') {
SpreadsheetApp.getActive().toast('Please, activate "ContactPrice" sheet');
return;
}
var rangesAddressesList = ['B5', 'B7', 'B9', 'B11', 'B15', 'B19'];
resetByRangesList_(sheet, rangesAddressesList);
}

/**
* Clear specifing ranges
*/
function userActionResetRangesByRangesAddresses() {
var sheet = SpreadsheetApp.getActive().getSheetByName('Reset ranges example');
sheet.activate();
var rangesAddressesList = ['B5:B15', 'B19'];
resetByRangesList_(sheet, rangesAddressesList);
}

/**
* Clear specifing sheets
*/
function userActionResetMultipleSheetsByRangesAddresses() {
var sheetNames = [
{ name: 'Sheet1', rangesAddressesList: ['B5:B15', 'B19'] },
{ name: 'Sheet2', rangesAddressesList: ['A1:Z20'] },
];
sheetNames.forEach((sn) => {
var sheet = SpreadsheetApp.getActive().getSheetByName(sn.name);
if (sheet) {
resetByRangesList_(sheet, sn.rangesAddressesList);
}
});
}

/**
* Clear specifing sheets by color
*/
function userActionResetMultipleSheetsByColor() {
var fColor = '#fa7d00';
var sheetNames = [
// { name: 'Sheet1' },
{ name: 'Reset by color (click the image)' },
];
sheetNames.forEach((sn) => {
var sheet = SpreadsheetApp.getActive().getSheetByName(sn.name);
if (sheet) {
var rangesAddressesList = sheet
.getDataRange()
.getFontColors()
.reduce((p, row, i) => {
var colors = row.reduce((p2, color, j) => {
if (color === fColor)
p2.push(Utilities.formatString('R%sC%s', i + 1, j + 1));
return p2;
}, []);
if (colors.length) p = p.concat(colors);
return p;
}, []);
if (rangesAddressesList.length)
resetByRangesList_(sheet, rangesAddressesList);
}
});
}

/**
* Cleaning the sheet and special columns
*/
function userActionResetMultipleSheetsBySpecialColumns() {
SpreadsheetApp.getActive()
.getSheets()
.forEach((sheet) => {
var lastRow = sheet.getLastRow();
var rangesAddressesList = sheet
.getRange('2:2')
.getValues()[0]
.reduce((p, cell, i) => {
if (cell === 'GSA')
p.push(
Utilities.formatString('R3C%s:R%sC%s', i + 1, lastRow, i + 1)
);
return p;
}, []);
if (rangesAddressesList.length) {
sheet.activate(); // Please remove this
resetByRangesList_(sheet, rangesAddressesList);
}
});
}

/**
* Reset to specific values
*/
function userActionResetToSpecificValue() {
var sheet = SpreadsheetApp.getActiveSheet();
if (sheet.getName() !== 'ContactPrice') {
SpreadsheetApp.getActive().toast('Please, activate "ContactPrice" sheet');
return;
}
var rangesAddressesList = ['B5', 'B7', 'B9', 'B11', 'B15', 'B19'];
resetByRangesListToValue_(sheet, rangesAddressesList, 'CLEARED');
}