Forum Discussion
create custom formula
Yeah, I was not much at math... so alot of the characters don't mean much to me... however...
The formula creates a point system for overall points for a sailboat racing season. The points awarded are dependent on the number of entries in the race, and the position of each boat in that race.
there is a graph that has the detail but I am trying to put the formula into excel for easier calculation...
if it works that is....
does that help?
pevenden If you have Excel for MS365, you can achieve the same results as the graph you've shared with the following formula:
=LET(n, B1, k, B2,
φ, IF(ISBLANK(k), 1, k),
MAKEARRAY(n, n, LAMBDA(p,a,
IF(p>a, "", IFERROR((p*(1-((50*a+4800)/98))+((a*(50*a+4800))/98)-1)/(a-1), 25)*φ))))
...where the attendance (A) is in cell B1 and the fleet factor (φ) is in cell B2. The results would look something like this:
MAKEARRAY Chart with Conditional Formatting
Conditional Formatting was applied to range C5:V24 to shade the empty string results blue using the following formula:
=AND(NOT(ISBLANK(C5)), C5="")
You could also create a custom LAMBDA function in Name Manager to award points to each team based on their finishing position for each race. For example, you could create a function called XPOINTS using the following formula:
=LAMBDA(a,p,[φ],
LET(
k, IF(ISBLANK(φ), 1, φ),
IFERROR((p*(1-((50*a+4800)/98))+((a*(50*a+4800))/98)-1)/(a-1), 25)*k
)
)
...then use it as follows:
Custom LAMBDA Function
The formula used in cell D4 in the screenshot above is:
=XPOINTS(COUNTIF($A$4:$A$20, A4), B4, $B$1)
...where COUNTIF is used to calculate the total attendance (A) for each Race No.
As for the Season Standings section shown above, the following formula was used in cell F4:
=LET(
u, UNIQUE(C4:C20),
a, SORT(HSTACK(u, SUMIFS(D4:D20, C4:C20, u)), 2, -1),
HSTACK(SEQUENCE(ROWS(u)), a))
I've also attached the workbook for your convenience. Cheers!