How to automatically fill in dates in between already existing dates?

DevAlex

New Member
Joined
May 26, 2022
Messages
14
Office Version
  1. 2021
Platform
  1. Windows
I have hundreds of products that I am trying to track the monthly price for. I currently have all the prices of these products but only for specific dates. What I need to do is fill in all the dates in between the existing dates by month up until the present (Dec. 2022).

For example, I have the following products and pricing:

Product 1
2/15/2022​
$1​
Product 1
6/30/2022​
$2​
Product 2
5/5/2022​
$5​
Product 2
7/27/2022​
$5.50​
Product 3
6/11/2022​
$4​

I want to fill in the in-between dates of these products monthly with the first date of the month up until the present date (December 1st, 2022). When the price changes for the product, I want the monthly pattern to still be followed. It should look like this:

Product 1
2/15/2022​
$1​
Product 1
3/1/2022​
$1​
Product 1
4/1/2022​
$1​
Product 1
5/1/2022​
$1​
Product 1
6/1/2022​
$1​
Product 1
6/30/2022​
$2​
Product 1
7/1/2022​
$2​
Product 1
8/1/2022​
$2​
Product 1
9/1/2022​
$2​
Product 1
10/1/2022​
$2​
Product 1
11/1/2022​
$2​
Product 1
12/1/2022​
$2​
Product 2
5/5/2022​
$5​
Product 2
6/1/2022​
$5​
Product 2
7/1/2022​
$5​
Product 2
7/27/2022​
$5.50​
Product 2
8/1/2022​
$5.50​
Product 2
9/1/2022​
$5.50​
Product 2
10/1/2022​
$5.50​
Product 2
11/1/2022​
$5.50​
Product 2
12/1/2022​
$5.50​
Product 3
6/11/2022​
$4​
Product 3
7/1/2022​
$4​
Product 3
8/1/2022​
$4​
Product 3
9/1/2022​
$4​
Product 3
10/1/2022​
$4​
Product 3
11/1/2022​
$4​
Product 3
12/1/2022​
$4​

Any help is appreciated!

 
Hi, see the linked file (with an auxiliary column) for a possible solution...

The formulas used in the table:
A3: =IF(A2="","",IF(INDEX(Sheet1!A:A,A2+1)="",IF(AND(B2<>"",C2<A$1),A2,""),IF(INDEX(Sheet1!A:A,A2+1)=B2,IF(AND(C2<A$1,EOMONTH(C2,0)+1<INDEX(Sheet1!B:B,A2+1)),A2,A2+1),IF(C2<A$1,A2,A2+1))))
B3: =IF(A3="","",IF(INDEX(Sheet1!A:A,A2+1)="",IF(AND(B2<>"",C2<A$1),B2,""),IF(INDEX(Sheet1!A:A,A2+1)=B2,B2,IF(C2<A$1,B2,INDEX(Sheet1!A:A,A2+1)))))
C3: =IF(A3="","",IF(INDEX(Sheet1!A:A,A2+1)="",IF(AND(B2<>"",C2<A$1),EOMONTH(C2,0)+1,""),IF(INDEX(Sheet1!A:A,A2+1)=B2,IF(AND(C2<A$1,EOMONTH(C2,0)+1<INDEX(Sheet1!B:B,A2+1)),EOMONTH(C2,0)+1,INDEX(Sheet1!B:B,A2+1)),IF(C2<A$1,EOMONTH(C2,0)+1,INDEX(Sheet1!B:B,A2+1)))))
D3: =IF(A3="","",IF(INDEX(Sheet1!A:A,A2+1)="",IF(AND(B2<>"",C2<A$1),D2,""),IF(INDEX(Sheet1!A:A,A2+1)=B2,IF(AND(C2<A$1,EOMONTH(C2,0)+1<INDEX(Sheet1!B:B,A2+1)),D2,INDEX(Sheet1!C:C,A2+1)),IF(C2<A$1,D2,INDEX(Sheet1!C:C,A2+1)))))

ProductsPrices.xlsx
Sorry to bump this thread again, but how would I do this exact task with the last day of the month instead?
 
Upvote 0

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
Hi, see the linked file for the new table...

The formulas used in the new table:
A3: =IF(A2="","",IF(INDEX(Sheet1!A:A,A2+1)="",IF(AND(B2<>"",C2<A$1),A2,""),IF(INDEX(Sheet1!A:A,A2+1)=B2,IF(AND(C2<A$1,EOMONTH(C2+1,0)<INDEX(Sheet1!B:B,A2+1)),A2,A2+1),IF(C2<A$1,A2,A2+1))))
B3: =IF(A3="","",IF(INDEX(Sheet1!A:A,A2+1)="",IF(AND(B2<>"",C2<A$1),B2,""),IF(INDEX(Sheet1!A:A,A2+1)=B2,B2,IF(C2<A$1,B2,INDEX(Sheet1!A:A,A2+1)))))
C3: =IF(A3="","",IF(INDEX(Sheet1!A:A,A2+1)="",IF(AND(B2<>"",C2<A$1),EOMONTH(C2+1,0),""),IF(INDEX(Sheet1!A:A,A2+1)=B2,IF(AND(C2<A$1,EOMONTH(C2+1,0)<INDEX(Sheet1!B:B,A2+1)),EOMONTH(C2+1,0),INDEX(Sheet1!B:B,A2+1)),IF(C2<A$1,EOMONTH(C2+1,0),INDEX(Sheet1!B:B,A2+1)))))
D3: =IF(A3="","",IF(INDEX(Sheet1!A:A,A2+1)="",IF(AND(B2<>"",C2<A$1),D2,""),IF(INDEX(Sheet1!A:A,A2+1)=B2,IF(AND(C2<A$1,EOMONTH(C2+1,0)<INDEX(Sheet1!B:B,A2+1)),D2,INDEX(Sheet1!C:C,A2+1)),IF(C2<A$1,D2,INDEX(Sheet1!C:C,A2+1)))))

ProductsPrices2.xlsx
 
Upvote 0

Forum statistics

Threads
1,214,641
Messages
6,120,691
Members
448,978
Latest member
rrauni

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