Jun 17 2023 11:53 PM
Greetings everyone!
I am trying to create an index/match where it checks the teaching subject in a certain city and returns the most selling teacher in that area, but it keeps returning #N/A
Here is the function:
=INDEX(Shamal_D[Teacher_name], MATCH(MAX(IF((Shamal_D[Subject]=[@Subject])*(Shamal_D[city]=[@City]), Shamal_D[Sales Count], -1)), Shamal_D[Sales Count], 0))
Please help me.
Jun 18 2023 03:14 AM
The #N/A error in your formula could be caused by a few different reasons.
Here are a few things you can check:
=IFERROR(INDEX(Shamal_D[Teacher_name], MATCH(MAX(IF((Shamal_D[Subject]=[@Subject])*(Shamal_D[city]=[@City]), Shamal_D[Sales Count], -1)), Shamal_D[Sales Count], 0)), "No match found")
This modified formula will display "No match found" when there is no matching teacher.
By checking these points, you should be able to identify and resolve the #N/A error in your formula.
If this does not solve your problem, then you should enter detailed information. Information about what exactly you want to do, nothing can be seen from the picture that can help. Step by step (cell by cell) description. Additional information such as Excel version, operating system, storage medium, etc. would also help.
Jun 18 2023 05:43 AM
SolutionIn addition, I'd adjust the logic a bit. You are searching max sales count for given combination of subject and city. For that max sales count you return Teacher name.
However, same Sales count as found max one could be for another record. If so you return first of the, subject and city criteria are not applied again after the mas was found.
On such sample
your formula
=INDEX(Shamal_D[Teacher_name], MATCH(MAX(IF((Shamal_D[Subject]=[@Subject])*(Shamal_D[city]=[@City]), Shamal_D[Sales Count], -1)), Shamal_D[Sales Count], 0))
returns result for top left table.
Bit modified formula
=LET(
criteria, (Shamal_D[Subject] = [@Subject]) * (Shamal_D[city] = [@City]),
maxSales, AGGREGATE(14, 6, 1 / criteria * Shamal_D[Sales Count], 1),
position, XMATCH(1, criteria * (Shamal_D[Sales Count] = maxSales), 0),
IFERROR( INDEX(Shamal_D[Teacher_name], position), "wrong data" )
)
is in bottom left table.
Jun 18 2023 07:03 AM
Jun 18 2023 07:06 AM
Jun 18 2023 05:43 AM
SolutionIn addition, I'd adjust the logic a bit. You are searching max sales count for given combination of subject and city. For that max sales count you return Teacher name.
However, same Sales count as found max one could be for another record. If so you return first of the, subject and city criteria are not applied again after the mas was found.
On such sample
your formula
=INDEX(Shamal_D[Teacher_name], MATCH(MAX(IF((Shamal_D[Subject]=[@Subject])*(Shamal_D[city]=[@City]), Shamal_D[Sales Count], -1)), Shamal_D[Sales Count], 0))
returns result for top left table.
Bit modified formula
=LET(
criteria, (Shamal_D[Subject] = [@Subject]) * (Shamal_D[city] = [@City]),
maxSales, AGGREGATE(14, 6, 1 / criteria * Shamal_D[Sales Count], 1),
position, XMATCH(1, criteria * (Shamal_D[Sales Count] = maxSales), 0),
IFERROR( INDEX(Shamal_D[Teacher_name], position), "wrong data" )
)
is in bottom left table.