ALFCR

=ALFCR(ar,lf,cr)

ar
array
lf
last first arg., 0 or 1, 0 for last,1 for first
cr
clms rows arg., 0 or 1, 0 for clms,1 for rows

Array Last or First values, by Columns or Rows, blanks excluded

Xlambda

Well-known Member
Joined
Mar 8, 2021
Messages
839
Office Version
  1. 365
Platform
  1. Windows
ALFCR Array Last or First values, by Columns or Rows, blanks excluded.
-lf, last first argument, 0 for last, 1 for first
-cr columns rows argument 0 for columns, 1 for rows. (have chosen 0 for last and 0 for columns, because is the most frequent scenario)
Other function on minisheet AFILTER
Excel Formula:
=LAMBDA(ar,lf,cr,
    LET(z,{0,1},x,IF(lf,1,-1),r,ROWS(ar),c,COLUMNS(ar),s,SEQUENCE(r*c),y,IF(cr,SEQUENCE(,c),SEQUENCE(r)),
       q,QUOTIENT(s-1,c),m,MOD(s-1,c),a,INDEX(IF(ar="","",ar),q+1,m+1),
       xm,XMATCH(y,1/(a<>"")+IF(cr,m,q),,x),
       IF(AND(OR(lf=z),OR(cr=z)),IFNA(INDEX(a,xm),""),"only 0 or 1 values")
    )
)
LAMBDA 7.0.xlsx
ABCDEFGHIJKLMNOPQRSTU
1ALFCR(ar,lf,cr) Array LastFirst ClmsRows
2last,first clms,rows
3 0,1 0,1last clm1 st clm
4lf,0,cr,0lf,1,cr,0lf,1,cr,0
5sample=ALFCR(A6:F9,,)=ALFCR(A6:F9,1,)=ALFCR(A6:F9,,1)
6d3ab11d7q82e1last row
7v5d44vlf,1,cr,1
87s227=ALFCR(A6:F9,1,1)
9q8eeqd3adb11 st row
10
11row or clmn only blanks=ALFCR(A12:F15,,)=ALFCR(A12:F15,1,)=ALFCR(A12:F15,,1)
12dab11dd8de1last row
135d445
14=ALFCR(A12:F15,1,1)
158ee8dadb11 st row
16
17if we need 2nd clm2nd clm
18(exclude blnks and align to left)other function on minisheetAFILTER
19=AFILTER(A6:F9,,)=INDEX(A20#,,2)
20d3ab13
21v5d45
227s2s
23q8e8
24
25if we need 2nd row
26(exclude blanks and align to the top)
27=TRANSPOSE(AFILTER(TRANSPOSE(A6:F9),,))=INDEX(A28#,2,)
28d3adb17v5242nd row
297v524
30qse
318
32
ALFCR post
Cell Formulas
RangeFormula
H5,J5,M27,A27,H19,A19,M14,M11,H11,J11,M8,M5H5=FORMULATEXT(H6)
H6:H9,H12:H15H6=ALFCR(A6:F9,,)
J6:J9,J12:J15J6=ALFCR(A6:F9,1,)
M6:R6,M12:R12M6=ALFCR(A6:F9,,1)
M9:R9,M15:R15M9=ALFCR(A6:F9,1,1)
A20:E23A20=AFILTER(A6:F9,,)
H20:H23H20=INDEX(A20#,,2)
A28:F31A28=TRANSPOSE(AFILTER(TRANSPOSE(A6:F9),,))
M28:R28M28=INDEX(A28#,2,)
Dynamic array formulas.
 
Upvote 0

Forum statistics

Threads
1,218,264
Messages
6,141,433
Members
450,357
Latest member
Pritch_0

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