Hi rcomag,
It's easier to stick with the original two column VLOOKUP and you can extend those columns down as many rows as you like (as long as the formulae also look down to the maximum row).
You don't say how the paid date is entered so again I'll assume a full date.
You've taken away the pre-1973 row so I'll wrap the formula in an IFERROR and return zero if an earlier date is selected.
It is possible to do it with VLOOKUP but it gets very messy. Your example data doesn't show it but what if they pay June 1993? VLOOKUP returns the 1992 row and you could select the column related to the month but June 1992 might be at a different rate than December 1992, which is the closest earlier date with data.
I'd change to use INDEX and MATCH to select from that array:
[TABLE="width: 780"]
<tbody>[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]
[TH][/TH]
[TH]A[/TH]
[TH]B[/TH]
[TH]C[/TH]
[TH]D[/TH]
[TH]E[/TH]
[TH]F[/TH]
[TH]G[/TH]
[TH]H[/TH]
[TH]I[/TH]
[TH]J[/TH]
[TH]K[/TH]
[TH]L[/TH]
[TH]M[/TH]
[/TR]
[TR]
[TD="align: center"]1[/TD]
[TD]TABLE OF PENALTIES[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[/TR]
[TR]
[TD="align: center"]2[/TD]
[TD="align: center"][/TD]
[TD="align: center"]january[/TD]
[TD="align: center"]february[/TD]
[TD="align: center"]march[/TD]
[TD="align: center"]april[/TD]
[TD="align: center"]may[/TD]
[TD="align: center"]june[/TD]
[TD="align: center"]july[/TD]
[TD="align: center"]august[/TD]
[TD="align: center"]september[/TD]
[TD="align: center"]october[/TD]
[TD="align: center"]november[/TD]
[TD="align: center"]december[/TD]
[/TR]
[TR]
[TD="align: center"]3[/TD]
[TD="align: center"]1973[/TD]
[TD="align: center"]12%[/TD]
[TD="align: center"]12%[/TD]
[TD="align: center"]12%[/TD]
[TD="align: center"]12%[/TD]
[TD="align: center"]12%[/TD]
[TD="align: center"]12%[/TD]
[TD="align: center"]12%[/TD]
[TD="align: center"]12%[/TD]
[TD="align: center"]12%[/TD]
[TD="align: center"]12%[/TD]
[TD="align: center"]12%[/TD]
[TD="align: center"]12%[/TD]
[/TR]
[TR]
[TD="align: center"]4[/TD]
[TD="align: center"]1974[/TD]
[TD="align: center"]24%[/TD]
[TD="align: center"]24%[/TD]
[TD="align: center"]24%[/TD]
[TD="align: center"]24%[/TD]
[TD="align: center"]24%[/TD]
[TD="align: center"]24%[/TD]
[TD="align: center"]24%[/TD]
[TD="align: center"]24%[/TD]
[TD="align: center"]24%[/TD]
[TD="align: center"]24%[/TD]
[TD="align: center"]24%[/TD]
[TD="align: center"]24%[/TD]
[/TR]
[TR]
[TD="align: center"]5[/TD]
[TD="align: center"]1992[/TD]
[TD="align: center"]72%[/TD]
[TD="align: center"]72%[/TD]
[TD="align: center"]72%[/TD]
[TD="align: center"]72%[/TD]
[TD="align: center"]72%[/TD]
[TD="align: center"]72%[/TD]
[TD="align: center"]72%[/TD]
[TD="align: center"]72%[/TD]
[TD="align: center"]72%[/TD]
[TD="align: center"]72%[/TD]
[TD="align: center"]72%[/TD]
[TD="align: center"]72%[/TD]
[/TR]
[TR]
[TD="align: center"]6[/TD]
[TD="align: center"]2017[/TD]
[TD="align: center"]50%[/TD]
[TD="align: center"]52%[/TD]
[TD="align: center"]54%[/TD]
[TD="align: center"]56%[/TD]
[TD="align: center"]58%[/TD]
[TD="align: center"]60%[/TD]
[TD="align: center"]62%[/TD]
[TD="align: center"]64%[/TD]
[TD="align: center"]66%[/TD]
[TD="align: center"]68%[/TD]
[TD="align: center"]70%[/TD]
[TD="align: center"]72%[/TD]
[/TR]
[TR]
[TD="align: center"]7[/TD]
[TD="align: center"]2018[/TD]
[TD="align: center"]26%[/TD]
[TD="align: center"]28%[/TD]
[TD="align: center"]30%[/TD]
[TD="align: center"]32%[/TD]
[TD="align: center"]34%[/TD]
[TD="align: center"]36%[/TD]
[TD="align: center"]38%[/TD]
[TD="align: center"]40%[/TD]
[TD="align: center"]42%[/TD]
[TD="align: center"]44%[/TD]
[TD="align: center"]46%[/TD]
[TD="align: center"]48%[/TD]
[/TR]
[TR]
[TD="align: center"]8[/TD]
[TD="align: center"]2019[/TD]
[TD="align: center"]-10%[/TD]
[TD="align: center"]-10%[/TD]
[TD="align: center"]-10%[/TD]
[TD="align: center"]8%[/TD]
[TD="align: center"]10%[/TD]
[TD="align: center"]12%[/TD]
[TD="align: center"]14%[/TD]
[TD="align: center"]16%[/TD]
[TD="align: center"]18%[/TD]
[TD="align: center"]20%[/TD]
[TD="align: center"]22%[/TD]
[TD="align: center"]24%[/TD]
[/TR]
[TR]
[TD="align: center"]9[/TD]
[TD="align: center"]2020[/TD]
[TD="align: center"]-20%[/TD]
[TD="align: center"]-20%[/TD]
[TD="align: center"]-20%[/TD]
[TD="align: center"]-20%[/TD]
[TD="align: center"]-20%[/TD]
[TD="align: center"]-20%[/TD]
[TD="align: center"]-20%[/TD]
[TD="align: center"]-20%[/TD]
[TD="align: center"]-20%[/TD]
[TD="align: center"]-20%[/TD]
[TD="align: center"]-20%[/TD]
[TD="align: center"]-20%[/TD]
[/TR]
[TR]
[TD="align: center"]10[/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"]................[/TD]
[TD="align: center"].......[/TD]
[TD="align: center"].......[/TD]
[TD="align: center"].......[/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[/TR]
[TR]
[TD="align: center"]11[/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"]Date Paid[/TD]
[TD="align: center"]Penalty[/TD]
[TD="align: center"]Amount[/TD]
[TD="align: center"]Penalty[/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[/TR]
[TR]
[TD="align: center"]12[/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"]06-Jun-18[/TD]
[TD="align: center"]36%[/TD]
[TD="align: center"]1500[/TD]
[TD="align: center"]540.00[/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: right"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[/TR]
[TR]
[TD="align: center"]13[/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"]01-Oct-17[/TD]
[TD="align: center"]68%[/TD]
[TD="align: center"]1500[/TD]
[TD="align: center"]1020.00[/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: right"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[/TR]
[TR]
[TD="align: center"]14[/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"]02-Feb-19[/TD]
[TD="align: center"]-10%[/TD]
[TD="align: center"]1500[/TD]
[TD="align: center"]-150.00[/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: right"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[/TR]
[TR]
[TD="align: center"]15[/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"]02-Feb-93[/TD]
[TD="align: center"]72%[/TD]
[TD="align: center"]1500[/TD]
[TD="align: center"]1080.00[/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: right"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[/TR]
[TR]
[TD="align: center"]16[/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"]01-Jan-21[/TD]
[TD="align: center"]-20%[/TD]
[TD="align: center"]1500[/TD]
[TD="align: center"]-300.00[/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: right"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[/TR]
[TR]
[TD="align: center"]17[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: center"]01-Jan-45[/TD]
[TD="align: center"]0%[/TD]
[TD="align: center"]1500[/TD]
[TD="align: center"]0.00[/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: right"][/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: right"][/TD]
[/TR]
[TR]
[TD="align: center"]18[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: center"]03-Mar-02[/TD]
[TD="align: center"]72%[/TD]
[TD="align: center"]707[/TD]
[TD="align: center"]509.04[/TD]
[TD="align: center"][/TD]
[TD="align: center"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[/TR]
</tbody>[/TABLE]
Sheet1
[TABLE="width: 85%"]
<tbody>[TR]
[TD]
Worksheet Formulas[TABLE="width: 100%"]
<tbody>[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]
[TH]Cell[/TH]
[TH="align: left"]Formula[/TH]
[/TR]
[TR]
[TH="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]E12[/TH]
[TD="align: left"]=IFERROR(
IF(ISNA(MATCH(YEAR(D12),$A$3:$A$9,0)),INDEX($M$3:$M$9,MATCH(YEAR(D12),$A$3:$A$9,TRUE)),
INDEX($B$3:$M$9,MATCH(YEAR(D12),$A$3:$A$9,0),MONTH(D12))),0)[/TD]
[/TR]
[TR]
[TH="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]G12[/TH]
[TD="align: left"]=F12*E12[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
</tbody>[/TABLE]