├── AddColsToNestedTable ├── BucketingViaDimensionTableContainingFunctions ├── CombinerOnly1DistincValue ├── CreateTable ├── CreateTable2 ├── CreateTable3 ├── Dataverse Optionset and Logical to Display ├── Logical to Display SQL to M ├── Optionset Record ├── Optionset Record to Table ├── Optionset Records to Finished Table └── SQL Code for Logical to Display ├── DateListOfMonthStarts ├── FY ├── DateToFinancialYear ├── DateToFinancialYearEndDate └── DateToFinancialYearStartDate ├── FunctionAlternatives ├── Function.Compose ├── Function.InvokeFromRecord ├── Function.InvokePartialApply ├── FunctionsForFuture.md ├── List.Transform ├── List.TransformPartialApply └── ReadMe.md ├── GenerateOrders ├── HexToDec ├── LogicalToDisplay ├── Month3to1 ├── MonthlyRatios ├── MultipleCombineColumnsRecord ├── Old ├── ExampleOfAddingTablesSideways.pq ├── TakeTypesAndTryApply.pq ├── TakeTypesAndTryApply2.pq ├── fAddColOfRandNum.pq ├── fAddRandomColumn.pq └── fTakeTypesAndTryApply3.pq ├── PrefixColumnFunctions ├── PrefixAllColsExcept.pq └── PrefixCols.pq ├── ReplaceUsingTable ├── Replacer.ReplaceText_CI ├── ReplacerReplaceWholeText_CI ├── RunningTotal ├── SharepointFolderFromURL ├── Table.TransformOtherColumns ├── TableCombineColumnsRecord ├── TableListFunctions ├── TableFromRecordOfLists └── TableToRecordOfLists ├── TextCleaner ├── TimeZone ├── DateTimeZoneToDateTime_SwitchZone └── DateTimeZoneToDate_SwitchTimeZone ├── fAddRandomColumn.pq ├── fClusteredIndex.pq ├── fCombineJoins.pq ├── fCombineJoinsExpandCoalesce.pq ├── fDistinctColumns.pq ├── fNonAggPivotMultRows.pq ├── fNonAggPivotMultRows2.pq ├── fOrderFirstOccurrence.pq ├── fStableSortAndOrderFirstOccurrence.pq ├── fSyncTableTypeOfCol.pq ├── fTableComparerSort.pq ├── fTableSelectRowsWeb ├── fTakeTypesAndTryApply.pq └── fnSplitColsDateTime.pq /AddColsToNestedTable: -------------------------------------------------------------------------------- 1 | (table as table 2 | ,nestedTableCol as text 3 | ,optional outerCols as nullable list 4 | ,optional nestedCols as any)=> 5 | let 6 | outerCols2 = List.Buffer( 7 | if outerCols is null then List.RemoveItems(Table.ColumnNames(table),{nestedTableCol}) 8 | else outerCols), 9 | newCols = List.Buffer( 10 | let 11 | nestedColsIsNull = outerCols2, 12 | nestedColsIsFunction = List.Transform(outerCols2, nestedCols), 13 | nestedColsIsList = 14 | let 15 | zip = List.Zip({outerCols2,nestedCols}), 16 | coalesce = List.Transform(zip, each List.Last(List.RemoveNulls(_))) 17 | in 18 | coalesce 19 | in 20 | if nestedCols is null then nestedColsIsNull 21 | else if nestedCols is function then nestedColsIsFunction 22 | else if nestedCols is list then nestedColsIsList 23 | else error "nestedCols parameter must be ommited or of type: null, list or function" 24 | ), 25 | /* might be inefficient here but general use is for control tables 26 | where outer table is simple to evaluate and inner table is difficult to evaluate*/ 27 | outerColTypes = List.Buffer(List.Transform(outerCols2, each Type.TableColumn(Value.Type(table),_))), 28 | listsTogether = List.Buffer(Table.ToRecords(Table.FromColumns({outerCols2,newCols, outerColTypes},{"outerColName","newColName","outerColType"}))), 29 | next = Table.AddColumn( 30 | table, 31 | "TableToCombine", 32 | (outerRec as record)=>List.Accumulate( 33 | listsTogether, 34 | Record.Field(outerRec,nestedTableCol), 35 | (tab,ltRec)=>Table.AddColumn( 36 | tab, 37 | ltRec[newColName], 38 | each Record.Field(outerRec,ltRec[outerColName]), 39 | ltRec[outerColType])) 40 | ,type table) 41 | in 42 | next 43 | -------------------------------------------------------------------------------- /BucketingViaDimensionTableContainingFunctions: -------------------------------------------------------------------------------- 1 | (#"Lookup Table" as table 2 | ,#"Function Column" as text 3 | ,#"Result Column" as text) as function => 4 | let 5 | TableType = Value.Type(#"Lookup Table") 6 | ,FunctionTypeFromTableType = Type.TableColumn(TableType,#"Function Column") 7 | ,FunctionTypeFromFirstRow = Value.Type(Record.Field(#"Lookup Table"{0},#"Function Column")) 8 | ,FunctionTypeForParameters = 9 | if 10 | (try Type.FunctionParameters(FunctionTypeFromTableType))[HasError] //If function type is abstract... 11 | then 12 | FunctionTypeFromFirstRow 13 | else 14 | FunctionTypeFromTableType 15 | ,FunctionReturnType = Type.TableColumn(TableType,#"Result Column") 16 | ,FunctionParameters = Type.FunctionParameters(FunctionTypeForParameters) 17 | ,NumberOfRequiredParameters = Type.FunctionRequiredParameters(FunctionTypeForParameters) 18 | ,FunctionType = 19 | Type.ForFunction( 20 | [ReturnType = FunctionReturnType 21 | ,Parameters = FunctionParameters] 22 | ,NumberOfRequiredParameters 23 | ) 24 | in 25 | Function.From( 26 | FunctionType 27 | , 28 | (list as list)=> 29 | let 30 | //TypeChecking = List.Zip(list,Record.FieldValues(FunctionParameters)) 31 | //Value = Value.As(#"Lookup Value",FunctionParameterType), //Would be good to add type checking back in 32 | LookUpCol = Table.Column(#"Lookup Table",#"Function Column") as list, //List of functions 33 | ResultCol = Table.Column(#"Lookup Table",#"Result Column") as list, 34 | Position = List.PositionOf(LookUpCol,list,Occurrence.First,(Func as function,lst as list)=>Function.Invoke(Func,lst)=true), 35 | Position2 = if Position = -1 then error "Value not matching with any function" else Position, 36 | Result = ResultCol{Position2} 37 | in 38 | Result 39 | ) 40 | -------------------------------------------------------------------------------- /CombinerOnly1DistincValue: -------------------------------------------------------------------------------- 1 | Value.ReplaceType( 2 | each List.SingleOrDefault(List.Distinct(List.RemoveNulls(_))) 3 | ,Type.ForFunction([ReturnType = type text, Parameters = [_ = type list]], 1)) 4 | -------------------------------------------------------------------------------- /CreateTable: -------------------------------------------------------------------------------- 1 | (InputTable as table) as text => 2 | let 3 | Source = Table.Schema(InputTable), 4 | SortRows = Table.Sort(Source,{{"Position", Order.Ascending}}), 5 | SimplifyTypeNameRec = 6 | [#"Any.Type" = "any" 7 | ,#"Binary.Type" = "binary" 8 | ,#"Date.Type" = "date" 9 | ,#"DateTime.Type" = "datetime" 10 | ,#"DateTimeZone.Type" = "datetimezone" 11 | ,#"Duration.Type" = "duration" 12 | ,#"Function.Type" = "function" 13 | ,#"List.Type" = "list" 14 | ,#"Logical.Type" = "logical" 15 | ,#"None.Type" = "none" 16 | ,#"Null.Type" = "null" 17 | ,#"Number.Type" = "number" 18 | ,#"Record.Type" = "record" 19 | ,#"Table.Type" = "table" 20 | ,#"Text.Type" = "text" 21 | ,#"Time.Type" = "time" 22 | ,#"Type.Type" = "type"], 23 | SimplifyTypeNames = Table.TransformColumns(SortRows,{{"TypeName", each Record.FieldOrDefault(SimplifyTypeNameRec,_,_), type text}}), 24 | RemoveColumns = Table.SelectColumns(SimplifyTypeNames,{"Name", "TypeName","IsNullable"}), 25 | AddCustom = 26 | Table.AddColumn( 27 | RemoveColumns, 28 | "TypeNames", 29 | each 30 | Expression.Identifier([Name]) & " = " & (if [IsNullable] then "nullable " else "") & [TypeName]), 31 | TableTypeRec = 32 | "[" & Text.Combine(AddCustom[TypeNames], ", ") & "]" 33 | 34 | //Code above is based on a function by Chris Webb 35 | 36 | ,ValuesToConstant = Table.TransformColumns(InputTable,{},Expression.Constant) 37 | ,ValuesToConstLen = Table.TransformColumns(ValuesToConstant,{},Text.Length) 38 | ,MaxLengthEachCol = List.Buffer(List.Transform(Table.ToColumns(ValuesToConstLen),List.Max)) 39 | ,List = List.Transform(Table.ToRows(ValuesToConstant) 40 | ,(RowAsList)=> 41 | let 42 | Zip = List.Zip({RowAsList,MaxLengthEachCol}) 43 | ,PadOut = List.Transform(Zip,each Function.Invoke(Text.PadEnd,_)) 44 | ,CombineValues = "{"&Text.Combine(PadOut,",")&"}" 45 | in 46 | CombineValues) 47 | ,Body = "{"&Text.Combine(List,"#(lf),")&"}" 48 | ,Together = "#table(type table" 49 | & TableTypeRec 50 | & ",#(lf)" 51 | & Body 52 | & "#(lf))" 53 | in 54 | 55 | Together 56 | -------------------------------------------------------------------------------- /CreateTable2: -------------------------------------------------------------------------------- 1 | (inputTable as table) as text => 2 | let 3 | source = Table.Schema(inputTable) 4 | ,sortRows = Table.Sort(source,{{"Position", Order.Ascending}}) 5 | ,simplifyTypeNameRec = 6 | [#"Any.Type" = "any" 7 | ,#"Binary.Type" = "binary" 8 | ,#"Date.Type" = "date" 9 | ,#"DateTime.Type" = "datetime" 10 | ,#"DateTimeZone.Type" = "datetimezone" 11 | ,#"Duration.Type" = "duration" 12 | ,#"Function.Type" = "function" 13 | ,#"List.Type" = "list" 14 | ,#"Logical.Type" = "logical" 15 | ,#"None.Type" = "none" 16 | ,#"Null.Type" = "null" 17 | ,#"Number.Type" = "number" 18 | ,#"Record.Type" = "record" 19 | ,#"Table.Type" = "table" 20 | ,#"Text.Type" = "text" 21 | ,#"Time.Type" = "time" 22 | ,#"Type.Type" = "type"] 23 | ,simplifyTypeNames = Table.TransformColumns(sortRows,{{"TypeName", each Record.FieldOrDefault(simplifyTypeNameRec,_,_)}}) 24 | ,selectColumns = Table.SelectColumns(simplifyTypeNames,{"Name", "TypeName","IsNullable"}) 25 | ,addColOfTypeNames = 26 | Table.AddColumn( 27 | selectColumns 28 | ,"TypeNames" 29 | ,each 30 | Expression.Identifier([Name]) 31 | & " = " 32 | & (if [IsNullable] then "nullable " else "") 33 | & [TypeName] 34 | ) 35 | ,tableTypeRec = "[" & Text.Combine(addColOfTypeNames[TypeNames], ", ") & "]" 36 | 37 | //Code above is based on a function by Chris Webb 38 | 39 | ,tableOfExpressions = Table.TransformColumns(inputTable,{},Expression.Constant) 40 | ,listOfCols = Table.ToColumns(tableOfExpressions) 41 | ,listOfColsOfPaddedText = 42 | List.Transform( 43 | listOfCols 44 | ,(col as list)=> 45 | let 46 | buf = List.Buffer(col), 47 | maxTextLength = List.Max(List.Transform(buf,Text.Length)), 48 | paddedText = List.Transform(buf,each Text.PadEnd(_,maxTextLength)) 49 | in 50 | paddedText 51 | ) 52 | ,listOfRowsOfPaddedText = List.Zip(listOfColsOfPaddedText) 53 | ,bodyAsList = List.Transform(listOfRowsOfPaddedText, (row as list)=> "{"&Text.Combine(row,",")&"}") 54 | ,bodyAsText = "{"&Text.Combine(bodyAsList,"#(lf),")&"#(lf)}" 55 | ,together = "#table(type table " 56 | & tableTypeRec 57 | & ",#(lf)" 58 | & bodyAsText 59 | & ")" 60 | in 61 | together 62 | -------------------------------------------------------------------------------- /CreateTable3: -------------------------------------------------------------------------------- 1 | (inputTable as table, optional #"table type is vertical?" as nullable logical) as text => 2 | let 3 | vert = #"table type is vertical?" ?? false 4 | ,source = Table.Schema(inputTable) 5 | ,sortRows = Table.Sort(source,{{"Position", Order.Ascending}}) 6 | ,simplifyTypeNameRec = 7 | [#"Any.Type" = "any" 8 | ,#"Binary.Type" = "binary" 9 | ,#"Date.Type" = "date" 10 | ,#"DateTime.Type" = "datetime" 11 | ,#"DateTimeZone.Type" = "datetimezone" 12 | ,#"Duration.Type" = "duration" 13 | ,#"Function.Type" = "function" 14 | ,#"List.Type" = "list" 15 | ,#"Logical.Type" = "logical" 16 | ,#"None.Type" = "none" 17 | ,#"Null.Type" = "null" 18 | ,#"Number.Type" = "number" 19 | ,#"Record.Type" = "record" 20 | ,#"Table.Type" = "table" 21 | ,#"Text.Type" = "text" 22 | ,#"Time.Type" = "time" 23 | ,#"Type.Type" = "type"] 24 | ,simplifyTypeNames = Table.TransformColumns(sortRows,{{"TypeName", each Record.FieldOrDefault(simplifyTypeNameRec,_,_)}}) 25 | ,selectColumns = Table.SelectColumns(simplifyTypeNames,{"Name", "TypeName","IsNullable"}) 26 | ,addColOfTypeNames = 27 | Table.AddColumn( 28 | selectColumns 29 | ,"TypeNames" 30 | ,each 31 | Expression.Identifier([Name]) 32 | & " = " 33 | & (if [IsNullable] then "nullable " else "") 34 | & [TypeName] 35 | ) 36 | ,tableTypeRec = "[" & Text.Combine(addColOfTypeNames[TypeNames], if vert then "#(lf)," else ", ") & "]" 37 | 38 | //Code above is based on a function by Chris Webb 39 | 40 | ,tableOfExpressions = Table.TransformColumns(inputTable,{},Expression.Constant) 41 | ,listOfCols = Table.ToColumns(tableOfExpressions) 42 | ,listOfColsOfPaddedText = 43 | List.Transform( 44 | listOfCols 45 | ,(col as list)=> 46 | let 47 | buf = List.Buffer(col), 48 | maxTextLength = List.Max(List.Transform(buf,Text.Length)), 49 | paddedText = List.Transform(buf,each Text.PadEnd(_,maxTextLength)) 50 | in 51 | paddedText 52 | ) 53 | ,listOfRowsOfPaddedText = List.Zip(listOfColsOfPaddedText) 54 | ,bodyAsList = List.Transform(listOfRowsOfPaddedText, (row as list)=> "{"&Text.Combine(row,",")&"}") 55 | ,bodyAsText = "{"&Text.Combine(bodyAsList,"#(lf),")&"#(lf)}" 56 | ,together = 57 | "#table(type table" 58 | & (if vert then "#(lf)" else "") 59 | & tableTypeRec 60 | & ",#(lf)" 61 | & bodyAsText 62 | & ")" 63 | in 64 | together 65 | -------------------------------------------------------------------------------- /Dataverse Optionset and Logical to Display/Logical to Display SQL to M: -------------------------------------------------------------------------------- 1 | let 2 | Source = SQL, 3 | #"Added custom 5" = Table.AddColumn(Source, "Column Display Name if change", each if [Column Logical Name] = [Column Display Name] then null else [Column Display Name], type text), 4 | #"Added custom" = Table.AddColumn(#"Added custom 5", "Column Logical Name With Name Suffix", each _[Column Logical Name]&"name", type nullable text), 5 | #"Self Join" = Table.NestedJoin(#"Added custom",{"Table Logical Name","Column Logical Name With Name Suffix"},#"Added custom",{"Table Logical Name","Column Logical Name"},"Text Col",JoinKind.LeftOuter), 6 | #"Expanded Text Col 1" = Table.ExpandTableColumn(#"Self Join", "Text Col", {"Column Display Name if change"}, {"Column Display Name of Text Version"}), 7 | #"Removed columns 3" = Table.RemoveColumns(#"Expanded Text Col 1", {"Column Logical Name With Name Suffix"}), 8 | #"Sorted rows 1" = Table.Sort(#"Removed columns 3", {{"Column Id", Order.Ascending}}), 9 | #"Added custom 2" = Table.AddColumn(#"Sorted rows 1", "Make Unique", each [Column Display Name of Text Version] & " " & Record.FieldOrDefault([#"uniqueidentifier"="GUID",#"int"="ID",#"bit"="True/False"],[Column Type Name]), type nullable text), 10 | #"Removed columns 1" = Table.RemoveColumns(#"Added custom 2", {"Column Display Name of Text Version"}), 11 | #"Added custom 6" = Table.AddColumn(#"Removed columns 1", "Status Columns", each Record.FieldOrDefault([statecode = "Status ID",statecodename = "Status",statuscode = "Status Reason ID",statuscodename = "Status Reason"],[Column Logical Name]), type nullable text), 12 | #"Added custom 3" = Table.AddColumn(#"Added custom 6", "Project ID Names", each if [Is First Primary Key] = true then [Table Display Name] & " GUID" else if [Column Display Name] = "Name" then [Table Display Name] else null, type nullable text), 13 | #"Renamed columns" = Table.RenameColumns(#"Added custom 3", {{"Column Display Name", "Column Display Name Original"}}), 14 | #"Added custom 1" = Table.AddColumn(#"Renamed columns", "Column Display Name", each [Project ID Names] ?? [Status Columns] ?? [Make Unique] ?? [Column Display Name if change], type nullable text), 15 | #"Removed columns 2" = Table.RemoveColumns(#"Added custom 1", {"Column Display Name if change", "Make Unique", "Status Columns", "Project ID Names", "Is First Primary Key"}), 16 | #"Reordered columns 2" = Table.ReorderColumns(#"Removed columns 2", {"Table Logical Name", "Table Display Name", "Column Logical Name", "Column Display Name Original", "Column Display Name", "Column Id", "Column Type Name", "Column Max Length"}), 17 | ColumnType = 18 | type nullable table 19 | [ #"Table Logical Name" = nullable text 20 | , #"Table Display Name" = nullable text 21 | , #"Column Logical Name" = nullable text 22 | , #"Column Display Name Original" = nullable text 23 | , #"Column Display Name" = nullable text 24 | , #"Column Id" = nullable Int64.Type 25 | , #"Column Type Name" = nullable text 26 | , #"Column Max Length" = nullable Int64.Type 27 | ], 28 | #"Grouped rows" = Table.Group(#"Reordered columns 2", {"Table Logical Name", "Column Display Name"}, {{"Column Display Name Count", each Table.RowCount(_), Int64.Type}, {"Table", each _, ColumnType}}), 29 | #"Expanded Table" = Table.ExpandTableColumn(#"Grouped rows", "Table", {"Table Display Name", "Column Logical Name", "Column Display Name Original", "Column Id", "Column Type Name", "Column Max Length"}, {"Table Display Name", "Column Logical Name", "Column Display Name Original", "Column Id", "Column Type Name", "Column Max Length"}), 30 | #"Reordered columns" = Table.ReorderColumns(#"Expanded Table", {"Table Logical Name", "Table Display Name", "Column Logical Name", "Column Display Name Original", "Column Display Name", "Column Id", "Column Type Name", "Column Max Length","Column Display Name Count"}), 31 | #"Added custom 4" = Table.AddColumn(#"Reordered columns", "Custom", each let val = [Column Display Name] in if val = null then null else if [Column Display Name Count] > 1 then val & " (" & [Column Logical Name] & ")" else val, type nullable text), 32 | #"Reordered columns 1" = Table.ReorderColumns(#"Added custom 4", {"Custom", "Column Display Name"}), 33 | #"Removed columns" = Table.RemoveColumns(#"Reordered columns 1", {"Column Display Name", "Column Display Name Count"}), 34 | #"Renamed columns 1" = Table.RenameColumns(#"Removed columns", {{"Custom", "Column Display Name"}}), 35 | #"Sorted rows" = Table.Sort(#"Renamed columns 1", {{"Table Logical Name", Order.Ascending}, {"Column Id", Order.Ascending}}) 36 | in 37 | #"Sorted rows" 38 | -------------------------------------------------------------------------------- /Dataverse Optionset and Logical to Display/Optionset Record: -------------------------------------------------------------------------------- 1 | Json.Document(Web.Contents("https://servername.crm6.dynamics.com/api/data/v9.1/stringmaps?$filter=objecttypecode eq 'table name'")) 2 | -------------------------------------------------------------------------------- /Dataverse Optionset and Logical to Display/Optionset Record to Table: -------------------------------------------------------------------------------- 1 | (#"Optionset Example Value" as record) as table => 2 | let 3 | Source = #"Optionset Example Value", 4 | Custom = Source[value], 5 | #"Custom 1" = Table.FromRecords(Custom,{"objecttypecode","attributename","value","displayorder"},MissingField.UseNull), 6 | #"Changed column type" = Table.TransformColumnTypes(#"Custom 1", {{"attributename", type text}, {"value", type text}, {"displayorder", type text}, {"objecttypecode", type text}}) 7 | in 8 | #"Changed column type" 9 | -------------------------------------------------------------------------------- /Dataverse Optionset and Logical to Display/Optionset Records to Finished Table: -------------------------------------------------------------------------------- 1 | let 2 | Source = ListOfTableMetadata, 3 | Transform = List.Transform(Source,TransformToTable), 4 | Append = Table.Combine(Transform), 5 | #"Changed column type" = Table.TransformColumnTypes(Append, {{"displayorder", Int64.Type}}), 6 | #"Renamed columns" = Table.RenameColumns(#"Changed column type", {{"objecttypecode", "Table Logical Name"},{"attributename","Column Logical Name"},{"value","Value"},{"displayorder","Order"}}), 7 | #"Merged queries" = Table.NestedJoin(#"Renamed columns", {"Table Logical Name","Column Logical Name"}, #"Logical and Display Names", {"Table Logical Name","Column Logical Name"}, "Logical and Display Names", JoinKind.LeftOuter), 8 | #"Expanded Logical and Display Names" = Table.ExpandTableColumn(#"Merged queries", "Logical and Display Names", {"Column Display Name"}, {"Column Display Name"}), 9 | #"Reordered columns" = Table.ReorderColumns(#"Expanded Logical and Display Names", {"Table Logical Name", "Column Logical Name", "Column Display Name", "Value", "Order"}), 10 | #"Sorted rows" = Table.Sort(#"Reordered columns", {{"Table Logical Name", Order.Ascending}, {"Column Logical Name", Order.Ascending}, {"Order", Order.Ascending}}) 11 | in 12 | #"Sorted rows" 13 | -------------------------------------------------------------------------------- /Dataverse Optionset and Logical to Display/SQL Code for Logical to Display: -------------------------------------------------------------------------------- 1 | SELECT 2 | tb.name as 'Table Logical Name' 3 | ,tb.DisplayName as 'Table Display Name' 4 | ,c.name as 'Column Logical Name' 5 | ,TRIM(c.DisplayName) as 'Column Display Name' 6 | ,c.column_id as 'Column Id' 7 | ,ty.name as 'Column Type Name' 8 | ,c.max_length as 'Column Max Length' 9 | ,iic.is_first_primary_key as 'Is First Primary Key' 10 | FROM 11 | sys.tables as tb 12 | INNER JOIN 13 | sys.columns as c 14 | ON tb.object_id = c.object_id 15 | INNER JOIN 16 | sys.types as ty 17 | ON c.system_type_id = ty.system_type_id 18 | AND 19 | c.user_type_id = ty.user_type_id 20 | LEFT JOIN 21 | ( 22 | SELECT 23 | i.is_primary_key as is_first_primary_key 24 | ,ic.object_id 25 | ,ic.column_id 26 | FROM 27 | sys.index_columns ic 28 | INNER JOIN 29 | sys.indexes i 30 | ON 31 | i.object_id = ic.object_id 32 | AND 33 | i.index_id = ic.index_id 34 | WHERE 35 | i.is_primary_key = 1 36 | AND 37 | ic.key_ordinal = 1 38 | 39 | ) as iic 40 | ON 41 | c.object_id = iic.object_id 42 | AND 43 | c.column_id = iic.column_id 44 | WHERE 45 | tb.name IN 46 | ('tablename1' 47 | ,'tablename2' 48 | ) 49 | -------------------------------------------------------------------------------- /DateListOfMonthStarts: -------------------------------------------------------------------------------- 1 | (start as nullable date 2 | ,end as nullable date)=> 3 | let 4 | datesAsInt = 5 | let 6 | DateToInt = each Date.Year(_)*12 7 | + Date.Month(_)-1 8 | in 9 | {DateToInt(start)..DateToInt(end)} 10 | ,datesAsDate = List.Transform(datesAsInt 11 | ,each #date(Number.IntegerDivide(_,12) 12 | ,Number.Mod(_,12)+1 13 | ,1)) 14 | ,checkForNulls = if start = null 15 | or end = null 16 | then {} 17 | else datesAsDate 18 | ,replaceType = Value.ReplaceType(checkForNulls, type {date}) 19 | in 20 | replaceType 21 | -------------------------------------------------------------------------------- /FY/DateToFinancialYear: -------------------------------------------------------------------------------- 1 | (date as nullable date) as nullable number=> 2 | let 3 | year = Date.Year(date), 4 | finYear = if Date.Month(date) > 6 5 | then year+1 6 | else year 7 | in 8 | if date is null then null else finYear 9 | -------------------------------------------------------------------------------- /FY/DateToFinancialYearEndDate: -------------------------------------------------------------------------------- 1 | (date as nullable date) as nullable date=>if date is null then null else #date(DateToFinancialYear(date),6,30) 2 | -------------------------------------------------------------------------------- /FY/DateToFinancialYearStartDate: -------------------------------------------------------------------------------- 1 | (date as nullable date) as nullable date=>if date is null then null else #date(DateToFinancialYear(date)-1,7,1) 2 | -------------------------------------------------------------------------------- /FunctionAlternatives/Function.Compose: -------------------------------------------------------------------------------- 1 | //Based on Curt Hagenlochers code at 2 | //https://social.technet.microsoft.com/Forums/en-US/10b20f9f-488b-4626-868f-35eedcbfab87/whats-functionfrom-for?forum=powerquery 3 | //But uses the function return type of the outer function 4 | 5 | (innerFunction as function, outerFunction as function) as function => 6 | let 7 | innerFunctionType = Value.Type(innerFunction) 8 | ,outerFunctionType = Value.Type(outerFunction) 9 | ,resultantFunctionType = Type.ForFunction( 10 | [ReturnType = Type.FunctionReturn(outerFunctionType) 11 | ,Parameters = Type.FunctionParameters(innerFunctionType)] 12 | ,Type.FunctionRequiredParameters(innerFunctionType)) 13 | ,resultantFunction = Function.From( 14 | resultantFunctionType 15 | ,(list) => outerFunction(Function.Invoke(innerFunction, list))) 16 | in 17 | resultantFunction 18 | -------------------------------------------------------------------------------- /FunctionAlternatives/Function.InvokeFromRecord: -------------------------------------------------------------------------------- 1 | (function as function)=> 2 | let 3 | funcType = Value.Type(function) 4 | ,InvokedFunction = Value.ReplaceType( 5 | (record as record)=> 6 | Function.Invoke( 7 | function 8 | ,Record.FieldValues( 9 | Record.SelectFields( 10 | record 11 | ,Record.FieldNames(Type.FunctionParameters(funcType)) 12 | ,MissingField.UseNull))) 13 | ,Type.ForFunction([ReturnType=Type.FunctionReturn(funcType), Parameters=[record = type record]],1)) 14 | in 15 | InvokedFunction 16 | -------------------------------------------------------------------------------- /FunctionAlternatives/Function.InvokePartialApply: -------------------------------------------------------------------------------- 1 | (function as function)=> 2 | Value.ReplaceType( 3 | (args as list)=> 4 | Function.Invoke( 5 | function 6 | ,args) 7 | ,Type.ForFunction( 8 | [ReturnType=Type.FunctionReturn(Value.Type(function)) 9 | ,Parameters=[args = type list] 10 | ] 11 | ,1) 12 | ) 13 | -------------------------------------------------------------------------------- /FunctionAlternatives/FunctionsForFuture.md: -------------------------------------------------------------------------------- 1 | List.Accumulate, Function.PartialApply 2 | -------------------------------------------------------------------------------- /FunctionAlternatives/List.Transform: -------------------------------------------------------------------------------- 1 | (list as list, transform as function)=> 2 | let 3 | listTransform = List.Transform(list, transform), 4 | listType = type {Type.FunctionReturn(Value.Type(transform))} 5 | in 6 | Value.ReplaceType(listTransform,listType) 7 | -------------------------------------------------------------------------------- /FunctionAlternatives/List.TransformPartialApply: -------------------------------------------------------------------------------- 1 | (transform as function)=> 2 | let 3 | listType = type {Type.FunctionReturn(Value.Type(transform))} 4 | ,returnType = Type.ForFunction([ReturnType = listType 5 | ,Parameters = [args = type list] 6 | ] 7 | ,1) 8 | in 9 | Value.ReplaceType((list as list)=> 10 | Value.ReplaceType( 11 | List.Transform(list,transform) 12 | ,listType) 13 | ,returnType) 14 | -------------------------------------------------------------------------------- /FunctionAlternatives/ReadMe.md: -------------------------------------------------------------------------------- 1 | These functions are mostly versions of functions that have been created by Microsoft. These functions however, help keep the function type return types that are so easily lost. One of the pratical outcomes of using these functions in your queries is that your table columns are less likely to change to type any. 2 | -------------------------------------------------------------------------------- /GenerateOrders: -------------------------------------------------------------------------------- 1 | /* 2 | This for small tables such as dimension table as Table.Buffer is used 3 | Generates order based on first Occurrence 4 | 2 versions presented here 5 | */ 6 | (table as table 7 | ,optional columns as nullable list 8 | ,optional ignorecols as nullable logical)=> 9 | let 10 | tableBuffered = Table.Buffer(table), 11 | cols = (if ignorecols = true 12 | then List.RemoveItems(Table.ColumnNames(tableBuffered),columns) 13 | else columns) 14 | ?? Table.ColumnNames(tableBuffered), 15 | addColumns = List.Accumulate( 16 | cols, 17 | tableBuffered, 18 | (x,y)=>Table.AddColumn( 19 | x, 20 | y&" Order", 21 | (rec)=>List.PositionOf( 22 | Table.ToColumns(Table.Group(tableBuffered,{y},{},GroupKind.Global,Comparer.OrdinalIgnoreCase)){0}, 23 | Record.Field(rec,y), 24 | Occurrence.First, 25 | Comparer.OrdinalIgnoreCase), 26 | type nullable Int64.Type)) 27 | in 28 | addColumns 29 | 30 | //In this version Table.Group would have probably been a bit quicker 31 | //Also could do indexing from 1, so blanks and 0's can't be confused in your DAX 32 | (table as table,columns as list)=> 33 | let 34 | 35 | tableBuffered = Table.Buffer(table), 36 | addColumns = List.Accumulate( 37 | columns, 38 | tableBuffered, 39 | (x,y)=> 40 | let 41 | lst = List.Buffer(List.Distinct(Table.Column(tableBuffered,y))) 42 | in 43 | Table.AddColumn( 44 | x, 45 | y&" Order", 46 | (rec)=>List.PositionOf( 47 | lst, 48 | Record.Field(rec,y), 49 | Occurrence.First), 50 | type nullable Int64.Type) 51 | ) 52 | 53 | in 54 | addColumns 55 | -------------------------------------------------------------------------------- /HexToDec: -------------------------------------------------------------------------------- 1 | let 2 | Source = "AF67", 3 | List = {"0".."9"}&{"A".."F"}, 4 | Next = List.Transform(Text.ToList(Text.Upper(Source)),each List.PositionOf(List,_,Occurrence.First)), 5 | RevBuf = List.Buffer(List.Reverse(Next)), 6 | RevPosPowers = List.Transform(List.Positions(RevBuf),each Number.Power(16,_)), 7 | Next2 = List.Sum(List.Transform(List.Zip({RevBuf,RevPosPowers}),List.Product)) 8 | in 9 | Next2 10 | //Make it function, better step names and faster by using Character.ToNumber with if 11 | -------------------------------------------------------------------------------- /LogicalToDisplay: -------------------------------------------------------------------------------- 1 | /api/data/v9.1/EntityDefinitions(LogicalName='activitypointer')/Attributes?$select=LogicalName,DisplayName 2 | -------------------------------------------------------------------------------- /Month3to1: -------------------------------------------------------------------------------- 1 | let 2 | Source = Table.Combine( 3 | List.Transform( 4 | {1..12}, 5 | each Table.FromValue(Date.ToText(#date(2000,_,1),"MMM")))), 6 | #"Renamed Columns" = Table.RenameColumns(Source,{{"Value", "Month 3"}}), 7 | #"Added Custom" = Table.AddColumn(#"Renamed Columns", "Month 1", each Text.Start([Month 3],1), type text), 8 | #"Added Index" = Table.AddIndexColumn(#"Added Custom", "Index", 0, 1, Int64.Type), 9 | #"Grouped Rows" = Table.Group(#"Added Index", {"Month 1"}, {{"Table", each Table.AddIndexColumn(_,"WS",0,1,Int64.Type)}}), 10 | Custom1 = Table.Combine(#"Grouped Rows"[Table]), 11 | #"Sorted Rows" = Table.Sort(Custom1,{{"Index", Order.Ascending}}), 12 | #"Removed Columns" = Table.RemoveColumns(#"Sorted Rows",{"Index"}), 13 | #"Added Custom1" = Table.AddColumn(#"Removed Columns", "Custom", each [Month 1]&Text.Repeat(Character.FromNumber(8203),[WS]), type text), 14 | #"Removed Columns1" = Table.RemoveColumns(#"Added Custom1",{"Month 1", "WS"}), 15 | #"Renamed Columns1" = Table.RenameColumns(#"Removed Columns1",{{"Custom", "Month 1"}}), 16 | #"Add Key for Joining" = Table.AddKey(#"Renamed Columns1", {"Month 3"}, true) 17 | in 18 | #"Add Key for Joining" 19 | 20 | 21 | /* 22 | Month Name 1 Letter = 23 | SWITCH([Month Name Short] 24 | ,"Jan","J" 25 | ,"Feb","F" 26 | ,"Mar","M" 27 | ,"Apr","A" 28 | ,"May","M"&REPT(UNICHAR(8203),1) 29 | ,"Jun","J"&REPT(UNICHAR(8203),1) 30 | ,"Jul","J"&REPT(UNICHAR(8203),2) 31 | ,"Aug","A"&REPT(UNICHAR(8203),1) 32 | ,"Sep","S" 33 | ,"Oct","O" 34 | ,"Nov","N" 35 | ,"Dec","D") 36 | */ 37 | 38 | -------------------------------------------------------------------------------- /MonthlyRatios: -------------------------------------------------------------------------------- 1 | (start as date 2 | ,end as date)=> 3 | let 4 | datesAsInt = 5 | let 6 | DateToInt = each Date.Year(_)*12 7 | + Date.Month(_)-1 8 | in 9 | {DateToInt(start)..DateToInt(end)} 10 | ,datesAsDate = 11 | List.Buffer( 12 | Value.ReplaceType( 13 | List.Transform( 14 | datesAsInt 15 | ,each #date( 16 | Number.RoundDown(_/12) 17 | ,Number.Mod(_,12)+1 18 | ,1)) 19 | ,type {date})) 20 | ,FracOfMonthToEnd = (date as date) => Date.Day(date)/Date.DaysInMonth(date) 21 | ,FracOfMonthToDayBeforeStart = (date as date) => (Date.Day(date)-1)/Date.DaysInMonth(date) 22 | ,noOfDates = List.Count(datesAsDate) 23 | ,fracsOfMonths = Value.ReplaceType( 24 | if start>end then error "end date before start date" 25 | else if noOfDates = 1 then {FracOfMonthToEnd(end)-FracOfMonthToDayBeforeStart(start)} 26 | else {1-FracOfMonthToDayBeforeStart(start)} 27 | &List.Repeat({1},noOfDates-2) 28 | &{FracOfMonthToEnd(end)} 29 | ,type {Percentage.Type}) 30 | ,datesInTable = Table.FromColumns({datesAsDate, fracsOfMonths},{"Date","Fraction"}) 31 | ,addKey = Table.AddKey(datesInTable,{"Date"},true) 32 | in 33 | addKey 34 | -------------------------------------------------------------------------------- /MultipleCombineColumnsRecord: -------------------------------------------------------------------------------- 1 | 2 | /* Example Control Table 3 | #table(type table [_Name = nullable text, Value = nullable number, Flag = nullable text], 4 | {{"Temperature Min" ,"Temperature Min" ,"Temperature Min Flag" } 5 | ,{"Temperature Mean" ,"Temperature Mean" ,"Temperature Mean Flag" } 6 | ,{"Temperature Max" ,"Temperature Max" ,"Temperature Max Flag" } 7 | ,{"Precipitation Liquid","Precipitation Liquid","Precipitation Liquid Flag"} 8 | ,{"Precipitation Solid" ,"Precipitation Solid" ,"Precipitation Solid Flag" } 9 | }) 10 | */ 11 | 12 | (table as table, controlTable as table)=> 13 | let 14 | RecType = Type.TableRow(Value.Type(Table.RemoveColumns(controlTable,"_Name"))), 15 | RecFieldNames = List.Buffer(Record.FieldNames(Type.RecordFields(RecType))), 16 | ControlVals = List.Transform(Table.ToRows(controlTable),each [ColName = _{0}, OriginalRecFieldNames = List.Skip(_)]), 17 | Next = List.Accumulate( 18 | ControlVals, 19 | table, 20 | (tab,cv)=> 21 | let 22 | RenameCols = Table.RenameColumns(tab,List.Zip({cv[OriginalRecFieldNames],RecFieldNames})), 23 | CombineCols = Table.CombineColumnsToRecord(RenameCols,cv[ColName],RecFieldNames) 24 | in 25 | CombineCols 26 | ) 27 | in 28 | Next 29 | -------------------------------------------------------------------------------- /Old/ExampleOfAddingTablesSideways.pq: -------------------------------------------------------------------------------- 1 | let 2 | ListOfTables = {Table1, Table2, Table3} 3 | ,ConcatLists = (func as function) => List.Accumulate(ListOfTables,{},(old, new) => old & func(new)) 4 | ,TableNames = ConcatLists(Table.ColumnNames) 5 | ,TableData = ConcatLists(Table.ToColumns) 6 | ,Final = Table.FromColumns(TableData, TableNames) 7 | in 8 | Final 9 | -------------------------------------------------------------------------------- /Old/TakeTypesAndTryApply.pq: -------------------------------------------------------------------------------- 1 | //You would normally do something like: Value.ReplaceType(#"Replaced Value", Value.Type(Source)) 2 | //But this tries each column out as columns may be missing. 3 | 4 | let ChangeTypes = (tblToAlter as table, tblGet as table) => 5 | 6 | let 7 | smallschemaGet = Table.SelectColumns(Table.Schema(tblGet),{"Name","TypeName"}) 8 | ,nameandtypeGet = Table.TransformColumns(smallschemaGet,{{"TypeName", each Expression.Evaluate(_,#shared), type type}}) 9 | ,Convert = List.Accumulate(Table.ToRows(nameandtypeGet) 10 | ,tblToAlter 11 | ,(old, new) => try Table.TransformColumnTypes(old,new) otherwise old) 12 | in 13 | Convert 14 | 15 | in ChangeTypes 16 | -------------------------------------------------------------------------------- /Old/TakeTypesAndTryApply2.pq: -------------------------------------------------------------------------------- 1 | //Another way of doing TakeTypesAndTryApply 2 | 3 | let ChangeTypes = (tblToAlter as table, tblGet as table) => 4 | 5 | let 6 | colnamesAlter = List.Buffer(Table.ColumnNames(tblToAlter)) 7 | ,smallschemaGet = Table.SelectColumns(Table.Schema(tblGet),{"Name","TypeName"}) 8 | ,nameandtypeGet = Table.TransformColumns(smallschemaGet,{{"TypeName", each Expression.Evaluate(_,#shared), type type}}) 9 | ,#"Filtered Rows" = Table.SelectRows(nameandtypeGet, each List.Contains(colnamesAlter,_[Name])) 10 | ,Convert = Table.TransformColumnTypes(tblToAlter,Table.ToRows(#"Filtered Rows")) 11 | in 12 | Convert 13 | 14 | in ChangeTypes 15 | -------------------------------------------------------------------------------- /Old/fAddColOfRandNum.pq: -------------------------------------------------------------------------------- 1 | //Adds a column of random numbers 2 | (Table as table, RandColName as text) => 3 | let 4 | ListTable = Table.ToColumns(Table) 5 | ,ColNames = Table.ColumnNames(Table) 6 | ,NumRows = Table.RowCount(Table) 7 | ,RandList = Value.ReplaceType(List.Random(NumRows),type {number}) 8 | ,Together = Table.FromColumns(ListTable&{RandList},ColNames&{RandColName}) 9 | in 10 | Together 11 | -------------------------------------------------------------------------------- /Old/fAddRandomColumn.pq: -------------------------------------------------------------------------------- 1 | /*Add column of random numbers between 0 and 1: 2 | fAddRandomColumn(Source,"Random Numbers")*/ 3 | /*Add column of random percentages between 0% and 100%: 4 | fAddRandomColumn(Source,"Random Numbers", Percentage.Type)*/ 5 | /*Retrieve random item from list: 6 | fAddRandomColumn(Source,"RandItems", {each ListOfItems{Number.RoundDown(_*List.Count(ListOfItems))}, type text})*/ 7 | 8 | (Table as table, RandColName as text, optional TransformAndTypeCriteria as any) => 9 | let 10 | List = List.Buffer( 11 | if not (TransformAndTypeCriteria is list) then {TransformAndTypeCriteria} else 12 | if List.Count(TransformAndTypeCriteria)<=2 then TransformAndTypeCriteria else 13 | error "Invalid Criteria (Too many items)" ) 14 | ,Transform = if List{0} is null 15 | or List{0} is type then null else 16 | if List{0} is function then List{0} else 17 | error "Invalid Criteria (Tranform)" 18 | ,ListLast = List.Last(List) 19 | ,Type = if ListLast is null 20 | or ListLast is function then type number else 21 | if ListLast is type then ListLast else 22 | error "Invalid Criteria (Type)" 23 | ,ListTable = Table.ToColumns(Table) 24 | ,ColNames = Table.ColumnNames(Table) 25 | ,NumRows = Table.RowCount(Table) 26 | ,ListRand = List.Random(NumRows) 27 | ,ListRandTrans = if Transform = null then ListRand else List.Transform(ListRand,Transform) 28 | ,ListRandTransType = Value.ReplaceType(ListRandTrans, type {Type}) 29 | ,Together = Table.FromColumns(ListTable&{ListRandTransType},ColNames&{RandColName}) 30 | in 31 | Together 32 | -------------------------------------------------------------------------------- /Old/fTakeTypesAndTryApply3.pq: -------------------------------------------------------------------------------- 1 | let ChangeTypes = (tblGet as table, tblToAlter as table) => 2 | 3 | let 4 | colNames = List.Intersect({Table.ColumnNames(tblGet),Table.ColumnNames(tblToAlter)}) 5 | ,colTypes = List.Transform(colNames,each Type.TableColumn(Value.Type(tblGet),_)) 6 | ,colNamesTypes = List.Zip({colNames,colTypes}) 7 | ,Convert = Table.TransformColumnTypes(tblToAlter,colNamesTypes) 8 | in 9 | Convert 10 | 11 | in 12 | ChangeTypes 13 | -------------------------------------------------------------------------------- /PrefixColumnFunctions/PrefixAllColsExcept.pq: -------------------------------------------------------------------------------- 1 | (Table as table, Prefix as text, optional IgnoreCols as any) => 2 | let 3 | listIgnoreCols = if IgnoreCols is list then IgnoreCols else 4 | if IgnoreCols is text then {IgnoreCols} else 5 | if IgnoreCols is null then {} else 6 | error "Invalid IgnoreCols Argument" 7 | ,ColNamesToChange = List.RemoveItems(Table.ColumnNames(Table), listIgnoreCols) 8 | ,ListOfLists = List.Transform(ColNamesToChange, each {_,Prefix&_}) 9 | ,RenameCols = Table.RenameColumns(Table,ListOfLists) 10 | in 11 | RenameCols 12 | -------------------------------------------------------------------------------- /PrefixColumnFunctions/PrefixCols.pq: -------------------------------------------------------------------------------- 1 | (Table as table, Prefix as text, Cols as list) => 2 | let 3 | ListOfLists = List.Transform(Cols, each {_,Prefix&_}) 4 | ,RenameCols = Table.RenameColumns(Table,ListOfLists) 5 | in 6 | RenameCols 7 | -------------------------------------------------------------------------------- /ReplaceUsingTable: -------------------------------------------------------------------------------- 1 | (Table as table)=> 2 | let 3 | Rec = Record.FromTable(Table.FromColumns(List.FirstN(Table.ToColumns(Table),2),{"Name","Value"})) 4 | in 5 | (Text as text)=> if Text = null then null else Record.FieldOrDefault(Rec,Text,Text) 6 | -------------------------------------------------------------------------------- /Replacer.ReplaceText_CI: -------------------------------------------------------------------------------- 1 | (original as nullable text 2 | ,old as nullable text 3 | ,new as nullable text) as nullable text => 4 | let 5 | newText = if new = null 6 | then "" 7 | else new 8 | ,oldPosList = Text.PositionOf(original,old, Occurrence.All, Comparer.OrdinalIgnoreCase) 9 | ,oldLen = Text.Length(old) 10 | in 11 | if original = null 12 | or old = null 13 | then original 14 | else List.Accumulate(List.Reverse(oldPosList) 15 | ,original 16 | ,(ori,oldPos) => Text.ReplaceRange(ori, oldPos, oldLen, newText)) 17 | -------------------------------------------------------------------------------- /ReplacerReplaceWholeText_CI: -------------------------------------------------------------------------------- 1 | (original as nullable text 2 | ,old as nullable text 3 | ,new as nullable text) as nullable text => 4 | if Text.Upper(original)=Text.Upper(old) then new else original 5 | -------------------------------------------------------------------------------- /RunningTotal: -------------------------------------------------------------------------------- 1 | (table as table, colToSum as text, colAsNew as text)=> 2 | let 3 | tableB = Table.Buffer(table), 4 | listToSum = List.Buffer(Table.Column(tableB,colToSum)), 5 | listToSumCount = List.Count(listToSum), 6 | runningTotalB = List.Buffer(List.Skip( 7 | List.Generate( 8 | ()=> [item = 0 9 | ,counter = 0], 10 | each [counter] <= listToSumCount, 11 | each [item = [item]+listToSum{[counter]} 12 | ,counter = [counter]+1], 13 | each [item] 14 | ),1)), 15 | addIndex = Table.AddIndexColumn(tableB,"IndexUniqueName",0,1), 16 | addRunningTotal = Table.AddColumn(addIndex,colAsNew,each runningTotalB{[IndexUniqueName]}, type number), 17 | removeIndex = Table.RemoveColumns(addRunningTotal,{"IndexUniqueName"}) 18 | in 19 | removeIndex 20 | -------------------------------------------------------------------------------- /SharepointFolderFromURL: -------------------------------------------------------------------------------- 1 | (folderURL as text, optional includeSubFolders as nullable logical) as table => 2 | let 3 | Folder = Text.Replace(folderURL,"%20"," "), 4 | SplitSite = "sites/", 5 | SplitSiteLen = Text.Length(SplitSite), 6 | SplitSitePos = Text.PositionOf(Folder,SplitSite,Occurrence.First,Comparer.OrdinalIgnoreCase), 7 | Folder2 = Text.Range(Folder,SplitSitePos+SplitSiteLen), 8 | Position2 = Text.PositionOf(Folder2,"/",Occurrence.First), 9 | SharePointURL = Text.Start(Folder,SplitSitePos+SplitSiteLen+Position2+1), 10 | Source = SharePoint.Files(SharePointURL, [ApiVersion = 15]), 11 | #"Filtered Rows" = Table.SelectRows(Source, each ([Folder Path] = Folder)), 12 | RemoveFolderPath = Table.RemoveColumns(#"Filtered Rows",{"Folder Path"}), 13 | MakeNameKey = Table.AddKey(RemoveFolderPath,{"Name"},true) 14 | in 15 | if includeSubFolders = true then #"Filtered Rows" else MakeNameKey 16 | 17 | (folderURL as text) as table => 18 | let 19 | Folder = let sp = Text.Replace(folderURL,"%20"," ") in if Text.EndsWith(sp,"/") then sp else sp&"/", 20 | SplitSite = "sites/", 21 | SplitSiteLen = Text.Length(SplitSite), 22 | SplitSitePos = Text.PositionOf(Folder,SplitSite,Occurrence.First,Comparer.OrdinalIgnoreCase), 23 | Folder2 = Text.Range(Folder,SplitSitePos+SplitSiteLen), 24 | Position2 = Text.PositionOf(Folder2,"/",Occurrence.First), 25 | SharePointURL = Text.Start(Folder,SplitSitePos+SplitSiteLen+Position2+1), 26 | Source = SharePoint.Files(SharePointURL, [ApiVersion = 15]), 27 | Filter = Table.SelectRows(Source, each Text.StartsWith([Folder Path],Folder,Comparer.OrdinalIgnoreCase)), 28 | SkipText = Table.TransformColumns(Filter,{{"Folder Path", each Text.Range(_,Text.Length(Folder)), type text}}) 29 | in 30 | SkipText //Think about using Splitter.SplitTextByEachDelimiter for start part //If I don't include https then filter won't work? Might have to put this in documentation 31 | -------------------------------------------------------------------------------- /Table.TransformOtherColumns: -------------------------------------------------------------------------------- 1 | (Table as table 2 | ,ColumnsToIgnore as list 3 | ,Function as function 4 | ,optional TypeForColumns as nullable type) as table => 5 | let 6 | FunctionType = 7 | Value.Type(Function), 8 | TypeForFunction = 9 | Type.ForFunction( 10 | [ReturnType = TypeForColumns 11 | ,Parameters = Type.FunctionParameters(FunctionType)], 12 | Type.FunctionRequiredParameters(FunctionType)), 13 | FunctionWithNewReturnType = 14 | if TypeForColumns is null 15 | then Function 16 | else Value.ReplaceType(Function,TypeForFunction), 17 | TransformOtherCols = 18 | Table.TransformColumns( 19 | Table, 20 | List.Transform( 21 | ColumnsToIgnore, 22 | (ColName)=> {ColName, each _}), 23 | FunctionWithNewReturnType) 24 | in 25 | TransformOtherCols 26 | -------------------------------------------------------------------------------- /TableCombineColumnsRecord: -------------------------------------------------------------------------------- 1 | (table as table, sourceColumns as list, feildNames as any, column as text) as table=> 2 | let 3 | combiner = each Record.FromList(_,feildNames), 4 | combinerWithReturnType = Value.ReplaceType( 5 | combiner, 6 | Type.ForFunction([ReturnType = feildNames,Parameters= [_ = type any]],1)), 7 | combinerFinal = if feildNames is type then combinerWithReturnType else combiner, 8 | func = Table.CombineColumns(table, sourceColumns, combinerFinal, column) 9 | in 10 | func 11 | 12 | 13 | /* - beta, not tried yet 14 | (table as table, sourceColumns as list, feildNames as any, column as text) as table=> 15 | let 16 | combiner = each Record.FromList(_,feildNames), 17 | combinerWithReturnType = Value.ReplaceType( 18 | combiner, 19 | Type.ForFunction([ReturnType = feildNames,Parameters= [_ = type any]],1)), 20 | combinerFinal = if feildNames is type then combinerWithReturnType 21 | else if feildNames is list then 22 | let 23 | toList = List.Transform(feildNames, (t) => [Type=t, Optional=false]), 24 | toRecord = Record.FromList(toList, feildNames), 25 | toType = Type.ForRecord(toRecord, false) 26 | in 27 | toType //Adapted from Microsoft trippin code 28 | else if feildNames is null then combiner 29 | else error "feildNames must either be record type, list of types of same size as sourceColumns or null", 30 | func = Table.CombineColumns(table, sourceColumns, combinerFinal, column) 31 | in 32 | func 33 | */ 34 | -------------------------------------------------------------------------------- /TableListFunctions/TableFromRecordOfLists: -------------------------------------------------------------------------------- 1 | (rec as record)=> 2 | let 3 | tab2col = Record.ToTable(rec), 4 | valuess_names = List.Reverse(Table.ToColumns(tab2col)), 5 | tab = Function.Invoke(Table.FromColumns,Valuess_Names) 6 | in 7 | tab 8 | -------------------------------------------------------------------------------- /TableListFunctions/TableToRecordOfLists: -------------------------------------------------------------------------------- 1 | (table as table, optional buffer as nullable logical)=> 2 | let 3 | tab = if buffer = true then Table.Buffer(table) else table, 4 | Name = Table.ColumnNames(tab), 5 | Value = Table.ToColumns(tab), 6 | Record = Record.FromTable(Table.FromColumns({Name, Value},{"Name","Value"})) 7 | in 8 | Record 9 | -------------------------------------------------------------------------------- /TextCleaner: -------------------------------------------------------------------------------- 1 | (text as nullable text) as nullable text => 2 | let 3 | Space = Character.FromNumber(32) 4 | Words = Text.Split(text,Space) as list 5 | GetRidOfWhitespace = (word as text) as text => Text.Combine(Splitter.SplitTextByWhitespace()(word)) 6 | Combined = Text.Combine(List.Transform(Words,GetRidOfWhitespace),Space) 7 | in 8 | if text is null then null else Combined 9 | -------------------------------------------------------------------------------- /TimeZone/DateTimeZoneToDateTime_SwitchZone: -------------------------------------------------------------------------------- 1 | (TimeZone as number) as function => 2 | (DateTimeZone as nullable datetimezone) as nullable datetime=> 3 | let 4 | SwitchedZone = DateTimeZone.SwitchZone(DateTimeZone,TimeZone), 5 | DateTime = DateTime.Date(SwitchedZone) & DateTime.Time(SwitchedZone) 6 | in 7 | if DateTimeZone is null then null else DateTime 8 | -------------------------------------------------------------------------------- /TimeZone/DateTimeZoneToDate_SwitchTimeZone: -------------------------------------------------------------------------------- 1 | (TimeZone as number) as function => 2 | (DateTimeZone as nullable datetimezone) as nullable date=> 3 | let 4 | SwitchedZone = DateTimeZone.SwitchZone(DateTimeZone,TimeZone), 5 | Date = DateTime.Date(SwitchedZone) // & DateTime.Time(DateTimeZone) 6 | in 7 | if DateTimeZone is null then null else Date 8 | -------------------------------------------------------------------------------- /fAddRandomColumn.pq: -------------------------------------------------------------------------------- 1 | /*Add column of random numbers between 0 and 1: 2 | fAddRandomColumn(Source,"Random Number",0,1)*/ 3 | /*Add column of random percentages between 0% and 100%: 4 | fAddRandomColumn(Source,"Random Percentage",0,1,Percentage.Type)*/ 5 | /*Retrieve random item from list: 6 | fAddRandomColumn(Source,"Random Item",0,List.Count(ListOfItems),{each ListOfItems{Number.RoundDown(_)}, type text}) 7 | (ListOfItems would need to be buffered into memory for it to run quickly, e.g. ListOfItems = List.Buffer(SomeList))*/ 8 | 9 | (Table as table, RandColName as text, Min as number, Max as number, optional TransformAndTypeCriteria as any) => 10 | let 11 | List = List.Buffer( 12 | if not (TransformAndTypeCriteria is list) then {TransformAndTypeCriteria} else 13 | if List.Count(TransformAndTypeCriteria)<=2 then TransformAndTypeCriteria else 14 | error "Invalid Criteria (Too many items)" ) 15 | ,TransformFunc = if List{0} is null 16 | or List{0} is type then null else 17 | if List{0} is function then List{0} else 18 | error "Invalid Criteria (Tranform)" 19 | ,ListLast = List.Last(List) 20 | ,Type = if ListLast is null 21 | or ListLast is function then type number else 22 | if ListLast is type then ListLast else 23 | error "Invalid Criteria (Type)" 24 | ,FirstName = Table.ColumnNames(Table){0} 25 | ,AddColumn = Table.AddColumn(Table 26 | ,RandColName 27 | ,each Number.RandomBetween(if Record.Field(_,FirstName)=null then Min else Min,Max) 28 | ,Type) 29 | ,Transform = if TransformFunc = null then AddColumn else 30 | Table.TransformColumns(AddColumn,{RandColName, TransformFunc}) 31 | in 32 | Transform 33 | -------------------------------------------------------------------------------- /fClusteredIndex.pq: -------------------------------------------------------------------------------- 1 | (Table as table, GroupOnCols as list) => 2 | let 3 | Group = Table.Group(Table, GroupOnCols, {"ColumnOfTables",each Table.AddIndexColumn(_, "ClustIndex", 0, 1)}) 4 | ,Combine = Table.Combine(Group[ColumnOfTables]) 5 | in 6 | Combine 7 | -------------------------------------------------------------------------------- /fCombineJoins.pq: -------------------------------------------------------------------------------- 1 | (LeftTable as table, LeftKey as list 2 | ,RightTable as table, RightKey as list 3 | ,ListOfJoins as list) => 4 | let 5 | Func = each Table.NestedJoin(LeftTable, LeftKey, RightTable, RightKey,"Right",_) 6 | ,ListOfTables = List.Transform(ListOfJoins, Func) 7 | ,Combine = Table.Combine(ListOfTables) 8 | in 9 | Combine 10 | -------------------------------------------------------------------------------- /fCombineJoinsExpandCoalesce.pq: -------------------------------------------------------------------------------- 1 | /* Similar to combine joins, but also: 2 | 1) Preserves the order 3 | 2) Expands right hand side table 4 | 3) Right key is transferred to left key when left key is null, right key is then deleted */ 5 | 6 | (LeftTable as table ,LeftKeys as list 7 | ,RightTable as table ,RightKeys as list 8 | ,ListOfJoins as list) => 9 | 10 | let 11 | Func = each Table.NestedJoin(LeftTable, LeftKeys, RightTable, RightKeys,"Right",_) 12 | ,ListOfTables = List.Transform(ListOfJoins, Func) 13 | ,Combine = Table.Combine(ListOfTables) 14 | ,OldRightColNames = List.Buffer(Table.ColumnNames(RightTable)) 15 | ,NewRightKeys = List.Buffer(List.Transform(RightKeys, each "Right." & _)) 16 | ,NewRightColNames = List.ReplaceMatchingItems(OldRightColNames,List.Zip({RightKeys,NewRightKeys})) 17 | //Below: Using Table.Buffer, so that order is preserved on expand 18 | ,ExpandRight = Table.ExpandTableColumn(Table.Buffer(Combine), "Right", OldRightColNames, NewRightColNames) 19 | ,Coalesce = List.Accumulate(List.Zip({LeftKeys,NewRightKeys}),ExpandRight, (Table, Keys) => 20 | Table.ReplaceValue(Table, null,each Record.Field(_,Keys{1}),Replacer.ReplaceValue,{Keys{0}})) 21 | ,RemoveRightKeys = Table.RemoveColumns(Coalesce,NewRightKeys) 22 | ,OriginalLeftKeyTypes = List.Transform(LeftKeys, each Type.TableColumn(Value.Type(LeftTable),_)) 23 | ,ChangeTypes = Table.TransformColumnTypes(RemoveRightKeys,List.Zip({LeftKeys, OriginalLeftKeyTypes})) 24 | in 25 | ChangeTypes 26 | 27 | 28 | -------------------------------------------------------------------------------- /fDistinctColumns.pq: -------------------------------------------------------------------------------- 1 | (Table as table, optional MaxLength as number)=> 2 | let 3 | TableType = Value.Type(Table) 4 | ,ColNames = Table.ColumnNames(Table) 5 | ,ListOfCols = List.Transform(Table.ToColumns(Table), List.Distinct) 6 | ,Meta = List.Transform(List.Zip({ListOfCols,ColNames}), each _{0} meta [ColName = _{1}]) 7 | ,SelectList = List.Buffer(if MaxLength = null then Meta else List.Select(Meta, each List.Count(_)<=MaxLength)) 8 | ,NewColNames = List.Transform(SelectList, each Value.Metadata(_)[ColName]) 9 | ,NewTable = Table.FromColumns(SelectList,NewColNames) 10 | in 11 | NewTable 12 | -------------------------------------------------------------------------------- /fNonAggPivotMultRows.pq: -------------------------------------------------------------------------------- 1 | //https://www.dingbatdata.com/non-aggregate-pivot-with-multiple-rows-in-powerquery/ 2 | 3 | (Source as table 4 | ,ColToPivot as text 5 | ,ColForValues as text)=> 6 | 7 | let 8 | PivotColNames = List.Buffer(List.Distinct(Table.Column(Source,ColToPivot))) 9 | ,#"Pivoted Column" = Table.Pivot(Source, PivotColNames, ColToPivot, ColForValues, each _) 10 | 11 | ,TableFromRecordOfLists = (rec as record, fieldnames as list) => 12 | let 13 | PartialRecord = Record.SelectFields(rec,fieldnames) 14 | ,RecordToList = Record.ToList(PartialRecord) 15 | ,Table = Table.FromColumns(RecordToList,fieldnames) 16 | in 17 | Table 18 | 19 | ,#"Added Custom" = Table.AddColumn(#"Pivoted Column", "Values", each TableFromRecordOfLists(_,PivotColNames)) 20 | ,#"Removed Other Columns" = Table.RemoveColumns(#"Added Custom",PivotColNames) 21 | ,#"Expanded Values" = Table.ExpandTableColumn(#"Removed Other Columns", "Values", PivotColNames) 22 | in 23 | #"Expanded Values" 24 | 25 | 26 | -------------------------------------------------------------------------------- /fNonAggPivotMultRows2.pq: -------------------------------------------------------------------------------- 1 | (Source as table 2 | ,PivotCol as text 3 | ,ValueCol as text)=> 4 | let 5 | Source = Table.Buffer(Source) //As source table is referenced 3 times 6 | ,GroupClustIndex = Table.Group(Source 7 | ,List.RemoveItems(Table.ColumnNames(Source),{ValueCol}) 8 | ,{"ColOfTables" 9 | ,each Table.AddIndexColumn(_,"idx")}) 10 | ,CombineTables = Table.Combine(GroupClustIndex[ColOfTables]) 11 | ,Pivot = Table.Pivot(CombineTables, List.Distinct(Table.Column(Source,PivotCol)), PivotCol, ValueCol) 12 | ,RemoveIndex = Table.RemoveColumns(Pivot,{"idx"}) 13 | in 14 | RemoveIndex 15 | -------------------------------------------------------------------------------- /fOrderFirstOccurrence.pq: -------------------------------------------------------------------------------- 1 | /*Orders table by grouping on a column(s). 2 | The result is that you order by first occurence. 3 | https://www.geeksforgeeks.org/group-multiple-occurrence-of-array-elements-ordered-by-first-occurrence */ 4 | 5 | (Source as table, GroupBy as list) => 6 | let 7 | #"Grouped Rows" = Table.Group(Source, GroupBy, {{"Tables", each _, type table}}) 8 | ,#"Removed Columns" = Table.RemoveColumns(#"Grouped Rows", GroupBy) 9 | ,#"Expanded Tables" = Table.ExpandTableColumn(#"Removed Columns", "Tables", Table.ColumnNames(Source)) 10 | ,RevertTypes = Value.ReplaceType(#"Expanded Tables", Value.Type(Source)) 11 | in 12 | RevertTypes 13 | 14 | -------------------------------------------------------------------------------- /fStableSortAndOrderFirstOccurrence.pq: -------------------------------------------------------------------------------- 1 | /*It's a bit like Table.Sort, but: 2 | 1) Sorts are stable 3 | 2) If you neglect to put a Order.Ascending or a Order.Descending then ordered by first occurrence */ 4 | 5 | (Table as table, List as list) => 6 | let 7 | fMakeEfficientList = (List as list) => 8 | let 9 | ColName = List.Transform(List, each _{0}) 10 | ,Order = List.Transform(List, each _{1}?) 11 | ,TableForm = Table.FromColumns({ColName,Order},{"ColName","Order"}) 12 | ,Comparer = (a as record, b as record) => Number.From(a[Order] is null or b[Order] is null) 13 | ,PartionedTable = Table.Group(TableForm, {"Order"}, {{"NestedLists", each Table.ToRows(_), type list}},GroupKind.Local, Comparer) 14 | ,PartionedList = PartionedTable[NestedLists] 15 | in 16 | PartionedList 17 | 18 | ,fReorder = (Table as table, List as list) => 19 | let 20 | ListItem = List.Buffer(List{0}) 21 | ,ListItemColNames = List.Buffer(List.Zip(ListItem){0}) 22 | ,GroupedTable = Table.Group(Table, ListItemColNames, {{"NestedTables", each Table.RemoveColumns(_,ListItemColNames), type table}}) 23 | ,SortedTable = if ListItem{0}{1} = null then GroupedTable else Table.Sort(GroupedTable,ListItem) 24 | ,fRecursion = each if List.Count(List) > 1 then @fReorder(_, List.Skip(List)) else _ 25 | ,RecurseOnNestedTables = Table.Buffer(Table.TransformColumns(SortedTable, {"NestedTables", fRecursion})) 26 | ,Expand = Table.ExpandTableColumn(RecurseOnNestedTables, "NestedTables", Table.ColumnNames(RecurseOnNestedTables[NestedTables]{0})) 27 | in 28 | Expand 29 | 30 | ,EfficientList = List.Buffer(fMakeEfficientList(List)) 31 | ,ReorderRows = fReorder(Table,EfficientList) 32 | ,ReclaimColOrder = Table.ReorderColumns(ReorderRows,Table.ColumnNames(Table)) 33 | ,ReclaimColTypes = Value.ReplaceType(ReclaimColOrder,Value.Type(Table)) 34 | 35 | in 36 | ReclaimColTypes 37 | -------------------------------------------------------------------------------- /fSyncTableTypeOfCol.pq: -------------------------------------------------------------------------------- 1 | /*Ascribes table type of column based on first table in column as 2 | Table.TransformColumnTypes does not work with complex types. E.g. type table[A=text, B=number] 3 | Based on Marcel Beugals code at 4 | https://social.technet.microsoft.com/Forums/en-US/636e9b44-6820-4ff2-ab60-5dd6a5307bd2/type-conversion-mysteries 5 | */ 6 | 7 | (PreviousStep as table,ColName as text) => 8 | Table.TransformColumns(PreviousStep, {ColName, each {_}{0}, Value.Type(Table.Column(PreviousStep,ColName){0})}) 9 | -------------------------------------------------------------------------------- /fTableComparerSort.pq: -------------------------------------------------------------------------------- 1 | //https://www.dingbatdata.com/2018/06/07/multilevel-sorting-comparers/ 2 | //https://www.dingbatdata.com/2018/05/31/documentationsortcomparer/ 3 | //Works like a Table.Sort, but also allows sorting using a comparer at the column level. 4 | //One use of this is for culture sensitive sorting. 5 | 6 | (Table as table 7 | ,comparisonCriteria as any 8 | ,optional defaultcomparisonCriteria as any) => 9 | let 10 | fMakeSureIsList = each if _ is list then _ else {_} 11 | 12 | ,Default = 13 | let 14 | List = fMakeSureIsList(defaultcomparisonCriteria) 15 | ,Sort = if List{0} is number then List{0} else 16 | if (List{0} is null or List{0} is function) then Order.Ascending 17 | else error "invalid defaultcomparisonCriteria" 18 | ,Comparer = if List{0} is function then List{0} else 19 | if List{1}? is function then List{1} else 20 | if List{1}? is null then Value.Compare else 21 | error "invalid defaultcomparisonCriteria" 22 | ,Record = [Sort = Sort, Comparer = Comparer] 23 | in 24 | Record 25 | 26 | ,compCritListRecords = 27 | let 28 | FirstCheck = if Value.Type(comparisonCriteria{0}?) = type text 29 | and Value.Type(comparisonCriteria{1}?) = type number 30 | then {comparisonCriteria} else comparisonCriteria 31 | ,List = fMakeSureIsList(FirstCheck) 32 | ,ListList = List.Transform(List, fMakeSureIsList) 33 | ,fSort = (Order) => if Order = Order.Ascending then 1 else 34 | if Order = Order.Descending then -1 else 35 | error "Order must be Order.Ascending or Order.Descending" 36 | ,ListRec = List.Transform(ListList 37 | ,each let ColNam = _{0} as text 38 | ,Order = _{1}? as nullable number 39 | ,Comp = _{2}? as nullable function 40 | in [ColNam = ColNam 41 | ,Order = fSort(if Order = null then Default[Sort] else Order) 42 | ,Comp = if Comp = null then Default[Comparer] else Comp ]) 43 | in 44 | List.Buffer(ListRec as list) 45 | 46 | ,fComparer = (x as record, y as record) => 47 | let 48 | fFullCompare = (x,y, compCrit) => 49 | let 50 | cC = compCrit{0} 51 | ,comparison = cC[Comp](Record.Field(x,cC[ColNam]),Record.Field(y,cC[ColNam])) 52 | ,comparisonAllCols = if comparison = 0 and List.Count(compCrit)>1 then 53 | @fFullCompare(x,y,List.Skip(compCrit)) else 54 | comparison *cC[Order] 55 | in 56 | comparisonAllCols 57 | ,CompareRec = fFullCompare(x,y,compCritListRecords) 58 | in 59 | CompareRec 60 | 61 | ,Execute = Table.Sort(Table, fComparer) 62 | in 63 | Execute 64 | -------------------------------------------------------------------------------- /fTableSelectRowsWeb: -------------------------------------------------------------------------------- 1 | (Table as table 2 | ,fnFilter as function 3 | ,optional Range as nullable list 4 | ,optional Horizontal as nullable logical)=> 5 | 6 | let 7 | Range = if Range = null then {0} else Range 8 | ,Horizontal = if Horizontal = null then false else Horizontal 9 | ,AddIndex = Table.AddIndexColumn(Table, "Index", 0, 1) 10 | ,Filter = Table.SelectRows(AddIndex, fnFilter) 11 | ,Positions = List.Buffer(Filter[Index]) 12 | ,Values = List.Buffer(Table[Column1]) 13 | ,ListOfTables = List.Transform(Positions, (Pos)=> 14 | let 15 | Len = List.Count(Range) 16 | ,Gen = List.Generate(()=>[i= 0 , Rng = Range{i}, Position = Pos+Rng, Value = Values{Position}] 17 | ,each _[i] < Len 18 | ,each [i= _[i]+1, Rng = Range{i}, Position = Pos+Rng, Value = Values{Position}] 19 | ,each _[[Value],[Rng],[Position]]) 20 | ,Table = Table.FromRecords(Gen) 21 | ,RenameAndChangeTypes = Value.ReplaceType(Table, type table[Value = text, Range = Int64.Type, Position = Int64.Type]) 22 | in 23 | RenameAndChangeTypes) 24 | ,Combine = Table.Combine(ListOfTables) 25 | ,ValuesToRows = Table.FromRows(List.Transform(ListOfTables, each _[Value])) 26 | in 27 | if Horizontal then ValuesToRows else Combine 28 | -------------------------------------------------------------------------------- /fTakeTypesAndTryApply.pq: -------------------------------------------------------------------------------- 1 | //Ascribes types from one table and applies it to columns with the same name on another table 2 | 3 | (tblToAlter as table, tblGet as table) => 4 | let 5 | typetblGet = Value.Type(tblGet) 6 | ,NameCols = List.Intersect({Table.ColumnNames(tblGet) 7 | ,Table.ColumnNames(tblToAlter)}) 8 | ,NameFuncTypes = List.Transform(NameCols, (x) => { x 9 | ,each {_}{0} 10 | ,Type.TableColumn(typetblGet, x) }) 11 | ,Transform = Table.TransformColumns(tblToAlter, NameFuncTypes) 12 | in 13 | Transform 14 | -------------------------------------------------------------------------------- /fnSplitColsDateTime.pq: -------------------------------------------------------------------------------- 1 | (table as table 2 | ,ColName as any // Can be as list of column names or a single column name 3 | ,optional ColNameDate as nullable text 4 | ,optional ColNameTime as nullable text 5 | ,optional Delimiter as nullable text) as table=> 6 | let 7 | ColNameDateD = if ColNameDate is null then "Date" else ColNameDate // Default values can be changed to fit 8 | ,ColNameTimeD = if ColNameTime is null then "Time" else ColNameTime // your own language or table naming standards 9 | ,DelimiterD = if Delimiter is null then "." else Delimiter // (only applicable when ColName is list) 10 | ,ColNameIsText = if ColName is text then true else 11 | if ColName is list then false else 12 | error "ColName needs to be a text value or a list of text values" 13 | ,fnSplitColumn = (State as table, CurrentColName as text) as table=> 14 | let 15 | CurrentColNamesNew = if ColNameIsText then {ColNameDateD 16 | ,ColNameTimeD} 17 | else {CurrentColName & DelimiterD & ColNameDateD 18 | ,CurrentColName & DelimiterD & ColNameTimeD} 19 | ,SplitColumn = Table.SplitColumn(State, CurrentColName, each {_,_}, CurrentColNamesNew) 20 | ,ColumnTransType = {{DateTime.Date, type nullable date} 21 | ,{DateTime.Time, type nullable time}} 22 | ,TransformColumns = Table.TransformColumns(SplitColumn,List.Zip({CurrentColNamesNew}&List.Zip(ColumnTransType))) 23 | in 24 | TransformColumns 25 | in 26 | List.Accumulate( 27 | if ColNameIsText then {ColName} 28 | else ColName 29 | ,table 30 | ,fnSplitColumn) 31 | 32 | --------------------------------------------------------------------------------