5

I have an issue with getLastRow(). I thought this function is supposed to return the last row that has data. But since the worksheet that I am working on has a lot more vacant rows below the rows filled with data, the functions seems to go in and select the last vacant row on its execution instead of selecting the last row which has data, which may not be the same. Can some one tell me how to fix this anomaly. Is this a google script bug or am I not clearly understanding what to do? Please ask further questions if I didn't make myself clear.

Rubén
  • 34,714
  • 9
  • 70
  • 166
Rijo Simon
  • 777
  • 3
  • 15
  • 35

4 Answers4

10

Do you have any "whole-column" formulae in the sheet? Either array formulae, or formulae that are copied all the way down? Even if these formulae are designed to return blank cells down the bottom, getLastRow() will still catch them.

If this is the case, try:

function getLastPopulatedRow(sheet) {
  var data = sheet.getDataRange().getValues();
  for (var i = data.length-1; i > 0; i--) {
    for (var j = 0; j < data[0].length; j++) {
      if (data[i][j]) return i+1;
    }
  }
  return 0; // or 1 depending on your needs
}
interestinglythere
  • 1,230
  • 13
  • 16
AdamL
  • 23,691
  • 6
  • 68
  • 59
  • Well I figured that when i do sheet.getLastRow(), it actually grabs the last row of the spreadsheet, even if it is unpopulated. What I want to do here is actually get the 'last populated row' of the spreadsheet. Now I could set the active range to the populated section of the spreadsheet. But since the worksheet will be getting populated from time to time, I will have to dynamically determine this populated range. So what should I do to dynamically determine the last populated row from a worksheet. – Rijo Simon Jun 04 '12 at 22:47
  • I am sorry man I am not yet gonna mark this comment of yours as the answer. – Rijo Simon Jun 04 '12 at 22:48
  • << I am not yet gonna mark this comment of yours as the answer >> Haha no problem. From your comment, I _think_ it is the case that you might have formulae all the way down. In which case try the function in the edited answer. – AdamL Jun 04 '12 at 23:18
  • The case with having formulae that are copied all the way down, is my case. I am putting it down here for future reference. – Rijo Simon Jun 05 '12 at 16:21
  • See posted answer below. An alternative to this which swaps out the inner loop for an array join test that seems to process significantly faster. – bryanp Oct 25 '19 at 14:32
  • For some reason, if I only have 1 populated row in the relevant data range, this code returns 0 instead of 1. I tried changing the last "return 0" to "return 1", but it didn't help. What can I change to fix this issue? Thanks! – YYR Aug 12 '22 at 15:25
2

Here is another version of the currently selected answer. This swaps out the inner loop for an array join with no spaces between items. This joins all characters on the row. If there is a character in any position it will kick out similar to the current answer.

I did some speed tests, and while I thought the chosen answer might be faster, for some reason this seems to process faster based on my tests. I believe I found this concept a few years ago here on stack overflow, but not seeing that reference now.

function getLastPopulatedRow(sheetX) {
  var arrVals = sheetX.getDataRange().getValues();
  for (var i = arrVals.length-1; i > 0; i--) {
    if (arrVals[i].join('')){
      return i+1
    }
  }
  return 0; 
}
bryanp
  • 271
  • 3
  • 9
  • For some reason, if I only have 1 populated row in the relevant data range, this code returns 0 instead of 1. I tried changing the last "return 0" to "return 1", but it didn't help. What can I change to fix this issue? Thanks! – YYR Aug 12 '22 at 15:25
0

A simpler way is

var lastRow = sheet.getDataRange().getValues().length ;
Srik
  • 7,907
  • 2
  • 20
  • 29
  • 1
    Srik, if I enter this into A1 of an empty sheet: `=ArrayFormula(IF(ROW(B:B)<11;"This is row "&ROW(B:B);IFERROR(1/0)))`, I still get the total number of rows in the sheet with your method. – AdamL Jun 05 '12 at 08:42
  • By creating an ArrayFormula on column B, you are populating the entire column B (although blank). So, getDataRange() will factor this in and give you the number of rows. – Srik Jun 13 '12 at 09:16
-1

while Adams solution will work with some tweaking, I have come across another solution to this issue with some searching. I saw a code that was supposed to find the first empty row, and I figured that I could simply return the row behind the first empty row to get the last populated row. I am attaching the code here:

function getLastPopulatedRow(sheet) {
  var cell = sheet.getRange('a1');
  var ct = 0;
  while ( cell.offset(ct, 0).getValue() != "" ) {
    ct++;
  }
  return (ct--);
}
Rijo Simon
  • 777
  • 3
  • 15
  • 35
  • This involved much less loop iterations and also avoids the nested looping, so i believe it is supposed to be faster than the previous solution. – Rijo Simon Jun 05 '12 at 19:39
  • Yes but it doesn't look anywhere else than column A. Adam's solution was scanning the whole sheet. No miracles in scripts ;-) – Serge insas Jun 05 '12 at 19:57
  • Also, I wonder about the performance with this method of iteration - potentially lots of `getValues()` will be called. – AdamL Jun 05 '12 at 22:12
  • Yea Adam you are rite about that. I probably should work on it a bit more. Thanks – Rijo Simon Jun 06 '12 at 01:06
  • I probably can have the data of the relevant range into a var (like u did) and then use that within the while condition. – Rijo Simon Jun 06 '12 at 01:09
  • I've reduced the number of lines in Adam's solution above to about the same as this one. Also note this this solutions involves many API calls while Adam's involves only 1. – interestinglythere Mar 12 '15 at 11:43