@@ -1134,6 +1134,68 @@ public static function COUNTIF($aArgs, $condition)
1134
1134
return $ returnValue ;
1135
1135
}
1136
1136
1137
+ /**
1138
+ * COUNTIFS.
1139
+ *
1140
+ * Counts the number of cells that contain numbers within the list of arguments
1141
+ *
1142
+ * Excel Function:
1143
+ * COUNTIFS(criteria_range1, criteria1, [criteria_range2, criteria2]…)
1144
+ *
1145
+ * @category Statistical Functions
1146
+ *
1147
+ * @param mixed $args Criterias
1148
+ *
1149
+ * @return int
1150
+ */
1151
+ public static function COUNTIFS (...$ args )
1152
+ {
1153
+ $ arrayList = $ args ;
1154
+
1155
+ // Return value
1156
+ $ returnValue = 0 ;
1157
+
1158
+ if (!$ arrayList ) {
1159
+ return $ returnValue ;
1160
+ }
1161
+
1162
+ $ aArgsArray = [];
1163
+ $ conditions = [];
1164
+
1165
+ while (count ($ arrayList ) > 0 ) {
1166
+ $ aArgsArray [] = Functions::flattenArray (array_shift ($ arrayList ));
1167
+ $ conditions [] = Functions::ifCondition (array_shift ($ arrayList ));
1168
+ }
1169
+
1170
+ // Loop through each arg and see if arguments and conditions are true
1171
+ foreach (array_keys ($ aArgsArray [0 ]) as $ index ) {
1172
+ $ valid = true ;
1173
+
1174
+ foreach ($ conditions as $ cidx => $ condition ) {
1175
+ $ arg = $ aArgsArray [$ cidx ][$ index ];
1176
+
1177
+ // Loop through arguments
1178
+ if (!is_numeric ($ arg )) {
1179
+ $ arg = Calculation::wrapResult (strtoupper ($ arg ));
1180
+ }
1181
+ $ testCondition = '= ' . $ arg . $ condition ;
1182
+ if (!Calculation::getInstance ()->_calculateFormulaValue ($ testCondition )) {
1183
+ // Is not a value within our criteria
1184
+ $ valid = false ;
1185
+
1186
+ break ; // if false found, don't need to check other conditions
1187
+ }
1188
+ }
1189
+
1190
+ if ($ valid ) {
1191
+ ++$ returnValue ;
1192
+ }
1193
+ }
1194
+
1195
+ // Return
1196
+ return $ returnValue ;
1197
+ }
1198
+
1137
1199
/**
1138
1200
* COVAR.
1139
1201
*
@@ -2105,44 +2167,61 @@ public static function MAXA(...$args)
2105
2167
}
2106
2168
2107
2169
/**
2108
- * MAXIF .
2170
+ * MAXIFS .
2109
2171
*
2110
2172
* Counts the maximum value within a range of cells that contain numbers within the list of arguments
2111
2173
*
2112
2174
* Excel Function:
2113
- * MAXIF(value1[,value2[, ...]],condition )
2175
+ * MAXIFS(max_range, criteria_range1, criteria1, [criteria_range2, criteria2], ...)
2114
2176
*
2115
- * @category Mathematical and Trigonometric Functions
2177
+ * @category Statistical Functions
2116
2178
*
2117
- * @param mixed $aArgs Data values
2118
- * @param string $condition the criteria that defines which cells will be checked
2119
- * @param mixed $sumArgs
2179
+ * @param mixed $args Data range and criterias
2120
2180
*
2121
2181
* @return float
2122
2182
*/
2123
- public static function MAXIF ( $ aArgs , $ condition , $ sumArgs = [] )
2183
+ public static function MAXIFS (... $ args )
2124
2184
{
2185
+ $ arrayList = $ args ;
2186
+
2187
+ // Return value
2125
2188
$ returnValue = null ;
2126
2189
2127
- $ aArgs = Functions::flattenArray ($ aArgs );
2128
- $ sumArgs = Functions::flattenArray ($ sumArgs );
2129
- if (empty ($ sumArgs )) {
2130
- $ sumArgs = $ aArgs ;
2190
+ $ maxArgs = Functions::flattenArray (array_shift ($ arrayList ));
2191
+ $ aArgsArray = [];
2192
+ $ conditions = [];
2193
+
2194
+ while (count ($ arrayList ) > 0 ) {
2195
+ $ aArgsArray [] = Functions::flattenArray (array_shift ($ arrayList ));
2196
+ $ conditions [] = Functions::ifCondition (array_shift ($ arrayList ));
2131
2197
}
2132
- $ condition = Functions::ifCondition ($ condition );
2133
- // Loop through arguments
2134
- foreach ($ aArgs as $ key => $ arg ) {
2135
- if (!is_numeric ($ arg )) {
2136
- $ arg = Calculation::wrapResult (strtoupper ($ arg ));
2137
- }
2138
- $ testCondition = '= ' . $ arg . $ condition ;
2139
- if (Calculation::getInstance ()->_calculateFormulaValue ($ testCondition )) {
2140
- if (($ returnValue === null ) || ($ arg > $ returnValue )) {
2141
- $ returnValue = $ arg ;
2198
+
2199
+ // Loop through each arg and see if arguments and conditions are true
2200
+ foreach ($ maxArgs as $ index => $ value ) {
2201
+ $ valid = true ;
2202
+
2203
+ foreach ($ conditions as $ cidx => $ condition ) {
2204
+ $ arg = $ aArgsArray [$ cidx ][$ index ];
2205
+
2206
+ // Loop through arguments
2207
+ if (!is_numeric ($ arg )) {
2208
+ $ arg = Calculation::wrapResult (strtoupper ($ arg ));
2209
+ }
2210
+ $ testCondition = '= ' . $ arg . $ condition ;
2211
+ if (!Calculation::getInstance ()->_calculateFormulaValue ($ testCondition )) {
2212
+ // Is not a value within our criteria
2213
+ $ valid = false ;
2214
+
2215
+ break ; // if false found, don't need to check other conditions
2142
2216
}
2143
2217
}
2218
+
2219
+ if ($ valid ) {
2220
+ $ returnValue = $ returnValue === null ? $ value : max ($ value , $ returnValue );
2221
+ }
2144
2222
}
2145
2223
2224
+ // Return
2146
2225
return $ returnValue ;
2147
2226
}
2148
2227
@@ -2268,44 +2347,61 @@ public static function MINA(...$args)
2268
2347
}
2269
2348
2270
2349
/**
2271
- * MINIF .
2350
+ * MINIFS .
2272
2351
*
2273
2352
* Returns the minimum value within a range of cells that contain numbers within the list of arguments
2274
2353
*
2275
2354
* Excel Function:
2276
- * MINIF(value1[,value2[, ...]],condition )
2355
+ * MINIFS(min_range, criteria_range1, criteria1, [criteria_range2, criteria2], ...)
2277
2356
*
2278
- * @category Mathematical and Trigonometric Functions
2357
+ * @category Statistical Functions
2279
2358
*
2280
- * @param mixed $aArgs Data values
2281
- * @param string $condition the criteria that defines which cells will be checked
2282
- * @param mixed $sumArgs
2359
+ * @param mixed $args Data range and criterias
2283
2360
*
2284
2361
* @return float
2285
2362
*/
2286
- public static function MINIF ( $ aArgs , $ condition , $ sumArgs = [] )
2363
+ public static function MINIFS (... $ args )
2287
2364
{
2365
+ $ arrayList = $ args ;
2366
+
2367
+ // Return value
2288
2368
$ returnValue = null ;
2289
2369
2290
- $ aArgs = Functions::flattenArray ($ aArgs );
2291
- $ sumArgs = Functions::flattenArray ($ sumArgs );
2292
- if (empty ($ sumArgs )) {
2293
- $ sumArgs = $ aArgs ;
2370
+ $ minArgs = Functions::flattenArray (array_shift ($ arrayList ));
2371
+ $ aArgsArray = [];
2372
+ $ conditions = [];
2373
+
2374
+ while (count ($ arrayList ) > 0 ) {
2375
+ $ aArgsArray [] = Functions::flattenArray (array_shift ($ arrayList ));
2376
+ $ conditions [] = Functions::ifCondition (array_shift ($ arrayList ));
2294
2377
}
2295
- $ condition = Functions::ifCondition ($ condition );
2296
- // Loop through arguments
2297
- foreach ($ aArgs as $ key => $ arg ) {
2298
- if (!is_numeric ($ arg )) {
2299
- $ arg = Calculation::wrapResult (strtoupper ($ arg ));
2300
- }
2301
- $ testCondition = '= ' . $ arg . $ condition ;
2302
- if (Calculation::getInstance ()->_calculateFormulaValue ($ testCondition )) {
2303
- if (($ returnValue === null ) || ($ arg < $ returnValue )) {
2304
- $ returnValue = $ arg ;
2378
+
2379
+ // Loop through each arg and see if arguments and conditions are true
2380
+ foreach ($ minArgs as $ index => $ value ) {
2381
+ $ valid = true ;
2382
+
2383
+ foreach ($ conditions as $ cidx => $ condition ) {
2384
+ $ arg = $ aArgsArray [$ cidx ][$ index ];
2385
+
2386
+ // Loop through arguments
2387
+ if (!is_numeric ($ arg )) {
2388
+ $ arg = Calculation::wrapResult (strtoupper ($ arg ));
2389
+ }
2390
+ $ testCondition = '= ' . $ arg . $ condition ;
2391
+ if (!Calculation::getInstance ()->_calculateFormulaValue ($ testCondition )) {
2392
+ // Is not a value within our criteria
2393
+ $ valid = false ;
2394
+
2395
+ break ; // if false found, don't need to check other conditions
2305
2396
}
2306
2397
}
2398
+
2399
+ if ($ valid ) {
2400
+ $ returnValue = $ returnValue === null ? $ value : min ($ value , $ returnValue );
2401
+ }
2307
2402
}
2308
2403
2404
+ // Return
2309
2405
return $ returnValue ;
2310
2406
}
2311
2407
0 commit comments