3

I have a Google Sheet with cells of both data and =sparkline() in-cell charts, and want to send this data view in an email. I currently use Apps Script to make an HTML email, but the sparkline charts display as blank cells in the email's table.

The data as viewed on Google Sheets:
enter image description here The data as viewed in the email:
enter image description here

This is my Apps Script code:

function drawTable() {
    var ss_data = getData();
    var data = ss_data[0];
    var background = ss_data[1];
    var fontColor = ss_data[2];
    var fontStyles = ss_data[3];
    var fontWeight = ss_data[4];
    var fontSize = ss_data[5];
    var html = "<table border='1'>";
    for (var i = 0; i < data.length; i++) {
        html += "<tr>"
        for (var j = 0; j < data[i].length; j++) {
            html += "<td style='height:20px;background:" + background[i][j] + ";color:" + fontColor[i][j] + ";font-style:" + fontStyles[i][j] + ";font-weight:" + fontWeight[i][j] + ";font-size:" + (fontSize[i][j] + 6) + "px;'>" + data[i][j] + "</td>";
        }
        html += "</tr>";
    }
    html + "</table>"
    MailApp.sendEmail({
        to: Session.getUser().getEmail(),
        subject: "Spreadsheet Data",
        htmlBody: html
    });
}


function getData(){
  var ss = SpreadsheetApp.getActiveSpreadsheet().getSheetByName("Sheet1").getDataRange();
  var background = ss.getBackgrounds();
  var val = ss.getDisplayValues();
  var fontColor = ss.getFontColors();
  var fontStyles = ss.getFontStyles();
  var fontWeight = ss.getFontWeights();
  var fontSize = ss.getFontSizes();
  return [val, background, fontColor, fontStyles, fontWeight, fontSize];
}

Could anyone please suggest the code needed to display sparkline charts in the email, or any other work around?

tehhowch
  • 9,645
  • 4
  • 24
  • 42
okconfused
  • 3,567
  • 4
  • 25
  • 38
  • I have experienced the same issue embedding a Sheet with sparklines in a Doc and a Slide. I think its a bug and have reported it. https://issuetracker.google.com/issues/78443405 – Aidan May 03 '18 at 12:32

1 Answers1

8

How about this workaround? I think that there are several workaround in your situation. So please think of this as one of them.

Unfortunately, the chart created by SPARKLINE() cannot be directly imported to the email. So as a workaround, I used the following flow.

  1. Convert from the chart created by SPARKLINE() to the images using EmbeddedChart.
  2. Send email with the images as the inline images.

Modified script :

drawTable();
function drawTable() {
    var ss_data = getData();
    var data = ss_data[0];
    var background = ss_data[1];
    var fontColor = ss_data[2];
    var fontStyles = ss_data[3];
    var fontWeight = ss_data[4];
    var fontSize = ss_data[5];
    var html = "<table border='1'>";
    var images = {}; // Added
    for (var i = 0; i < data.length; i++) {
        html += "<tr>"
        for (var j = 0; j < data[i].length; j++) {
            if (typeof data[i][j] == "object") { // Added
                html += "<td style='height:20px;background:" + background[i][j] + ";color:" + fontColor[i][j] + ";font-style:" + fontStyles[i][j] + ";font-weight:" + fontWeight[i][j] + ";font-size:" + (fontSize[i][j] + 6) + "px;'><img src='cid:img" + i + "'></td>"; // Added
                images["img" + i] = data[i][j]; // Added
            } else {
                html += "<td style='height:20px;background:" + background[i][j] + ";color:" + fontColor[i][j] + ";font-style:" + fontStyles[i][j] + ";font-weight:" + fontWeight[i][j] + ";font-size:" + (fontSize[i][j] + 6) + "px;'>" + data[i][j] + "</td>";
            }
        }
        html += "</tr>";
    }
    html + "</table>"
    MailApp.sendEmail({
        to: Session.getUser().getEmail(),
        subject: "Spreadsheet Data",
        htmlBody: html,
        inlineImages: images // Added
    })
}

function getData(){
  var sheet = SpreadsheetApp.getActiveSpreadsheet().getSheetByName("Sheet1");
  var ss = sheet.getDataRange();
  var val = ss.getDisplayValues();
  var background = ss.getBackgrounds();
  var fontColor = ss.getFontColors();
  var fontStyles = ss.getFontStyles();
  var fontWeight = ss.getFontWeights();
  var fontSize = ss.getFontSizes();
  var formulas = ss.getFormulas(); // Added
  val = val.map(function(e, i){return e.map(function(f, j){return f ? f : getSPARKLINE(sheet, formulas[i][j])})}); // Added
  return [val,background,fontColor,fontStyles,fontWeight,fontSize]; 
}

// Added
function getSPARKLINE(sheet, formula) {
  formula = formula.toUpperCase();
  if (~formula.indexOf("SPARKLINE")) {
    var chart = sheet.newChart()
      .setChartType(Charts.ChartType.SPARKLINE)
      .addRange(sheet.getRange(formula.match(/\w+:\w+/)[0]))
      .setTransposeRowsAndColumns(true)
      .setOption("showAxisLines", false)
      .setOption("showValueLabels", false)
      .setOption("width", 200)
      .setOption("height", 100)
      .setPosition(1, 1, 0, 0)
      .build();
    sheet.insertChart(chart); 
    var createdChart = sheet.getCharts()[0];
    var blob = createdChart.getAs('image/png');
    sheet.removeChart(createdChart);
    return blob;
  }
}

Result :

enter image description here

Note :

  • In this modified script, it supposes that you use the chart as SPARKLINE.
  • I created a chart in the sheet using insertChart(), because the blob directly retrieved from newChart() cannot be used as an image. When the chart is created to the sheet, the blob retrieved from the created chart can be used as an image.
  • If you want to modify the size of images, please modify setOption("width", 200) and setOption("height", 100).

References :

If I misunderstand your question, I'm sorry.

Tanaike
  • 181,128
  • 11
  • 97
  • 165
  • 2
    @okconfused Welcome. I'm glad your issue was solved. – Tanaike May 03 '18 at 23:45
  • This is actually even closer to what I need. I really just need to email myself some SPARKLINE charts to my email. But I'm getting this error: ```TypeError: Cannot read property '0' of null```. What could be wrong? – Verminous Jun 05 '22 at 00:00
  • 1
    @Verminous About your comment, I have to apologize for my poor skill. Unfortunately, I cannot imagine your current situation from `But I'm getting this error: TypeError: Cannot read property '0' of null. `. But, I would like to support you. So, in order to correctly understand your current situation, can you post it as a new question by including more information? By this, I would like to confirm your situation. If you can cooperate to resolve your question, I'm glad. Can you cooperate to do it? I would be grateful if you can forgive my poor skill. – Tanaike Jun 05 '22 at 00:46
  • Here is my question regarding this situation: https://stackoverflow.com/questions/72508810/email-sparkline-graphs-as-image-blog-png-from-google-sheets-range Thanks @Tanaike – Verminous Jun 05 '22 at 18:22
  • 1
    @Verminous Thank you for your response. Now, I noticed that an answer has already been posted and the discussions have already been advanced. In this case, I would like to respect the answer and discussions. – Tanaike Jun 05 '22 at 23:50
  • I managed to get your solution working. I really have to use just SPARLIKE on the formula. Problem is I need to use other functions on the formula like ARRAYFORMULA and IFERROR etc. Also I'd like to use your solution to choose specific ranges of SPARKLINES and not the whole sheet. I can do that if I use GETRANGE() but then if I need to specify a second range for a second SPARKLINE it wont work and I don't know how to adapt your solution for my case. I will keep trying. If I do not find a way I will post a question and let you know. Thank you for your replies @Tanaike – Verminous Jun 06 '22 at 06:16
  • 1
    @Verminous Thank you for replying. When I saw your new question, I would like to check it. – Tanaike Jun 06 '22 at 07:30