Skip to content

Instantly share code, notes, and snippets.

@jimtalksdata
Created March 14, 2018 23:17
Show Gist options
  • Save jimtalksdata/d9b786dd9a5c0c4f50b86fa58af04e7d to your computer and use it in GitHub Desktop.
Save jimtalksdata/d9b786dd9a5c0c4f50b86fa58af04e7d to your computer and use it in GitHub Desktop.
Google sheets - RefreshImports
/**
* Go through all sheets in a spreadsheet, identify and remove all spreadsheet
* import functions, then replace them a while later. This causes a "refresh"
* of the "import" functions. For periodic refresh of these formulas, set this
* function up as a time-based trigger.
*
* Caution: Formula changes made to the spreadsheet by other scripts or users
* during the refresh period COULD BE OVERWRITTEN.
*
* From: https://stackoverflow.com/a/33875957/1677912
*/
function RefreshImports() {
var lock = LockService.getScriptLock();
if (!lock.tryLock(5000)) return; // Wait up to 5s for previous refresh to end.
var id = "1UMuvokp7lmEyuIgL7QsPcqdUnkDvJjgy3chhI7c0MWo";
var ss = SpreadsheetApp.openById(id);
var sheet = ss.getSheetByName("data2");
var dataRange = sheet.getDataRange();
var formulas = dataRange.getFormulas();
var content = "";
var now = new Date();
var time = now.getTime();
var re = /.*[^a-z0-9]import(?:xml|data|feed|html|range)\(.*/gi;
var re2 = /((\?|&)(update=[0-9]*))/gi;
var re3 = /(",)/gi;
for (var row=0; row<formulas.length; row++) {
for (var col=0; col<formulas[0].length; col++) {
content = formulas[row][col];
if (content != "") {
var match = content.search(re);
if (match !== -1 ) {
// import function is used in this cell
var updatedContent = content.toString().replace(re2,"$2update=" + time);
if (updatedContent == content) {
// No querystring exists yet in url
updatedContent = content.toString().replace(re3,"?update=" + time + "$1");
}
// Update url in formula with querystring param
sheet.getRange(row+1, col+1).setFormula(updatedContent);
}
}
}
}
// Done refresh; release the lock.
lock.releaseLock();
var sheet = ss.getSheetByName("chart");
// Show last updated time on sheet somewhere
var d = new Date();
sheet.getRange(33,1).setValue("Sheet last updated at " + d.toUTCString());
}
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment