├── .gitignore ├── AutoXL.txt ├── Demo ├── AutoXL-Demo.xlsx └── VersionControl.gif ├── LICENSE └── README.md /.gitignore: -------------------------------------------------------------------------------- 1 | .DS_Store 2 | Demo/~$*.xlsx 3 | -------------------------------------------------------------------------------- /AutoXL.txt: -------------------------------------------------------------------------------- 1 | // return the name and version of the library 2 | A.VERSION = LAMBDA("AutoXL 0.1.2"); 3 | 4 | // return whether two values or arrays are equal 5 | // case-insensitive 6 | A.EQ = LAMBDA(value1, value2, 7 | IF(AND(ISBLANK(value1), ISBLANK(value2)), TRUE, 8 | IF(AND(ISBLANK(value1), NOT(ISBLANK(value2))), FALSE, 9 | IF(AND(NOT(ISBLANK(value1)), ISBLANK(value2)), FALSE, 10 | IF(COLUMNS(value1) <> COLUMNS(value2), FALSE, 11 | ARRAYTOTEXT(value1, 1) = ARRAYTOTEXT(value2, 1))))) 12 | ); 13 | 14 | // search for a specified row in an array row by row, and then return the row's relative position 15 | // lookup_row: the row to search for 16 | // accept: a single value, a 1D array, a 2D array 17 | // if omitted: return #VALUE! 18 | // lookup_array: the array to search 19 | // accept: a single value, a 1D array, a 2D array 20 | // if omitted: return #VALUE! 21 | // [search_mode]: specify the search mode to use 22 | // 1 - Perform a search starting at the first item (default). 23 | // -1 - Perform a reverse search starting at the last item. 24 | // remarks: 25 | // lookup_row can accept multiple rows, then the function will return a 1D array 26 | // lookup_row and lookup_array should have same number of columns to match 27 | A.XMATCH.ROWS = LAMBDA(lookup_row, lookup_array, [search_mode], 28 | LET( 29 | search_mode, IF(ISOMITTED(search_mode), 1, search_mode * 1), 30 | IF( 31 | OR( 32 | ISOMITTED(lookup_row), 33 | ISOMITTED(lookup_array), 34 | AND(search_mode <> 1, search_mode <> -1)), 35 | #VALUE!, 36 | IF(AND(COLUMNS(lookup_row) = 1, COLUMNS(lookup_array) = 1), 37 | XMATCH(lookup_row, lookup_array, 0, search_mode), 38 | LET( 39 | XMATCH_ROW, 40 | LAMBDA(lookup_1_row, lookup_array, [search_mode], 41 | XMATCH(TRUE, BYROW(lookup_array, LAMBDA(row, A.EQ(row, lookup_1_row))), 0, search_mode)), 42 | BYROW( 43 | lookup_row, 44 | LAMBDA(row, XMATCH_ROW(row, lookup_array, search_mode))))))) 45 | ); 46 | 47 | // search for a specified column in an array column by column, and then return the column's relative position 48 | // lookup_col: the column to search for 49 | // accept: a single value, a 1D array, a 2D array 50 | // if omitted: return #VALUE! 51 | // lookup_array: the array to search 52 | // accept: a single value, a 1D array, a 2D array 53 | // if omitted: return #VALUE! 54 | // search_mode: specify the search mode to use 55 | // 1 - Perform a search starting at the first item (default). 56 | // -1 - Perform a reverse search starting at the last item. 57 | // remarks: 58 | // lookup_col can accept multiple columns, then the function will return a 1D array 59 | // lookup_col and lookup_array should have same number of rows to match 60 | A.XMATCH.COLS = LAMBDA(lookup_col, lookup_array, [search_mode], 61 | LET( 62 | search_mode, IF(ISOMITTED(search_mode), 1, search_mode * 1), 63 | IF( 64 | OR( 65 | ISOMITTED(lookup_col), 66 | ISOMITTED(lookup_array), 67 | AND(search_mode <> 1, search_mode <> -1)), 68 | #VALUE!, 69 | IF(AND(ROWS(lookup_col) = 1, ROWS(lookup_array) = 1), 70 | XMATCH(lookup_col, lookup_array, 0, search_mode), 71 | LET( 72 | XMATCH_COL, 73 | LAMBDA(lookup_1_col, lookup_array, [search_mode], 74 | XMATCH(TRUE, BYCOL(lookup_array, LAMBDA(col, A.EQ(col, lookup_1_col))), 0, search_mode)), 75 | BYCOL( 76 | lookup_col, 77 | LAMBDA(col, XMATCH_COL(col, lookup_array, search_mode))))))) 78 | ); 79 | 80 | // search an array row by row for a match with a given row and return the corresponding item from a second array 81 | // lookup_row: the row to search for 82 | // accept: a single value, a 1D array, a 2D array 83 | // if omitted: return #VALUE! 84 | // lookup_array: the array to search 85 | // accept: a single value, a 1D array, a 2D array 86 | // if omitted: return #VALUE! 87 | // return_array: the array to return 88 | // accept: a single value, a 1D array, a 2D array 89 | // if omitted: return #VALUE! 90 | // [if_not_found]: Where a valid match is not found, return the [if_not_found] text you supply. 91 | // [search_mode]: specify the search mode to use 92 | // 1 - Perform a search starting at the first item (default). 93 | // -1 - Perform a reverse search starting at the last item. 94 | // remarks: 95 | // lookup_row can accept multiple rows, then the function will return a 1D array 96 | // lookup_row and lookup_array should have same number of columns to match 97 | A.XLOOKUP.ROWS = LAMBDA(lookup_row, lookup_array, return_array, [if_not_found], [search_mode], 98 | LET( 99 | if_not_found, IF(ISOMITTED(if_not_found), #N/A, if_not_found), 100 | search_mode, IF(ISOMITTED(search_mode), 1, search_mode * 1), 101 | IF( 102 | OR( 103 | ISOMITTED(lookup_row), 104 | ISOMITTED(lookup_array), 105 | ISOMITTED(return_array), 106 | AND(search_mode <> 1, search_mode <> -1)), 107 | #VALUE!, 108 | IF(AND(COLUMNS(lookup_row) = 1, COLUMNS(lookup_array) = 1), 109 | XLOOKUP(lookup_row, lookup_array, return_array, if_not_found, 0, search_mode), 110 | LET( 111 | x, 112 | A.XMATCH.ROWS(lookup_row, lookup_array, search_mode), 113 | BYROW( 114 | SEQUENCE(ROWS(lookup_row)), 115 | LAMBDA(row, 116 | IF(ISERROR(CHOOSEROWS(x, row)), if_not_found, CHOOSEROWS(return_array, CHOOSEROWS(x, row))))))))) 117 | ); 118 | 119 | // search an array column by column for a match with a given column and return the corresponding item from a second array 120 | // lookup_col: the column to search for 121 | // accept: a single value, a 1D array, a 2D array 122 | // if omitted: return #VALUE! 123 | // lookup_array: the array to search 124 | // accept: a single value, a 1D array, a 2D array 125 | // if omitted: return #VALUE! 126 | // return_array: the array to return 127 | // accept: a single value, a 1D array, a 2D array 128 | // if omitted: return #VALUE! 129 | // [if_not_found]: Where a valid match is not found, return the [if_not_found] text you supply. 130 | // [search_mode]: specify the search mode to use 131 | // 1 - Perform a search starting at the first item (default). 132 | // -1 - Perform a reverse search starting at the last item. 133 | // remarks: 134 | // lookup_col can accept multiple columns, then the function will return a 1D array 135 | // lookup_col and lookup_array should have same number of rows to match 136 | A.XLOOKUP.COLS = LAMBDA(lookup_col, lookup_array, return_array, [if_not_found], [search_mode], 137 | LET( 138 | if_not_found, IF(ISOMITTED(if_not_found), #N/A, if_not_found), 139 | search_mode, IF(ISOMITTED(search_mode), 1, search_mode * 1), 140 | IF( 141 | OR( 142 | ISOMITTED(lookup_col), 143 | ISOMITTED(lookup_array), 144 | ISOMITTED(return_array), 145 | AND(search_mode <> 1, search_mode <> -1)), 146 | #VALUE!, 147 | IF(AND(ROWS(lookup_col) = 1, ROWS(lookup_array) = 1), 148 | XLOOKUP(lookup_col, lookup_array, return_array, if_not_found, 0, search_mode), 149 | LET( 150 | x, 151 | A.XMATCH.COLS(lookup_col, lookup_array, search_mode), 152 | BYCOL( 153 | SEQUENCE(COLUMNS(lookup_col)), 154 | LAMBDA(col, 155 | IF(ISERROR(CHOOSECOLS(x, col)), if_not_found, CHOOSECOLS(return_array, CHOOSECOLS(x, col))))))))) 156 | ); 157 | 158 | // reduce an array to an accumulated value by applying a LAMBDA function to each row and returning the total value in the accumulator 159 | // initial_value: set the starting value for the accumulator 160 | // if omitted: return #VALUE! 161 | // array: an array to be scanned 162 | // if omitted: return #VALUE! 163 | // function: a function that is called to reduce the array 164 | // the function takes two parameters: 165 | // 1) accumulator: the value totaled up and returned as the final result; 166 | // 2) row: the calculation applied to each row in the array 167 | A.REDUCE.ROWS = LAMBDA(initial_value, array, function, 168 | IF( 169 | OR(ISOMITTED(initial_value), ISOMITTED(array), ISOMITTED(function)), 170 | #VALUE!, 171 | REDUCE(initial_value, SEQUENCE(ROWS(array)), 172 | LAMBDA(acc, i, function(acc, CHOOSEROWS(array, i)))) 173 | ) 174 | ); 175 | 176 | // reduce an array to an accumulated value by applying a LAMBDA function to each column and returning the total value in the accumulator 177 | // initial_value: set the starting value for the accumulator 178 | // if omitted: return #VALUE! 179 | // array: an array to be scanned 180 | // if omitted: return #VALUE! 181 | // function: a function that is called to reduce the array 182 | // the function takes two parameters: 183 | // 1) accumulator: the value totaled up and returned as the final result; 184 | // 2) column: the calculation applied to each column in the array 185 | A.REDUCE.COLS = LAMBDA(initial_value, array, function, 186 | IF( 187 | OR(ISOMITTED(initial_value), ISOMITTED(array), ISOMITTED(function)), 188 | #VALUE!, 189 | REDUCE(initial_value, SEQUENCE(COLUMNS(array)), 190 | LAMBDA(acc, i, function(acc, CHOOSECOLS(array, i)))) 191 | ) 192 | ); 193 | 194 | // scan an array row by row by applying a function to each row, and return an array that has each intermediate value 195 | // initial_value: set the starting value for the accumulator 196 | // if omitted: return #VALUE! 197 | // array: an array to be scanned 198 | // if omitted: return #VALUE! 199 | // function: a function that is called to scan the array 200 | // the function takes two parameters: 201 | // 1) accumulator: the value totaled up and returned as the final result; 202 | // 2) row: the calculation applied to each row in the array 203 | // if omitted: return #VALUE! 204 | // remarks: 205 | // unlike in SCAN function, initial_value cannot be omitted to avoid confusion 206 | A.SCAN.ROWS = LAMBDA(initial_value, array, function, 207 | IF( 208 | OR(ISOMITTED(initial_value), ISOMITTED(array), ISOMITTED(function)), 209 | #VALUE!, 210 | SCAN(initial_value, SEQUENCE(ROWS(array)), 211 | LAMBDA(acc, i_row, function(acc, CHOOSEROWS(array, i_row))))) 212 | ); 213 | 214 | // scan an array column by column by applying a function to each column, and return an array that has each intermediate value 215 | // initial_value: set the starting value for the accumulator 216 | // if omitted: return #VALUE! 217 | // array: an array to be scanned 218 | // if omitted: return #VALUE! 219 | // function: a function that is called to scan the array 220 | // the function takes two parameters: 221 | // 1) accumulator: the value totaled up and returned as the final result; 222 | // 2) column: the calculation applied to each column in the array 223 | // if omitted: return #VALUE! 224 | // remarks: 225 | // unlike in SCAN function, initial_value cannot be omitted to avoid confusion 226 | A.SCAN.COLS = LAMBDA(initial_value, array, function, 227 | IF( 228 | OR(ISOMITTED(initial_value), ISOMITTED(array), ISOMITTED(function)), 229 | #VALUE!, 230 | SCAN(initial_value, SEQUENCE(COLUMNS(array)), 231 | LAMBDA(acc, i_col, function(acc, CHOOSECOLS(array, i_col))))) 232 | ); 233 | 234 | // find the union of two arrays by cells; return an array of the unique cells that are in either of the two input arrays 235 | // array1: an input array 236 | // if omitted: return #VALUE! 237 | // array2: an input array 238 | // if omitted: return the union within array1 239 | // ignore: whether to ignore certain types of values 240 | // 0 - keep all values (default) 241 | // 1 - Ignore blanks 242 | // 2 - Ignore errors 243 | // 3 - Ignore blanks and errors 244 | // scan_by_column: 245 | // FALSE - scan by row (default) 246 | // TRUE - scan by column 247 | A.UNION.CELLS = LAMBDA(array1, [array2], [ignore], [scan_by_column], 248 | LET( 249 | array2, IF(ISOMITTED(array2), array1, array2), 250 | ignore, IF(ISOMITTED(ignore), 0, ignore * 1), 251 | scan_by_column, IF(ISOMITTED(scan_by_column), 0, scan_by_column * 1), 252 | IF(ISOMITTED(array1), #VALUE!, 253 | IF(AND(ignore <> 0, ignore <> 1, ignore <> 2, ignore <> 3), #VALUE!, 254 | IF(AND(scan_by_column <> 0, scan_by_column <> 1), #VALUE!, 255 | UNIQUE(VSTACK( 256 | TOCOL(array1, ignore, scan_by_column), 257 | TOCOL(array2, ignore, scan_by_column))))))) 258 | ); 259 | 260 | // find the union of two arrays by rows; return an array of the unique rows that are in either of the two input arrays 261 | // array1: an input array 262 | // if omitted: return #VALUE! 263 | // array2: an input array 264 | // if omitted: return the union within array1 265 | // remarks: 266 | // if a row has fewer columns than the resulting array, it will be completed by #N/A 267 | A.UNION.ROWS = LAMBDA(array1, [array2], 268 | LET( 269 | array2, IF(ISOMITTED(array2), array1, array2), 270 | IF( 271 | ISOMITTED(array1), 272 | #VALUE!, 273 | UNIQUE(VSTACK(array1, array2), FALSE))) 274 | ); 275 | 276 | // find the union of two arrays by columns; return an array of the unique columns that are in either of the two input arrays 277 | // array1: an input array 278 | // if omitted: return #VALUE! 279 | // array2: an input array 280 | // if omitted: return the union within array1 281 | // remarks: 282 | // if a column has fewer rows than the resulting array, it will be completed by #N/A 283 | A.UNION.COLS = LAMBDA(array1, [array2], 284 | LET( 285 | array2, IF(ISOMITTED(array2), array1, array2), 286 | IF( 287 | ISOMITTED(array1), 288 | #VALUE!, 289 | UNIQUE(HSTACK(array1, array2), TRUE))) 290 | ); 291 | 292 | // find the intersection of two arrays by cells; return an array of the unique cells that are in both of the two input arrays 293 | // array1: an input array 294 | // if omitted: return #VALUE! 295 | // array2: an input array 296 | // if omitted: return the intersection within array1 297 | // ignore: whether to ignore certain types of values 298 | // 0 - keep all values (default) 299 | // 1 - Ignore blanks 300 | // 2 - Ignore errors 301 | // 3 - Ignore blanks and errors 302 | // scan_by_column: 303 | // FALSE - scan by row (default) 304 | // TRUE - scan by column 305 | // remarks: 306 | // if the result is empty, return #CALC! 307 | A.INTERSECT.CELLS = LAMBDA(array1, [array2], [ignore], [scan_by_column], 308 | LET( 309 | array2, IF(ISOMITTED(array2), array1, array2), 310 | ignore, IF(ISOMITTED(ignore), 0, ignore * 1), 311 | scan_by_column, IF(ISOMITTED(scan_by_column), 0, scan_by_column * 1), 312 | IF(ISOMITTED(array1), #VALUE!, 313 | IF(AND(ignore <> 0, ignore <> 1, ignore <> 2, ignore <> 3), #VALUE!, 314 | IF(AND(scan_by_column <> 0, scan_by_column <> 1), #VALUE!, 315 | LET( 316 | array1du_1, UNIQUE(TOCOL(array1, ignore, scan_by_column)), 317 | array1du_2, UNIQUE(TOCOL(array2, ignore, scan_by_column)), 318 | FILTER(array1du_1, NOT(ISERROR(XMATCH(array1du_1, array1du_2))))))))) 319 | ); 320 | 321 | // find the intersection of two arrays by rows; return an array of the unique rows that are in both of the two input arrays 322 | // array1: an input array 323 | // if omitted: return #VALUE! 324 | // array2: an input array 325 | // if omitted: return the intersection within array1 326 | // remarks: 327 | // if the result is empty, return #CALC! 328 | // array1 and array2 should have same number of columns to compare 329 | A.INTERSECT.ROWS = LAMBDA(array1, [array2], 330 | LET( 331 | array2, IF(ISOMITTED(array2), array1, array2), 332 | IF( 333 | ISOMITTED(array1), 334 | #VALUE!, 335 | LET( 336 | arrayu_1, UNIQUE(array1, FALSE), 337 | arrayu_2, UNIQUE(array2, FALSE), 338 | FILTER(arrayu_1, NOT(ISERROR(A.XMATCH.ROWS(arrayu_1, arrayu_2))))))) 339 | ); 340 | 341 | // find the intersection of two arrays by columns; return an array of the unique columns that are in both of the two input arrays 342 | // array1: an input array 343 | // if omitted: return #VALUE! 344 | // array2: an input array 345 | // if omitted: return the intersection within array1 346 | // remarks: 347 | // if the result is empty, return #CALC! 348 | // array1 and array2 should have same number of rows to compare 349 | A.INTERSECT.COLS = LAMBDA(array1, [array2], 350 | LET( 351 | array2, IF(ISOMITTED(array2), array1, array2), 352 | IF( 353 | ISOMITTED(array1), 354 | #VALUE!, 355 | LET( 356 | arrayu_1, UNIQUE(array1, TRUE), 357 | arrayu_2, UNIQUE(array2, TRUE), 358 | FILTER(arrayu_1, NOT(ISERROR(A.XMATCH.COLS(arrayu_1, arrayu_2))))))) 359 | ); 360 | 361 | // find the set difference of two arrays by cells; return an array of the unique cells in one array that are not in the other 362 | // array1: an input array 363 | // if omitted: return #VALUE! 364 | // array2: an input array 365 | // if omitted: return the unique cells of array1 366 | // ignore: whether to ignore certain types of values 367 | // 0 - keep all values (default) 368 | // 1 - Ignore blanks 369 | // 2 - Ignore errors 370 | // 3 - Ignore blanks and errors 371 | // scan_by_column: 372 | // FALSE - scan by row (default) 373 | // TRUE - scan by column 374 | // remarks: 375 | // if the result is empty, return #CALC! 376 | A.SETDIFF.CELLS = LAMBDA(array1, [array2], [ignore], [scan_by_column], 377 | LET( 378 | ignore, IF(ISOMITTED(ignore), 0, ignore * 1), 379 | scan_by_column, IF(ISOMITTED(scan_by_column), 0, scan_by_column * 1), 380 | IF(ISOMITTED(array1), #VALUE!, 381 | IF(ISOMITTED(array2), UNIQUE(TOCOL(array1, ignore, scan_by_column)), 382 | IF(AND(ignore <> 0, ignore <> 1, ignore <> 2, ignore <> 3), #VALUE!, 383 | IF(AND(scan_by_column <> 0, scan_by_column <> 1), #VALUE!, 384 | LET( 385 | array1du_1, UNIQUE(TOCOL(array1, ignore, scan_by_column)), 386 | array1du_2, UNIQUE(TOCOL(array2, ignore, scan_by_column)), 387 | FILTER(array1du_1, ISERROR(XMATCH(array1du_1, array1du_2))))))))) 388 | ); 389 | 390 | // find the set difference of two arrays by rows; return an array of the unique rows in one array that are not in the other 391 | // array1: an input array 392 | // if omitted: return #VALUE! 393 | // array2: an input array 394 | // if omitted: return the unique rows of array1 395 | // remarks: 396 | // if the result is empty, return #CALC! 397 | // array1 and array2 should have same number of columns to compare 398 | A.SETDIFF.ROWS = LAMBDA(array1, [array2], 399 | IF(ISOMITTED(array1), #VALUE!, 400 | IF(ISOMITTED(array2), UNIQUE(array1, FALSE), 401 | LET( 402 | arrayu_1, UNIQUE(array1, FALSE), 403 | arrayu_2, UNIQUE(array2, FALSE), 404 | FILTER(arrayu_1, ISERROR(A.XMATCH.ROWS(arrayu_1, arrayu_2)))))) 405 | ); 406 | 407 | // find the set difference of two arrays by columns; return an array of the unique columns in one array that are not in the other 408 | // array1: an input array 409 | // if omitted: return #VALUE! 410 | // array2: an input array 411 | // if omitted: return the unique columns of array1 412 | // remarks: 413 | // if the result is empty, return #CALC! 414 | // array1 and array2 should have same number of rows to compare 415 | A.SETDIFF.COLS = LAMBDA(array1, [array2], 416 | IF(ISOMITTED(array1), #VALUE!, 417 | IF(ISOMITTED(array2), UNIQUE(array1, TRUE), 418 | LET( 419 | arrayu_1, UNIQUE(array1, TRUE), 420 | arrayu_2, UNIQUE(array2, TRUE), 421 | FILTER(arrayu_1, ISERROR(A.XMATCH.COLS(arrayu_1, arrayu_2)))))) 422 | ); 423 | 424 | // count the number of rows within an array that is equal to the given row 425 | // criteria_row: the row to compare with 426 | // accept: a single value, a 1D array, a 2D array 427 | // if omitted: return #VALUE! 428 | // array: the array to search 429 | // accept: a single value, a 1D array, a 2D array 430 | // if omitted: return #VALUE! 431 | // remarks: 432 | // criteria_row can accept multiple rows, then the function will return a 1D array 433 | // criteria_row and array should have same number of columns to match 434 | A.COUNTEQ.ROWS = LAMBDA(array, criteria_row, 435 | IF( 436 | OR(ISOMITTED(array), ISOMITTED(criteria_row)), 437 | #VALUE!, 438 | IF(AND(COLUMNS(array) = 1, COLUMNS(criteria_row) = 1), 439 | COUNTIF(array, criteria_row), 440 | BYROW( 441 | criteria_row, 442 | LAMBDA( 443 | row, 444 | A.REDUCE.ROWS(0, array, LAMBDA(acc, row_bis, 445 | IF(A.EQ(row_bis, row), acc + 1, acc))))))) 446 | ); 447 | 448 | // count the number of columns within an array that is equal to the given column 449 | // criteria_col: the column to compare with 450 | // accept: a single value, a 1D array, a 2D array 451 | // if omitted: return #VALUE! 452 | // array: the array to search 453 | // accept: a single value, a 1D array, a 2D array 454 | // if omitted: return #VALUE! 455 | // remarks: 456 | // criteria_col can accept multiple columns, then the function will return a 1D array 457 | // criteria_col and array should have same number of rows to match 458 | A.COUNTEQ.COLS = LAMBDA(array, criteria_col, 459 | IF( 460 | OR(ISOMITTED(array), ISOMITTED(criteria_col)), 461 | #VALUE!, 462 | IF(AND(ROWS(array) = 1, ROWS(criteria_col) = 1), 463 | COUNTIF(array, criteria_col), 464 | BYCOL( 465 | criteria_col, 466 | LAMBDA( 467 | col, 468 | A.REDUCE.COLS(0, array, LAMBDA(acc, col_bis, 469 | IF(A.EQ(col_bis, col), acc + 1, acc))))))) 470 | ); 471 | 472 | // values that occur a given number of times in an array are indicated as TRUE in the resulting array. 473 | // array: the input array 474 | // if omitted: return #VALUE! 475 | // occurrence: the given number of occurrence times 476 | // if omitted: return #VALUE! 477 | // by_col: 478 | // FALSE: by rows (default) 479 | // TRUE: by columns 480 | A.DUPLICATED.BYTIMES = LAMBDA(array, occurrence, [by_col], 481 | LET( 482 | by_col, IF(ISOMITTED(by_col), 0, by_col * 1), 483 | IF(OR(ISOMITTED(array), ISOMITTED(occurrence)), #VALUE!, 484 | IF(AND(by_col <> 0, by_col <> 1), #VALUE!, 485 | IF(by_col = 0, A.COUNTEQ.ROWS(array, array) = occurrence, 486 | IF(by_col = 1, A.COUNTEQ.COLS(array, array) = occurrence, 487 | #VALUE!))))) 488 | ); 489 | 490 | // values that occur a given number of times in an array are indicated as TRUE in the resulting array. 491 | // array: the input array 492 | // if omitted: return #VALUE! 493 | // keep: 494 | // 0 - mark all duplicates as TRUE 495 | // 1 - mark duplicates as TRUE except for the first occurrence 496 | // -1 - mark duplicates as TRUE except for the last occurrence 497 | // by_col: 498 | // FALSE: by rows (default) 499 | // TRUE: by columns 500 | A.DUPLICATED = LAMBDA(array, [keep], [by_col], 501 | LET( 502 | keep, IF(ISOMITTED(keep), 0, keep * 1), 503 | by_col, IF(ISOMITTED(by_col), 0, by_col * 1), 504 | IF(ISOMITTED(array), #VALUE!, 505 | IF(AND(keep <> 0, keep <> 1, keep <> -1), #VALUE!, 506 | IF(AND(by_col <> 0, by_col <> 1), #VALUE!, 507 | IF(by_col = 0, 508 | IF(keep = 0, A.COUNTEQ.ROWS(array, array) >= 2, 509 | IF(keep = 1, ROW(array) - MIN(ROW(array)) + 1 <> A.XMATCH.ROWS(array,array), 510 | IF(keep = -1, ROW(array) - MIN(ROW(array)) + 1 <> A.XMATCH.ROWS(array, array, -1), 511 | #VALUE!))), 512 | IF(by_col = 1, 513 | IF(keep = 0, A.COUNTEQ.COLS(array, array) >= 2, 514 | IF(keep = 1, COLUMN(array) - MIN(COLUMN(array)) + 1 <> A.XMATCH.COLS(array,array), 515 | IF(keep = -1, COLUMN(array) - MIN(COLUMN(array)) + 1 <> A.XMATCH.COLS(array, array, -1), 516 | #VALUE!))), 517 | #VALUE!)))))) 518 | ); 519 | 520 | // search duplicated values by occurrence times in an array and return the corresponding item from a second array 521 | // array: the array to search 522 | // if omitted: return #VALUE! 523 | // return_array: the array to return 524 | // occurrence: the given number of occurrence times 525 | // if omitted: return #VALUE! 526 | // by_col: 527 | // FALSE: by rows (default) 528 | // TRUE: by columns 529 | A.DUPLICATES.BYTIMES = LAMBDA(array, occurrence, [by_col], [return_array], 530 | LET( 531 | return_array, IF(ISOMITTED(return_array), array, return_array), 532 | FILTER(return_array, A.DUPLICATED.BYTIMES(array, occurrence, by_col))) 533 | ); 534 | 535 | // search duplicated values in an array and return the corresponding item from a second array 536 | // array: the array to search 537 | // if omitted: return #VALUE! 538 | // return_array: the array to return 539 | // keep: 540 | // 0 - mark all duplicates as TRUE 541 | // 1 - mark duplicates as TRUE except for the first occurrence 542 | // -1 - mark duplicates as TRUE except for the last occurrence 543 | // by_col: 544 | // FALSE: by rows (default) 545 | // TRUE: by columns 546 | A.DUPLICATES = LAMBDA(array, [keep], [by_col], [return_array], 547 | LET( 548 | return_array, IF(ISOMITTED(return_array), array, return_array), 549 | FILTER(return_array, A.DUPLICATED(array, keep, by_col))) 550 | ); 551 | 552 | // return a reference to the first cell within an array that contains a given text 553 | // find_text: the text that you want to find 554 | // if omitted: return #VALUE! 555 | // within_array: the array where you want to search for the value of the find_text argument 556 | // if omitted: return #VALUE! 557 | // find_direction: 558 | // 0 - top-down and left-right (default) 559 | // 1 - top-down and right-left 560 | // 2 - bottom-up and left-right 561 | // 3 - bottom-up and right-left 562 | // text_function: 563 | // 0 - by SEARCH function (default) 564 | // 1 - by FIND function 565 | // 2 - by SEARCHB function 566 | // 3 - by FINDB function 567 | // start_num: 568 | // the character number in every cell at which you want to start searching 569 | // if_omitted: 1 570 | // remarks: 571 | // if no cell matching find_text is found, return #N/A 572 | // there are differences by using SEARCH function and FIND function, for instance, 573 | // SEARCH and SEARCHB are not case sensitive, whereas FIND and FINDB are case sensitive 574 | // by SEARCH and SEARCHB, you can use the wildcard characters — the question mark (?) and asterisk (*) — in the find_text argument 575 | A.LOCATE.CELLBYTEXT = LAMBDA(find_text, within_array, [find_direction], [text_function], [start_num], 576 | LET( 577 | ROTATEROWS, 578 | LAMBDA(array, 579 | MAKEARRAY(ROWS(array), COLUMNS(array), 580 | LAMBDA(i, j, INDEX(array, ROWS(array) - i + 1, j)))), 581 | ROTATECOLS, 582 | LAMBDA(array, 583 | MAKEARRAY(ROWS(array), COLUMNS(array), 584 | LAMBDA(i, j, INDEX(array, i, COLUMNS(array) - j + 1)))), 585 | find_direction, IF(ISOMITTED(find_direction), 0, find_direction * 1), 586 | text_function, IF(ISOMITTED(text_function), 0, text_function * 1), 587 | start_num, IF(ISOMITTED(start_num), 1, start_num), 588 | IF(OR(ISOMITTED(find_text), ISOMITTED(within_array)), #VALUE!, 589 | IF(AND(find_direction <> 0, find_direction <> 1, find_direction <> 2, find_direction <> 3), #VALUE!, 590 | IF(AND(text_function <> 0, text_function <> 1, text_function <> 2, text_function <> 3), #VALUE!, 591 | LET( 592 | matches, 593 | IF(text_function = 0, ISNUMBER(SEARCH(find_text, within_array, start_num)), 594 | IF(text_function = 1, ISNUMBER(FIND(find_text, within_array, start_num)), 595 | IF(text_function = 2, ISNUMBER(SEARCHB(find_text, within_array, start_num)), 596 | IF(text_function = 3, ISNUMBER(FINDB(find_text, within_array, start_num)), 597 | #VALUE!)))), 598 | IF(find_direction = 0, 599 | LET( 600 | x, XMATCH(TRUE, TOCOL(matches)), 601 | row_rel, INT((x - 1) / COLUMNS(within_array)) + 1, 602 | col_rel, LET(r, MOD(x, COLUMNS(within_array)), IF(r = 0, COLUMNS(within_array), r)), 603 | INDEX(within_array, row_rel, col_rel)), 604 | IF(find_direction = 1, 605 | LET( 606 | x, XMATCH(TRUE, TOCOL(ROTATECOLS(matches))), 607 | row_rel, INT((x - 1) / COLUMNS(within_array)) + 1, 608 | col_rel, COLUMNS(within_array) - LET(r, MOD(x, COLUMNS(within_array)), IF(r = 0, COLUMNS(within_array), r)) + 1, 609 | INDEX(within_array, row_rel, col_rel)), 610 | IF(find_direction = 2, 611 | LET( 612 | x, XMATCH(TRUE, TOCOL(ROTATEROWS(matches))), 613 | row_rel, ROWS(within_array) - INT((x - 1) / COLUMNS(within_array)), 614 | col_rel, LET(r, MOD(x, COLUMNS(within_array)), IF(r = 0, COLUMNS(within_array), r)), 615 | INDEX(within_array, row_rel, col_rel)), 616 | IF(find_direction = 3, 617 | LET( 618 | x, XMATCH(TRUE, TOCOL(matches), 0, -1), 619 | row_rel, ROWS(within_array) - INT((x - 1) / COLUMNS(within_array)), 620 | col_rel, LET(r, MOD(x, COLUMNS(within_array)), IF(r = 0, COLUMNS(within_array), r)), 621 | INDEX(within_array, row_rel, col_rel)), 622 | #VALUE!))))))))) 623 | ); 624 | 625 | // locate a range by jumping from an origin range in a direction within a scope range to special cells, and return a reference to that range 626 | // reference: the origin range 627 | // if omitted: #VALUE! 628 | // direction: 629 | // 0 - down (default) 630 | // 1 - to right 631 | // 2 - up 632 | // 3 - to left 633 | // scope_range: 634 | // if omitted: the entire worksheet 635 | // special_cell: 636 | // 0 - locate by the last non-blank cell in that direction within scope_range (default) 637 | // 1 - locate by the last cell in the direction within scope_range 638 | // remarks: 639 | // reference must be inside scope_range 640 | // pay attention that the cell calling this function should not intersect with relevant rows and columns, otherwise a circle reference error will be raised 641 | A.JUMP = LAMBDA(reference, [direction], [scope_range], [special_cell], 642 | LET( 643 | RANGE, 644 | LAMBDA(reference, row_min, col_min, row_max, col_max, 645 | LET( 646 | topleft, OFFSET(reference, -1 * MIN(ROW(reference)) + 1, -1 * MIN(COLUMN(reference)) + 1, 1, 1), 647 | OFFSET(topleft, row_min - 1, col_min - 1, row_max - row_min + 1, col_max - col_min + 1))), 648 | CHANGEROW, 649 | LAMBDA(reference, row_new, 650 | RANGE(reference, row_new, MIN(COLUMN(reference)), row_new, MAX(COLUMN(reference)))), 651 | CHANGECOL, 652 | LAMBDA(reference, col_new, 653 | RANGE(reference, MIN(ROW(reference)), col_new, MAX(ROW(reference)), col_new)), 654 | f, 655 | LAMBDA(scope, special_cell, 656 | IF(special_cell = 0, NOT(ISBLANK(scope)), 657 | IF(special_cell = 1, 1, 658 | #VALUE!))), 659 | direction, IF(ISOMITTED(direction), 0, direction * 1), 660 | scope_range, IF(ISOMITTED(scope_range), RANGE(reference, 1, 1, 1048576, 16384), scope_range), 661 | special_cell, IF(ISOMITTED(special_cell), 0, special_cell * 1), 662 | IF(ISOMITTED(reference), #VALUE!, 663 | IF(AND(direction <> 0, direction <> 1, direction <> 2, direction <> 3), #VALUE!, 664 | IF(AND(special_cell <> 0, special_cell <> 1), #VALUE!, 665 | IF(NOT(AND(MIN(ROW(reference)) >= MIN(ROW(scope_range)), MAX(ROW(reference)) <= MAX(ROW(scope_range)), 666 | MIN(COLUMN(reference)) >= MIN(COLUMN(scope_range)), MAX(COLUMN(reference)) <= MAX(COLUMNS(scope_range)))), 667 | #VALUE!, 668 | IF(direction = 0, 669 | LET( 670 | scope_inter, RANGE(reference, MAX(MIN(ROW(reference)), MIN(ROW(scope_range))), MIN(COLUMN(reference)), MAX(ROW(scope_range)), MAX(COLUMN(reference))), 671 | LET( 672 | row_new, MAX(ROW(scope_inter) * f(scope_inter, special_cell)), 673 | IF(row_new > MAX(ROW(reference)), CHANGEROW(reference, row_new), reference))), 674 | IF(direction = 1, 675 | LET( 676 | scope_inter, RANGE(reference, MIN(ROW(reference)), MAX(MIN(COLUMN(reference)), MIN(COLUMN(scope_range))), MAX(ROW(reference)), MAX(COLUMNS(scope_range))), 677 | LET( 678 | col_new, MAX(COLUMN(scope_inter) * f(scope_inter, special_cell)), 679 | IF(col_new > MAX(COLUMN(reference)), CHANGECOL(reference, col_new), reference))), 680 | IF(direction = 2, 681 | LET( 682 | scope_inter, RANGE(reference, MIN(ROW(scope_range)), MIN(COLUMN(reference)), MIN(MAX(ROW(reference)), MAX(ROW(scope_range))), MAX(COLUMN(reference))), 683 | LET( 684 | row_new, 685 | LET(x, ROW(scope_inter) * f(scope_inter, special_cell), IFERROR(MIN(FILTER(x, x <> 0)), 1048577)), 686 | IF(row_new < MIN(ROW(reference)), CHANGEROW(reference, row_new), reference))), 687 | IF(direction = 3, 688 | LET( 689 | scope_inter, RANGE(reference, MIN(ROW(reference)), MIN(COLUMN(scope_range)), MAX(ROW(reference)), MIN(MAX(COLUMN(reference)), MAX(COLUMNS(scope_range)))), 690 | LET( 691 | col_new, 692 | LET(x, COLUMN(scope_inter) * f(scope_inter, special_cell), IFERROR(MIN(FILTER(x, x <> 0)), 16385)), 693 | IF(col_new < MIN(COLUMN(reference)), CHANGECOL(reference, col_new), reference))), 694 | #VALUE!))))))))) 695 | ); 696 | 697 | // locate a range by an origin range and the direction to jump within a scope range, and return a reference to that range 698 | // reference: the origin range 699 | // if omitted: #VALUE! 700 | // direction: 701 | // 0 - down (default) 702 | // 1 - to right 703 | // 2 - up 704 | // 3 - to left 705 | // scope_range: 706 | // if omitted: the entire worksheet 707 | // special_cell: 708 | // 0 - locate by the last non-blank cell in that direction within scope_range (default) 709 | // 1 - locate by the last cell in the direction within scope_range 710 | // include_origin: 711 | // FALSE - the resulting range does not include the origin range 712 | // TRUE - the resulting rage includes the origin range 713 | // remarks: 714 | // reference must be inside scope_range 715 | // pay attention that the cell calling this function should not intersect with relevant rows and columns, otherwise a circle reference error will be raised 716 | A.EXTEND = LAMBDA(reference, [direction], [scope_range], [special_cell], [include_origin], 717 | LET( 718 | RANGE, 719 | LAMBDA(reference, row_min, col_min, row_max, col_max, 720 | LET( 721 | topleft, OFFSET(reference, -1 * MIN(ROW(reference)) + 1, -1 * MIN(COLUMN(reference)) + 1, 1, 1), 722 | OFFSET(topleft, row_min - 1, col_min - 1, row_max - row_min + 1, col_max - col_min + 1))), 723 | calcerror, FILTER({1},FALSE), 724 | direction, IF(ISOMITTED(direction), 0, direction * 1), 725 | include_origin, IF(ISOMITTED(include_origin), 0, include_origin * 1), 726 | IF(ISOMITTED(reference), #VALUE!, 727 | IF(AND(direction <> 0, direction <> 1, direction <> 2, direction <> 3), #VALUE!, 728 | IF(AND(special_cell <> 0, special_cell <> 1), #VALUE!, 729 | IF(AND(include_origin <> 0, include_origin <> 1), #VALUE!, 730 | IF(include_origin = 0, 731 | LET( 732 | jump_to, A.JUMP(reference, direction, scope_range, special_cell), 733 | IF(A.EQ(reference, jump_to), calcerror, 734 | IF(direction = 0, RANGE(reference, MAX(ROW(reference)) + 1, MIN(COLUMN(jump_to)), MAX(ROW(jump_to)), MAX(COLUMN(jump_to))), 735 | IF(direction = 1, RANGE(reference, MIN(ROW(jump_to)), MAX(COLUMN(reference)) + 1, MAX(ROW(jump_to)), MAX(COLUMN(jump_to))), 736 | IF(direction = 2, RANGE(reference, MIN(ROW(jump_to)), MIN(COLUMN(jump_to)), MIN(ROW(reference)) - 1, MAX(COLUMN(jump_to))), 737 | IF(direction = 3, RANGE(reference, MIN(ROW(jump_to)), MIN(COLUMN(jump_to)), MAX(ROW(jump_to)), MIN(COLUMN(reference)) - 1), 738 | #VALUE!)))))), 739 | IF(include_origin = 1, 740 | reference:A.JUMP(reference, direction, scope_range, special_cell), 741 | #VALUE!))))))) 742 | ); 743 | 744 | // find the first cell within an array that contains a text, extend it in a direction within a scope range to obtain a range, and return a reference to that range 745 | // find_text: the text that you want to 746 | // if omitted: return #VALUE! 747 | // within_array: the array where you want to search for the value of the find_text argument 748 | // if omitted: return #VALUE! 749 | // reference: the origin range 750 | // if omitted: #VALUE! 751 | // find_direction: 752 | // 0 - top-down and left-right (default) 753 | // 1 - top-down and right-left 754 | // 2 - bottom-up and left-right 755 | // 3 - bottom-up and right-left 756 | // extend_direction: 757 | // 0 - down (default) 758 | // 1 - to right 759 | // 2 - up 760 | // 3 - to left 761 | // scope_range: 762 | // if omitted: the entire worksheet 763 | // special_cell: 764 | // 0 - locate by the last non-blank cell in that direction within scope_range (default) 765 | // 1 - locate by the last cell in the direction within scope_range 766 | // include_origin: 767 | // FALSE - the resulting range does not include the origin range 768 | // TRUE - the resulting rage includes the origin range 769 | // text_function: 770 | // 0 - by SEARCH function (default) 771 | // 1 - by FIND function 772 | // 2 - by SEARCHB function 773 | // 3 - by FINDB function 774 | // start_num: 775 | // the character number in every cell at which you want to start searching 776 | // if_omitted: 1 777 | // pay attention that the cell calling this function should not intersect with relevant rows and columns, otherwise a circle reference error will be raised 778 | A.LOCATE.RANGEBYTEXT = LAMBDA(find_text, within_array, [find_direction], [extend_direction], [scope_range], [special_cell], [include_origin], [text_function], [start_num], 779 | LET( 780 | cell, A.LOCATE.CELLBYTEXT(find_text, within_array, find_direction), 781 | A.EXTEND(cell, extend_direction, scope_range, special_cell, include_origin)) 782 | ); 783 | -------------------------------------------------------------------------------- /Demo/AutoXL-Demo.xlsx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/MatrixFun/AutoXL/5c10a2a998cfde95d0457a37c10ae66c9e05f8b2/Demo/AutoXL-Demo.xlsx -------------------------------------------------------------------------------- /Demo/VersionControl.gif: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/MatrixFun/AutoXL/5c10a2a998cfde95d0457a37c10ae66c9e05f8b2/Demo/VersionControl.gif -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2022, SAS Matrix Lead and AutoXL Developers. 4 | All rights reserved. 5 | 6 | Permission is hereby granted, free of charge, to any person obtaining a copy 7 | of this software and associated documentation files (the "Software"), to deal 8 | in the Software without restriction, including without limitation the rights 9 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 10 | copies of the Software, and to permit persons to whom the Software is 11 | furnished to do so, subject to the following conditions: 12 | 13 | The above copyright notice and this permission notice shall be included in all 14 | copies or substantial portions of the Software. 15 | 16 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 17 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 18 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 19 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 20 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 21 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 22 | SOFTWARE. 23 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # AutoXL 2 | 3 | **AutoXL is a fundamental and powerful library of Excel functions written in Excel formula language.** It especially enables Excel users to automate manual tasks, by extensions of lookup and references functions, and elementary functions for array and set, etc. It thus saves Excel users lots of time, and avoids tedious and error-prone manual operations. 4 | 5 | ## Function categories 6 | 7 | At the moment, AutoXL consists of 29 functions mainly in 3 categories: 8 | - Practical, useful, handy and powerful functions to automate manual tasks. For instance, 9 | - `A.LOCATE.CELLBYTEXT` to find a cell in a range that contains a given text.`A.LOCATE.RANGEBYTEXT` to find a header in a range that contains a given text and to return the data below the header 10 | - `A.DUPLICATES` to find duplicates in a range 11 | - Extensions of traditional built-in "lookup and reference" functions, to make them address all real-world use cases. For instance, 12 | - `A.XLOOKUP.ROWS` and `A.XLOOKUP.COLS` for built-in `XLOOKUP` 13 | - `A.XMATCH.ROWS` and `A.XMATCH.COLS` for built-in `XMATCH` 14 | - Elementary functions for compound data types such as array and set. For instance, 15 | - `A.UNION.CELLS`, `A.INTERSECT.CELLS`, `A.SETDIFF.CELLS` for set 16 | - `A.EQ` for array 17 | 18 | ## Users 19 | 20 | As manual operations in Excel exist everywhere, AutoXL is **cross-sectors**. It will mainly benefit 21 | - Excel users who know basic functions like `VLOOKUP` and are willing to try more 22 | - Advanced Excel users who have lots of formulas in their workbooks 23 | - VBA developers 24 | - Developers in other programming languages and want to realize tasks in Excel 25 | 26 | ## Demo 27 | 28 | [![Demo Video](https://i.imgur.com/dJFYTs8.png)](https://www.youtube.com/watch?v=WtBtnwtyBM4) 29 | 30 | ## Installation 31 | 32 | **Excel version requirement:** Many functions of AutoXL are written with newly-introduced built-in functions of Excel, which require Microsoft 365 and probably don't exist in non-subscription Office 2019 or later. Therefore, AutoXL has the same requirement. You could simply type `=VSTACK` in a cell, if its intellisense shows up, that means your Excel meets the requirement. 33 | 34 | 35 | 36 | **Get started quickly:** You could download the workbook `Demo/AutoXL-Demo.xlsx` where AutoXL has been already added. It also contains sample data and formulas which allow you to get familiar with use of functions. Formula Editor will be auto-opened. 37 | 38 | **Installation:** Besides using Microsoft's AFE, you could use [Formula Editor](https://www.10studio.tech/docs/formulaEditor) to add the AutoXL library to your workbook, which will provide a version control. The latest stable versions of AutoXL will always be available in Formula Editor. 39 | 40 | ![alt text](Demo/VersionControl.gif) 41 | 42 | **Uninstallation:** To remove the library from your workbook, 43 | - either you could go to "Name Manager" and manually delete all the functions starting with `A.` (make sure that you don't have other user-defined functions or ranged names starting with `A.`) 44 | - or under Formula Editor, you could go to "Libraries => AutoXL => Remove"; it will only remove AutoXL's functions. 45 | ## Documentation 46 | 47 | The documentation on a website is coming soon. At the moment, you could refer to the comments in the file `AutoXL.txt` to see the list of the functions, their purpose, their arguments, etc. 48 | 49 | Additionally, here are related built-in functions of Excel: 50 | - Traditional [lookup and reference functions](https://support.microsoft.com/en-us/office/lookup-and-reference-functions-reference-8aa21a3a-b56a-4055-8257-3ec89df2b23e) 51 | - [LAMBDA function](https://techcommunity.microsoft.com/t5/excel-blog/announcing-lambda-turn-excel-formulas-into-custom-functions/ba-p/1925546) 52 | - [LAMBDA helper functions](https://techcommunity.microsoft.com/t5/excel-blog/announcing-lambda-helper-functions-lambdas-as-arguments-and-more/ba-p/2576648) 53 | - [New text and array functions](https://techcommunity.microsoft.com/t5/excel-blog/announcing-new-text-and-array-functions/ba-p/3186066) 54 | 55 | ## License 56 | 57 | AutoXL is [MIT licensed](https://github.com/MatrixFun/AutoXL/blob/main/LICENSE). 58 | ## Design principles 59 | 60 | The design and implementation of AutoXL has the following principles: 61 | - Make practical, useful and friendly functions for concrete common tasks driven by Excel end-users 62 | - Make conventional and basic functions for fundamental and compound data types that Excel does not provide 63 | - Follow existing terminology, convention and style of Excel for naming functions and arguments, and default value of parameters, etc. 64 | - Robust, safe, easy-to-understand, and efficient implementation 65 | 66 | 67 | 68 | ## Contributing 69 | 70 | The AutoXL project welcomes your expertise and enthusiasm! Contributions include: 71 | 72 | - Tell us what manual operations you undertake frequently, what you want to achieve in Excel, what functions you think good to have 73 | - Use and test the functions of AutoXL, and report bugs 74 | - Suggest better naming, documentation and code optimization 75 | - Propose to write documentation 76 | - Propose to code new functions 77 | ## Contact 78 | 79 | You could [open an issue](https://github.com/MatrixFun/AutoXL/issues) or write to chengtie@gmail.com. 80 | 81 | ## Full list of functions 82 | - `A.VERSION`: return the name and version of the library 83 | - `A.EQ`: return whether two values or arrays are equal 84 | - `A.XMATCH.ROWS` (similarly for `A.XMATCH.COLS`): search for a specified row in an array row by row, and then return the row's relative position 85 | - `A.XLOOKUP.ROWS` (similarly for `A.XLOOKUP.COLS`): search an array row by row for a match with a given row and return the corresponding item from a second array 86 | - `A.REDUCE.ROWS` (similarly for `A.REDUCE.COLS`): reduce an array to an accumulated value by applying a LAMBDA function to each row and returning the total value in the accumulator 87 | - `A.SCAN.ROWS` (similarly for `A.SCAN.COLS`): scan an array row by row by applying a function to each row, and return an array that has each intermediate value 88 | - `A.UNION.CELLS`: find the union of two arrays by cells; return an array of the unique cells that are in either of the two input arrays 89 | - `A.UNION.ROWS` (similarly for `A.UNION.COLS`): find the union of two arrays by rows; return an array of the unique rows that are in either of the two input arrays 90 | - `A.INTERSECT.CELLS`: find the intersection of two arrays by cells; return an array of the unique cells that are in both of the two input arrays 91 | - `A.INTERSECT.ROWS` (similarly for `A.INTERSECT.COLS`): find the intersection of two arrays by rows; return an array of the unique rows that are in both of the two input arrays 92 | - `A.SETDIFF.CELLS`: find the set difference of two arrays by cells; return an array of the unique cells in one array that are not in the other 93 | - `A.SETDIFF.ROWS` (similarly for `A.SETDIFF.ROWS`): find the set difference of two arrays by rows; return an array of the unique rows in one array that are not in the other 94 | - `A.COUNTEQ.ROWS` (similarly for `A.COUNTEQ.COLS`): count the number of rows within an array that is equal to the given row 95 | - `A.DUPLICATED.BYTIMES`: values that occur a given number of times in an array are indicated as TRUE in the resulting array. 96 | - `A.DUPLICATED`: values that occur a given number of times in an array are indicated as TRUE in the resulting array. 97 | - `A.DUPLICATES.BYTIMES`: search duplicated values by occurrence times in an array and return the corresponding item from a second array 98 | - `A.DUPLICATES`: search duplicated values in an array and return the corresponding item from a second array 99 | - `A.LOCATE.CELLBYTEXT`: return a reference to the first cell within an array that contains a given text 100 | - `A.JUMP`: locate a range by jumping from an origin range in a direction within a scope range to special cells, and return a reference to that range 101 | - `A.EXTEND`: locate a range by an origin range and the direction to jump within a scope range, and return a reference to that range 102 | - `A.LOCATE.RANGEBYTEXT`: find the first cell within an array that contains a text, extend it in a direction within a scope range to obtain a range, and return a reference to that range 103 | 104 | ## Other resources 105 | 106 | - Video courses: [Spreadsheet Language and Programming](https://chengtie.thinkific.com/courses/excel-programming-en) and [表格语言与编程](https://study.163.com/course/courseMain.htm?courseId=1211128814&share=2&shareId=480000002246464) 107 | - Software for spreadsheets: [www.10studio.tech](https://www.10studio.tech) 108 | - Social media: [YouTube](https://www.youtube.com/watch?v=Jr1x1EnP1qA&list=PLOeixAylgNENCnQr9pUWjyAVFzJGbiOSX), [LinkedIn](https://www.linkedin.com/in/chengtie/) 109 | --------------------------------------------------------------------------------