Segregation of Dates based on DOW (Numeric)

shansakhi

Active Member
Joined
Apr 5, 2008
Messages
292
Office Version
  1. 365
Platform
  1. Windows
Hello Everybody,
Need your assistance.
Is there a way we can segregates dates based on DOW (Day of week - numeric).
The data can come in any format.
Below sample data for your reference...

RAW DATA (Here DOW numeric = 1-MON,2-TUE, 3-WED,4-THU,5-FRI,6-SAT,7-SUN)

INPUT OUTPUT
[TABLE="class: grid, width: 500"]
<tbody>[TR]
[TD]Eff Date[/TD]
[TD]Dis Date[/TD]
[TD]DOW[/TD]
[TD]Date[/TD]
[TD]DOW[/TD]
[/TR]
[TR]
[TD]28-Dec-18[/TD]
[TD]31-Dec-18[/TD]
[TD]15[/TD]
[TD]28-Dec-18[/TD]
[TD]5[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]31-Dec-18[/TD]
[TD]1[/TD]
[/TR]
[TR]
[TD]13-Dec-18[/TD]
[TD]16-Dec-18[/TD]
[TD]457[/TD]
[TD]13-Dec-18[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]14-Dec-18[/TD]
[TD]5[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]16-Dec-18[/TD]
[TD]7[/TD]
[/TR]
[TR]
[TD]5-Dec-18[/TD]
[TD]6-Dec-18[/TD]
[TD]34[/TD]
[TD]5-Dec-18[/TD]
[TD]3[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]6-Dec-18[/TD]
[TD]4[/TD]
[/TR]
[TR]
[TD]24-Dec-18[/TD]
[TD]31-Dec-18[/TD]
[TD]1357[/TD]
[TD]24-Dec-18[/TD]
[TD]1[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]26-Dec-18[/TD]
[TD]3[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]28-Dec-18[/TD]
[TD]5[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]30-Dec-18[/TD]
[TD]7[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]31-Dec-18[/TD]
[TD]1[/TD]
[/TR]
</tbody>[/TABLE]
Thank you in Advance.

Regards,
Shan
 

Excel Facts

Save Often
If you start asking yourself if now is a good time to save your Excel workbook, the answer is Yes
Hello,

Not sure to fully understand your question ...

You can use the weekday function :
Code:
=weekday(yourdate,2)

HTH
 
Upvote 0
Thank you James. My requirement is not getting a DOW in numeric... but based on these numeric DOW segregate the dates.

As mentioned below I am getting Input in Eff Date and Dis Date and DOW format which I need to segregate to Date and DOW level

INPUT OUTPUT
[TABLE="class: cms_table_grid, width: 500"]
<tbody>[TR]
[TD]Eff Date[/TD]
[TD]Dis Date[/TD]
[TD]DOW[/TD]
[TD]Date[/TD]
[TD]DOW[/TD]
[/TR]
[TR]
[TD]28-Dec-18[/TD]
[TD]31-Dec-18[/TD]
[TD]15[/TD]
[TD]28-Dec-18[/TD]
[TD]5[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]31-Dec-18[/TD]
[TD]1[/TD]
[/TR]
</tbody>[/TABLE]


Regards,
Shantanu
 
Upvote 0
Hello again,

With your set-up .... when you say ' segregate ' ... do you mean transpose ...???
 
Upvote 0
Hi, shansakhi
Does your original data look like this? I mean no blank rows between data rows.

Excel 2007 32 bit
[Table="width:, class:head"][tr=bgcolor:#008B8B][th] [/th][th]
A
[/th][th]
B
[/th][th]
C
[/th][/tr]
[tr=bgcolor:#FFFFFF][td=bgcolor:#008B8B]
1
[/td][td]Eff Date[/td][td]Dis Date[/td][td]DOW[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#008B8B]
2
[/td][td]
28-Des-18​
[/td][td]
31-Des-18​
[/td][td]
15​
[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#008B8B]
3
[/td][td]
13-Des-18​
[/td][td]
16-Des-18​
[/td][td]
457​
[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#008B8B]
4
[/td][td]
05-Des-18​
[/td][td]
06-Des-18​
[/td][td]
34​
[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#008B8B]
5
[/td][td]
24-Des-18​
[/td][td]
31-Des-18​
[/td][td]
1357​
[/td][/tr]
[/table]
[Table="width:, class:grid"][tr][td]Sheet: Sheet4[/td][/tr][/table]
 
Last edited:
Upvote 0
Hello Akuini,
Sorry for late reply. Yes you are correct...which needs to break it down down to single date based on DOW.

Regards,
Shantanu
 
Upvote 0
Hello Akuini,
Sorry for late reply. Yes you are correct...which needs to break it down down to single date based on DOW.

Regards,
Shantanu

Ok, try this:

Code:
[FONT=lucida console][COLOR=Royalblue]Sub[/COLOR] a1076113a()
[I][COLOR=seagreen]'https://www.mrexcel.com/forum/excel-questions/1076113-segregation-dates-based-dow-numeric.html[/COLOR][/I]
[COLOR=Royalblue]Dim[/COLOR] i [COLOR=Royalblue]As[/COLOR] [COLOR=Royalblue]Long[/COLOR], j [COLOR=Royalblue]As[/COLOR] [COLOR=Royalblue]Long[/COLOR], k [COLOR=Royalblue]As[/COLOR] [COLOR=Royalblue]Long[/COLOR], q [COLOR=Royalblue]As[/COLOR] [COLOR=Royalblue]Long[/COLOR]
[COLOR=Royalblue]Dim[/COLOR] va [COLOR=Royalblue]As[/COLOR] [COLOR=Royalblue]Variant[/COLOR], vb [COLOR=Royalblue]As[/COLOR] [COLOR=Royalblue]Variant[/COLOR], vc [COLOR=Royalblue]As[/COLOR] [COLOR=Royalblue]Variant[/COLOR]
[COLOR=Royalblue]Dim[/COLOR] stDate [COLOR=Royalblue]As[/COLOR] [COLOR=Royalblue]Date[/COLOR], enDate [COLOR=Royalblue]As[/COLOR] [COLOR=Royalblue]Date[/COLOR], d [COLOR=Royalblue]As[/COLOR] [COLOR=Royalblue]Date[/COLOR]

va = Range([COLOR=brown]"A2:C"[/COLOR] & Cells(Rows.count, [COLOR=brown]"A"[/COLOR]).[COLOR=Royalblue]End[/COLOR](xlUp).Row)
[COLOR=Royalblue]ReDim[/COLOR] vb([COLOR=crimson]1[/COLOR] [COLOR=Royalblue]To[/COLOR] UBound(va, [COLOR=crimson]1[/COLOR]) * [COLOR=crimson]10[/COLOR], [COLOR=crimson]1[/COLOR] [COLOR=Royalblue]To[/COLOR] [COLOR=crimson]2[/COLOR])
[COLOR=Royalblue]ReDim[/COLOR] vc([COLOR=crimson]1[/COLOR] [COLOR=Royalblue]To[/COLOR] UBound(va, [COLOR=crimson]1[/COLOR]) * [COLOR=crimson]10[/COLOR], [COLOR=crimson]1[/COLOR] [COLOR=Royalblue]To[/COLOR] [COLOR=crimson]3[/COLOR])

[COLOR=Royalblue]For[/COLOR] i = [COLOR=crimson]1[/COLOR] [COLOR=Royalblue]To[/COLOR] UBound(va, [COLOR=crimson]1[/COLOR])
    stDate = va(i, [COLOR=crimson]1[/COLOR])
    enDate = va(i, [COLOR=crimson]2[/COLOR])
      [COLOR=Royalblue]For[/COLOR] d = stDate [COLOR=Royalblue]To[/COLOR] enDate
            q = Weekday(d) - [COLOR=crimson]1[/COLOR]
            [COLOR=Royalblue]If[/COLOR] q = [COLOR=crimson]0[/COLOR] [COLOR=Royalblue]Then[/COLOR] q = [COLOR=crimson]7[/COLOR]
                [COLOR=Royalblue]If[/COLOR] q [COLOR=Royalblue]Like[/COLOR] [COLOR=brown]"["[/COLOR] & Trim(va(i, [COLOR=crimson]3[/COLOR])) & [COLOR=brown]"]"[/COLOR] [COLOR=Royalblue]Then[/COLOR]
                    j = j + [COLOR=crimson]1[/COLOR]
                    k = k + [COLOR=crimson]1[/COLOR]
                    vb(j, [COLOR=crimson]1[/COLOR]) = d
                    vb(j, [COLOR=crimson]2[/COLOR]) = q
                [COLOR=Royalblue]End[/COLOR] [COLOR=Royalblue]If[/COLOR]
      [COLOR=Royalblue]Next[/COLOR]
        vc(j - k + [COLOR=crimson]1[/COLOR], [COLOR=crimson]1[/COLOR]) = va(i, [COLOR=crimson]1[/COLOR])
        vc(j - k + [COLOR=crimson]1[/COLOR], [COLOR=crimson]2[/COLOR]) = va(i, [COLOR=crimson]2[/COLOR])
        vc(j - k + [COLOR=crimson]1[/COLOR], [COLOR=crimson]3[/COLOR]) = va(i, [COLOR=crimson]3[/COLOR])
        k = [COLOR=crimson]0[/COLOR]
[COLOR=Royalblue]Next[/COLOR]

Range([COLOR=brown]"A2"[/COLOR]).Resize(j, [COLOR=crimson]3[/COLOR]) = vc
Range([COLOR=brown]"D2"[/COLOR]).Resize(j, [COLOR=crimson]2[/COLOR]) = vb

[COLOR=Royalblue]End[/COLOR] [COLOR=Royalblue]Sub[/COLOR][/FONT]
 
Upvote 0
You're welcome, glad to help, & thanks for the feedback.:)
 
Upvote 0
Hi,
Need you help.
The code is working fine. Currently its providing output in D and E column.. Is it possible to provide this output end of all used column.
e.g.
In below case with the existing code I getting output in D and E column... I need this Output in L and M column.

Actual Data

[TABLE="width: 616"]
<colgroup><col span="10"><col></colgroup><tbody>[TR]
[TD]A COLUMN[/TD]
[TD]B COLUMN[/TD]
[TD]C COLUMN[/TD]
[TD]D COLUMN[/TD]
[TD]E COLUMN[/TD]
[TD]F COLUMN[/TD]
[TD]G COLUMN[/TD]
[TD]H COLUMN[/TD]
[TD]I COLUMN[/TD]
[TD]J COLUMN[/TD]
[TD]K COLUMN[/TD]
[/TR]
[TR]
[TD]Eff Dt[/TD]
[TD]Dis Dt[/TD]
[TD]FRQ[/TD]
[TD]Aln[/TD]
[TD]CTC[/TD]
[TD]DEP_1[/TD]
[TD]Dep_2[/TD]
[TD]DEP_3[/TD]
[TD]Dep_4[/TD]
[TD]DEP_5[/TD]
[TD]Dep_6[/TD]
[/TR]
[TR]
[TD]24-Apr-19[/TD]
[TD]28-Apr-19[/TD]
[TD]37[/TD]
[TD]AL[/TD]
[TD]202[/TD]
[TD]7:40[/TD]
[TD]8:55[/TD]
[TD]7:40[/TD]
[TD]8:55[/TD]
[TD]7:40[/TD]
[TD]8:55[/TD]
[/TR]
[TR]
[TD]31-Mar-19[/TD]
[TD]7-Apr-19[/TD]
[TD]37[/TD]
[TD]AL[/TD]
[TD]202[/TD]
[TD]7:40[/TD]
[TD]8:55[/TD]
[TD]7:40[/TD]
[TD]8:55[/TD]
[TD]7:40[/TD]
[TD]8:55[/TD]
[/TR]
[TR]
[TD]14-Apr-19[/TD]
[TD]14-Apr-19[/TD]
[TD]7[/TD]
[TD]AL[/TD]
[TD]202[/TD]
[TD]7:40[/TD]
[TD]8:55[/TD]
[TD]7:40[/TD]
[TD]8:55[/TD]
[TD]7:40[/TD]
[TD]8:55[/TD]
[/TR]
</tbody>[/TABLE]

Output Data

[TABLE="width: 741"]
<colgroup><col><col span="2"><col><col span="2"><col span="2"><col><col><col><col><col></colgroup><tbody>[TR]
[TD]A COLUMN[/TD]
[TD]B COLUMN[/TD]
[TD]C COLUMN[/TD]
[TD]D COLUMN[/TD]
[TD]E COLUMN[/TD]
[TD]F COLUMN[/TD]
[TD]G COLUMN[/TD]
[TD]H COLUMN[/TD]
[TD]I COLUMN[/TD]
[TD]J COLUMN[/TD]
[TD]K COLUMN[/TD]
[TD]L COLUMN[/TD]
[TD]M COLUMN[/TD]
[/TR]
[TR]
[TD]Eff Dt[/TD]
[TD]Dis Dt[/TD]
[TD]FRQ[/TD]
[TD]Aln[/TD]
[TD]CTC[/TD]
[TD]DEP_1[/TD]
[TD]Dep_2[/TD]
[TD]DEP_3[/TD]
[TD]Dep_4[/TD]
[TD]DEP_5[/TD]
[TD]Dep_6[/TD]
[TD]Date[/TD]
[TD]freq[/TD]
[/TR]
[TR]
[TD]24-Apr-19[/TD]
[TD]28-Apr-19[/TD]
[TD]37[/TD]
[TD]AL[/TD]
[TD]202[/TD]
[TD]7:40[/TD]
[TD]8:55[/TD]
[TD]7:40[/TD]
[TD]8:55[/TD]
[TD]7:40[/TD]
[TD]8:55[/TD]
[TD]24-Apr-19[/TD]
[TD]3[/TD]
[/TR]
[TR]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD]28-Apr-19[/TD]
[TD]7[/TD]
[/TR]
[TR]
[TD]31-Mar-19[/TD]
[TD]7-Apr-19[/TD]
[TD]37[/TD]
[TD]AL[/TD]
[TD]202[/TD]
[TD]7:40[/TD]
[TD]8:55[/TD]
[TD]7:40[/TD]
[TD]8:55[/TD]
[TD]7:40[/TD]
[TD]8:55[/TD]
[TD]31-Mar-19[/TD]
[TD]7[/TD]
[/TR]
[TR]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD]3-Apr-19[/TD]
[TD]3[/TD]
[/TR]
[TR]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD] [/TD]
[TD]7-Apr-19[/TD]
[TD]7[/TD]
[/TR]
[TR]
[TD]14-Apr-19[/TD]
[TD]14-Apr-19[/TD]
[TD]7[/TD]
[TD]AL[/TD]
[TD]202[/TD]
[TD]7:40[/TD]
[TD]8:55[/TD]
[TD]7:40[/TD]
[TD]8:55[/TD]
[TD]7:40[/TD]
[TD]8:55[/TD]
[TD]14-Apr-19[/TD]
[TD]7[/TD]
[/TR]
</tbody>[/TABLE]



[TABLE="width: 448"]
<colgroup><col width="64" span="7" style="width:48pt"></colgroup><tbody>[TR]
[TD="class: xl68, width: 64"][/TD]
[TD="class: xl68, width: 64"][/TD]
[TD="class: xl69, width: 64"][/TD]
[TD="class: xl69, width: 64"][/TD]
[TD="class: xl69, width: 64"][/TD]
[TD="class: xl70, width: 64"][/TD]
[/TR]
</tbody>[/TABLE]
 
Upvote 0

Forum statistics

Threads
1,223,911
Messages
6,175,325
Members
452,635
Latest member
laura12345

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