Consulting

Results 1 to 7 of 7

Thread: Solved: Issue with applying a name to a range in autofiltered table

  1. #1
    VBAX Regular
    Joined
    Aug 2010
    Posts
    7
    Location

    Solved: Issue with applying a name to a range in autofiltered table

    Hi all,

    first post on this forum but hoping you can help.

    I have an excel 2007 table with rows A, B, C and D

    I have a userform with a listbox for which I am trying to populate a list based on a named range. The name of the range is "Filtered".

    I have a little textbox in the userform which will then autofilter the "table1" and that is working perfectly but when I have the below code and then check the list of data in "Filtered" in the Name Manager in excel, only the first visible line of the filtered table is visible and not the 19 others...

    ActiveWorkbook.Names.Add Name:="Filtered", RefersToR1C1:=Range("Table1").SpecialCells(xlCellTypeVisible).Columns(1).Ce lls

    I have no clue as to why it isn't picking up the 20 cells for taht specific filtering (the length is variable on the filtering done previously of course).

    Any help would be very appreciated.

    Simon

  2. #2
    Knowledge Base Approver VBAX Wizard p45cal's Avatar
    Joined
    Oct 2005
    Location
    Surrey UK
    Posts
    5,875
    because such a range will only be the first area of the non-contiguous range.
    something like this perhaps:[VBA]Sub blah()
    ListBox1.Clear
    For Each cll In Range("Table1").Columns(1).SpecialCells(xlCellTypeVisible).Cells
    ListBox1.AddItem cll.Value
    Next cll
    End Sub
    [/VBA]
    p45cal
    Everyone: If I've helped and you can't be bothered to acknowledge it, I can't be bothered to look at further posts from you.

  3. #3
    Mac Moderator VBAX Guru mikerickson's Avatar
    Joined
    May 2007
    Location
    Davis CA
    Posts
    2,778
    Perhaps
    [VBA]Range("Table1").Columns(1).SpecialCells(xlCellTypeVisible).Name = "Filtered"[/VBA]

  4. #4
    VBAX Regular
    Joined
    Aug 2010
    Posts
    7
    Location

    Thumbs up

    Quote Originally Posted by p45cal
    because such a range will only be the first area of the non-contiguous range.
    something like this perhaps:[vba]Sub blah()
    ListBox1.Clear
    For Each cll In Range("Table1").Columns(1).SpecialCells(xlCellTypeVisible).Cells
    ListBox1.AddItem cll.Value
    Next cll
    End Sub
    [/vba]
    Worked perfectly thanks

  5. #5
    Knowledge Base Approver VBAX Wizard p45cal's Avatar
    Joined
    Oct 2005
    Location
    Surrey UK
    Posts
    5,875
    Quote Originally Posted by mikerickson
    Perhaps
    [vba]Range("Table1").Columns(1).SpecialCells(xlCellTypeVisible).Name = "Filtered"[/vba]
    mikerickson, what code do you then use to fill the listbox with that named range?
    p45cal
    Everyone: If I've helped and you can't be bothered to acknowledge it, I can't be bothered to look at further posts from you.

  6. #6
    Mac Moderator VBAX Guru mikerickson's Avatar
    Joined
    May 2007
    Location
    Davis CA
    Posts
    2,778
    It appeared that the issue was how to name a discontinuous range.
    Using Columns(1).SpecialCells instead of SpecialCells.Columns(1)

    As you pointed out, naming the range is not needed to loop through its cells.

  7. #7
    Knowledge Base Approver VBAX Wizard p45cal's Avatar
    Joined
    Oct 2005
    Location
    Surrey UK
    Posts
    5,875
    Quote Originally Posted by mikerickson
    It appeared that the issue was how to name a discontinuous range.
    Using Columns(1).SpecialCells instead of SpecialCells.Columns(1)

    As you pointed out, naming the range is not needed to loop through its cells.
    I hadn't noticed that!
    I thought the issue was trying to assign a non-contiguous range to a listbox, which so far, I've not found a way of doing in a single statement (though I haven't looked very hard).
    p45cal
    Everyone: If I've helped and you can't be bothered to acknowledge it, I can't be bothered to look at further posts from you.

Posting Permissions

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