Skip to content

Instantly share code, notes, and snippets.

@ExcelRobot
Last active February 18, 2024 09:46
Show Gist options
  • Save ExcelRobot/c96b9e129281ae18b239ef0d6e521c6a to your computer and use it in GitHub Desktop.
Save ExcelRobot/c96b9e129281ae18b239ef0d6e521c6a to your computer and use it in GitHub Desktop.
Cross Join LAMBDA Function
/*
Name: Cross Join Two Arrays or Tables (CROSSJOIN)
Description: Returns all possible combinations of two arrays of data, with or without header rows.
If the arrays have only one row, it will be assumed that they are row vectors, otherwise it
assumes the arrays are columns of data.
Parameters:
array1 - first array of data with one or more columns
array2 - second array of data with one or more columns
[has_header_row] - true if the first row of the arrays contain a header row, default: false
Source: Excel Robot (@ExcelRobot)
Gist URL: https://gist.github.com/ExcelRobot/c96b9e129281ae18b239ef0d6e521c6a
*/
CROSSJOIN = LAMBDA(array1, array2,[has_header_row],
LET(
HasHeader, IF(ISOMITTED(has_header_row), FALSE, has_header_row),
BothRowArrays, AND(ROWS(array1) = 1, ROWS(array2) = 1),
Data1, IF(BothRowArrays, TRANSPOSE(array1), IF(HasHeader, DROP(array1, 1), array1)),
Data2, IF(BothRowArrays, TRANSPOSE(array2), IF(HasHeader, DROP(array2, 1), array2)),
D1Rows, ROWS(Data1),
D1Cols, COLUMNS(Data1),
D2Rows, ROWS(Data2),
D2Cols, COLUMNS(Data2),
OuterJoinedData, MAKEARRAY(D1Rows * D2Rows, D1Cols + D2Cols,
LAMBDA(i,j,
IF(j <= D1Cols,
INDEX(Data1, ROUNDUP(i / D2Rows, 0), j),
INDEX(Data2, MOD(i - 1, D2Rows)+1, j - D1Cols))
)
),
WithHeader, IF(BothRowArrays, TRANSPOSE(OuterJoinedData), IF(HasHeader,VSTACK(HSTACK(TAKE(array1, 1), TAKE(array2, 1)), OuterJoinedData), OuterJoinedData)),
WithHeader
)
);
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment