Created
September 10, 2013 06:52
-
-
Save clupasq/6505837 to your computer and use it in GitHub Desktop.
SumByColor v1.1 - Added methods for Foreground Color
- replaced the deprecated getBackgroundColor() with getBackground()
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
function getBackgroundColor(rangeSpecification) { | |
var sheet = SpreadsheetApp.getActiveSpreadsheet(); | |
return sheet.getRange(rangeSpecification).getBackground(); | |
} | |
function getForegroundColor(rangeSpecification) { | |
var sheet = SpreadsheetApp.getActiveSpreadsheet(); | |
return sheet.getRange(rangeSpecification).getFontColor(); | |
} | |
function sumWhereBackgroundColorIs(color, rangeSpecification) { | |
var condition = function (cell) { return cell.getBackground() == color; }; | |
return sumByCondition(color, rangeSpecification, condition); | |
} | |
function sumWhereBackgroundColorIsNot(color, rangeSpecification) { | |
var condition = function (cell) { return cell.getBackground() != color; }; | |
return sumByCondition(color, rangeSpecification, condition); | |
} | |
function sumWhereForegroundColorIs(color, rangeSpecification) { | |
var condition = function (cell) { return cell.getFontColor() == color; }; | |
return sumByCondition(color, rangeSpecification, condition); | |
} | |
function sumWhereForegroundColorIsNot(color, rangeSpecification) { | |
var condition = function (cell) { return cell.getFontColor() != color; }; | |
return sumByCondition(color, rangeSpecification, condition); | |
} | |
function sumByCondition(color, rangeSpecification, condition) { | |
var sheet = SpreadsheetApp.getActiveSpreadsheet(); | |
var range = sheet.getRange(rangeSpecification); | |
var x = 0; | |
for (var i = 1; i <= range.getNumRows(); i++) { | |
for (var j = 1; j <= range.getNumColumns(); j++) { | |
var cell = range.getCell(i, j); | |
if(condition(cell)) | |
x += parseFloat(cell.getValue()); | |
} | |
} | |
return x; | |
} |
Added skip empty cells in this fork: https://gist.github.com/jeffdgr8/1553faa6360ad04e9c17
If you want to do multiple lines filtered by color you can use this instead of "A1:A2" types of strings which you cannot drag in spreadsheets:
=getBackgroundColor(CONCAT("G", ROW(G2))) for a column, vice versa for a row
Thank you all!
I combined WaffleSouffle's work and jeffdgr8.
Everything is here in this fork: https://gist.github.com/jwdinkel/6e4051f057d62204907b
Anybody know how to cause the functions to update if the color of a cell in the range is changed?
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment
Added "count" functions in this fork: https://gist.github.com/WaffleSouffle/7675480