Star (Min) and End (Max) date claculation from series of dates in table

ateeqsindhu

New Member
Joined
Jan 31, 2021
Messages
6
Office Version
  1. 365
  2. 2019
  3. 2016
  4. 2013
  5. 2010
Platform
  1. Windows
Facing trouble calculating Star(Min) and End(Max) dates from a table so a to show start and end date of a closing balance amount appeared in respective GL. this is a minute extract of huge data set. also need to calculate duration (days) from start to end and ageing of same.

Book2.xlsx
ABCDEFGHIJ
1Sr. No.Branch CodeDateGL CodeClosing BalanceStartEndDays (no. of days from start till end)Count Trns.(count of unique Closing Balances)Ageing (w.r.t. how many days closing balance remained in this table, slabs are 0-30days, 31-60days, 61-90days, 91-180days & 18+)
284003811-Nov-19105130028223-5
384373812-Nov-19105130028223-5
484683813-Nov-19105130028223-5
585323815-Nov-19105130028223-5
685583816-Nov-19105130028223-5
785843817-Nov-19105130028223-5
886093818-Nov-19105130028223-5
920533818-Apr-191051300282234
1021003820-Apr-191051300282234
1121463821-Apr-191051300282234
1221963822-Apr-191051300282234
1323643826-Apr-191051300282234
1424043827-Apr-191051300282234
1524443828-Apr-191051300282234
16168803817-Oct-201051300282234
17168913818-Oct-201051300282234
Sheet1
 

Excel Facts

Can you sort left to right?
To sort left-to-right, use the Sort dialog box. Click Options. Choose "Sort left to right"

alz

Board Regular
Joined
Jul 17, 2020
Messages
130
Office Version
  1. 2019
Platform
  1. Windows
what is your expected answer on column J on your given Question?

how negative value will be count?
 

ateeqsindhu

New Member
Joined
Jan 31, 2021
Messages
6
Office Version
  1. 365
  2. 2019
  3. 2016
  4. 2013
  5. 2010
Platform
  1. Windows
what is your expected answer on column J on your given Question?

how negative value will be count?

It may be either (best option) separate column for 0-30days, 31-60days etc……. and a Tik mark appears where ever that figure falls OR in single column highlighting either as 0-30days, 31-60days etc.
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
56,729
Office Version
  1. 365
Platform
  1. Windows
Welcome to the MrExcel Message Board!

Cross-posting (posting the same question in more than one forum) is not against our rules, but the method of doing so is covered by #13 of the Forum Rules.

Be sure to follow & read the link at the end of the rule too!

Cross posted at: Star (Min) and End (Max) date claculation from series of dates in table
If you have posted the question at more places, please provide links to those as well.

If you do cross-post in the future and also provide links, then there shouldn’t be a problem.
 

alz

Board Regular
Joined
Jul 17, 2020
Messages
130
Office Version
  1. 2019
Platform
  1. Windows

ADVERTISEMENT

Check this out!.

Excel Message board.xlsm
ABCDEFGHIJKL
1Sr. No.Branch CodeDateGL CodeClosing BalanceGL CodeStartEndDays (no. of days from start till end)Count Trns.(count of unique Closing Balances)Ageing (w.r.t. how many days closing balance remained in this table, slabs are 0-30days, 31-60days, 61-90days, 91-180days & 180+)
284003811/11/2019105130028223-510513002822318/04/201918/10/20205492180 +
384373812/11/2019105130028223-5
484683813/11/2019105130028223-5
585323815/11/2019105130028223-5
685583816/11/2019105130028223-5
785843817/11/2019105130028223-5
886093818/11/2019105130028223-5
920533818/04/20191051300282234
1021003820/04/20191051300282234
1121463821/04/20191051300282234
1221963822/04/20191051300282234
1323643826/04/20191051300282234
1424043827/04/20191051300282234
1524443828/04/20191051300282234
16168803817/10/20201051300282234
17168913818/10/20201051300282234
49
Cell Formulas
RangeFormula
H2H2=AGGREGATE(15,6,$C$2:$C$17/($D$2:$D$17=$G2),1)
I2I2=AGGREGATE(14,6,$C$2:$C$17/($D$2:$D$17=$G2),1)
J2J2=I2-H2
K2K2=SUM(--((FREQUENCY(IF($D$2:$D$17=G2,$E$2:$E$17),$E$2:$E$17))>0))
L2L2=IF(J2<=30," 0-31 Days",IF(J2<=60,"31-60 Days",IF(J2<=90,"61-90 Days",IF(J2<=180,"91-180 Days","180 + "))))
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Solution

ateeqsindhu

New Member
Joined
Jan 31, 2021
Messages
6
Office Version
  1. 365
  2. 2019
  3. 2016
  4. 2013
  5. 2010
Platform
  1. Windows
Check this out!.

Excel Message board.xlsm
ABCDEFGHIJKL
1Sr. No.Branch CodeDateGL CodeClosing BalanceGL CodeStartEndDays (no. of days from start till end)Count Trns.(count of unique Closing Balances)Ageing (w.r.t. how many days closing balance remained in this table, slabs are 0-30days, 31-60days, 61-90days, 91-180days & 180+)
284003811/11/2019105130028223-510513002822318/04/201918/10/20205492180 +
384373812/11/2019105130028223-5
484683813/11/2019105130028223-5
585323815/11/2019105130028223-5
685583816/11/2019105130028223-5
785843817/11/2019105130028223-5
886093818/11/2019105130028223-5
920533818/04/20191051300282234
1021003820/04/20191051300282234
1121463821/04/20191051300282234
1221963822/04/20191051300282234
1323643826/04/20191051300282234
1424043827/04/20191051300282234
1524443828/04/20191051300282234
16168803817/10/20201051300282234
17168913818/10/20201051300282234
49
Cell Formulas
RangeFormula
H2H2=AGGREGATE(15,6,$C$2:$C$17/($D$2:$D$17=$G2),1)
I2I2=AGGREGATE(14,6,$C$2:$C$17/($D$2:$D$17=$G2),1)
J2J2=I2-H2
K2K2=SUM(--((FREQUENCY(IF($D$2:$D$17=G2,$E$2:$E$17),$E$2:$E$17))>0))
L2L2=IF(J2<=30," 0-31 Days",IF(J2<=60,"31-60 Days",IF(J2<=90,"61-90 Days",IF(J2<=180,"91-180 Days","180 + "))))
Press CTRL+SHIFT+ENTER to enter array formulas.
Thanks dear
 

ateeqsindhu

New Member
Joined
Jan 31, 2021
Messages
6
Office Version
  1. 365
  2. 2019
  3. 2016
  4. 2013
  5. 2010
Platform
  1. Windows
Thanks dear
dear would appreciate if you could also help me on another issue in another table extracted from above table

MonthStartEndDaysDays in Current Month
0202/01/202002/25/20202525
0201/15/202002/08/2020258
0201/26/202003/05/20204029
0202/22/202003/21/2020298

i want to calculate # in "Days in Current Month" column now if i use separate formulas (04 scenarios) then calculation is ok but when i use all these formulas in combination it returns # as column "Days" SEPERATELY;
(1) =IF(AND(MONTH(N11446=M11446),(MONTH(O11446=M11446))),(O11446-N11446)+1,"")
(2) =IF(AND(MONTH(N11447<M11447),MONTH(O11447=M11447)),(O11447-(EOMONTH(M11447,-1)+1)+1),"")
(3) =IF(AND(MONTH(N11448<M11448),MONTH(O11448>M11448)),((EOMONTH(M11448,0))-(EOMONTH(M11448,-1)+1)+1),"")
(4) =IF(AND(MONTH(N11449=M11449),MONTH(O11449>M11449)),((EOMONTH(M11449,0)-N11449)+1),"")
Combined:
IF(AND(MONTH(N11446=M11446),(MONTH(O11446=M11446))),(O11446-N11446)+1,IF(AND(MONTH(N11447<M11447),MONTH(O11447=M11447)),(O11447-(EOMONTH(M11447,-1)+1)+1),IF(AND(MONTH(N11448<M11448),MONTH(O11448>M11448)),((EOMONTH(M11448,0))-(EOMONTH(M11448,-1)+1)+1),IF(AND(MONTH(N11449=M11449),MONTH(O11449>M11449)),((EOMONTH(M11449,0)-N11449)+1),""))))
 

Watch MrExcel Video

Forum statistics

Threads
1,129,921
Messages
5,639,011
Members
417,062
Latest member
CM214

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
Top