Consulting

Results 1 to 16 of 16

Thread: VBA Excel (variable range) help

  1. #1

    VBA Excel (variable range) help

    Hi there, been puzzling over this one to the point of destruction!

    Can someone help.....please!!!

    For Each c In Range("b67:fe67")
    
    If c.Value < 200 Then
    c.EntireColumn.Hidden = True
    Else
    c.EntireColumn.Hidden = False
    End If
    
    Next
    Ok, so there's my basic code.

    I have a ss with a load of data on, the last row being the totals. I need to hide any columns that are less than 200 which my code does. The problem I have is that the data changes daily and therefore the end row can be different, therefore B67 can easily be B100, so I need some way of finding the last row and putting this into my code.

    Something like

    For Each c In Range("bx:fex")
    where x is the number of the row.

    Any ideas what I can do?

    Thanks in advance

  2. #2
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    [vba]

    LastRow = Cells.Find(What:="*", _
    After:=Range("A1"), _
    SearchOrder:=xlByRows, _
    SearchDirection:=xlPrevious).Row

    For i = 67 To LastRow

    Num = Application.CountIf(Cells(i, "B").Resize(, 5), "<200")
    Rows(i).Hidden = Num > 0
    Next i
    [/vba]
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  3. #3
    that didn't seem to work? I don't even undertand it to try and manipulate it though!

    more info:-

    so this last row (which can be on any row) looks like this:-

    grand total | 100 | 200 | 300 | 10 | 400 | 500 | 123 | 199

    what it needs to do is hide any columns on the grand totals row less than 200

  4. #4
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    What did it do for you? It seemed to work in my tests.
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  5. #5
    it hides the whole row of data, whereas it needs to hide individual columns based on their total value being less than 200

  6. #6
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    You can't hide individual cells, it is either rows or columns.
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  7. #7
    its columns i want to hide (if the value on the grand total row is less than 200)

  8. #8
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    Sorry, I messed that up

    [vba]

    LastRow = Cells.Find(What:="*", _
    After:=Range("A1"), _
    SearchOrder:=xlByRows, _
    SearchDirection:=xlPrevious).Row

    For i = 2 To 6

    Num = Application.CountIf(Cells(67, i).Resize(LastRow - 66), "<200")
    Columns(i).Hidden = Num > 0
    Next i
    [/vba]
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  9. #9
    hehe, thanks for trying, it's better, but still not right.

    it correctly hides columns if grand total is on row 67 and a few more beyond, but if grand total is on row 50, it errors out "run time error 1004".

  10. #10
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    You original code started on row 67. Are you now saying that you want it in any row?
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  11. #11
    my original code said it was row 67, but I explained that was the problem, the grand total can be on any row. My original code worked if it was only row 67!

  12. #12
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    So what happens if the Grand Total is in row 50 say, and in $20 there is a number < 200, should column B be hidden, or should it just be testing ONLY that very last row.
    ____________________________________________
    Nihil simul inventum est et perfectum

    Abusus non tollit usum

    Last night I dreamed of a small consolation enjoyed only by the blind: Nobody knows the trouble I've not seen!
    James Thurber

  13. #13
    its only the grand total row numbers we need to concentrate on, there will be a lot of numbers in the other rows preceeding the grand total (the last column will be a sum of these numbers). Any number in any column on the grand total row <200 should be hidden. And this grand total row could be between row 5 and row 1000 .

  14. #14
    Administrator
    VP-Knowledge Base
    VBAX Grand Master mdmackillop's Avatar
    Joined
    May 2004
    Location
    Scotland
    Posts
    14,489
    Location
    Assuming "grand total" in column A
    [vba]
    Sub HideCols()
    Dim cel As Range, c As Range
    Set cel = Columns(1).Find("grand total")
    For Each c In Range(cel.Offset(, 1), Cells(cel.Row, Columns.Count).End(xlToLeft))
    If c < 200 Then c.EntireColumn.Hidden = True
    Next
    End Sub
    [/vba]
    MVP (Excel 2008-2010)

    Post a workbook with sample data and layout if you want a quicker solution.


    To help indent your macros try Smart Indent

    Please remember to mark threads 'Solved'

  15. #15
    oh thanks so much, that works perfectly every time

    really appreciate it and thanks xld for trying.

    Chrizzler

  16. #16
    Administrator
    VP-Knowledge Base VBAX Grand Master mdmackillop's Avatar
    Joined
    May 2004
    Location
    Scotland
    Posts
    14,489
    Location
    Now you can see the importance of getting the question clear and concise.

    XLD did all the work.
    MVP (Excel 2008-2010)

    Post a workbook with sample data and layout if you want a quicker solution.


    To help indent your macros try Smart Indent

    Please remember to mark threads 'Solved'

Posting Permissions

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