TOFILE

TOFILE(table, headers, delimiter, [transformdates])
a
Required. The table or "Table[#Data]".
header
Required. The header (or Table[#Headers], In some cases, the row above headers can be used).
delimiter
Required. The delimiter.
transformdates
Optional, Transform column with dates based on header.

TOFILE, a function putting a delmiter between the headers and each cell with regards to hiding columns.

jaeiow

Board Regular
Joined
Jun 12, 2022
Messages
139
Office Version
  1. 365
Platform
  1. Windows
If there such a need for a flat file generating lambda. Able to make csv/tsv (tilde)/pipe/tab delimited, files, etc. In my case a need arises to concatenate the header with the cell. This was a more monumental task until I found out that the old "&" (thee ole Concatenate function) can handle arrays. Joining the result and you get a flat line for your data exchange needs.
  • hiding columns, blanking out headers
    • erases header and data from output
    • except last column, in case you need to append something.
  • column is competely empty
    • also erases header and data form output
  • sample output
    Excel Formula:
    =FILTER(TOFILE(Table2[#Data],OFFSET(Table2[#Headers],-1,0),"~",1), Table2[Email]="r")
    • Nome~c~email~r~ID~3~Date~06/27/2021
      Nome~c~email~r~ID~6~Date~06/27/2024
      Nome~c~email~r~ID~~Date~06/27/2027
Here is that function, TOFILE. Requires FORMATDATE only if [xtransformdate] parameter is set to TRUE, see below, or replace with just a & ""

Excel Formula:
=LAMBDA(a,header,delimiter,[transformdates],
LET(
    transformxdate, IF(
        OR(ISOMITTED(transformdates), NOT(transformdates)),
        a & "",
        FORMATDATE(
            a & "",
            XLOOKUP("*Date", header, COLUMN(header), 0, 2),
            "MM/DD/YYYY"
        )
    ),
    cleancolumns, IF(ISERROR(transformxdate), "", transformxdate),
    cellwidth, BYCOL(header, LAMBDA(l, LARGE(CELL("width", l), 1))),
    filteronlyvisible, FILTER(cleancolumns, cellwidth <> 0),
    columnisnotempty, NOT(BYCOL(filteronlyvisible, LAMBDA(x, AND(x = "")))),
    headersvisible, FILTER(FILTER(header, cellwidth <> 0), columnisnotempty),
    columnsoutput, FILTER(filteronlyvisible, columnisnotempty),
    concatwithcolheader, headersvisible & delimiter & columnsoutput,
    omitblankheaderexceptlast, IFNA(
        IF(ISBLANK(DROP(headersvisible, , -1)), "", concatwithcolheader),
        IF(
            ISBLANK(CHOOSECOLS(headersvisible, -1)),
            columnsoutput,
            concatwithcolheader
        )
    ),
    BYROW(omitblankheaderexceptlast, LAMBDA(join, TEXTJOIN(delimiter, , join)))
)
)

FORMATDATE (credits ADATE, reduced to a smaller function, It could improve yet with newer functions).

Excel Formula:
=LAMBDA(a,cl,df,
LET(
    c, MAX(0, cl),
    l, COLUMNS(a),
    sl, SEQUENCE(, l),
    IF(sl = c, TEXT(a, df), a)
)
)

I'm thinking of ways to improve this, as it is for my specific use-case at a software where I work. This is a simple way to send rows of data to the system where the columns map again, but we don't have to worry about copy-pasting headers, finding the rows, and then copy-pasting the rows.
We could:
  1. Allow output of standard tables by stacking the headers instead of concatenating with each cell. This is simple with an optional parameter.
  2. Stacking tables. You can already see Stacking The Beatles in Excel: An Exercise in 3D stacking for using multiple tables as a source.
  3. If two rows of headers are used for input, handle those
 
Upvote 0
It is to change to textjoin not skipping blanks, per requirements,
As to #1 and #3, Stacking and two headers, see this revised lambda.
Excel Formula:
=LAMBDA(a,header,delimiter,[transformdates],[concat_or_vstack1],
LET(
    transformxdate, IF(
        OR(ISOMITTED(transformdates), NOT(transformdates)),
        a & "",
        _FORMATDATE(
            a & "",
            XLOOKUP( "*Date", TOCOL(header),
                LET(c, COLUMNS(header),
                    MOD(SEQUENCE(ROWS(header) * c) - 1, c) + 1
                ), 0, 2),
            "MM/DD/YYYY"
        )
    ),
    cleancolumns, IF(ISERROR(transformxdate), "", transformxdate),
    cellwidth, BYCOL(header, LAMBDA(l, LARGE(CELL("width", l), 1))),
    filteronlyvisible, FILTER(cleancolumns, cellwidth <> 0),
    columnisnotempty, NOT(
        BYCOL(filteronlyvisible, LAMBDA(x, AND(x = "")))
    ),
    headersvisible, FILTER(
        FILTER(
            BYCOL(header, LAMBDA(x, TEXTJOIN("_", , x))),
            cellwidth <> 0
        ),
        columnisnotempty
    ),
    columnsoutput, FILTER(filteronlyvisible, columnisnotempty),
    concatwithcolheader, IF(
        OR(ISOMITTED(concat_or_vstack1), NOT(concat_or_vstack1)),
        headersvisible & delimiter & columnsoutput,
        VSTACK(headersvisible, columnsoutput)
    ),
    omitblankheaderexceptlast, IFNA(
        IF(ISBLANK(DROP(headersvisible, , -1)), "", concatwithcolheader),
        IF(
            ISBLANK(CHOOSECOLS(headersvisible, -1)),
            columnsoutput,
            concatwithcolheader
        )
    ),
    BYROW(
        omitblankheaderexceptlast,
        LAMBDA(join, TEXTJOIN(delimiter, FALSE, join))
    )
)
)

Now we can output different file types.
CSV basicCSV with date formatWhat I refer to as flat file, tilde delimTab delimited file
Nombre_Name,email_Email,ID_ID,Fecha_Hire dateNombre_Name,email_Email,ID_ID,Fecha_Hire dateNombre_Name~j~email_Email~p~ID_ID~0~Fecha_Hire date~06/25/2021NameEmailIDHire date
j,p,0,44372j,p,0,06/25/2021Nombre_Name~b~email_Email~q~ID_ID~2~Fecha_Hire date~06/26/2021jp006/25/2021
b,q,2,44373b,q,2,06/26/2021Nombre_Name~c~email_Email~r~ID_ID~~Fecha_Hire date~06/27/2027bq206/26/2021
c,r,,46565c,r,,06/27/2027cr06/27/2027
Filter must be moved inside the formula parameter, so as to not filter out the header with the VSTACK.
Excel Formula:
=TOFILE(FILTER(Table2[#Data],Table2[ID]<30),OFFSET(Table2[#Headers],-1,0,2),",",0,1)
 
In trying to understand the performance differences of filtering the data vs. the output, but it does not seem to have any. I came across the hints that excel builds an "internal cached index". Filtering the export seems to work just fine. but it does crunch on 400,000 rows ( :unsure:)
It is to change to textjoin not skipping blanks, per requirements,
As to #1 and #3, Stacking and two headers, see this revised lambda.
Excel Formula:
=LAMBDA(a,header,delimiter,[transformdates],[concat_or_vstack1],
LET(
    transformxdate, IF(
        OR(ISOMITTED(transformdates), NOT(transformdates)),
        a & "",
        _FORMATDATE(
            a & "",
            XLOOKUP( "*Date", TOCOL(header),
                LET(c, COLUMNS(header),
                    MOD(SEQUENCE(ROWS(header) * c) - 1, c) + 1
                ), 0, 2),
            "MM/DD/YYYY"
        )
    ),
    cleancolumns, IF(ISERROR(transformxdate), "", transformxdate),
    cellwidth, BYCOL(header, LAMBDA(l, LARGE(CELL("width", l), 1))),
    filteronlyvisible, FILTER(cleancolumns, cellwidth <> 0),
    columnisnotempty, NOT(
        BYCOL(filteronlyvisible, LAMBDA(x, AND(x = "")))
    ),
    headersvisible, FILTER(
        FILTER(
            BYCOL(header, LAMBDA(x, TEXTJOIN("_", , x))),
            cellwidth <> 0
        ),
        columnisnotempty
    ),
    columnsoutput, FILTER(filteronlyvisible, columnisnotempty),
    concatwithcolheader, IF(
        OR(ISOMITTED(concat_or_vstack1), NOT(concat_or_vstack1)),
        headersvisible & delimiter & columnsoutput,
        VSTACK(headersvisible, columnsoutput)
    ),
    omitblankheaderexceptlast, IFNA(
        IF(ISBLANK(DROP(headersvisible, , -1)), "", concatwithcolheader),
        IF(
            ISBLANK(CHOOSECOLS(headersvisible, -1)),
            columnsoutput,
            concatwithcolheader
        )
    ),
    BYROW(
        omitblankheaderexceptlast,
        LAMBDA(join, TEXTJOIN(delimiter, FALSE, join))
    )
)
)

Now we can output different file types.
CSV basicCSV with date formatWhat I refer to as flat file, tilde delimTab delimited file
Nombre_Name,email_Email,ID_ID,Fecha_Hire dateNombre_Name,email_Email,ID_ID,Fecha_Hire dateNombre_Name~j~email_Email~p~ID_ID~0~Fecha_Hire date~06/25/2021NameEmailIDHire date
j,p,0,44372j,p,0,06/25/2021Nombre_Name~b~email_Email~q~ID_ID~2~Fecha_Hire date~06/26/2021jp006/25/2021
b,q,2,44373b,q,2,06/26/2021Nombre_Name~c~email_Email~r~ID_ID~~Fecha_Hire date~06/27/2027bq206/26/2021
c,r,,46565c,r,,06/27/2027cr06/27/2027
Filter must be moved inside the formula parameter, so as to not filter out the header with the VSTACK.
Excel Formula:
=TOFILE(FILTER(Table2[#Data],Table2[ID]<30),OFFSET(Table2[#Headers],-1,0,2),",",0,1)
Revised formula with good variable naming (chatgpt generated), and patched an if(isblank) error, it should be if(a = ""), since it was superimposed by an IF above in the last revision.
Excel Formula:
=LAMBDA(a,header,delimiter,[transformdates],[concat_or_vstack1],
LET(
    transformed_date, IF(
        OR(ISOMITTED(transformdates), NOT(transformdates)),
        a & "",
        FORMATDATE(
            a & "",
            XLOOKUP(
                "*Date",
                TOCOL(header),
                LET(
                    num_cols, COLUMNS(header),
                    MOD(SEQUENCE(ROWS(header) * num_cols) - 1, num_cols) + 1
                ),
                0,
                2
            ),
            "MM/DD/YYYY"
        )
    ),
    cleaned_columns, IF(ISERROR(transformed_date), "", transformed_date),
    column_width, BYCOL(header, LAMBDA(column, LARGE(CELL("width", column), 1))),
    columns_visible, FILTER(cleaned_columns, column_width <> 0),
    columns_notempty, NOT(BYCOL(columns_visible, LAMBDA(column, AND(column = "")))),
    headers_visible, FILTER(
        FILTER(BYCOL(header, LAMBDA(x, TEXTJOIN("_", FALSE, x))), column_width <> 0),
        columns_notempty
    ),
    output_columns, FILTER(columns_visible, columns_notempty),
    concatenated_or_stacked, IF(
        OR(ISOMITTED(concat_or_vstack1), NOT(concat_or_vstack1)),
        headers_visible & delimiter & output_columns,
        VSTACK(headers_visible, output_columns)
    ),
    omit_headerblanks_not_last, IFNA(
        IF(DROP(headers_visible, , -1) = "", "", concatenated_or_stacked),
        IF(TAKE(headers_visible, , -1) = "", output_columns, concatenated_or_stacked)
    ),
    BYROW(omit_headerblanks_not_last, LAMBDA(join_row, TEXTJOIN(delimiter, , join_row)))
)
)
At bottom, textjoin ignore blanks should indeed remain at the default. It works out fine even if providing a cell blank.
 
Last edited:
At bottom, textjoin ignore blanks should indeed remain at the default. It works out fine even if providing a cell blank.
I retract that, The Textjoin ignore blanks parameter must be set to formula:
Excel Formula:
IF(OR(ISOMITTED(concat_or_vstack1), NOT(concat_or_vstack1)),TRUE,FALSE)
 
Update to include a numbering on the 'notes'. These are the text after the last delimiter. This is not dynamic, but it is what I have . New Requires: ROWSUNQ, StackedIndicesλ and ATEXTJOIN. Also, FORMATDATE

Excel Formula:
=LAMBDA(a,header,delimiter,[transformdates],[concat_or_vstack1],[number_notes],LET(transformed_date, IF(OR(ISOMITTED(transformdates), NOT(transformdates)), a & "", FORMATDATE(a & "", XLOOKUP("*Date", TOCOL(header), LET(num_cols, COLUMNS(header), MOD(SEQUENCE(ROWS(header) * num_cols) - 1, num_cols) + 1), 0, 2), "MM/DD/YYYY")), cleaned_columns, IF(ISERROR(transformed_date), "", transformed_date), column_width, BYCOL(header, LAMBDA(column, LARGE(CELL("width", column), 1))), columns_visible, FILTER(cleaned_columns, column_width <> 0), columns_notempty, NOT(BYCOL(columns_visible, LAMBDA(column, AND(column = "")))), headers_visible, FILTER(FILTER(BYCOL(header, LAMBDA(x, TEXTJOIN("_", FALSE, x))), column_width <> 0), columns_notempty), output_columns, FILTER(columns_visible, columns_notempty), concatenated_or_stacked, IF(OR(ISOMITTED(concat_or_vstack1), NOT(concat_or_vstack1)), headers_visible & delimiter & output_columns, VSTACK(headers_visible, output_columns)), omit_headerblanks_not_last, IFNA(IF(DROP(headers_visible, , -1) = "", "", concatenated_or_stacked), IF(TAKE(headers_visible, , -1) = "", output_columns, concatenated_or_stacked)), join_by_row, BYROW(omit_headerblanks_not_last, LAMBDA(join_row, TEXTJOIN(delimiter, IF(OR(ISOMITTED(concat_or_vstack1), NOT(concat_or_vstack1)), TRUE, FALSE), join_row))), IF(number_notes = 1, LET(delimited, join_by_row, cutarray, TEXTAFTER(delimited, delimiter, -1), unqchoices, ROWSUNQ(cutarray, -1, 0), column_occurences, CHOOSECOLS(unqchoices, 2), array1, REDUCE(SEQUENCE(SUM(column_occurences)), SEQUENCE(ROWS(column_occurences)), LAMBDA(v,i, IF(v <= SUM(INDEX(column_occurences, SEQUENCE(i))), INDEX(CHOOSECOLS(unqchoices, 1), i), v))), array2, DROP(REDUCE("", column_occurences, StackedIndicesλ), 1), ATEXTJOIN(HSTACK(SORTBY(IFERROR(TEXTBEFORE(delimited, delimiter, -1), ""), cutarray, 1), array1 & IF(array2 = 1, "", " (" & array2 & ")")), delimiter, 1)), join_by_row)))

Sample Output;
Name~j~Email~r~ID~0~Hire date~06/25/2021~Note~a header delimiter
Name~b~Email~r~ID~2~Hire date~06/26/2021~Note~a header delimiter (2)
Name~c~Email~r~ID~6~Hire date~06/27/2024~Note~a header delimiter (3)
 
Last edited:
TOFILE(a, header, delimiter, [transformdates], [concat_or_vstack1], [number_notes])

Transform cells of an array into a flat file, delimiting header and each cell. New version that pastes into name manager box.

Requires ROWSUNQ, and ATEXTJOIN. Also, FORMATDATE from top post.

Excel Formula:
=LAMBDA(a,header,delimiter,[transformdates],[concat_or_vstack1],[number_notes],
LET(transformed_date, IF(OR(ISOMITTED(transformdates),NOT(transformdates)),
a&"",FORMATDATE(a&"",
    XLOOKUP("*Date",TOCOL(header),LET(c,COLUMNS(header),
    MOD(SEQUENCE(ROWS(header)*c)-1,c)+1),0,2),"MM/DD/YYYY")
),
cleaned_columns, IF(ISERROR(transformed_date),"",transformed_date),
column_width, BYCOL(header,LAMBDA(column,LARGE(CELL("width",column),1))),
columns_visible, FILTER(cleaned_columns,column_width<>0),
columns_notempty, NOT(
    BYCOL(columns_visible,LAMBDA(column,AND(column = "")))
),
headers_visible, FILTER(
FILTER(
    BYCOL(header,LAMBDA(x,TEXTJOIN("_",,x))),
    column_width <> 0),
columns_notempty
),
output_columns, FILTER(columns_visible,columns_notempty),
concatenated_or_stacked, IF(
    OR(ISOMITTED(concat_or_vstack1),NOT(concat_or_vstack1)),
    headers_visible&delimiter&output_columns,
    VSTACK(headers_visible,output_columns)
),
omit_headerblanks_not_last, IFNA(
    IF(DROP(headers_visible,,-1)="","",concatenated_or_stacked),
    IF(TAKE(headers_visible,,-1)="",output_columns, concatenated_or_stacked)
),
join_by_row, BYROW(omit_headerblanks_not_last,
LAMBDA(join_row,TEXTJOIN(delimiter,
    IF(OR(ISOMITTED(concat_or_vstack1),NOT(concat_or_vstack1)),TRUE,FALSE),join_row))
),
IF(number_notes=1,LET(text_array,TEXTAFTER(join_by_row,delimiter,-1),
unique_choices, ROWSUNQ(text_array,-1,0),occurrences,CHOOSECOLS(unique_choices, 2),
sorted_array, SORTBY(
    IFERROR(TEXTBEFORE(join_by_row,delimiter,-1),""),
    text_array,1
),
choice_array, REDUCE(SEQUENCE(SUM(occurrences)),SEQUENCE(ROWS(occurrences)),
    LAMBDA(v,i,IF(v<= SUM(INDEX(occurrences,SEQUENCE(i))),INDEX(CHOOSECOLS(unique_choices, 1), i),v))
),
after_dot, IFERROR("."&TEXTAFTER(choice_array,".",-1),""),
suffix_array, DROP(
    REDUCE("",occurrences,LAMBDA(u,n,VSTACK(u,SEQUENCE(n)))),1
),
final_array,
HSTACK(
sorted_array,
TEXTBEFORE(choice_array,".",-1,,,choice_array)
&IF(suffix_array = 1, after_dot, " ("
&suffix_array&")"
&after_dot)
),
ATEXTJOIN(final_array,delimiter,1)),join_by_row)))
 
To use the formula (and logic) proposed by @Xlambda in ARCHCLS, we add a new parameter, the optional New Sequence param.
We can also name all parameters and "variables" shorter to save space. The name manager "refers to:" can only accept up to 2000 and some characters.
The AFE (Advance Formula Environment) formats the text when opening it up, I need to de-indent twice, to bring the lambda formula to 1800 characters.
TOFILE(a,h,d,[XD],[AV],[AN],[N])
a
: array
h: header
d: delimiter
XD: transform dates?, 0 or omitted, NO, 1, YES
AV: concatenate or vstack headers with cells? 0 or omitted, Concat, 1, Vstack
AN: number the notes, and sort the output? 0 or omitted, NO, 1, YES (not to be combined with AV = 1)
N: new sequence to feed ARCHCLS
Excel Formula:
= LAMBDA(a, h, d, [XD], [AV], [AN], [N],
LET(
t_date, IF(
OR(ISOMITTED(XD), NOT(XD)),
a & "",
FORMATDATE(
    a & "",
    XLOOKUP(
        "*Date",
        TOCOL(h),
        LET(c, COLUMNS(h), MOD(SEQUENCE(ROWS(h) * c) - 1, c) + 1),
        0, 2), "MM/DD/YYYY")
),
c_columns, IF(ISERROR(t_date), "", t_date),
c_width, BYCOL(h, LAMBDA(c, LARGE(CELL("width", c), 1))),
c_visible, FILTER(c_columns, c_width <> 0),
c_notempty, NOT(BYCOL(c_visible, LAMBDA(c, AND(c = "")))),
h_visible, FILTER(
FILTER(BYCOL(h, LAMBDA(x, TEXTJOIN("_", , x))), c_width <> 0),
c_notempty
),
o_columns, FILTER(c_visible, c_notempty),
c_or_s, IF(
OR(ISOMITTED(AV), NOT(AV)),
h_visible & d & o_columns,
VSTACK(h_visible, o_columns)
),
o_hblanks_not_last, ARCHCLS(
IFNA(
    IF(DROP(h_visible, , -1) = "", "", c_or_s),
    IF(TAKE(h_visible, , -1) = "", TEXTAFTER(c_or_s, d, , , , c_or_s), c_or_s)
),N
),
j_by_row, BYROW(
o_hblanks_not_last,
LAMBDA(j_row, TEXTJOIN(d, IF(OR(ISOMITTED(AV), NOT(AV)), TRUE, FALSE), j_row))
),
IF(
AND(AN = 1, OR(ISOMITTED(AV), NOT(AV))),
LET(
    t_array, TEXTAFTER(j_by_row, d, -1,,," "),
    u_choices, SORT(ROWSUNQ(t_array, -1, 0), 1, 1),
    o, CHOOSECOLS(u_choices, 2),
    s_array, SORTBY(TEXTBEFORE(j_by_row, d, -1), t_array, 1),
    c_array, REDUCE(
        SEQUENCE(SUM(o)),
        SEQUENCE(ROWS(o)),
        LAMBDA(v, i,
            IF(v <= SUM(INDEX(o, SEQUENCE(i))), INDEX(CHOOSECOLS(u_choices, 1), i), v)
        )
    ),
    a_dot, IFERROR("." & TEXTAFTER(c_array, ".", -1), ""),
    su_array, DROP(REDUCE("", o, LAMBDA(u, n, VSTACK(u, SEQUENCE(n)))), 1),
    f_array, HSTACK(
        s_array,
        TEXTBEFORE(c_array, ".", -1, , , c_array) &
            IF(
                NOT(c_array = " "),
                IF(su_array > 1, " (" & su_array & ")" & a_dot, a_dot),
                ""
            )
    ),
    ATEXTJOIN(f_array, d, 1)
),
j_by_row
)))

This generates a result that looks like this. (There are ways to make these dynamic dropdows, I will not cover my formula here). Use the filter from dropdowns as an input, And we have the dynamic "choosecols" that are 1. (and) all cells are not empty, 2. (whole column) hidden, and 3. (appends to front) picked in the NS parameter.

As a data cleansing activity I think this is pretty good.
 

Attachments

  • edb.PNG
    edb.PNG
    23.9 KB · Views: 23
my apologies. modified my copy of ARCHCLS
Excel Formula:
=LET(
    a, IF(ar = "", "", ar),
    s, SEQUENCE(, COLUMNS(a)),
    h, IF(OR(ISOMITTED(ns), ns = ""), DROP(s, , -1), CHOOSECOLS(s, ns)),
    x, XMATCH(s, h),
    f, IFERROR(FILTER(s, ISNA(x)), 0),
    INDEX(a, SEQUENCE(ROWS(a)), HSTACK(h, f))
)
 

Attachments

  • 1672922799421.png
    1672922799421.png
    17.3 KB · Views: 23
For AFE module or namespace users, this IS working. I just tested on a new workbook. But, separate out to your name manager, still works (just tested). @steven88
Excel Formula:
FORMATDATE = LAMBDA(a, cl, df,
 LET(c, MAX(0, cl), l, COLUMNS(a), sl, SEQUENCE(, l), IF(sl = c, TEXT(a, df), a))
);
ARCHCLS = LAMBDA(ar, ns,
 LET(
  a, IF(ar = "", "", ar),
  s, SEQUENCE(, COLUMNS(a)),
  h, IF(OR(ISOMITTED(ns), ns = ""), DROP(s, , -1), CHOOSECOLS(s, ns)),
  x, XMATCH(s, h),
  f, IFERROR(FILTER(s, ISNA(x)), 0),
  INDEX(a, SEQUENCE(ROWS(a)), HSTACK(h, f))
 )
);
ROWSUNQ = LAMBDA(ar, [oc], [ex],
 LET(
  a, IF(ar = "", "", ar),
  t, TYPE(oc),
  b, BYROW(a, LAMBDA(x, CONCAT(x))),
  s, SCAN(
   0,
   SEQUENCE(ROWS(a)),
   LAMBDA(v, i,
    LET(x, INDEX(b, i), y, INDEX(b, SEQUENCE(i)), SUM(--IF(ex, EXACT(x, y), x = y)))
   )
  ),
  f, FILTER(b, s = 1),
  r, FILTER(a, s = 1),
  m, MAP(f, LAMBDA(x, SUM(--(IF(ex, EXACT(x, b), x = b))))),
  l, LEFT(oc, 1),
  v, --RIGHT(oc, LEN(oc) - 1),
  w, SWITCH(
   l,
   "+", m = MAX(m),
   "-", m = MIN(m),
   "<", m < v,
   ">", m > v,
   "/", m <= v,
   "\", m >= v,
   "#", m <> v
  ),
  SWITCH(
   oc,
   -1, HSTACK(r, m),
   0, r,
   IF(t = 1, FILTER(r, m = oc, NA()), HSTACK(FILTER(r, w, NA()), FILTER(m, w, NA())))
  )
 )
);
ATEXTJOIN = LAMBDA(a, [dl], [ea],
 LET(d, IF(ISOMITTED(dl), ",", dl), e, IF(ea, 0, 1), BYROW(a, LAMBDA(a, TEXTJOIN(d, e, a))))
);
TOFILE = LAMBDA(a, h, d, [XD], [AV], [AN], [N],
 LET(
  t_date, IF(
   OR(ISOMITTED(XD), NOT(XD)),
   a & "",
   FORMATDATE(
    a & "",
    XLOOKUP(
  "*Date",
  TOCOL(h),
  LET(c, COLUMNS(h), MOD(SEQUENCE(ROWS(h) * c) - 1, c) + 1),
  0,
  2
    ),
    "MM/DD/YYYY"
   )
  ),
  c_columns, IF(ISERROR(t_date), "", t_date),
  c_width, BYCOL(h, LAMBDA(c, LARGE(CELL("width", c), 1))),
  c_visible, FILTER(c_columns, c_width <> 0),
  c_notempty, NOT(BYCOL(c_visible, LAMBDA(c, AND(c = "")))),
    h_visible, FILTER(
     FILTER(BYCOL(h, LAMBDA(x, TEXTJOIN("_", , x))), c_width <> 0),
     c_notempty
    ),
  o_columns, FILTER(c_visible, c_notempty),
    c_or_s, IF(
    OR(ISOMITTED(AV), NOT(AV)),
    h_visible & d & o_columns,
    VSTACK(h_visible, o_columns)
    ),
  o_hblanks_not_last, ARCHCLS(
    IFNA(
        IF(DROP(h_visible, , -1) = "", "", c_or_s),
        IF(TAKE(h_visible, , -1) = "", TEXTAFTER(c_or_s, d, , , , c_or_s), c_or_s)
    ),
    N
    ),
  j_by_row, BYROW(
    o_hblanks_not_last,
    LAMBDA(j_row, TEXTJOIN(d, IF(OR(ISOMITTED(AV), NOT(AV)), TRUE, FALSE), j_row))
    ),
  IF(
   AND(AN = 1, OR(ISOMITTED(AV), NOT(AV))),
    LET(
      t_array, TEXTAFTER(j_by_row, d, -1, , , " "),
      u_choices, SORT(ROWSUNQ(t_array, -1, 0), 1, 1),
      o, CHOOSECOLS(u_choices, 2),
      s_array, SORTBY(TEXTBEFORE(j_by_row, d, -1), t_array, 1),
      c_array, REDUCE(
    SEQUENCE(SUM(o)),
    SEQUENCE(ROWS(o)),
    LAMBDA(v, i,
    IF(v <= SUM(INDEX(o, SEQUENCE(i))), INDEX(CHOOSECOLS(u_choices, 1), i), v)
    )
      ),
      a_dot, IFERROR("." & TEXTAFTER(c_array, ".", -1), ""),
      su_array, DROP(REDUCE("", o, LAMBDA(u, n, VSTACK(u, SEQUENCE(n)))), 1),
      f_array, HSTACK(
    s_array,
    TEXTBEFORE(c_array, ".", -1, , , c_array) &
    IF(
      NOT(c_array = " "),
      IF(su_array > 1, " (" & su_array & ")" & a_dot, a_dot),
      ""
    )
      ),
      ATEXTJOIN(f_array, d, 1)
    ),
   j_by_row
  )
 )
);
 

Forum statistics

Threads
1,223,604
Messages
6,173,316
Members
452,510
Latest member
RCan29

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