Consulting

Results 1 to 5 of 5

Thread: Solved: helpwith WorkSheet Selection_ change & command button

  1. #1
    VBAX Mentor
    Joined
    Apr 2009
    Location
    Kingsbury
    Posts
    423
    Location

    Solved: helpwith WorkSheet Selection_ change & command button

    Hi
    I have some code in a WorkSheet Selection_Change (ByVal Target as Range)
    On the same sheet i have 2 command buttons, 1 changes the cell values and the other to clear the contents of a range of cells.

    I have been debugging the code on the command button for clearing the data and after a coulpe of lines of code it goes into the Selection_change event.
    Is this supposed to happen or can i stop it from going into the change event everytime i click on the clear data button ?
    Here is the code i have got.
    Select Change Button
    [VBA]
    Dim Block As Boolean
    Private Sub WorkSheet_SelectionChange(ByVal Target As Range)
    If Not Block Then
    '// Check whether Q3 has a value 1st if 0 then reset
    'Application.ScreenUpdating = False
    If Range("Q3").Value = 0 Then Range("H26").Value = 0
    If Range("Q3").Value = 0 Then Range("H14") = 0
    If Range("Q3").Value = 0 Then Range("H23") = " "
    If Range("Q3").Value > 0 And Range("H14").Value >= 0 _
    Then Range("H26") = 50
    If Range("Q3").Value > 0 And Range("H14").Value <> 0 _
    Then Range("H26").Value = Range("H14").Value
    'Application.ScreenUpdating = True
    End If
    End Sub
    [/VBA]
    Clear Data Button
    [VBA]
    Sub CommandButton1_Click()
    '// Delete all data fields except top line leave this as default
    Application.ScreenUpdating = False
    Range("E5").Select
    ActiveCell.FormulaR1C1 = " "
    Range("J5").Select
    ActiveCell.FormulaR1C1 = " "
    Range("K5").Select
    ActiveCell.FormulaR1C1 = " "
    Range("L5").Select
    ActiveCell.FormulaR1C1 = " "
    Range("Q5").Select
    ActiveCell.FormulaR1C1 = " "
    Range("R5").Select
    ActiveCell.FormulaR1C1 = " "
    Range("B9:G9").Select
    '// Send curser back to start position ok
    Application.ScreenUpdating = True
    End Sub
    [/VBA]
    Any help would be appreciated
    Rob342

  2. #2
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    Take out all of the selects

    [vba]

    Private Sub CommandButton1_Click()
    '// Delete all data fields except top line leave this as default
    Application.ScreenUpdating = False
    Range("E5").Value = ""
    Range("J5").Value = ""
    Range("K5").Value = ""
    Range("L5").Value = ""
    Range("Q5").Value = ""
    Range("R5").Value = ""
    '// Send curser back to start position ok
    Application.ScreenUpdating = True
    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
    VBAX Mentor
    Joined
    Apr 2009
    Location
    Kingsbury
    Posts
    423
    Location
    Hi
    XLD

    Many thanks, works at treat now
    For future reference, was it the ".select" in contention With Selection_change ?

    Thanks for your time
    Regards
    Rob342

  4. #4
    Administrator
    VP-Knowledge Base
    VBAX Grand Master mdmackillop's Avatar
    Joined
    May 2004
    Location
    Scotland
    Posts
    14,489
    Location
    Changing Selection triggers the SelectionChange macro. XLD.s change removes this trigger. You can also use Application.EnableEvents=False to prevent such looping for SheetChange events and the like.
    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'

  5. #5
    VBAX Mentor
    Joined
    Apr 2009
    Location
    Kingsbury
    Posts
    423
    Location
    Thanks mdmackillop
    I will remeber it for future use
    Rob342

Posting Permissions

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