+ Reply to Thread
Results 1 to 7 of 7

Worksheet_Change question

Hybrid View

  1. #1
    Registered User
    Join Date
    03-31-2011
    Location
    Manchester
    MS-Off Ver
    Excel 2010
    Posts
    68

    Worksheet_Change question

    Hi all,

    I am writing the below code, but when i step through it.

    Its goes to the below line
    Range("B" & ThisRow).Formula
    then "END IF"

    Then it goes back to the top of the code, then instead of going to the line above it goes to this
    Range("C" & ThisRow).Formula
    Its more of a loop. And its causing me problems when trying to "ClearContents"

    Please help


    
    Private Sub Worksheet_Change(ByVal Target As Excel.Range)
    Dim ThisRow As Long
    Dim dRng As Range
        ThisRow = Target.Row
        If Target.Column = 1 Then
            If Target.Value <> "" Then
                Range("B" & ThisRow).Formula = "=VLOOKUP(A" & ThisRow & ",'All Staff (Names)'!A:C,3,FALSE)"
                Range("C" & ThisRow).Formula = "=VLOOKUP(A" & ThisRow & ",'All Staff (Names)'!A:C,2,FALSE)"
                Range("E" & ThisRow).Formula = "=DATEDIF(VLOOKUP(A" & ThisRow & ",DETAILS!A:D,4,FALSE),""14/02/2014"",""Y"")"
                Range("F" & ThisRow).Formula = "=DATEDIF(VLOOKUP(A" & ThisRow & ",Salary!A:D,4,FALSE),""14/02/2014"",""Y"")"
                Range("G" & ThisRow).Formula = "=VLOOKUP(VLOOKUP(A" & ThisRow & ",DETAILS!A:I,8,FALSE),Division!B:C,2,FALSE)"
                Range("H" & ThisRow).Formula = "=VLOOKUP(VLOOKUP(A" & ThisRow & ",DETAILS!A:I,9,FALSE),Department!B:C,2,FALSE)"
                Range("I" & ThisRow).Formula = "=VLOOKUP(A" & ThisRow & ",DETAILS!A:G,7,FALSE)"
                Range("J" & ThisRow).Formula = "=VLOOKUP(VLOOKUP(A" & ThisRow & ",DETAILS!A:E,5,FALSE),'All Staff (Names)'!A:D,4,FALSE)"
                Range("R" & ThisRow).Formula = "=VLOOKUP(A" & ThisRow & ",'Active SUP'!A:J,10,FALSE)"
                Range("S" & ThisRow).Formula = "=IF(AND(R" & ThisRow & "=""LGPS"",E" & ThisRow & ">=55),""Y"",""N"")"
                Range("AA" & ThisRow).Formula = "=VLOOKUP(A" & ThisRow & ",Salary!A:C,2,FALSE)"
                Range("AB" & ThisRow).Formula = "=VLOOKUP(A" & ThisRow & ",Salary!A:C,3,FALSE)"
                'Range("AC" & ThisRow).Formula = "=VLOOKUP(A" & ThisRow & ",Salary!A:C,3,FALSE)"
                Range("AD" & ThisRow).Formula = "=AA" & ThisRow & "*3"
                Range("AE" & ThisRow).Formula = "=AA" & ThisRow & "*2"
                Range("AF" & ThisRow).Formula = "=AC" & ThisRow & "+AD" & ThisRow & "+AE" & ThisRow
                Range("AG" & ThisRow).Formula = "=IF(S" & ThisRow & "=""Y"",AF" & ThisRow & "-T" & ThisRow & ",""NO CAP COST"")"
                Range("AH" & ThisRow).Formula = "=(AD" & ThisRow & "*22%)+AE" & ThisRow & "+AC" & ThisRow
                Range("AI" & ThisRow).Formula = "=IF(S" & ThisRow & "=""Y"",AH" & ThisRow & "+T" & ThisRow & ",""NO CAP COST"")"
                Range("AJ" & ThisRow).Formula = "=AB" & ThisRow & "*22%"
                Range("AK" & ThisRow).Formula = "=AB" & ThisRow & "+AJ" & ThisRow & ""
            Else
                Rows(ThisRow).ClearContents
                Exit Sub
            End If
        End If
    End Sub
    Last edited by wrightyrx7; 01-15-2014 at 10:55 AM.

  2. #2
    Forum Guru Norie's Avatar
    Join Date
    02-02-2005
    Location
    Stirling, Scotland
    MS-Off Ver
    Microsoft Office 365
    Posts
    19,646

    Re: Worksheet_Change question

    That line of code changes the sheet, so the worksheet change event is called.

    Try disabling events,
    Application.EnableEvents = False
    but don't forget to enable them again.
    Application.EnableEvents = True
    If posting code please use code tags, see here.

  3. #3
    Forum Guru Norie's Avatar
    Join Date
    02-02-2005
    Location
    Stirling, Scotland
    MS-Off Ver
    Microsoft Office 365
    Posts
    19,646

    Re: Worksheet_Change question

    http://www.mrexcel.com/forum/excel-q...-question.html


    Your post does not comply with Rule 8 of our Forum RULES. Do not crosspost your question on multiple forums without including links here to the other threads on other forums.

    Cross-posting is when you post the same question in other forums on the web. The last thing you want to do is waste people's time working on an issue you have already resolved elsewhere. We prefer that you not cross-post at all, but if you do (and it's unlikely to go unnoticed), you MUST provide a link (copy the url from the address bar in your browser) to the cross-post.

    Expect cross-posted questions without a link to be closed and a message will be posted by the moderator explaining why. We are here to help so help us to help you!

    Read this to understand why we ask you to do this, and then please edit your first post to include links to any and all cross-posts in any other forums (not just this site).

  4. #4
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    48,975

    Re: Worksheet_Change question

    For testing purposes, please provide a sample workbook in future. To test your code, it was necessary to create a new workbook and then create and name 7 worksheets.

    Also, if you make changes to a sheet within a Change event handler, you need to disable event handling.

    Private Sub Worksheet_Change(ByVal Target As Excel.Range)
    Dim ThisRow As Long
    Dim dRng As Range
    ThisRow = Target.Row
    If Target.Column = 1 Then
        If Target.Value <> "" Then
            Application.EnableEvents = False
            Range("B" & ThisRow).Formula = "=VLOOKUP(A" & ThisRow & ",'All Staff (Names)'!A:C,3,FALSE)"
            Range("C" & ThisRow).Formula = "=VLOOKUP(A" & ThisRow & ",'All Staff (Names)'!A:C,2,FALSE)"
            Range("E" & ThisRow).Formula = "=DATEDIF(VLOOKUP(A" & ThisRow & ",DETAILS!A:D,4,FALSE),""14/02/2014"",""Y"")"
            Range("F" & ThisRow).Formula = "=DATEDIF(VLOOKUP(A" & ThisRow & ",Salary!A:D,4,FALSE),""14/02/2014"",""Y"")"
            Range("G" & ThisRow).Formula = "=VLOOKUP(VLOOKUP(A" & ThisRow & ",DETAILS!A:I,8,FALSE),Division!B:C,2,FALSE)"
            Range("H" & ThisRow).Formula = "=VLOOKUP(VLOOKUP(A" & ThisRow & ",DETAILS!A:I,9,FALSE),Department!B:C,2,FALSE)"
            Range("I" & ThisRow).Formula = "=VLOOKUP(A" & ThisRow & ",DETAILS!A:G,7,FALSE)"
            Range("J" & ThisRow).Formula = "=VLOOKUP(VLOOKUP(A" & ThisRow & ",DETAILS!A:E,5,FALSE),'All Staff (Names)'!A:D,4,FALSE)"
            Range("R" & ThisRow).Formula = "=VLOOKUP(A" & ThisRow & ",'Active SUP'!A:J,10,FALSE)"
            Range("S" & ThisRow).Formula = "=IF(AND(R" & ThisRow & "=""LGPS"",E" & ThisRow & ">=55),""Y"",""N"")"
            Range("AA" & ThisRow).Formula = "=VLOOKUP(A" & ThisRow & ",Salary!A:C,2,FALSE)"
            Range("AB" & ThisRow).Formula = "=VLOOKUP(A" & ThisRow & ",Salary!A:C,3,FALSE)"
            'Range("AC" & ThisRow).Formula = "=VLOOKUP(A" & ThisRow & ",Salary!A:C,3,FALSE)"
            Range("AD" & ThisRow).Formula = "=AA" & ThisRow & "*3"
            Range("AE" & ThisRow).Formula = "=AA" & ThisRow & "*2"
            Range("AF" & ThisRow).Formula = "=AC" & ThisRow & "+AD" & ThisRow & "+AE" & ThisRow
            Range("AG" & ThisRow).Formula = "=IF(S" & ThisRow & "=""Y"",AF" & ThisRow & "-T" & ThisRow & ",""NO CAP COST"")"
            Range("AH" & ThisRow).Formula = "=(AD" & ThisRow & "*22%)+AE" & ThisRow & "+AC" & ThisRow
            Range("AI" & ThisRow).Formula = "=IF(S" & ThisRow & "=""Y"",AH" & ThisRow & "+T" & ThisRow & ",""NO CAP COST"")"
            Range("AJ" & ThisRow).Formula = "=AB" & ThisRow & "*22%"
            Range("AK" & ThisRow).Formula = "=AB" & ThisRow & "+AJ" & ThisRow & ""
            Application.EnableEvents = True
            Exit Sub
        Else
            Application.EnableEvents = False
            Rows(ThisRow).ClearContents
            Application.EnableEvents = True
            Exit Sub
        End If
    End If
    End Sub

    Regards, TMS
    Trevor Shuttleworth - Retired Excel/VBA Consultant

    I dream of a better world where chickens can cross the road without having their motives questioned

    'Being unapologetic means never having to say you're sorry' John Cooper Clarke


  5. #5
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    48,975

    Re: Worksheet_Change question

    @Norie: sorry, busy creating the workbook to test the code.

    @wrightyrx7: if you change one cell, its address is not going to be "$A$3:$A$65536". That's why the code was failing, unless you were selecting and deleting everything from row 3 down.


    Regards, TMS

  6. #6
    Registered User
    Join Date
    03-31-2011
    Location
    Manchester
    MS-Off Ver
    Excel 2010
    Posts
    68

    Re: Worksheet_Change question

    Thank you so so much
    Last edited by wrightyrx7; 01-15-2014 at 11:49 AM.

  7. #7
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    48,975

    Re: Worksheet_Change question

    You're welcome.



    If you are satisfied with the solution(s) provided, please mark your thread as Solved.


    New quick method:
    Select Thread Tools-> Mark thread as Solved. To undo, select Thread Tools-> Mark thread as Unsolved.

    Or you can use this way:

    How to mark a thread Solved
    Go to the first post
    Click edit
    Click Go Advanced
    Just below the word Title you will see a dropdown with the word No prefix.
    Change to Solved
    Click Save


    You may also want to consider thanking those people who helped you by clicking on the little star at the bottom left of their reply to your question.

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Similar Threads

  1. [SOLVED] Question about Worksheet_Change
    By 2sqrd in forum Excel Programming / VBA / Macros
    Replies: 13
    Last Post: 03-29-2013, 09:53 AM
  2. Worksheet_change and last value - quick question
    By losmi8 in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 12-02-2010, 03:54 PM
  3. [SOLVED] worksheet_change question
    By HRman in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 03-30-2006, 12:40 PM
  4. [SOLVED] Worksheet_Change
    By Dan in forum Excel Programming / VBA / Macros
    Replies: 5
    Last Post: 11-16-2005, 03:45 PM
  5. [SOLVED] Worksheet_Change DDE
    By Johan de Kok in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 04-23-2005, 02:07 PM

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