Match Formula with Datedif

JoeRooney

Board Regular
Joined
Nov 27, 2017
Messages
171
Office Version
  1. 365
Hi,

I need some assistance in writing a two match formula.

The first one i would like to match the policy id and report on the last effective date for that policy.

The second one i would like to count the number of months between dates , this is in sequence so first instance of the policy number will have nothing to compare against so would be blank.

I have attached example below of how it should look.

Any help is greatly appreachiated


Policy IDTypeCodeNumber of concurrentEffective dateFirst effectexpiration dateLast DateDifference Between Months
111111111010112022-11-012021-11-042027-04-28
111111111010122022-12-012021-11-042027-04-28
1​
111111111010132023-01-012021-11-042027-04-28
1​
111111111010142023-02-012021-11-042027-04-28
1​
111111111010152023-03-012021-11-042027-04-28
1​
111111111010162023-04-012021-11-042027-04-282023-04-01
1​
222222222010112022-11-012021-11-302058-10-14
222222222010122022-12-012021-11-302058-10-14
1​
222222222010132023-01-012021-11-302058-10-14
1​
222222222010142023-02-012021-11-302058-10-14
1​
222222222010152023-03-012021-11-302058-10-14
1​
222222222010162023-04-012021-11-302058-10-142023-04-01
1​
 

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
try this, note that I've altered data for testing

Book1
ABCDEFGHI
4Policy IDTypeCodeNumber of concurrentEffective dateFirst effectexpiration dateLast DateDifference Between Months
511111111111101/11/202204/11/202128/04/2027  
611111111111201/12/202204/11/202128/04/2027 1
711111111111301/01/202304/11/202128/04/2027 1
811111111111401/02/202304/11/202128/04/2027 1
911111111111501/03/202304/11/202128/04/2027 1
1011111111111601/04/202304/11/202128/04/202701/04/20231
1122222222211101/11/202230/11/202114/10/2058  
1222222222211201/01/202330/11/202114/10/2058 2
1322222222211301/02/202330/11/202114/10/2058 1
1422222222211401/03/202330/11/202114/10/2058 1
1522222222211501/04/202330/11/202114/10/2058 1
1622222222211601/07/202330/11/202114/10/205801/07/20233
Sheet2
Cell Formulas
RangeFormula
H5:H16H5=IF(MAXIFS($E$5:$E$16,$A$5:$A$16,A5)=E5,E5,"")
I5:I16I5=IF(A5=A4,DATEDIF(E4, E5, "M"),"")
 
Last edited:
Upvote 0
Solution
Thanks , made small amendments but works great

=IF(MAXIFS(E:E,A:A,A2)=E2,E2,"")
=IF(A2=A1,DATEDIF(E1, E2, "M"),"")
 
Upvote 0

Forum statistics

Threads
1,223,275
Messages
6,171,121
Members
452,381
Latest member
Nova88

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