Copy Condition Down

pto160

Active Member
Joined
Feb 1, 2009
Messages
482
Office Version
  1. 365
Platform
  1. Windows
I am trying to copy down a condition that resets itself. On any row in column A that has the word "date", it is 1 in column B and two for the next row and so on that has a value in column D (no blank values). When it gets to the next row date, it is 1 again.

Sheet1

<table style="BACKGROUND-COLOR: #ffffff; PADDING-LEFT: 2pt; PADDING-RIGHT: 2pt; FONT-FAMILY: Arial,Arial; FONT-SIZE: 10pt" border="1" cellpadding="0" cellspacing="0"> <colgroup> <col style="WIDTH: 30px; FONT-WEIGHT: bold"> <col style="WIDTH: 64px"> <col style="WIDTH: 64px"> <col style="WIDTH: 64px"> <col style="WIDTH: 64px"> <col style="WIDTH: 64px"></colgroup> <tbody> <tr style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt; FONT-WEIGHT: bold"> <td>
</td> <td>A</td> <td>B</td> <td>C</td> <td>D</td> <td>E</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">1</td> <td>
</td> <td>Number</td> <td>
</td> <td>
</td> <td>
</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">2</td> <td>Date</td> <td style="TEXT-ALIGN: right">1</td> <td style="TEXT-ALIGN: right">7/15/2011</td> <td>
</td> <td>
</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">3</td> <td>
</td> <td style="TEXT-ALIGN: right">2</td> <td>
</td> <td>Type</td> <td>A</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">4</td> <td>
</td> <td style="TEXT-ALIGN: right">3</td> <td>
</td> <td>Amount</td> <td style="TEXT-ALIGN: right">100</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">5</td> <td>
</td> <td style="TEXT-ALIGN: right">4</td> <td>
</td> <td>Ref</td> <td>John Doe</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">6</td> <td>
</td> <td style="TEXT-ALIGN: right">5</td> <td>
</td> <td>Trans ID</td> <td style="TEXT-ALIGN: right">465465</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">7</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">8</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">9</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td> <td>
</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">10</td> <td>Date</td> <td style="TEXT-ALIGN: right">1</td> <td style="TEXT-ALIGN: right">7/18/2011</td> <td>
</td> <td>
</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">11</td> <td>
</td> <td style="TEXT-ALIGN: right">2</td> <td>
</td> <td>
</td> <td>
</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">12</td> <td>
</td> <td style="TEXT-ALIGN: right">3</td> <td>
</td> <td>Type</td> <td>B</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">13</td> <td>
</td> <td style="TEXT-ALIGN: right">4</td> <td>
</td> <td>Amount</td> <td style="TEXT-ALIGN: right">200</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">14</td> <td>
</td> <td style="TEXT-ALIGN: right">5</td> <td>
</td> <td>Ref</td> <td>Mary Doe</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">15</td> <td>
</td> <td style="TEXT-ALIGN: right">6</td> <td>
</td> <td>Trans ID</td> <td style="TEXT-ALIGN: right">4646456</td></tr></tbody></table>

Excel tables to the web >> Excel Jeanie HTML 4
 

Excel Facts

How can you automate Excel?
Press Alt+F11 from Windows Excel to open the Visual Basic for Applications (VBA) editor.
My idea was to have it look through column C, looking for a date. (and enter a 1 in column B.) Then have it look at column D (or E?) starting in the next row and consecutively number column B for each cell in D or E with a value.
(Then start over in column C looking for the next date.)

What's throwing me off of this is that you have a date in C10 but there is no data in D11:E11, yet there is a 2 in B11. Is that the way your real data is set up, or will there really be a value in the next row of columns D or E for every date in column C?
 
Upvote 0
Yes, to make this work, there will be data in D11.
 
Upvote 0
Would we have to use a countif or lookup function here to make this work? The max number of rows after the date would be 8 before the next date.
 
Upvote 0
Sheet1

<table style="BACKGROUND-COLOR: #ffffff; PADDING-LEFT: 2pt; PADDING-RIGHT: 2pt; FONT-FAMILY: Arial,Arial; FONT-SIZE: 10pt" border="1" cellpadding="0" cellspacing="0"> <colgroup> <col style="WIDTH: 30px; FONT-WEIGHT: bold"> <col style="WIDTH: 64px"> <col style="WIDTH: 64px"> <col style="WIDTH: 64px"> <col style="WIDTH: 64px"> <col style="WIDTH: 64px"></colgroup> <tbody> <tr style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt; FONT-WEIGHT: bold"> <td> </td> <td>A</td> <td>B</td> <td>C</td> <td>D</td> <td>E</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">1</td> <td> </td> <td>Number</td> <td> </td> <td> </td> <td> </td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">2</td> <td>Date</td> <td style="TEXT-ALIGN: right">1</td> <td style="TEXT-ALIGN: right">7/15/2011</td> <td> </td> <td> </td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">3</td> <td> </td> <td style="TEXT-ALIGN: right">2</td> <td> </td> <td>Type</td> <td>A</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">4</td> <td> </td> <td style="TEXT-ALIGN: right">3</td> <td> </td> <td>Amount</td> <td style="TEXT-ALIGN: right">100</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">5</td> <td> </td> <td style="TEXT-ALIGN: right">4</td> <td> </td> <td>Ref</td> <td>John Doe</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">6</td> <td> </td> <td style="TEXT-ALIGN: right">5</td> <td> </td> <td>Trans ID</td> <td style="TEXT-ALIGN: right">465465</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">7</td> <td> </td> <td> </td> <td> </td> <td> </td> <td> </td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">8</td> <td> </td> <td> </td> <td> </td> <td> </td> <td> </td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">9</td> <td> </td> <td> </td> <td> </td> <td> </td> <td> </td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">10</td> <td>Date</td> <td style="TEXT-ALIGN: right">1</td> <td style="TEXT-ALIGN: right">7/18/2011</td> <td> </td> <td> </td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">11</td> <td> </td> <td> </td> <td> </td> <td> </td> <td> </td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">12</td> <td> </td> <td style="TEXT-ALIGN: right">2</td> <td> </td> <td>Type</td> <td>B</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">13</td> <td> </td> <td style="TEXT-ALIGN: right">3</td> <td> </td> <td>Amount</td> <td style="TEXT-ALIGN: right">200</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">14</td> <td> </td> <td style="TEXT-ALIGN: right">4</td> <td> </td> <td>Ref</td> <td>Mary Doe</td></tr> <tr style="HEIGHT: 17px"> <td style="TEXT-ALIGN: center; BACKGROUND-COLOR: #cacaca; FONT-SIZE: 8pt">15</td> <td> </td> <td style="TEXT-ALIGN: right">5</td> <td> </td> <td>Trans ID</td> <td style="TEXT-ALIGN: right">4646456</td></tr></tbody></table>
There was a mistake in my table. So I am tying to put a number beside anything that has a value in column D. When it gets to the date row, it will go back to one again. Is there any way to do this?

http://www.excel-jeanie-html.de/index.php?f=1
 
Upvote 0
Sorry for the delay. We're having about a week long typhoon here and it's playing he... (heck) with our hydro electric plants.

I see now how you want to handle the row 11 situation but it still might be a day or so before I can spend any real time coming up with a solution, but I must say it would be easier (for me at least, as formulas are not my strongest suit) to write a vba routine for this.

Would vba be acceptable to you, or are you strictly looking for a formula solution?
 
Upvote 0
No problem. VBA is fine if there is no formula solution. I will be using the numbers in a lookup table.
 
Upvote 0
OK, assuming your data layout is just as it's shown in the example, here's something you can try:
Code:
Sub NumberingDemo()
Dim LstRw As Long, StartDateRw As Long, _
    EndDateRw As Long, RwC As Range, _
    RwD As Range, Counter As Integer
        
LstRw = Cells.Find(What:="*", After:=[A1], SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
StartDateRw = 1
EndDateRw = 1

For Each RwC In Range("C1:C" & LstRw)
  If Not RwC = "" Then
    Counter = 1
    StartDateRw = RwC.Row
    Cells(RwC.Row, "B").Value = Counter
    Counter = Counter + 1
    If EndDateRw > StartDateRw Then StartDateRw = EndDateRw + 1
    EndDateRw = Cells(StartDateRw, "C").End(xlDown).Row - 1
    If EndDateRw > LstRw Then EndDateRw = LstRw
    For Each RwD In Range(Cells(StartDateRw, "D"), Cells(EndDateRw, "D"))
      If Not RwD = "" Then
        RwD.Offset(, -2) = Counter
        Counter = Counter + 1
      End If
    Next RwD
  End If
Next RwC
End Sub

Hope it helps.
 
Upvote 0
Yes, it works great. Thank you so much. It looks like VBA was the only way to do this. This will really help me to organize my data. I do not think there is a formula solution.
 
Upvote 0
Most welcome. Glad it helped.... but...
It looks like VBA was the only way to do this. ... I do not think there is a formula solution.
Just about the time I concede this, Aladin or Fairwinds or somebody usually throws up a formula that blows me away. :laugh:
 
Upvote 0

Forum statistics

Threads
1,224,602
Messages
6,179,848
Members
452,948
Latest member
UsmanAli786

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