+ Reply to Thread
Results 1 to 13 of 13

prevent empty rows from printing

Hybrid View

  1. #1
    Harlan Grove
    Guest

    Re: prevent empty rows from printing

    dill_weed wrote...
    >I have copied the formulae down several hundred rows, because it is a
    >template that will receive different sized files. So there are several
    >hundred rows with formulae in them, but they show up blank, and I would like
    >to avoid printing the blank cells.


    If all these blank rows will be clustered below the nonblank rows, you
    could define the print area for the worksheet using a formula. For
    example, if the worksheet were named WS, then run the menu command
    Insert > Name > Define, enter WS!Print_Area in the topmost field in the
    Define Name dialog and enter the formula

    =OFFSET(WS!$A$1:$J$1,0,0,
    LOOKUP(2,1/(WS!$A$2:$A$65536<>""),ROW(WS!$A$2:$A$65536)))

    in the 'Refers to' entry field, then click OK. Replace the worksheet
    name, WS, as needed. Also note that the print range could start in any
    cell, so replace the first argument to OFFSET, WS!$A$1:$J$10 in the
    formula above, with the range address of the topmost row of your
    intended print range, and adjust the LOOKUP call as needed to
    correspond to changes in the location of the print range (note that
    both ranges in the LOOKUP call begin in the cell immediately below the
    top-left cell of the print range).


  2. #2
    Registered User
    Join Date
    07-28-2006
    Posts
    7
    Quote Originally Posted by Harlan Grove
    dill_weed wrote...
    >I have copied the formulae down several hundred rows, because it is a
    >template that will receive different sized files. So there are several
    >hundred rows with formulae in them, but they show up blank, and I would like
    >to avoid printing the blank cells.


    If all these blank rows will be clustered below the nonblank rows, you
    could define the print area for the worksheet using a formula. For
    example, if the worksheet were named WS, then run the menu command
    Insert > Name > Define, enter WS!Print_Area in the topmost field in the
    Define Name dialog and enter the formula

    =OFFSET(WS!$A$1:$J$1,0,0,
    LOOKUP(2,1/(WS!$A$2:$A$65536<>""),ROW(WS!$A$2:$A$65536)))

    in the 'Refers to' entry field, then click OK. Replace the worksheet
    name, WS, as needed. Also note that the print range could start in any
    cell, so replace the first argument to OFFSET, WS!$A$1:$J$10 in the
    formula above, with the range address of the topmost row of your
    intended print range, and adjust the LOOKUP call as needed to
    correspond to changes in the location of the print range (note that
    both ranges in the LOOKUP call begin in the cell immediately below the
    top-left cell of the print range).
    I must say this is truly wonderful. I've been looking for a way to dynamically set the print area that is ideal for a long time without messing with hiding rows and cells and such. This has been working perfectly on all of my templates so far!

    Thanks!

  3. #3
    Registered User
    Join Date
    02-14-2023
    Location
    Los Angeles, California, USA
    MS-Off Ver
    MS Office Pro+ 2016
    Posts
    1

    Re: prevent empty rows from printing

    Quote Originally Posted by Harlan Grove View Post
    dill_weed wrote...
    >I have copied the formulae down several hundred rows, because it is a
    >template that will receive different sized files. So there are several
    >hundred rows with formulae in them, but they show up blank, and I would like
    >to avoid printing the blank cells.


    If all these blank rows will be clustered below the nonblank rows, you
    could define the print area for the worksheet using a formula. For
    example, if the worksheet were named WS, then run the menu command
    Insert > Name > Define, enter WS!Print_Area in the topmost field in the
    Define Name dialog and enter the formula

    =OFFSET(WS!$A$1:$J$1,0,0,
    LOOKUP(2,1/(WS!$A$2:$A$65536<>""),ROW(WS!$A$2:$A$65536)))

    in the 'Refers to' entry field, then click OK. Replace the worksheet
    name, WS, as needed. Also note that the print range could start in any
    cell, so replace the first argument to OFFSET, WS!$A$1:$J$10 in the
    formula above, with the range address of the topmost row of your
    intended print range, and adjust the LOOKUP call as needed to
    correspond to changes in the location of the print range (note that
    both ranges in the LOOKUP call begin in the cell immediately below the
    top-left cell of the print range).

    This is an old thread, but it is still useful. I agree with Vassago that this is awesome!

    I had to spend a few minutes studying it to understand how it works.
    For those interested:
    Syntax: OFFSET(reference, rows, cols, [height], [width])
    where rows and cols are the number of rows and columns to offset from the area "reference", and height and width are the number of rows and columns to include in the resulting area.
    If height and width are omitted, the OFFSET function defaults to the height and width of the reference area.
    Syntax: LOOKUP(lookup_value, lookup_vector, [result_vector])
    If the LOOKUP function doesn't find the lookup value (in this case 2), it returns the row of the largest value it finds.
    The fancy bit that I didn't know was that LOOKUP can do array formulas, not just arrays.
    So, 1/(cell<>"") returns 1 if the cell has a value in it and an error [#Div/0!] if not.
    The resulting lookup_vector is a 1 in every row with a value, and an error in the rest.
    The result_vector is the row number of each cell.
    So, the whole LOOKUP formula looks in Column A and returns the row number of the last cell that is not empty.
    NOTE: This is not the same as the number of rows which have values in them, nor is it the number of rows between the reference and the last row with a value.
    The OFFSET function then returns the area that starts with reference, and expands it down so that it has the number of rows equal to the row number of the last cell in column A with a value.

    This was perfect for dill_weed's original situation. I had a different situation.
    If you don't want to print the first 5 rows, and you change the reference to, say row 6. It will then print 5 empty rows at the bottom.
    If you want it to start at row 6 and print only to the end of the values you can either
    1) leave the reference at row 1 and put 5 in as the "rows" argument in the OFFSET function or
    2) Put the reference at WS!$A$6:$A$65536

    Either way, you need to subtract 5 from height (the LOOKUP function answer)

    =OFFSET(WS!$A$1:$J$1,5,0,LOOKUP(2,1/(WS!$A$2:$A$65536<>""),ROW(WS!$A$2:$A$65536))-5)

    I also had the issue where I didn't have values in column A in every row. I needed to check columns C and F.

    I modified Harlan Grove's excellent technique to set the print area to the last row with any cell in column C or F not empty:

    =OFFSET(WS!$A$1:$J$1,0,0,MAX(LOOKUP(2,1/(WS!$C$2:$C$65536<>""),ROW(WS!$A$2:$A$65536)),LOOKUP(2,1/(WS!$F$2:$F$65536<>""),ROW(WS!$A$2:$A$65536))))

    But then I realized that if the name manager and LOOKOUT functions can handle array functions I could use a MAX(IF( to generalize it.

    This sets the Print_Area to all columns in the reference area down to the last value in any of the columns:

    =OFFSET(WS!$A$1:$J$1,0,0,MAX(IF(WS!$A$2:$J$65536<>"",ROW(WS!$A$2:$A$65536),0)))

    Cheers!
    Dudley Sirius

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1