SOLVED

Problem with INDEX : returns only first match as a column

Copper Contributor

Hello, thanks in advance for your insights.

I'm trying to generate an array of multiple columns and rows using INDEX but it returns only the values corresponding to the first match row but on a column.

11 Replies

@johroc 

Please provide more detailed information.

@Hans Vogelaar, Here's an image with the table, the formula used and the output. I would expect to obtain an array of 12 rows and 4 columns, but instead I get one column with the information from the first row

Tableau1 :

CategoryNameProductLevelCost
FINBeltranApples185
FINHaraldCherries245
FINHansonPotatoes432
ADMYamahaBananas145
ADMMcCormackApples385
CSVKingstonBananas1255
CSVGalaedCherries321
CSVGermanApples254
FINTolskyCereal128
FINThortonTurnips21
CSVAlbertoTurnips265
ADMFelipePotatoes32

 

Formula : =INDEX(Tableau1;0;{3;1;2;4})

 

Output :

Apples
FIN
Beltran
1

 

@johroc 

Try this:

=LET(r,ROWS(tableau1),INDEX(tableau1,SEQUENCE(r),{3,1,2,4}))

Hi, @Patrick2788 Here's the outcome with that formula :

 

Apples
FIN
Hanson
1
#N/A
#N/A
#N/A
#N/A
#N/A
#N/A
#N/A
#N/A
You may want to switch my commas out for semi-colons.
The column indices need to form a row array in the machine locale. That may be
{3,1,2,4}
or
{3;1;2;4}
according to your computer settings.

@Patrick2788 , I did. And that was the output I've got. Thank you

I did take that into account. Here's the formula I adapted from the one @Patrick2788 suggested : =LET(r;LIGNES(Tableau1);INDEX(Tableau1;SEQUENCE(r);{3;1;2;4})) my system is in french, that's why I changed rows for lignes and commas for semicolons.
Excellent. Glad it's working!

@johroc 

Try

 

=LET(r;LIGNES(Tableau1);INDEX(Tableau1;SEQUENCE(r);{3\1\2\4}))

best response confirmed by johroc (Copper Contributor)
Solution

You said "I did take that into account. Here's the formula I adapted from the one @Patrick2788 suggested : =LET(r;LIGNES(Tableau1);INDEX(Tableau1;SEQUENCE(r);{3;1;2;4})) ..."
So did you try the formula with "3,1,2,4" FIRST? or immediately replace the commas with semi-colons? The rows must be in an array perpendicular to the array for columns (i.e. 1 must use commas and the other semi-colons if those are the 2 deliminators).

 

EDIT: here is a visual example of how rows & columns affect the output of INDEX:

mtarler_0-1667850223984.png

 

notice how if both input are commas, the output is 3 cells in a row {(1,2),(4,4),(5,3)}

and if both are using semi-colons the output is 3 in a column {(1,2);(4,4);(5,3)}, same pairs as above but in a column instead of a row.

then if the 2 are different and you swap them you end up with the 2 matrix that are transpose of each other.

1 best response

Accepted Solutions
best response confirmed by johroc (Copper Contributor)
Solution

You said "I did take that into account. Here's the formula I adapted from the one @Patrick2788 suggested : =LET(r;LIGNES(Tableau1);INDEX(Tableau1;SEQUENCE(r);{3;1;2;4})) ..."
So did you try the formula with "3,1,2,4" FIRST? or immediately replace the commas with semi-colons? The rows must be in an array perpendicular to the array for columns (i.e. 1 must use commas and the other semi-colons if those are the 2 deliminators).

 

EDIT: here is a visual example of how rows & columns affect the output of INDEX:

mtarler_0-1667850223984.png

 

notice how if both input are commas, the output is 3 cells in a row {(1,2),(4,4),(5,3)}

and if both are using semi-colons the output is 3 in a column {(1,2);(4,4);(5,3)}, same pairs as above but in a column instead of a row.

then if the 2 are different and you swap them you end up with the 2 matrix that are transpose of each other.

View solution in original post