Skip to main content

GOOGLEFINANCE Best Practices

Anyone using Google Sheets to manage stock portfolio investment must know how to use the GOOGLEFINANCE function to fetch historical prices of stocks. As I have used it extensively to manage my stock portfolio investment in Google Sheets, I have learned several best practices for using the GOOGLEFINANCE function that I would like to share in this post.

Keep only the price with GOOGLEFINANCE

Some inconveniences of using the GOOGLEFINANCE function to fetch historical prices

In Google Sheets, the GOOGLEFINANCE function allows fetching historical prices of stocks. GOOGLEFINANCE("NASDAQ:TSLA","price",TODAY()-30,TODAY()) returns the prices of tesla stock during the last 30 days. The returned results are a table of two columns with headers: Date and Close. The table is automatically sorted in ascending order by date. However, I have identified some inconveniences of using the GOOGLEFINANCE function to fetch historical prices:

  • The stock's latest price is not included in the price. If today is 29/09/2022, the results include only prices until 28/09/2022 as shown in the below picture.
  • In many scenarios, I need to use only the prices as a parameter to another formula but it is not quite practical because of the presence of the headers row and the Date column.
  • The Date column including time causes some difficulties in comparing dates, especially, in the case of using VLOOKUP.
  • The abusive use of the GOOGLEFINANCE can cause performance issue for the spreadsheet.
How to use the GOOGLEFINANCE function to fetch historical prices of stocks in Google Sheets

Include today price in the historical prices returned by the GOOGLEFINANCE function

The GOOGLEFINANCE function returns the historic prices of stocks in the form of a table having two columns and a headers row. In Google Sheets, a table is a two-dimensional array and the brackets { } syntax is used for working with the arrays. As the table is sorted in ascending order by date, including today's price requires simply adding a new row at the end. The new row consists of today's date and today's price.

={GOOGLEFINANCE("NASDAQ:TSLA","price",TODAY()-7,TODAY());{TODAY(),GOOGLEFINANCE("NASDAQ:TSLA")}}

  • To create a new row, I use { } with a comma
  • To add a new row to an existing table, I use { } with a semicolon
Include today price in the historical prices returned by the GOOGLEFINANCE function

Ignore the Date column returned by the GOOGLEFINANCE function

I use the INDEX function on the results returned by GOOGLEFINANCE to ignore the Date column.

=INDEX(GOOGLEFINANCE("NASDAQ:TSLA","price",TODAY()-7,TODAY()),0,2)

Ignore the Date column returned by the GOOGLEFINANCE function in Google Sheets

Ignore the headers row returned by the GOOGLEFINANCE function

It is more complicated to remove the header row than the Date column. The results are a two-dimensional array indexed by row, then by column. Removing the header row is like removing the first element of an array. As far as I have searched, I have not found any built-in formula to remove the first element of an array in Google Sheets. However, it is really simple to remove an element from an array with JavaScript, and Google Sheets supports the customizations with Google Apps Script that is based on JavaScript. That means I create a custom function with Google Apps Script and then use it inside Google Sheets. I explained the details in the post Slice array in Google Sheets. The below formula is how I apply it:

=SLICE(GOOGLEFINANCE("NASDAQ:TSLA","price",TODAY()-7,TODAY()),1)

Ignore the headers row returned by the GOOGLEFINANCE function in Google Sheets

Keep only the price

It is the combination of ignoring the Date column and the header row from data returned by the GOOGLEFINANCE function.

=SLICE(INDEX(GOOGLEFINANCE("NASDAQ:TSLA","price",TODAY()-7,TODAY()),0,2),1)

Keep only the price with GOOGLEFINANCE

Create a dedicated sheet to store prices for each stock to limit calls to GOOGLEFINANCE function

Too many calls to the GOOGLEFINANCE function to get historical prices can cause performance issues for the spreadsheet. It is a redundant task if it is for the same stock and the same duration. To avoid that, I create a dedicated sheet for each stock, then call GOOGLFINANCE once to get its historical price. I then use other built-in functions in Google Sheets to look up that sheet to get prices if I need them at others locations.

For example:

  • For the tesla stock, I create a sheet and name it NASDAQ:TSLA
  • On the cell A1 of that sheet, I put the formula GOOGLEFINANCE("NASDAQ:TSLA","price",TODAY()-7,TODAY())
  • When I need historical prices of tesla stock at other locations, I lookup for them in the NASDAQ:TSLA sheet instead of calling GOOGLFINANCE again.

Use QUERY function instead of VLOOKUP function for looking up by date

Because the Date column returned from GOOGLEFINANCE contains time data, it is difficult to use VLOOKUP for looking for a particular date. In Google Sheets, 9/28/2022 does not have the same numerical value as 9/28/2022 16:00:00, so VLOOKUP can not match them exactly. Instead, I use the QUERY function:

=QUERY(INDIRECT("NASDAQ:TSLA!A:B"),"select B where datediff(A, date '2022-09-26')=0 limit 1",0)

Another advantage of using the QUERY function over the VLOOKUP function is that the QUERY function can return multiple values whereas VLOOKUP returns only a single value.

=QUERY(INDIRECT("NASDAQ:TSLA!A:B"),"select B where A < date '2022-09-26' and A > date '2022-09-01' order by A asc",0)

Conclusion

In this post, I shared several best practices for using the GOOGLEFINANCE function that I have learned along the way of using Google Sheets to manage my stock portfolio investment. I will update this post whenever I learn an interesting practice. If you have any best practices for using Google Sheets, please share them in the comment section!

This post is part of a series of posts about effectively using the SPARKLINE function and the GOOGLEFINANCE function for managing a stock investment in Google Sheets.

Use the ARRAYFORMULA function to subtract the reference price from an array of prices
52-week range price indicator chart with SPARKLINE in Google Sheets
Use SPARKLINE column chart to show stock price trend of AMAZON stock in Google Sheets

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:

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

Popular posts

Use SPARKLINE to create 52-week range price indicator chart for stocks in Google Sheets

Use SPARKLINE to create 52-week range price indicator chart for stocks in Google Sheets

The 52-week range price indicator chart shows the relative position of the current price compared to the 52-week low and the 52-week high price. It visualizes whether the current price is closer to the 52-week low or the 52-week high price. In this post, I explain how to create a 52-week range price indicator chart for stocks by using the SPARKLINE function and the GOOGLEFINANCE function in Google Sheets.
Compute cost basis of stocks with FIFO method in Google Sheets

Compute cost basis of stocks with FIFO method in Google Sheets

After selling a portion of my holdings in a stock, the cost basis for the remain shares of that stock in my portfolio is not simply the sum of all transactions. When selling, I need to decide which shares I want to sell. One of the most common accounting methods is FIFO (first in, first out), meaning that the shares I bought earliest will be the shares I sell first. As you might already know, I use Google Sheets extensively to manage my stock portfolio investment, but, at the moment of writing this post, I find that Google Sheets does not provide a built-in formula for FIFO. Luckily, with lots of effort, I succeeded in building my own FIFO solution in Google Sheets, and I want to share it on this blog. In this post, I explain how to implement FIFO method in Google Sheets to compute cost basis in stocks investing.
Create personal stock portfolio tracker with Google Sheets and Google Data Studio

Create personal stock portfolio tracker with Google Sheets and Google Data Studio

I have been investing in the stock market for a while. I was looking for a software tool that could help me better manage my portfolio, but, could not find one that satisfied my needs. One day, I discovered that the Google Sheets application has a built-in function called GOOGLEFINANCE which fetches current or historical prices of stocks into spreadsheets. So I thought it is totally possible to build my own personal portfolio tracker with Google Sheets. I can register my transactions in a sheet and use the pivot table, built-in functions such as GOOGLEFINANCE, and Apps Script to automate the computation for daily evolutions of my portfolio as well as the current position for each stock in my portfolio. I then drew some sort of charts within the spreadsheet to have some visual ideas of my portfolio. However, I quickly found it inconvenient to have the charts overlapped the table and to switch back and forth among sheets in the spreadsheet. That's when I came to know the existen
How to convert column index into letters with Google Apps Script

How to convert column index into letters with Google Apps Script

Although Google Sheets does not provide a ready-to-use function that takes a column index as an input and returns corresponding letters as output, we can still do the task by leveraging other built-in functions ADDRESS , REGEXEXTRACT , INDEX , SPLIT as shown in the post . However, in form of a formula, that solution is not applicable for scripting with Google Apps Script. In this post, we look at how to write a utility function with Google Apps Script that converts column index into corresponding letters.
Demo stock investment portfolio tracker with Google Sheets and Google Data Studio

Demo stock investment portfolio tracker with Google Sheets and Google Data Studio

I am happy to announce the release of LION stock portfolio tracker. It is a personal stock portfolio tracker built with Google Sheets and Google Data Studio. The stock portfolio's transactions are managed in Google Sheets and its performance is monitored interactively on a beautiful dashboard in Google Data Studio. You can try with the demo below and follow the LION stock portfolio tracker guide to create your own personal stock portfolio tracker with Google Sheets and Google Data Studio.
Create a dividend income tracker with Google Sheets by simply using pivot tables

Create a dividend income tracker with Google Sheets by simply using pivot tables

As my investment strategy is to buy stocks that pay regular and stable dividends during a long-term period, I need to monitor my dividends income by stocks, by months, and by years, so that I can answer quickly and exactly the following questions: How much dividend did I receive on a given month and a given year? How much dividend did I receive for a given stock in a given year? Have a given stock's annual dividend per share kept increasing gradually over years? Have a given stock's annual dividend yield been stable over years? In this post, I explain how to create a dividend tracker for a stock investment portfolio with Google Sheets by simply using pivot tables.
How to use WEEKDAY function to get last Friday in Google Sheets

How to use WEEKDAY function to get last Friday in Google Sheets

As I manage my stock investment portfolio in Google Sheets, I need to see its evolution over time, for example, in the last year. However, the computation for daily evolution is resource-consuming and might cause performance issues for the spreadsheet. As an alternative, I compute only the weekly evolution of the investment portfolio for the last year. For each week, I compute only the portfolio's value at the end of the Friday. For that, I need a Google Sheets formula to return the last Friday for a given date. This post explains how I do that with the WEEKDAY formula in Google Sheets.
Slice array in Google Sheets

Slice array in Google Sheets

Many functions in Google Sheets return an array as the result. However, I find that there is a lack of built-in support functions in Google Sheets when working with an array. For example, the GOOGLEFINANCE function can return the historical prices of a stock as a table of two columns and the first-row being headers Date and Close. How can I ignore the headers or remove the headers from the results?