macro for date in column

arnoldmiranda

Board Regular
Joined
Jul 15, 2002
Messages
233
Hi,
I maintain a file which has data going into thosands, amongst several columns of data I have column reflecting "Names" and column D with Dates, I usually do a sort by name and date so it lists accordingly. Can I assign a macro which puts a number after the date for each name in the same column so 01-Sep-06 becomes 01-Sep-06 1 and 01-Sep-06 2 02-Sep-06 3 for a certain name and then just repeats accordingly for the next name. I do realise I I may have not explained this well, if not I guess I will try to explain myself again, thanks
 

Excel Facts

Copy a format multiple times
Select a formatted range. Double-click the Format Painter (left side of Home tab). You can paste formatting multiple times. Esc to stop
assuming the data were sorted, names in columnA and dates in columnD.

Code:
Sub test()
Dim i As Long
n = 1
Columns("d").NumberFormat = "dd-mmm-yy"
For i = 1 To Range("a" & Rows.Count).End(xlUp).Row
    Cells(i, "d") = Cells(i, "d").Text & " " & n
        If Cells(i + 1, "a") <> Cells(i, "a") Then
            n = 1
                Else
                n = n + 1
        End If
Next
End Sub
 
Upvote 0
Hi,
This is beautiful, it is exactly what I wanted..... only one minor change if possible, the date format running the macro returns as m/d/yy format, can that be changed to dd-mmm, thanks :)
 
Upvote 0
Hi,
I have discovered a small issue while working the macro. After I have run the macro once and later add more data in the file, and re-run the macro the 01-Sep-06 1 returns 01-Sep-06 1 1 ..... is there any way the macro can delete the earlier data while running it again, thanks
 
Upvote 0
should be;
Code:
Sub test()
Dim i As Long
n = 1
Columns("d").NumberFormat = "dd-mmm-yy"
For i = 1 To Range("a" & Rows.Count).End(xlUp).Row
    If InStr(1, Cells(i, "d"), " ") > 0 Then
        Cells(i, "d") = Left(Cells(i, "d"), InStr(1, Cells(i, "d"), " ") - 1)
    End If
    Cells(i, "d") = Cells(i, "d").Text & " " & n
        If Cells(i + 1, "a") <> Cells(i, "a") Then
            n = 1
                Else
                n = n + 1
        End If
Next
End Sub
 
Upvote 0
Hi,
Thanks, I have just one last roadblock, can the macro sort by column A and then D before triggiring the above macro, I actually tried to recors a macro and install it however it soesn't sort chronologically in the D "Date" column, please help... thanks
 
Upvote 0
I actually tried to recors a macro and install it however it soesn't sort chronologically in the D "Date" column, please help... thanks
what do you mean? when you sort the data in columnA & D does it works? if it is, it is confusing that the recorded macro will not work while the worksheet results is fine.post the code you have right now.
 
Upvote 0
Hi
I think I have been able to crack the code

Sub test()

Columns("E:E").Select
Selection.Insert Shift:=xlToRight
Columns("D:D").Select
Selection.TextToColumns Destination:=Range("D1"), DataType:=xlDelimited, _
TextQualifier:=xlDoubleQuote, ConsecutiveDelimiter:=True, Tab:=True, _
Semicolon:=False, Comma:=False, Space:=True, Other:=False, FieldInfo _
:=Array(Array(1, 1), Array(2, 1)), TrailingMinusNumbers:=True
Columns("E:E").Select
Selection.Delete Shift:=xlToLeft
Cells.Select
Selection.Sort Key1:=Range("A2"), Order1:=xlAscending, Key2:=Range("D2") _
, Order2:=xlAscending, Header:=xlYes, OrderCustom:=1, MatchCase:=False _
, Orientation:=xlTopToBottom, DataOption1:=xlSortNormal, DataOption2:= _
xlSortNormal
Range("A1").Select

Dim i As Long
n = 1
Columns("d").NumberFormat = "dd-mmm-yy"
For i = 1 To Range("a" & Rows.Count).End(xlUp).Row
If InStr(1, Cells(i, "d"), " ") > 0 Then
Cells(i, "d") = Left(Cells(i, "d"), InStr(1, Cells(i, "d"), " ") - 1)
End If
Cells(i, "d") = Cells(i, "d").Text & " " & n
If Cells(i + 1, "a") <> Cells(i, "a") Then
n = 1
Else
n = n + 1
End If
Next

Range("D1").Select
ActiveCell.FormulaR1C1 = "Date"
Range("D2").Select

End Sub

________________________

Thanks for your help on this, would appreciate if you have a cleaner codefor what I am attempting, as I like to read codes and see the logic behind it, thanks sir...
 
Upvote 0
Columns("E:E").Select
Selection.Insert Shift:=xlToRight
can be shorten to;
Code:
Columns("E").Insert Shift:=xlToRight
follow the same for the rest of the codes
 
Upvote 0

Forum statistics

Threads
1,213,550
Messages
6,114,265
Members
448,558
Latest member
aivin

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top