Consulting

Results 1 to 7 of 7

Thread: Intersect with multiple ranges

  1. #1
    VBAX Newbie
    Joined
    Mar 2009
    Posts
    2
    Location

    Intersect with multiple ranges

    I'm new to VBA so any help would be greatly appreciated...

    I'm using code found on this site for adding a checkmark to a cell when the cell is double-clicked. It works great for one range of cells but how do I get it to work for multiple ranges?

    My spreadsheet looks like this:
    Range A10:A20 named SLCkBoxes- Cells to double click for checkmark
    Range B10:B20 - List of Departments
    Range C10:C30 named PosCkBoxes1 - Cells to double click for checkmark
    Range D10:20 - List of Job Titles
    Range E10:E20 named PosCkBoxes2 - Cells to double click for checkmark
    Range F:10:F20 - Continued list of Job Titles

    If put all of this in one column it would be too long...

    Here's the code I'm using which works for the named range SLCkBoxes. How do I get this to work for the other ranges as well?

    [VBA]
    Private Sub Worksheet_BeforeDoubleClick(ByVal Target As Range, Cancel As Boolean)
    'Limit Target count to 1
    If Target.Count > 1 Then Exit Sub
    'Isolate Target to a specific range
    If Intersect(Target, Range("SLCkBoxes")) Is Nothing Then Exit Sub
    'Set Target font to "marlett"
    Target.Font.Name = "marlett"
    'Check value of target
    If Target.Value <> "a" Then
    Target.Value = "a" 'Sets target Value = "a"
    Cancel = True
    Exit Sub
    End If
    If Target.Value = "a" Then
    Target.ClearContents 'Sets target Value = ""
    Cancel = True
    Exit Sub
    End If
    End Sub
    [/VBA]

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

    Private Sub Worksheet_BeforeDoubleClick(ByVal Target As Range, Cancel As Boolean)
    'Limit Target count to 1
    If Target.Count > 1 Then Exit Sub
    'Isolate Target to a specific range
    If Intersect(Target, Range("SLCkBoxes", "PosCkBoxes1", "PosCkBoxes2")) Is Nothing Then Exit Sub
    'Set Target font to "marlett"
    Target.Font.Name = "marlett"
    'Check value of target
    If Target.Value <> "a" Then
    Target.Value = "a" 'Sets target Value = "a"
    Cancel = True
    Exit Sub
    End If
    If Target.Value = "a" Then
    Target.ClearContents 'Sets target Value = ""
    Cancel = True
    Exit Sub
    End If
    End Sub
    [/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
    Moderator VBAX Wizard lucas's Avatar
    Joined
    Jun 2004
    Location
    Tulsa, Oklahoma
    Posts
    7,323
    Location
    You will have to use union. In the attached I added range J1:J3 just to show you how to continue....that range was not included in the original example.

    [VBA]Option Explicit
    Private Sub Worksheet_BeforeDoubleClick(ByVal Target As Range, Cancel As Boolean)
    Dim CheckmarkCells As Range
    Set CheckmarkCells = Union(Range("C2:C54"), [H2:H54], [J1:J3])
    If Target.Cells.Count > 1 Then Exit Sub
    If Not Intersect(Target, CheckmarkCells) Is Nothing Then
    If Target.Font.Name = "Marlett" Then
    Target.ClearContents
    Target.Font.Name = "Arial"
    Target.Offset(0, 1).Select
    Else
    Target.Value = "a"
    Target.Font.Name = "Marlett"
    Target.Offset(0, 1).Select
    End If
    End If
    End Sub[/VBA]

    ps. if you select your code when posting and hit the vba button, the code will be formatted for the forum. I will edit your post.
    Steve
    "Nearly all men can stand adversity, but if you want to test a man's character, give him power."
    -Abraham Lincoln

  4. #4
    Moderator VBAX Wizard lucas's Avatar
    Joined
    Jun 2004
    Location
    Tulsa, Oklahoma
    Posts
    7,323
    Location
    Bob beat me to it and he addressed the named ranges, mine did not. By using the named ranges you avoid the need to use union, is that correct Bob? You used intersect instead. Any advantage one way or the other?
    Steve
    "Nearly all men can stand adversity, but if you want to test a man's character, give him power."
    -Abraham Lincoln

  5. #5
    VBAX Newbie
    Joined
    Mar 2009
    Posts
    2
    Location
    Using Union worked great. I did use the Target.Font.Name command and the 2 If statements that followed it from my original post. Without making this switch I could not uncheck a cell by double clicking.

    thanks to all who responded.

  6. #6
    Administrator
    VP-Knowledge Base
    VBAX Grand Master mdmackillop's Avatar
    Joined
    May 2004
    Location
    Scotland
    Posts
    14,489
    Location
    Hi SanDanam
    Lucas omitted Cancel = True from his code. Add this in at the end to uncheck the cell.
    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'

  7. #7
    Moderator VBAX Wizard lucas's Avatar
    Joined
    Jun 2004
    Location
    Tulsa, Oklahoma
    Posts
    7,323
    Location
    Malcolm is right. I took the code from a sheet selection code which doesn't respond to cancel = True so I use the offset line.

    replace this:
    [vba]Target.Offset(0, 1).Select [/vba]
    with
    [vba]
    cancel = true
    [/vba]
    Steve
    "Nearly all men can stand adversity, but if you want to test a man's character, give him power."
    -Abraham Lincoln

Posting Permissions

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