-
-
Save dmonder/7eb30991e9ebd8bbab23478d5235c8e8 to your computer and use it in GitHub Desktop.
Unpivot Table LAMBDA Function
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
/* | |
Name: Unpivot Table (UNPIVOT) | |
Description: Given a table range with headers and array of header names, unpivots the | |
specified columns in place, optionally removing any blank entries. | |
Written By: Excel Robot (@ExcelRobot) | |
Category: Array | |
*/ | |
UNPIVOT=LAMBDA(table,[columns_to_unpivot],[attribute_name],[value_name],[remove_blanks], LET( | |
_ColumnsToUnpivot, IF( | |
ISOMITTED(columns_to_unpivot), | |
DROP(TAKE(table, 1), , 1), | |
columns_to_unpivot | |
), | |
_AttributeLabel, IF(ISOMITTED(attribute_name), "Attribute", attribute_name), | |
_ValueLabel, IF(ISOMITTED(value_name), "Value", value_name), | |
_FirstColumnToUnpivot, MATCH(INDEX(_ColumnsToUnpivot, , 1), INDEX(table, 1, ), 0), | |
_UnpivotColumnCount, COLUMNS(_ColumnsToUnpivot), | |
_ColumnNumbers, SEQUENCE(1, COLUMNS(table)), | |
_IncludeColumns, (_ColumnNumbers >= _FirstColumnToUnpivot) | |
* (_ColumnNumbers < _FirstColumnToUnpivot + _UnpivotColumnCount), | |
_UnpivotColumns, FILTER(_ColumnNumbers, _IncludeColumns), | |
_OtherColumns, FILTER(_ColumnNumbers, NOT(_IncludeColumns)), | |
_FullOuterJoin, CROSSJOIN( | |
CHOOSECOLS(table, _OtherColumns), | |
VSTACK(_AttributeLabel, TRANSPOSE(_ColumnsToUnpivot)), | |
TRUE | |
), | |
_WithValues, HSTACK( | |
_FullOuterJoin, | |
VSTACK(_ValueLabel, TOCOL(DROP(CHOOSECOLS(table, _UnpivotColumns), 1))) | |
), | |
_RemoveBlanks, IF( | |
OR(ISOMITTED(remove_blanks), remove_blanks), | |
FILTER(_WithValues, INDEX(_WithValues, , COLUMNS(_WithValues)) <> ""), | |
IF(_WithValues = "", "", _WithValues) | |
), | |
_ColumnOrder, LET( | |
n, COLUMNS(_RemoveBlanks), | |
s, SEQUENCE(1, n), | |
IFS( | |
s < _FirstColumnToUnpivot, s, | |
s < _FirstColumnToUnpivot + 2, s + n - _FirstColumnToUnpivot - 1, | |
TRUE, s - 2 | |
) | |
), | |
_Result, CHOOSECOLS(_RemoveBlanks, _ColumnOrder), | |
_Result | |
)); | |
/* | |
Name: Cross Join Tables (CROSSJOIN) | |
Description: Given two tables, returns the Cartesian product of rows from the tables. | |
Written By: Excel Robot (@ExcelRobot) | |
Category: Array | |
*/ | |
CROSSJOIN = LAMBDA(table1, table2, [has_headers], LET( | |
_HasHeaders, IF(ISOMITTED(has_headers), TRUE, has_headers), | |
_Data1, IF(_HasHeaders, DROP(table1,1), table1), | |
_Data2, IF(_HasHeaders, DROP(table2,1), table2), | |
_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(_HasHeaders, VSTACK(HSTACK(TAKE(table1, 1), TAKE(table2, 1)), _OuterJoinedData), _OuterJoinedData), | |
_WithHeader | |
)); |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment