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. In this post, I explain how to copy data in Google Sheets as an HTML table by writing a small Apps Script program.
Table of Contents
Concept
- On a spreadsheet, users select a range that they want to copy as HTML table.
- With the selected range, users trigger a command Copy AS HTML table. The command can be added to the toolbar, or to the contextual menu, or accessed via a keyboard shortcut.
- The command is executed to transform the selected range into HTML code for table. The HTML code can be added to the clipboard or can be displayed somewhere so users can copy it manually.
- The HTML table must consist of all displayed cells of the selected range and the widths between columns must be respected proportionally.
Implementation
- Write a small Apps Script program
copyAsHTMLTable()
to transform the selected range in the active sheet into a HTML code for table - According to Apps Script documentation, getActiveRange() returns the selected range in the active sheet.
- According to Apps Script documentation, getDisplayValues() returns the rectangular grid of values for a range.
- From the rectangular grid of values:
- Use 2
for
loops to iterate row by row and then column by column - Each row is wrapped in a HTML row tag
<tr></tr>
- Each column is wrapped in a HTML column tag
<td></td>
- If the first row represents headers, its columns are wrapped in the tag
<th></th>
- If the first row represents headers, its columns are wrapped in the tag
- In order to respect the proportion of width between columns:
- Use the getColumnWidth(columnPosition) to get the width in pixel for a given column
- Compute the total width in pixels for the whole table
- Compute the percentage of each column in terms of width in the table
- Add the inline style, like
<table style="width: 100%;">
, for the table - Add the inline style, like
<th style="width:30.82191780821918%;">Date</th>
, for each cell in the first row
- Use 2
- Present the HTML table code in a dialog so that user can copy it manually
- Add the program
copyAsHTMLTable()
to a menu on the toolbar to easily run it
Source Code
function onOpen() {
var spreadsheet = SpreadsheetApp.getActive()
var menuItems = [
{ name: 'Copy as HTML table', functionName: 'copyAsHTMLTable' }
]
spreadsheet.addMenu('Personal Toolbox', menuItems)
}
function copyAsHTMLTable() {
let spreadsheet = SpreadsheetApp.getActive();
let activeRange = spreadsheet.getActiveRange();
let firstColumnPositionInTheSheet = activeRange.getColumn();
let tableWidth = 0;
for (var i = 0; i < activeRange.getWidth(); i++) {
tableWidth += spreadsheet.getColumnWidth(firstColumnPositionInTheSheet + i);
}
let values = activeRange.getDisplayValues();
let text = '<table style="width: 100%;">';
for (var i = 0; i < values.length; i++) {
text += '<tr>';
for (let j = 0; j < values[0].length; j++) {
if (i == 0) {
let thisColumnWidth = spreadsheet.getColumnWidth(firstColumnPositionInTheSheet + j);
let thisColumnWidthPercent = 100 * thisColumnWidth / tableWidth;
text += '<th style="width:' + thisColumnWidthPercent + '%;">';
} else {
text += '<td>';
}
text += values[i][j];
if (i == 0) {
text += '</th>';
} else {
text += '</td>';
}
}
text += '</tr>';
}
text += '</table>';
let ui = SpreadsheetApp.getUi();
ui.alert('Please manually select and copy the text below', text, ui.ButtonSet.OK);
}
Demo
HTML table code
<table style="width: 100%;">
<tr>
<th style="width:30.82191780821918%;">Date</th>
<th style="width:35.38812785388128%;">Type</th>
<th style="width:10.730593607305936%;">Symbol</th>
<th style="width:12.32876712328767%;">Amount</th>
<th style="width:10.730593607305936%;">Shares</th>
</tr>
<tr>
<td>04/05/2021</td>
<td>DIVIDEND</td>
<td>83</td>
<td>141.1</td>
<td>83</td>
</tr>
<tr>
<td>03/05/2021</td>
<td>DIVIDEND</td>
<td>165</td>
<td>74.25</td>
<td>165</td>
</tr>
<tr>
<td>30/04/2021</td>
<td>BUY</td>
<td>13</td>
<td>-479.55</td>
<td>13</td>
</tr>
<tr>
<td>30/04/2021</td>
<td>DEPOSIT</td>
<td></td>
<td>120</td>
<td></td>
</tr>
<tr>
<td>21/04/2021</td>
<td>DIVIDEND</td>
<td>226</td>
<td>354.82</td>
<td>226</td>
</tr>
<tr>
<td>13/04/2021</td>
<td>BUY</td>
<td>49</td>
<td>-504.49</td>
<td>49</td>
</tr>
</table>
HTML table visualization
Date | Type | Symbol | Amount | Shares |
---|---|---|---|---|
04/05/2021 | DIVIDEND | 83 | 141.1 | 83 |
03/05/2021 | DIVIDEND | 165 | 74.25 | 165 |
30/04/2021 | BUY | 13 | -479.55 | 13 |
30/04/2021 | DEPOSIT | 120 | ||
21/04/2021 | DIVIDEND | 226 | 354.82 | 226 |
13/04/2021 | BUY | 49 | -504.49 | 49 |
Getting Started
- Open a sheet in Google Sheets
- From the toolbar, click Tools and then Script Editor
- Copy the code above in to the script editor
- From the toolbar of the script editor, run the onOpen() function
- Come back to the sheet you will see the Personal Toolbox on the toolbar
- Select a range in the sheet that you want to copy as HTML table
- From the toolbar, click Personal Toolbox and then Copy as HTML table
- A dialog shows up containing HTML table code
- Select the html code in the dialog and do Ctrl + C to copy it
- Click OK to dismiss the dialog
Conclusion
In this post, I have explained step by step how to pull data from Google Sheets to an HTML table by writing a small Apps Script program. It is very useful for me to extract some sample data in Google Sheets and present it in my blog as an HTML table.
For further improvement, it is possible to make the apps script program send an email including an HTML table.
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!
One question: is it possible to copy the background color of the cell as well? (as in your case which date,type ect are with the yellow background). Thanks in advance
ReplyDeleteHi, I think it is possible to copy a range in google sheets as an HTML table while keeping the background color of cells. To do so, I think you need to use the getBackground method of the Apps Script API.
DeleteFor more information, check out the documentation. I'll update my blog post to include this feature. It might be helpful for future readers.
Thanks
https://developers.google.com/apps-script/reference/spreadsheet/range#getbackground