I own and follow several stocks in my investment portfolio. I pick a reference price for each stock. To effectively track the movement of a stock, I need to visualize its 52-week prices based on the reference price that I determined. In this post, I explain how to do so with the SPARKLINE column chart in Google Sheets.
Table of Contents
Concept
Everyone who uses the GOOGLEFINANCE function and SPARKLINE function in Google Sheets can easily find examples in this documentation about drawing a chart inside a cell to display stock price trends during the last 30 days, last 52 weeks, etc. For example, to display the last 52-week price trend for the NVIDIA Corporation stock:
SPARKLINE(INDEX(GOOGLEFINANCE("NVDA","price",EDATE(TODAY(),-12),TODAY())))
However, those are only the simplest uses of the SPARKLINE function and can only offer little information for watching stocks. As I have a reference price for each stock in my watching list, I need to benchmark the price movement with that reference price. Concretely:
- If stock prices are lower than the reference price, I want to draw those in red color.
- If stock prices are greater than the reference price, I want to draw those in green color.
After spending lots of time learning available options for the SPARKLINE function, I find the solution as follows:
- As usual, I use the GOOGLEFINANCE function to get historical prices of a stock, for example, during the last 30 days, during the last 52 weeks, etc.
- I then subtract the reference price from those prices returned by the GOOGLEFINANCE function. As a result, I have negative and positive numbers but the general trend is conserved.
- I then put those offset prices into the SPARKLINE function and specify the options so that:
- The negative numbers are plotted with red color.
- The positive numbers are plotted with green color.
The idea of this solution is quite simple as explained above. However, there are still several technical details worth mentioning for the implementation.
Implementation
Get last 52-week prices of stocks in Google Sheets
For example, to get the last 52-week prices for the Microsoft Corporation stock, I would use the formula below:
GOOGLEFINANCE("MSFT","price",EDATE(TODAY(),-12),TODAY())
Where:
MSFT
is the symbol for the Microsoft Corporation stockEDATE(TODAY(),-12)
is the date 12 months (as same as 52 weeks) before today.
As a result, I have a table of two columns Date and Close.
Extract only the prices and ignore the dates
In the post GOOGLEFINANCE Best Practices, I explained many useful practices for working with the GOOGLEFINANCE function in Google Sheets. Among those practices, I explained how to extract only the prices and ignore the dates from the result returned by the GOOGLEFINANCE function. This is necessary because I only need the prices as input to the SPARKLINE function. Here is an example:
=SLICE(INDEX(GOOGLEFINANCE("NASDAQ:TSLA","price",TODAY()-7,TODAY()),0,2),1)
Choose the reference price
The reference price for each stock can be chosen based on personal preference. For example:
- For stocks that I own in my investment portfolio, I use their FIFO unit cost basis as the reference prices. I have explained in details in the post Compute cost basis of stocks with FIFO method in Google Sheets.
- For stocks that I do not own in my investment portfolio, I could pick a price that I consider reasonable for myself.
Once again, the choice depends totally on personal preference.
Subtract the reference price from an array of prices
To subtract the reference price from an array of prices, I use the ARRAYFORMULA function in Google Sheets. For example, to subtract 100 from the prices of the TESLA stock last 7 days, I would use:
Use SPARKLINE column chart
With the prices offset by the reference price, I can put them into the SPARKLINE function and specify the options so that:
- The chart is a column chart.
- The negative numbers are plotted with red color.
- The positive numbers are plotted with green color.
For example, below is the result of plotting the last 52-week prices of the Amazon.com, Inc. stock with the reference price is 125.
=SPARKLINE(ARRAYFORMULA(SLICE(INDEX(GOOGLEFINANCE("AMZN","price",EDATE(TODAY(),-12),TODAY()),0,2),1)-125),{"charttype","column";"negcolor","red";"color","green"})
Demo
Demo spreadsheet: 52-Week Range Column Sparkline Chart With Reference Price In Google Sheets
Conclusion
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.
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