I use a google form for people to submit daily announcements. Some announcements only run for one day but some repeat over multiple weekdays. I was trying to figure out if there was a way to possibly use a google app script on the form results to create duplicate line items with the additional dates based on the number of times it should repeat
Sheet: FORM RESPONSES 1
A | B | C | D | E |
---|---|---|---|---|
Timestamp | Email Address | Date of Announcement | Announcement | Days to Repeat |
8/26/2024 04:08:31 | abc@yahoo.com | 08/29/2024 | Good luck... | 3 |
8/28/2024 14:08:31 | def@yahoo.com | 08/30/2024 | Join our club... | 2 |
What I would like to happen (or something similar):
A | B | C | D | E |
---|---|---|---|---|
Timestamp | Email Address | Date of Announcement | Announcement | Days to Repeat |
8/26/2024 04:08:31 | abc@yahoo.com | 08/29/2024 | Good luck... | 3 |
8/26/2024 04:08:31 | abc@yahoo.com | 08/30/2024 | Good luck... | 3 |
8/28/2024 14:08:31 | def@yahoo.com | 08/30/2024 | Join our club... | 2 |
8/26/2024 04:08:31 | abc@yahoo.com | 09/02/2024 | Good luck... | 3 |
8/28/2024 14:08:31 | def@yahoo.com | 09/02/2024 | Join our club... | 2 |
The order isn't necessarily a priority but would like it to repeat line items on weekdays (notice the jump from 8/30-9/2)
You can use an array formula in a separate sheet:
={ 'FORM RESPONSES 1'!A1:E1;
WRAPROWS(TOROW(LET(
rng,'FORM RESPONSES 1'!A2:E,
arr,FILTER(RNG, LEN(INDEX(rng,,1))),
BYROW(arr, LAMBDA(r, LET(
n,INDEX(r,,5), dt,INT(INDEX(r,,3)),
dts,SEQUENCE(n+CEILING(n/7,1)*2,1,dt),
wkdaze,FILTER(dts, WEEKDAY(dts,2)<6),
TOROW(MAP(SEQUENCE(n), LAMBDA(rw,
{ CHOOSECOLS(r,1,2), INDEX(wkdaze,rw),
CHOOSECOLS(r,4,5) })))))))),5) }
BYROW CEILING CHOOSECOLS FILTER INDEX INT LAMBDA LEN LET MAP SEQUENCE TOROW WEEKDAY WRAPROWS
The formula returns an array where the first row is the column labels from 'FORM RESPONSES 1'!A1:E1 and the remaining rows are created as follows:
rng
stores the data range 'FORM RESPONSES 1'!A2:Earr
holds the values in rng
after FILTER removes any empty rows.arr
, row-by-row, into a LAMBDA function that stores the current row in r
r
, the LAMBDA's formula:
n
.dt
stores the "Date of Announcement" value from Column 3, and INT ensures it doesn't include time.dts
stores an array of dates returned by SEQUENCE where:
dt
n
to an additional 2 days per week contained in n
which ensures dts
contains enough dates after weekends are discarded.wkdaze
stores the result of filtering dts
to exclude any weekend days. The FILTER condition uses WEEKDAY to convert dts
to numbers from 1 to 7. Its type argument is set to 2, meaning Monday=1 and Sunday=7. Then FILTER returns only those dates from dts
where the weekday number is less than 6 which excludes Saturday & Sunday.n
(each representing a repeated row), one-by-one into a LAMBDA function, where the current value is stored in rw
.rw
, the LAMBDA's formula creates a single-row array containing:
r
wkdaze
that is in row rw
to be used as the "Date of Announcement".r
r
therefore the result is transformed to a single row using TOROW to avoid errors where the repeats are >1.r