When working with Google Apps Script, there are some tasks that I need to perform quite often. For that, I create a list of snippets that I can easily copy whenever needed. In this post, I share my useful snippets and my tips and tricks when working with apps script. If you have any snippet/tip/trick, you can share in the comment section.
Table of Contents
- Effective use of the GOOGLEFINANCE function to get historical prices of stocks in a spreadsheet (Sheets, Apps Script)
- Clean empty cells for a sheet (Sheets, Apps Script)
- Get letter for a column index (Sheets, Apps Script)
- Copy a sheet as HTML table (Sheets, Apps Script)
- Add a menu on opening a spreadsheet (Sheets, Apps Script)
- Hide a sheet by name (Sheets, Apps Script)
- Show a sheet by name (Sheets, Apps Script)
- Create a new sheet or clear content of an old sheet if exists (Sheets, Apps Script)
- Disclaimer
- Feedback
- Support this blog
- Share with your friends
Effective use of the GOOGLEFINANCE function to get historical prices of stocks in a spreadsheet (Sheets, Apps Script)
As I manage my stock portfolio with Google Sheets, I have used the GOOGLEFINANCE function to get the historical prices of a stock. However, I experienced that the repetitive use of the GOOGLEFINANCE function cause performance issues for my spreadsheet. To avoid that problem, I create for each stock a dedicated tab to store its historical prices during a period that I'm interested in.
For example, if I need to get prices of GOOGL stock during the last 10 years
- I create a new tab and name it GOOGL (the ticker symbol itself).
- I put in the A1 cell this formula
=GOOGLEFINANCE("GOOGL","price",TODAY()-10*365,TODAY())
. - As the result, the column A and B contain respectively Date and Close prices of GOOGL during the last 10 years.
- And then:
- If I need to query the prices directly in the spreadsheet, I will use the VLOOKUP function on the above sheet instead of repetitive use of the GOOGLEFINANCE function.
- If I need to query the prices in an Apps Script program, I will read the content of the above sheet in an object whose key is Date and whose value is Close price.
/**
* Each symbol has its own sheet for its historical prices.
*
* Return a map from date to close price on that date.
* {
* '2020-01-31': 22.30,
* '2020-02-01': 21.54
* }
* @param {String} symbol
*/
function getHistoricalPricesBySymbol(symbol) {
var spreadsheet = SpreadsheetApp.getActive()
var historySheet = spreadsheet.getSheetByName(symbol)
var rows = historySheet.getRange('A:B').getValues()
var priceByDate = {}
for (var i = 1; i < rows.length; i++) { // Start from 1 to ignore headers
var tDate = rows[i][0]
if (tDate) {
tDate = getDateString(rows[i][0])
var close = rows[i][1]
priceByDate[tDate] = close
} else {
break // it means empty row.
}
}
return priceByDate
}
/**
* Convert date to a string YYYY-MM-DD
* @param {Date} aDate
* @returns String
*/
function getDateString(aDate) {
return aDate.getFullYear() + '-' + (aDate.getMonth() + 1) + '-' + aDate.getDate()
}
Clean empty cells for a sheet (Sheets, Apps Script)
When working on a spreadsheet, I often use Apps Script for automating some workflows, such as, create a new sheet and populate some data into that. Most of the time, I know in advance how many cells I need to store the data but apps script tends to create more cells than needed. For instance, each new sheet is created by default with 26 columns and 1000 rows. So it is quite wasted and not optimal for reading the sheet later on. Moreover, if we have too many sheets, we need to be aware of a spreadsheet's limitation in terms of size. In my opinion, it is better to not have empty cells and I always clean empty cells of the sheet after populating data into it. Here is the snippet with Google Apps Script.
function cleanEmptyCells(sheet) {
var lastColumn = sheet.getLastColumn()
var totalNumberOfColumns = sheet.getMaxColumns()
if (totalNumberOfColumns > lastColumn) {
sheet.deleteColumns(lastColumn + 1, totalNumberOfColumns - lastColumn)
}
var lastRow = sheet.getLastRow()
var totalNumberOfRows = sheet.getMaxRows()
if (totalNumberOfRows > lastRow) {
sheet.deleteRows(lastRow + 1, totalNumberOfRows - lastRow)
}
}
Get letter for a column index (Sheets, Apps Script)
Array in Javascript is indexed numerically, starting from 0, whereas, columns in a sheet are indexed alphabetically. If I iterate an array to populate data in columns, I need to convert a numerical index to a column letter. For example, an index 53 corresponds to the column BA in a sheet. Below is the utility function that I wrote to do the conversion. You can find a demo in this post or you can convert column index to column letter directly with formulas in a spreadsheet.
function getColumnLetters(columnIndexStartFromOne) {
const ALPHABETS = ['A', 'B', 'C', 'D', 'E', 'F', 'G', 'H', 'I', 'J', 'K', 'L', 'M', 'N', 'O', 'P', 'Q', 'R', 'S', 'T', 'U', 'V', 'W', 'X', 'Y', 'Z']
if (columnIndexStartFromOne < 27) {
return ALPHABETS[columnIndexStartFromOne - 1]
} else {
var res = columnIndexStartFromOne % 26
var div = Math.floor(columnIndexStartFromOne / 26)
if (res === 0) {
div = div - 1
res = 26
}
return getColumnLetters(div) + ALPHABETS[res - 1]
}
}
Copy a sheet as HTML table (Sheets, Apps Script)
I often need to extract some sample data in Google Sheets and present it in my blog as an HTML table. However, when copying a selected range in Google Sheets and paste it outside the Google Sheets, I only get plain text. That's why I wrote the function below to help me copying a selected range in Google Sheets as an HTML table. You can find a demo in this post.
function copyAsHTMLTable() {
var spreadsheet = SpreadsheetApp.getActive();
var values = spreadsheet.getActiveRange().getDisplayValues()
var text = '<table>'
for (var row = 0; row < values.length; row++) {
text += '<tr>'
for (var col = 0; col < values[0].length; col++) {
text += '<td>'
text += values[row][col]
text += '</td>'
}
text += '</tr>'
}
text += '</table>'
var ui = SpreadsheetApp.getUi()
ui.alert('Please manually select and copy the text below', text, ui.ButtonSet.OK)
}
Add a menu on opening a spreadsheet (Sheets, Apps Script)
function onOpen() {
var spreadsheet = SpreadsheetApp.getActive()
var menuItems = [
{ name: 'Generate Historical Prices Sheets', functionName: 'generateHistoricalPricesSheets' },
{ name: 'Delete Historical Prices Sheets', functionName: 'deleteHistoricalPricesSheets' },
{ name: 'Show Historical Prices Sheets', functionName: 'showHistoricalPricesSheets' },
{ name: 'Hide Historical Prices Sheets', functionName: 'hideHistoricalPricesSheets' },
{ name: 'Update Values Sheet', functionName: 'updateValuesSheet' },
{ name: 'Generate Evolutions Sheet', functionName: 'generateEvolutionsSheet' },
{ name: 'Generate Buy-Sell Evaluation Sheet', functionName: 'generateBuySellEvaluationSheet' },
{ name: 'Generate Benchmarks Sheet', functionName: 'generateBenchmarksSheet' },
{ name: 'Clear All Caches', functionName: 'clearAllCaches' }
]
spreadsheet.addMenu('Lion Stock Portfolio Tracker', menuItems)
}
Hide a sheet by name (Sheets, Apps Script)
function hideSheet(sheetName) {
var spreadsheet = SpreadsheetApp.getActive()
var sheet = spreadsheet.getSheetByName(sheetName)
if (sheet) {
sheet.hideSheet()
}
}
Show a sheet by name (Sheets, Apps Script)
function showSheet(sheetName) {
var spreadsheet = SpreadsheetApp.getActive()
var sheet = spreadsheet.getSheetByName(sheetName)
if (sheet) {
sheet.showSheet()
}
}
Create a new sheet or clear content of an old sheet if exists (Sheets, Apps Script)
function createNewOrClearOldSheet(sheetName) {
var spreadsheet = SpreadsheetApp.getActive()
var sheet = spreadsheet.getSheetByName(sheetName)
if (sheet) {
sheet.clear()
} else {
sheet = spreadsheet.insertSheet(sheetName, spreadsheet.getNumSheets())
}
return sheet
}
Disclaimer
The post is only for informational purposes and not for trading purposes or financial advice.
Feedback
If you have any feedback, question, or request please:
- leave a comment in the comment section
- write me an email to allstacksdeveloper@gmail.com
Support this blog
If you value my work, please support me with as little as a cup of coffee! I appreciate it. Thank you!
Share with your friends
If you read it this far, I hope you have enjoyed the content of this post. If you like it, share it with your friends!
Comments
Post a Comment