Consulting

Results 1 to 3 of 3

Thread: How do I reference the current cell?

  1. #1
    VBAX Expert
    Joined
    Aug 2007
    Location
    Windermere, FL, a 'burb in the greater Orlando metro area.
    Posts
    567
    Location

    How do I reference the current cell?

    Bob and all you other lurking gurus,

    How do I tell my program to use the contents of the currently selected cell? I want to take Chip Pearson's program for formating time values (which he wrote as a worksheet_change()) and run it instead as a user-selected macro.

    In his program, Chip tells the code which cell(s) are selected by having Excel look at Target as Excel.Range; it checks whether the selected 'Target' is in the specified Range by getting the Intersection of Target and the stipulated Range.

    How do I modify this code so it is invoked by the user on a user selected Cell? Do I still refer to my selected cell using Target? Or do I need to use a different reference?

    [vba]Private Sub Worksheet_Change(ByVal Target As Excel.Range)
    ' Private Sub written by Chip Pearson, from his website.
    Dim TimeStr As String

    On Error GoTo EndMacro
    '// Change Range() for the actual case
    If Application.Intersect(Target, Range("A1:A10")) Is Nothing Then
    Exit Sub
    End If
    '// Bail out if more than 1 cell is selected
    If Target.Cells.Count > 1 Then
    Exit Sub
    End If
    '// Bail if cell is empty
    If Target.Value = "" Then
    Exit Sub
    End If

    Application.EnableEvents = False
    With Target
    '// do not execute if formula in cell
    If .HasFormula = False Then
    Select Case Len(.Value)
    Case 1 ' e.g., 1 = 00:01 AM
    TimeStr = "00:0" & .Value
    Case 2 ' e.g., 12 = 00:12 AM
    TimeStr = "00:" & .Value
    Case 3 ' e.g., 735 = 7:35 AM
    TimeStr = Left(.Value, 1) & ":" & _
    Right(.Value, 2)
    Case 4 ' e.g., 1234 = 12:34
    TimeStr = Left(.Value, 2) & ":" & _
    Right(.Value, 2)
    Case 5 ' e.g., 12345 = 1:23:45 NOT 12:03:45
    TimeStr = Left(.Value, 1) & ":" & _
    Mid(.Value, 2, 2) & ":" & Right(.Value, 2)
    Case 6 ' e.g., 123456 = 12:34:56
    TimeStr = Left(.Value, 2) & ":" & _
    Mid(.Value, 3, 2) & ":" & Right(.Value, 2)
    Case Else
    Err.Raise 0
    End Select
    .Value = TimeValue(TimeStr)
    ' "hh:mm:ss")
    End If
    End With
    Application.EnableEvents = True
    Exit Sub

    EndMacro:
    ' Any error leads us to this msg
    MsgBox "You did not enter a valid time"
    Application.EnableEvents = True
    End Sub[/vba]
    Thanks!
    Last edited by RonMcK; 09-26-2008 at 09:26 PM.
    Ron
    Windermere, FL

  2. #2
    Distinguished Lord of VBAX VBAX Grand Master Bob Phillips's Avatar
    Joined
    Apr 2005
    Posts
    25,453
    Location
    Activecell is what you want Ron.

    Selection can refer to many cells, whereas ActiveCell will only refer to the one cell.
    ____________________________________________
    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 Expert
    Joined
    Aug 2007
    Location
    Windermere, FL, a 'burb in the greater Orlando metro area.
    Posts
    567
    Location
    Bob (aka XLD),

    Thanks for your help.

    Here is my solution of Dave Lecki's time entry problem as a user-invokable macro.
    [vba]Sub FormatTimeEntry()
    '
    ' FormatTimeEntry Macro
    ' Macro recorded 9/26/2008 by Ron McKenzie
    '
    ' Keyboard Shortcut: Option+Cmd+Shift+F
    '
    ' Original solution from Chip Pearson (www.cpearson.com)
    '
    Dim TimeStr As String
    On Error GoTo EndMacro
    '// Change Range() for the actual case
    '// Bail if cell is empty
    If ActiveCell.Value = "" Then
    Exit Sub
    End If
    Application.EnableEvents = False
    With ActiveCell
    '// do not execute if formula in cell
    If .HasFormula = False Then
    Select Case Len(.Value)
    Case 1 ' e.g., 1 = 00:01 AM
    TimeStr = "00:0" & .Value
    Case 2 ' e.g., 12 = 00:12 AM
    TimeStr = "00:" & .Value
    Case 3 ' e.g., 735 = 7:35 AM
    TimeStr = Left(.Value, 1) & ":" & _
    Right(.Value, 2)
    Case 4 ' e.g., 1234 = 12:34
    TimeStr = Left(.Value, 2) & ":" & _
    Right(.Value, 2)
    Case 5 ' e.g., 12345 = 1:23:45 NOT 12:03:45
    TimeStr = Left(.Value, 1) & ":" & _
    Mid(.Value, 2, 2) & ":" & Right(.Value, 2)
    Case 6 ' e.g., 123456 = 12:34:56
    TimeStr = Left(.Value, 2) & ":" & _
    Mid(.Value, 3, 2) & ":" & Right(.Value, 2)
    Case Else
    Err.Raise 0
    End Select
    .Value = TimeValue(TimeStr)
    .NumberFormat = "h:mm:ss"
    End If
    End With
    Application.EnableEvents = True
    Exit Sub

    EndMacro:
    MsgBox "You did not enter a valid time"
    Application.EnableEvents = True
    End Sub
    [/vba]
    Cheers,
    Ron
    Windermere, FL

Posting Permissions

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