├── Date.Today.pq ├── Date.Tomorrow.pq ├── Date.Yesterday.pq ├── Date.StartOfCurrentYear.pq ├── .gitignore ├── Date.NDaysInFuture.pq ├── Date.EndOfLastMonth.pq ├── Date.StartOfLastYear.pq ├── Date.StartOfMonth12MAgoExcCurMonth.pq ├── Date.StartOfMonth12MAgoIncCurMonth.pq ├── List.Dates.LastNDays.pq ├── DateTime.FormatSQL.pq ├── M.types.pq ├── Date.FormatSQL.pq ├── M.UDFs.pq ├── LoadPath.example.pq ├── M.constants.pq ├── UdfContents.pq ├── Table.FromString.pq ├── List.Dates.YTD.pq ├── List.ToText.pq ├── DateTime.UnixTime.pq ├── Date.NDaysAgo.pq ├── List.Dates.R12MIncCurMonthToDate.pq ├── List.Dates.YTDLastYear.pq ├── List.Dates.NYearsToDate.pq ├── List.Dates.R12MExcCurMonth.pq ├── List.Dates.LastNYears.pq ├── Text.Count.pq ├── List.Dates.LastNYearsAndCurYear.pq ├── List.FlatMap.pq ├── List.ReplaceErrors.pq ├── getUdfContent.pq ├── Text.AsciiOnly.pq ├── Text.ReplaceAll.pq ├── Time.EpochToTime.pq ├── Text.Queries.pq ├── List.RemoveErrors.pq ├── Text.ContainsAny.pq ├── Text.EachBetween.pq ├── Text.EachFromTo.pq ├── List.ToRecord.pq ├── Record.Rename.pq ├── List.DatesBetween.pq ├── Record.Transform.pq ├── Text.PowerTrim.pq ├── CrossUsage.pq ├── LoadTrace.pq ├── Record.TransformJoin.pq ├── Text.Between.pq ├── List.RemoveErrorsV2.pq ├── Text.FromTo.pq ├── Function.Profile.pq ├── Table.TranslateColumn.pq ├── Number.Dec2Bin.pq ├── List.RankEqual.pq ├── List.CrossJoin.pq ├── Table.MergeColumns.pq ├── Value.WaitFor.pq ├── Date.EpochToDate.pq ├── Misc.Wait.pq ├── Web.Scrape.pq ├── List.RankDense.pq ├── Web.ContentsCustomRetry.pq ├── Text.MixedSort.pq ├── List.Zip.pq ├── ByD.GetReportDataIDs.pq ├── Web.Curl.pq ├── Text.RemoveSymbols.pq ├── Table.CrossJoin.pq ├── LICENSE ├── M.library.pq ├── Files.SheetsInFolder.pq ├── Web.TimeAndDateCom.GetCountries.pq ├── Table.CrossJoinTables.pq ├── ByD.GetReportMetadataIdName.pq ├── M.functions.pq ├── Table.ExpandRecords.pq ├── Table.RowsCombination2.pq ├── Vlookup.pq ├── Value.TypeToText.pq ├── Table.ExpandTables.pq ├── Stat.Trend.pq ├── Web.FetchSequentially.pq ├── Table.AddScrape.pq ├── Table.ExpandAll.pq ├── Type.ToText.pq ├── Table.ExpandTablesRecursive.pq ├── Table.RemoveBlankColumns.pq ├── F.pq ├── Table.RowsCombination.pq ├── Text.Like.pq ├── ByD.GetReportData.pq ├── Table.JoinMany.pq ├── Table.UnpivotByNumbers.pq ├── List.Dates.HolidaysRU.pq ├── LoadFunctionFromGithub.pq ├── Old.Load.pq ├── Web.TimeAndDateCom.GetCountryCalendar.pq ├── Value.ToText.pq ├── Load.pq └── README.md /Date.Today.pq: -------------------------------------------------------------------------------- 1 | () => 2 | Date.From(DateTime.FixedLocalNow()) 3 | -------------------------------------------------------------------------------- /Date.Tomorrow.pq: -------------------------------------------------------------------------------- 1 | () => 2 | Date.AddDays(Date.From(DateTime.FixedLocalNow()), 1) 3 | -------------------------------------------------------------------------------- /Date.Yesterday.pq: -------------------------------------------------------------------------------- 1 | () => 2 | Date.AddDays(Date.From(DateTime.FixedLocalNow()), -1) 3 | -------------------------------------------------------------------------------- /Date.StartOfCurrentYear.pq: -------------------------------------------------------------------------------- 1 | () => 2 | Date.StartOfYear(Date.From(DateTime.FixedLocalNow())) 3 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | # personal file containing the path to load queries from 2 | /LoadPath.m 3 | LoadPath.m 4 | -------------------------------------------------------------------------------- /Date.NDaysInFuture.pq: -------------------------------------------------------------------------------- 1 | (N as number) => 2 | Date.AddDays(Date.From(DateTime.FixedLocalNow()), N) 3 | -------------------------------------------------------------------------------- /Date.EndOfLastMonth.pq: -------------------------------------------------------------------------------- 1 | () => 2 | Date.EndOfMonth(Date.AddMonths(Date.From(DateTime.FixedLocalNow()), -1)) 3 | -------------------------------------------------------------------------------- /Date.StartOfLastYear.pq: -------------------------------------------------------------------------------- 1 | () => 2 | Date.AddYears(Date.StartOfYear(Date.From(DateTime.FixedLocalNow())), -1) 3 | -------------------------------------------------------------------------------- /Date.StartOfMonth12MAgoExcCurMonth.pq: -------------------------------------------------------------------------------- 1 | () => 2 | Date.StartOfMonth(Date.AddMonths(Date.From(DateTime.FixedLocalNow()), -12)) 3 | -------------------------------------------------------------------------------- /Date.StartOfMonth12MAgoIncCurMonth.pq: -------------------------------------------------------------------------------- 1 | () => 2 | Date.StartOfMonth(Date.AddMonths(Date.From(DateTime.FixedLocalNow()), -11)) 3 | -------------------------------------------------------------------------------- /List.Dates.LastNDays.pq: -------------------------------------------------------------------------------- 1 | (N as number) => 2 | List.Dates(Date.AddDays(Date.From(DateTime.FixedLocalNow()), -N), N, #duration(1,0,0,0)) 3 | -------------------------------------------------------------------------------- /DateTime.FormatSQL.pq: -------------------------------------------------------------------------------- 1 | (DateTimeValue as any) => 2 | FormattedDate = DateTime.ToText(DateTime.From(DateTimeValue), "yyyy-MM-ddThh:mm:ss", "en-US") 3 | -------------------------------------------------------------------------------- /M.types.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = M_library, 3 | Types = Table.SelectRows(Source, each Value.Is([Value], type type)), 4 | Return = Types 5 | in 6 | Return 7 | -------------------------------------------------------------------------------- /Date.FormatSQL.pq: -------------------------------------------------------------------------------- 1 | (DateValue as any) => 2 | let 3 | FormattedDate = DateTime.ToText(DateTime.From(DateValue), "yyyy-MM-ddT00:00:00", "en-US") 4 | in 5 | FormattedDate 6 | -------------------------------------------------------------------------------- /M.UDFs.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = Record.FieldNames(#shared), 3 | UDFs = List.Select(Source, each Record.HasFields(#sections[Section1], _)), 4 | Return = UDFs 5 | in 6 | Return 7 | -------------------------------------------------------------------------------- /LoadPath.example.pq: -------------------------------------------------------------------------------- 1 | Excel.CurrentWorkbook(){[Name="Table1"]}[Content]{0}[Path] 2 | // Copy this file to `LoadPath.pq`, and replace its contents with your query path, like this: 3 | // "D:\pquery\" 4 | -------------------------------------------------------------------------------- /M.constants.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = M_library, 3 | Constants = Table.SelectRows(Source, each not Value.Is([Value], type type) and not Value.Is([Value], type function)), 4 | Return = Constants 5 | in 6 | Return 7 | -------------------------------------------------------------------------------- /UdfContents.pq: -------------------------------------------------------------------------------- 1 | let 2 | UdfTable = Table.RenameColumns(Table.FromList(M_UDFs), {"Column1", "Name"}), 3 | WithContents = Table.AddColumn(UdfTable, "Contents", each getUdfContent([Name])) 4 | in 5 | WithContents 6 | -------------------------------------------------------------------------------- /Table.FromString.pq: -------------------------------------------------------------------------------- 1 | // creates empty table with headers provided in string with delimiters 2 | 3 | (String as text, Separator as text) => 4 | Table.PromoteHeaders( Table.Transpose( Table.FromList( Text.Split( String, Separator ) ) ) ) 5 | -------------------------------------------------------------------------------- /List.Dates.YTD.pq: -------------------------------------------------------------------------------- 1 | () => 2 | let 3 | start = Date.StartOfYear(Date.From(DateTime.FixedLocalNow())), 4 | end = Date.From(DateTime.FixedLocalNow()), 5 | result = List.Dates(start, Duration.Days(end - start) + 1, #duration(1,0,0,0)) 6 | in 7 | result 8 | -------------------------------------------------------------------------------- /List.ToText.pq: -------------------------------------------------------------------------------- 1 | /* 2 | Create text representation of given List to use further in Power Query code 3 | Usage: List_ToText({"abc","def","hgk"}) = {"abc","def","hgk"} 4 | */ 5 | 6 | (list1 as list) as text => 7 | "{""" & Text.Combine(list1, """, """) & """}" 8 | -------------------------------------------------------------------------------- /DateTime.UnixTime.pq: -------------------------------------------------------------------------------- 1 | /* 2 | Convert unix timestamp into Power Query datetime formart 3 | Usage: DateTime_UnixTime(1526800525) = 20.05.2018 7:15:25 4 | */ 5 | 6 | (unixtime as number) as datetime => #datetime(1970, 01 , 01, 0, 0, 0) + #duration(0,0,0,unixtime) 7 | -------------------------------------------------------------------------------- /Date.NDaysAgo.pq: -------------------------------------------------------------------------------- 1 | /* 2 | return date of N days ago from Today 3 | usage: 4 | let 5 | Date.NDaysAgo = Load("Date.NDaysAgo") 6 | in 7 | Date.NDaysAgo(3) 8 | //Result depends on Today 9 | */ 10 | 11 | (N as number) => 12 | Date.AddDays(DateTime.FixedLocalNow(), -N) 13 | -------------------------------------------------------------------------------- /List.Dates.R12MIncCurMonthToDate.pq: -------------------------------------------------------------------------------- 1 | () => 2 | let 3 | start = Date.StartOfMonth(Date.AddMonths(Date.From(DateTime.FixedLocalNow()), -11)), 4 | end = Date.From(DateTime.FixedLocalNow()), 5 | result = List.Dates(start, Duration.Days(end - start) + 1, #duration(1,0,0,0)) 6 | in 7 | result 8 | -------------------------------------------------------------------------------- /List.Dates.YTDLastYear.pq: -------------------------------------------------------------------------------- 1 | () => 2 | let 3 | start = Date.StartOfYear(Date.AddYears(Date.From(DateTime.FixedLocalNow()), -1)), 4 | end = Date.AddYears(Date.From(DateTime.FixedLocalNow()), -1), 5 | result = List.Dates(start, Duration.Days(end - start) + 1, #duration(1,0,0,0)) 6 | in 7 | result 8 | -------------------------------------------------------------------------------- /List.Dates.NYearsToDate.pq: -------------------------------------------------------------------------------- 1 | // N years to today 2 | (N as number) => 3 | let 4 | start = Date.StartOfYear(Date.AddYears(Date.From(DateTime.FixedLocalNow()), -N)), 5 | end = Date.From(DateTime.FixedLocalNow()), 6 | result = List.Dates(start, Duration.Days(end - start) + 1, #duration(1,0,0,0)) 7 | in 8 | result 9 | -------------------------------------------------------------------------------- /List.Dates.R12MExcCurMonth.pq: -------------------------------------------------------------------------------- 1 | () => 2 | let 3 | start = Date.StartOfMonth(Date.AddMonths(Date.From(DateTime.FixedLocalNow()), -12)), 4 | end = Date.AddDays(Date.StartOfMonth(Date.From(DateTime.FixedLocalNow())), -1), 5 | result = List.Dates(start, Duration.Days(end - start) + 1, #duration(1,0,0,0)) 6 | in 7 | result 8 | -------------------------------------------------------------------------------- /List.Dates.LastNYears.pq: -------------------------------------------------------------------------------- 1 | // last N years 2 | (N as number) => 3 | let 4 | start = Date.StartOfYear(Date.AddYears(Date.From(DateTime.FixedLocalNow()), -N)), 5 | end = Date.EndOfYear(Date.AddYears(Date.From(DateTime.FixedLocalNow()), -1)), 6 | result = List.Dates(start, Duration.Days(end - start) + 1, #duration(1,0,0,0)) 7 | in 8 | result 9 | -------------------------------------------------------------------------------- /Text.Count.pq: -------------------------------------------------------------------------------- 1 | /* 2 | Returns the number of occurrences of a substring (needle) within another string (haystack). 3 | //Usage: 4 | let 5 | Text.Count = Load("Text.Count") 6 | in 7 | Text.Count("Abba", "b") 8 | //Result: 2 9 | */ 10 | 11 | (Haystack as text, Needle as text) as number => 12 | List.Count(Text.Split(Haystack, Needle)) - 1 13 | -------------------------------------------------------------------------------- /List.Dates.LastNYearsAndCurYear.pq: -------------------------------------------------------------------------------- 1 | // last N years and Current year 2 | (N as number) => 3 | let 4 | start = Date.StartOfYear(Date.AddYears(Date.From(DateTime.FixedLocalNow()), -N)), 5 | end = Date.EndOfYear(Date.From(DateTime.FixedLocalNow())), 6 | result = List.Dates(start, Duration.Days(end - start) + 1, #duration(1,0,0,0)) 7 | in 8 | result 9 | -------------------------------------------------------------------------------- /List.FlatMap.pq: -------------------------------------------------------------------------------- 1 | /* 2 | Maps a list using a lambda in such a way that all results are combined back into a single list. 3 | //Usage: 4 | let 5 | List.FlatMap = Load("List.FlatMap") 6 | in 7 | List.FlatMap({1,2,3}, (_) => List.Numbers(1, _)) 8 | //Result: {1, 1, 2, 1, 2, 3} 9 | */ 10 | 11 | (lst as list, fn as function) => List.Combine(List.Transform(lst, fn)) 12 | -------------------------------------------------------------------------------- /List.ReplaceErrors.pq: -------------------------------------------------------------------------------- 1 | /* 2 | Replaces error values in given list with passed replacement value (or with null if replacement is omitted) 3 | */ 4 | 5 | (ListWithError as list, optional Replacement as any) as list => 6 | let 7 | Source = List.Transform( 8 | List.Positions(ListWithError), 9 | each try ListWithError{_} otherwise Replacement) 10 | in 11 | Source 12 | -------------------------------------------------------------------------------- /getUdfContent.pq: -------------------------------------------------------------------------------- 1 | (fnName as text) => let 2 | Path = LoadPath & (if Text.End(LoadPath, 1) <> "\" then "\" else ""), 3 | File = Path & Text.Replace(fnName, "_", ".") & ".pq", 4 | AltFile = Path & fnName & ".m", //just in case... 5 | Source = Text.FromBinary(Binary.Buffer( 6 | try File.Contents(File) 7 | otherwise File.Contents(AltFile) 8 | )) 9 | in 10 | Source 11 | -------------------------------------------------------------------------------- /Text.AsciiOnly.pq: -------------------------------------------------------------------------------- 1 | //Filters out all non-ascii characters from a string 2 | 3 | (s as text) as text => 4 | let 5 | Listified = Text.ToList(s), 6 | Numbered = List.Transform(Listified, each Character.ToNumber(_)), 7 | Filtered = List.Select(Numbered, each _ <= 255), 8 | Stringified = List.Transform(Filtered, each Character.FromNumber(_)), 9 | Joined = Text.Combine(Stringified, ""), 10 | Return = Joined 11 | in 12 | Return 13 | -------------------------------------------------------------------------------- /Text.ReplaceAll.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Do multiple text replacements in one function call, passing the replacements as a list of lists 3 | //Usage: 4 | Text.ReplaceAll = Load("Text.ReplaceAll"), 5 | Text.ReplaceAll("(test)", { 6 | {"(", "["}, 7 | {")", "]"} 8 | }) 9 | //Result: "[test]" 10 | */ 11 | 12 | (str as text, Replacements as list) as text => List.Accumulate(Replacements, str, (s, x) => Text.Replace(s, x{0}, x{1})) 13 | -------------------------------------------------------------------------------- /Time.EpochToTime.pq: -------------------------------------------------------------------------------- 1 | (epoch as nullable text ) => 2 | let 3 | res = if epoch = null 4 | then null 5 | else 6 | let 7 | remove_word = Text.Replace(epoch, "PT", ""), 8 | remove_letterH = Text.Replace(remove_word, "H", ":"), 9 | remove_letterM = Text.Replace(remove_letterH, "M", ":"), 10 | remove_letterS = Text.Replace(remove_letterM, "S", "") 11 | in 12 | remove_letterS 13 | in 14 | res 15 | -------------------------------------------------------------------------------- /Text.Queries.pq: -------------------------------------------------------------------------------- 1 | let 2 | // text user-defined queries 3 | Files = Folder.Files(LoadPath), // Folder.Contents 4 | AddDecode = Table.AddColumn(Files, "Text", each Text.FromBinary([Content])), 5 | FilterCols = Table.SelectColumns(AddDecode, {"Name", "Text"}), 6 | TextCol = Table.Column(FilterCols, "Text"), 7 | TextMerged = Text.Combine(TextCol), 8 | TextCleaned = TextMerged, // sorry, no regex to clean out comments! 9 | Return = TextCleaned 10 | in 11 | Return 12 | -------------------------------------------------------------------------------- /List.RemoveErrors.pq: -------------------------------------------------------------------------------- 1 | (ListWithErrors as list) as list => 2 | /* 3 | Takes list as input and returns the same list but without Error values. 4 | Useful when errors came to list/column from external source, and there are no possibility to eliminate errors before using a list 5 | 6 | Usage: 7 | = List.RemoveErrors({1,2,error "this is an error",4}) 8 | returns 9 | {1,2,4} 10 | */ 11 | 12 | let 13 | CleanList = Table.RemoveRowsWithErrors(Table.FromColumns({ListWithErrors}))[Column1] 14 | in 15 | CleanList 16 | -------------------------------------------------------------------------------- /Text.ContainsAny.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Check if a string contains any of the keywords from a given list 3 | //Usage: 4 | Text.ContainsAny = Load("Text.ContainsAny"), 5 | Text.ContainsAny("the cat sat on the mat", {"cat", "apple"}) 6 | //Result: true 7 | */ 8 | 9 | (str, needles) as logical => 10 | let 11 | count = List.Count(needles) 12 | in 13 | 14 | List.AnyTrue( 15 | List.Generate( 16 | ()=>[i=0], 17 | each [i] < count, 18 | each [i=[i]+1], 19 | each Text.Contains(str,needles{[i]}) 20 | ) 21 | ) 22 | 23 | -------------------------------------------------------------------------------- /Text.EachBetween.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Grabs the substring between the specified 'after' and 'before' strings 3 | //Usage: 4 | Text.EachBetween = Load("Text.EachBetween"), 5 | Text.EachBetween("a[bc][d]ef", "[", "]") 6 | //Result: {"bc", "d"} 7 | */ 8 | 9 | (Haystack as text, After as text, Before as text) as list => 10 | let 11 | CutAfter = Text.Split(Haystack, After), 12 | SkipFirst = List.Skip(CutAfter), 13 | CutEach = List.Transform(SkipFirst, each Text.Split(_, Before){0}) 14 | in 15 | CutEach 16 | 17 | -------------------------------------------------------------------------------- /Text.EachFromTo.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Grabs the substring between the specified 'after' and 'before' strings 3 | //Usage: 4 | Text.EachFromTo = Load("Text.EachFromTo"), 5 | Text.EachFromTo("a[bc][d]ef", "[", "]") 6 | //Result: {"[bc]", "[d]"} 7 | */ 8 | 9 | (Haystack as text, After as text, Before as text) as text => 10 | let 11 | CutAfter = Text.Split(Haystack, After), 12 | SkipFirst = List.Skip(CutAfter), 13 | CutEach = List.Transform(SkipFirst, each After & Text.Split(_, Before){0} & Before) 14 | in 15 | CutEach 16 | 17 | -------------------------------------------------------------------------------- /List.ToRecord.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Transform a list of strings to a record using a given lambda (passed values k) 3 | //The built-in Record.FromList only takes static lists... 4 | //Usage: 5 | let 6 | List.ToRecord = Load("List.ToRecord"), 7 | list = {"a","b"} 8 | in 9 | List.ToRecord(list, (k) => Text.Upper(k)) 10 | //Result: [a="A", b="B"] 11 | */ 12 | 13 | (List as list, Lambda as function) as record => 14 | let 15 | Transformed = List.Transform(List, Lambda) //each Lambda(_) 16 | in 17 | Record.FromList(Transformed, List) 18 | -------------------------------------------------------------------------------- /Record.Rename.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Rename a record using a given lambda (passed values k,v) 3 | //Usage: 4 | let 5 | Record.Rename = Load("Record.Rename"), 6 | Rec = [A=1, B=2] 7 | in 8 | Record.Rename(Rec, (k,v) => k & Text.From(v)) 9 | //Result: [A1=1, B2=2] 10 | */ 11 | 12 | (Rec as record, Lambda as function) as record => 13 | let 14 | Keys = Record.FieldNames(Rec), 15 | Values = Record.FieldValues(Rec), 16 | Renamed = List.Transform(Keys, each Lambda(_, Record.Field(Rec, _))), 17 | Recorded = Record.FromList(Values, Renamed), 18 | Return = Recorded 19 | in 20 | Return 21 | -------------------------------------------------------------------------------- /List.DatesBetween.pq: -------------------------------------------------------------------------------- 1 | // List_DatesBetween 2 | // List_DatesBetween is an alternative for List.Dates function. It takes only two dates as arguments and creates a list of dates between given two dates. 3 | // Usage: List_DatesBetween(11/17/2016, 12/19/2016) 4 | 5 | (dateStart as date, dateFinish as date) => 6 | 7 | let 8 | 9 | countOfDays = Number.From(dateFinish - dateStart), 10 | output = if countOfDays > 0 11 | then List.Dates(dateStart, countOfDays+1, #duration(1,0,0,0)) 12 | else "Error! Your inputs are incorrect. Check the inputs." 13 | in 14 | output 15 | -------------------------------------------------------------------------------- /Record.Transform.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Transform a record using a given lambda (passed values k,v) 3 | //Usage: 4 | let 5 | Record.Transform = Load("Record.Transform"), 6 | // alt: F[Record.Transform] 7 | Rec = [A=1, B=2] 8 | in 9 | Record.Transform(Rec, (k,v) => k & Text.From(v)) 10 | //Result: [A="A1", B="B2"] 11 | */ 12 | 13 | (Rec as record, Lambda as function) as record => 14 | let 15 | Keys = Record.FieldNames(Rec), 16 | Transformed = List.Transform(Keys, each Lambda(_, Record.Field(Rec, _))), 17 | Recorded = Record.FromList(Transformed, Keys), 18 | Return = Recorded 19 | in 20 | Return 21 | -------------------------------------------------------------------------------- /Text.PowerTrim.pq: -------------------------------------------------------------------------------- 1 | /* 2 | Function removes double presents of specified characters. 3 | By default remove double spaces and leading + ending spaces. 4 | Like TRIM function in Excel 5 | 6 | Original is taked from Ken Puls's blog 7 | http://www.excelguru.ca/blog/2015/10/08/clean-whitespace-in-powerquery/ 8 | */ 9 | 10 | (text as text, optional char_to_trim as text) => 11 | let 12 | char = if char_to_trim = null then " " else char_to_trim, 13 | split = Text.Split(text, char), 14 | removeblanks = List.Select(split, each _ <> ""), 15 | result=Text.Combine(removeblanks, char) 16 | in 17 | result 18 | -------------------------------------------------------------------------------- /CrossUsage.pq: -------------------------------------------------------------------------------- 1 | let 2 | Table.CrossJoin = Load("Table.CrossJoin"), 3 | Tokens = Table.RenameColumns(Table.FromList(Record.FieldNames(#shared)), {"Column1", "Token"}), 4 | AddAlts = Table.AddColumn(Tokens, "TokenAlt", each Text.Replace([Token], "_", ".")), 5 | Crossed = Table.CrossJoin(AddAlts, UdfContents), 6 | Contained = Table.AddColumn(Crossed, "Contains", each Text.Contains([Contents], [Token]) or Text.Contains([Contents], [TokenAlt])), 7 | Filtered = Table.SelectRows(Contained, each [Contains]), 8 | FiltCols = Table.SelectColumns(Filtered, {"Token", "TokenAlt", "Name"}), 9 | Return = FiltCols 10 | in 11 | Return 12 | -------------------------------------------------------------------------------- /LoadTrace.pq: -------------------------------------------------------------------------------- 1 | //Original made by Chris Webb: 2 | //http://blog.crossjoin.co.uk/2014/12/11/reading-the-power-query-trace-filewith-power-query/ 3 | (Path as text) as table => 4 | let 5 | Source = Table.FromColumns({Lines.FromBinary(File.Contents(Path))}), 6 | Json = Table.TransformColumns(Source, {{"Column1", each Json.Document(Text.Split(_, " : "){1})}}), 7 | Expanded = Table.ExpandRecordColumn(Json, "Column1", {"Start","Action","Duration","Exception","CommandText","ResponseFieldCount","PackageReference","ProductVersion","ActivityId","Process","Pid","Tid"}), 8 | Typed = Table.TransformColumnTypes(Expanded, {{"Start", type datetime}, {"Duration", type duration}}) 9 | in 10 | Typed 11 | -------------------------------------------------------------------------------- /Record.TransformJoin.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Shorthand for returning a string representation (using a given lambda) of a record 3 | //Usage: 4 | Record.TransformJoin = Load("Record.TransformJoin"), 5 | Rec = [A=1, B=2], 6 | Record.TransformJoin(Rec, each _ & "=" & Text.From(Record.Field(Rec, _))) 7 | //Result: "A=1, B=2" 8 | */ 9 | 10 | (Rec as record, Lambda as function, optional Delimiter as text) as text => 11 | let 12 | Delimiter = if (Delimiter<>null) then Delimiter else ", ", 13 | 14 | Keys = Record.FieldNames(Rec), 15 | Transformed = List.Transform(Keys, each Lambda(_, Record.Field(Rec,_))), 16 | Combined = Text.Combine(Transformed, Delimiter), 17 | 18 | Return = Combined 19 | in 20 | Return 21 | -------------------------------------------------------------------------------- /Text.Between.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Grabs the substring between the specified 'after' and 'before' strings 3 | //Usage: 4 | Text.Between = Load("Text.Between"), 5 | Text.Between("abcdef", "bc", "f") 6 | //Result: "de" 7 | */ 8 | 9 | (Haystack as text, After as text, Before as text) as text => 10 | let 11 | CutAfter = Text.Split(Haystack, After), 12 | CutBefore = Text.Split(CutAfter{1}, Before), 13 | Needle = if List.Count(CutAfter) > 1 14 | then (if List.Count(CutBefore) > 1 then CutBefore{0} else Error.Record("FindTextFailed","The text did not contain the keyword " & Before, Haystack)) 15 | else error Error.Record("FindTextFailed","The text did not contain the keyword " & After, Haystack) 16 | in Needle 17 | 18 | -------------------------------------------------------------------------------- /List.RemoveErrorsV2.pq: -------------------------------------------------------------------------------- 1 | (ListWithError as list) as list => 2 | /* removes error values from list (without replacement) without "convert to table / remove rows" 3 | Author: Owen Auger https://nz.linkedin.com/in/owenauger http://owenaugerblog.wordpress.com/ 4 | Source: http://community.powerbi.com/t5/Desktop/Removing-errors-from-list-not-column-in-Power-Query-M/m-p/78765 5 | */ 6 | let 7 | Source = List.Accumulate( 8 | List.Positions(ListWithError), 9 | {}, 10 | (CleanListSoFar, CurrentPosition) => 11 | CleanListSoFar & 12 | (if (try ListWithError{CurrentPosition})[HasError] 13 | then {} 14 | else {ListWithError{CurrentPosition}} 15 | ) 16 | ) 17 | in 18 | Source 19 | -------------------------------------------------------------------------------- /Text.FromTo.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Grabs the first substring from the specified 'From' up to the 'UpTo' string 3 | //Usage: 4 | Text.FromTo = Load("Text.FromTo"), 5 | Text.FromTo("abcdef", "bc", "f") 6 | //Result: "bcdef" 7 | */ 8 | 9 | (Haystack as text, From as text, UpTo as text) as text => 10 | let 11 | CutAfter = Text.Split(Haystack, From), 12 | CutBefore = Text.Split(CutAfter{1}, UpTo), 13 | Needle = if List.Count(CutAfter) > 1 14 | then (if List.Count(CutBefore) > 1 then From & CutBefore{0} & UpTo else Error.Record("FindTextFailed","The text did not contain the keyword " & UpTo, Haystack)) 15 | else error Error.Record("FindTextFailed","The text did not contain the keyword " & From, Haystack) 16 | in Needle 17 | 18 | -------------------------------------------------------------------------------- /Function.Profile.pq: -------------------------------------------------------------------------------- 1 | /* 2 | // Profiles the time taken to execute a function for the given parameters 3 | //Usage: 4 | Text.Between = Load("Text.Between"), 5 | Function.Profile = Load("Function.Profile"), 6 | Function.Profile(Text.Between, {"abcdef", "bc", "f"}) 7 | //Result: "de" meta 00:00:00 8 | */ 9 | 10 | (fn as function, params as list) as datetime => 11 | let 12 | TimeBefore = DateTime.LocalNow(), 13 | evaluated = Function.Invoke(fn, params), 14 | TimeAfter = (try evaluated as none otherwise DateTime.LocalNow()), 15 | // ^ always evaluates to otherwise, just using the expression as a dummy to force getting the time only after evaluation has finished 16 | TimeTaken = TimeAfter - TimeBefore 17 | in 18 | evaluated meta [taken=TimeTaken] 19 | -------------------------------------------------------------------------------- /Table.TranslateColumn.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Makes a 'translated' column simultaneously executing multiple replaces on the original (using a list of lists as a 'translation sheet') 3 | //Usage: 4 | Table.TranslateColumn = Load("Table.TranslateColumn"), 5 | Tbl = #table({"可能"},{{"不可"},{"可"}}), 6 | Table.TranslateColumn(Tbl, "可能", "Possible", {{"不可", "Nope"},{"可","Yes"}}) 7 | //Result: #table({"Possible"},{{"Nope"},{"Yes"}}) 8 | */ 9 | 10 | (Tbl as table, OldCol as text, NewColName as text, TranslationList as list) as table => 11 | 12 | let 13 | ColAdded = Table.AddColumn(Tbl, NewColName, each List.ReplaceMatchingItems({Record.Field(_, OldCol)}, TranslationList)), 14 | Columnized = Table.ExpandListColumn(ColAdded, NewColName) 15 | in 16 | Columnized 17 | 18 | -------------------------------------------------------------------------------- /Number.Dec2Bin.pq: -------------------------------------------------------------------------------- 1 | // Function that converts number from decimal to binary notation 2 | // 3 | // Usage: 4 | // Number.Dec2Bin( 1026 ) 5 | // result: 10000000010 6 | // Same as Excel funciton DEC2BIN 7 | // https://support.office.com/en-us/article/DEC2BIN-function-0f63dd0e-5d1a-42d8-b511-5bf5c6d43838 8 | // 9 | 10 | (num as number, optional string as nullable text) => 11 | let 12 | input_string = if string = null then "" else string, 13 | 14 | reminder = Number.Mod( num, 2 ), 15 | resulting_string = Text.From( reminder ) & input_string, 16 | 17 | input = Number.IntegerDivide( num, 2 ), 18 | 19 | r = if input > 0 then 20 | @Number_Dec2Bin( input , resulting_string) 21 | else resulting_string 22 | in 23 | r 24 | -------------------------------------------------------------------------------- /List.RankEqual.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Ranks an input value in a series (ascendingly or descendingly). Does not filter out duplicates. 3 | //Usage: 4 | List.RankEqual = Load("List.RankEqual"), 5 | List.RankEqual("B",{"A","A","B","C"}) 6 | //Result: 3 7 | */ 8 | 9 | //Originally written by Colin Banfield: http://social.technet.microsoft.com/Forums/en-US/973e9381-ff46-4756-a071-88bb4c2105e4/pushing-more-calcs-to-power-query-replacing-dax-rankx 10 | 11 | (inputValue as any, inputSeries as list, optional orderDescending as nullable logical) as number => 12 | let 13 | order = if orderDescending or orderDescending = null then Order.Descending else Order.Ascending, 14 | SortedSeries = List.Sort(inputSeries, order), 15 | RankEqual = List.PositionOf(SortedSeries,inputValue)+1 16 | in 17 | RankEqual 18 | -------------------------------------------------------------------------------- /List.CrossJoin.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Returns the Cartesian product (i.e. crossjoin) of two arguments (can be lists or tables). 3 | //Usage: 4 | List.CrossJoin = Load("List.CrossJoin"), 5 | List.CrossJoin({"A","B"},{1..3}) 6 | //Result: #table({"A","B"},{{"A",1},{"A",2},{"A",3},{"B",1},{"B",2},{"B",3}}) 7 | */ 8 | 9 | (A as list, B as list) as table => 10 | 11 | let 12 | firstList = List.RemoveNulls(A), 13 | secondList = List.RemoveNulls(B), 14 | firstLength = List.Count(firstList), 15 | secondLength = List.Count(secondList), 16 | resultFirstList = List.Generate( () => 0, each _ < firstLength * secondLength, each _ + 1, each firstList{ Number.IntegerDivide(_, secondLength) }), 17 | resultSecondList = List.Repeat( secondList, firstLength) 18 | in 19 | Table.FromColumns({resultFirstList, resultSecondList}) 20 | 21 | -------------------------------------------------------------------------------- /Table.MergeColumns.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Merges two columns in a table that refer to the thing, taking column A but falling back to B where A is null 3 | //Usage: 4 | Table.MergeColumns = Load("Table.MergeColumns"), 5 | Tbl = #table({"Tel.", "Phone #"},{{"234", null},{null, "123"}}), 6 | Table.MergeColumns(Tbl, "Tel.", "Phone #") 7 | //Result: #table({"Tel."},{{"234"},{"123"}}) 8 | */ 9 | 10 | (Source as table, aCol as text, bCol as text) as table => let 11 | colName = "SomeCustomColName", 12 | InsertedCustom = Table.AddColumn(Source, colName, each if Record.Field(_,aCol)=null then Record.Field(_,bCol) else Record.Field(_,aCol) ), 13 | RemovedColumns = Table.RemoveColumns(InsertedCustom,{aCol, bCol}), 14 | RenamedColumns = Table.RenameColumns(RemovedColumns,{{colName, aCol}}) 15 | in RenamedColumns 16 | 17 | -------------------------------------------------------------------------------- /Value.WaitFor.pq: -------------------------------------------------------------------------------- 1 | //author: Curt Hagenlocher 2 | //https://gist.github.com/CurtHagenlocher/68ac18caa0a17667c805 3 | 4 | (producer as function, interval as function, optional count as number) as any => 5 | let 6 | list = List.Generate( 7 | //start: first try, no result 8 | () => {0, null}, 9 | //condition: stop if we have the result (try count null'd) or we've exceeded the max tries 10 | (state) => state{0} <> null and (count = null or state{0} < count), 11 | //next: stop try tally if we have our result, otherwise check again and tally a try 12 | (state) => if state{1} <> null 13 | then {null, state{1}} 14 | else {1 + state{0}, Function.InvokeAfter(() => producer(state{0}), interval(state{0}))}, 15 | //transformer: only return the result, not try tally 16 | (state) => state{1}) 17 | in 18 | List.Last(list) 19 | -------------------------------------------------------------------------------- /Date.EpochToDate.pq: -------------------------------------------------------------------------------- 1 | /* 2 | convert date from SAP ByDesign into normal date 3 | SAP JSON response shows date as "/Date(1357084800000)/" 4 | can be used with 5 | Table.TransformColumns(Expand,{{"Posting Date", EpochToDate}}) 6 | */ 7 | 8 | let EpochToDateTime = (epoch as nullable text ) => 9 | let 10 | res = if epoch = null 11 | then null 12 | else 13 | let 14 | remove_word = Text.Replace(epoch, "Date", ""), 15 | remove_slash = Text.Replace(remove_word, "/", ""), 16 | remove_left_par = Text.Replace(remove_slash, "(", ""), 17 | remove_right_par = Text.Replace(remove_left_par, ")", ""), 18 | calc = #datetime(1970, 1, 1, 0, 0, 0) + #duration(0, 0, 0, Number.FromText(Text.Start(remove_right_par,Text.Length(remove_right_par)-3))) 19 | in 20 | calc 21 | in 22 | res 23 | in 24 | EpochToDateTime 25 | -------------------------------------------------------------------------------- /Misc.Wait.pq: -------------------------------------------------------------------------------- 1 | // This function is now obsolete due to the addition of Function.InvokeAfter(), see: 2 | // https://cwebbbi.wordpress.com/2015/04/30/using-function-invokeafter-in-power-query/ 3 | 4 | /* 5 | //Delay the given action for the specified number of seconds 6 | //Usage: 7 | Misc.Wait = Load("Misc.Wait"), 8 | Misc.Wait(0.5, () => Web.Contents("www.bing.com")) 9 | //Result: [whatever result of the given action, except 0.5 seconds slower] 10 | */ 11 | 12 | (seconds as number, action as function) => 13 | if ( 14 | List.Count( 15 | List.Generate( 16 | () => DateTimeZone.LocalNow() + #duration(0,0,0,seconds), 17 | (x) => DateTimeZone.LocalNow() < x, 18 | (x) => x 19 | ) 20 | ) = 0 21 | ) 22 | then null 23 | // this if ... then null never triggers, but its purpose is to make the function depend on the waiting loop finishing 24 | else action() 25 | 26 | -------------------------------------------------------------------------------- /Web.Scrape.pq: -------------------------------------------------------------------------------- 1 | /* 2 | // Scrape a web page, raising an error with a curl command for debugging purposes in case the response is empty. 3 | //Usage: 4 | Web.Scrape = Load("Web.Scrape"), 5 | Web.Scrape("http://google.com", [#"Referer"="http://google.com"]) 6 | //Result: a binary representation of the Google front-page 7 | */ 8 | 9 | (url as text, optional options as record) as binary => 10 | 11 | let 12 | Web.Curl = Load("Web.Curl"), 13 | Response = Web.Contents(url, options), 14 | Buffered = Binary.Buffer(Response), 15 | Meta = try Value.Metadata(Response) otherwise null, 16 | Status = if Buffered = null then 0 else Meta[Response.Status], 17 | Return = if Status = 0 or Status >= 400 // Binary.Length(Buffered) = 0 18 | then error Error.Record("ScrapeFailed", Web.Curl(url, options), Meta) 19 | else Buffered 20 | in 21 | Return 22 | 23 | -------------------------------------------------------------------------------- /List.RankDense.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Ranks an input value in a series (ascendingly or descendingly). Removes duplicates to rank only unique values. 3 | //Usage: 4 | List.RankDense = Load("List.RankDense"), 5 | List.RankDense("B",{"A","A","B","C"}) 6 | //Result: 3 7 | */ 8 | 9 | //Originally written by Colin Banfield: http://social.technet.microsoft.com/Forums/en-US/973e9381-ff46-4756-a071-88bb4c2105e4/pushing-more-calcs-to-power-query-replacing-dax-rankx 10 | 11 | (inputValue as any, inputSeries as list, optional orderDescending as nullable logical) as number => 12 | let 13 | order = if orderDescending or orderDescending = null then Order.Descending else Order.Ascending, 14 | SortedSeries = List.Sort(inputSeries, order), 15 | DistinctSeries = List.Distinct(SortedSeries), 16 | RankDense = List.PositionOf(DistinctSeries,inputValue)+1 17 | in 18 | RankDense 19 | 20 | -------------------------------------------------------------------------------- /Web.ContentsCustomRetry.pq: -------------------------------------------------------------------------------- 1 | //This is an example of how one can use custom handling of a web response based on the request's response status. 2 | //author: Curt Hagenlocher 3 | //https://gist.github.com/CurtHagenlocher/68ac18caa0a17667c805 4 | 5 | (url as text, optional options as record) => let 6 | Value.WaitFor = Load("Value.WaitFor") 7 | in 8 | 9 | Value.WaitFor( 10 | (i) => 11 | let 12 | options2 = if options = null then [] else options, 13 | options3 = options2 & (if i=0 then [] else [IsRetry=true]), 14 | result = Web.Contents(url, options3 & [ManualStatusHandling={429}]), 15 | buffered = Binary.Buffer(result), // avoid risk of double request 16 | status = if buffered = null then 0 else Value.Metadata(result)[Response.Status], 17 | actualResult = if status = 429 then null else buffered 18 | in 19 | actualResult, 20 | (i) => #duration(0, 0, 0, i*0.1) 21 | ) 22 | -------------------------------------------------------------------------------- /Text.MixedSort.pq: -------------------------------------------------------------------------------- 1 | // About// Sorts mixed list of text and numbers in a numerical order for numbers and alphanumeric for text 2 | // Arguments// "txt"= Text value to sort 3 | // Source// Author: Bill Szysz in https://social.technet.microsoft.com/Forums/en-US/aed476c6-0daa-4aa2-b763-993195d4d0eb/how-to-sort-in-cell-values-with-comma-seperated-using-power-query?forum=powerquery 4 | // Imp// Suggested improvement: Integrate option to choose order direction (ascending, descending) by function parameters 5 | 6 | 7 | (txt as text) as text => 8 | let 9 | SplitTrim = List.Transform(Text.Split(txt, ","), each Text.Trim(_)), 10 | Transform = List.Transform(SplitTrim, each try Number.From(_) otherwise _), 11 | LstSort = List.Sort(Transform, 0), 12 | Transform2 = List.Transform(LstSort, each Text.From(_)), 13 | CombineText = Text.Combine(Transform2, ", ") 14 | in 15 | CombineText 16 | -------------------------------------------------------------------------------- /List.Zip.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Zip a list of lists so as to 'transpose' them -- as records if names are specified. 3 | //Usage: 4 | List.Zip = Load("List.Zip"), 5 | List.Zip({{1,2,3},{"a","b","c"}}, {"num","let"}) 6 | //Result: {[num=1, let="a"],[num=2, let="b"],[num=3, let="c"]} 7 | */ 8 | 9 | (listOfLists as list, optional names as list) as list => 10 | let 11 | max = List.Max(List.Transform(listOfLists, each List.Count(_))), 12 | zipped = List.Skip(List.Generate( 13 | ()=>[ 14 | i = -1, 15 | vals = {}, 16 | combined = {} 17 | ], 18 | each [i] < max, 19 | each [ 20 | i = [i] + 1, 21 | vals = List.Transform(listOfLists, each _{i}), 22 | combined = if names = null then vals else Record.FromList(vals, names) 23 | ], 24 | each [combined] 25 | )), 26 | tablized = Table.FromRecords(zipped) //Table.FromRows 27 | in 28 | tablized 29 | 30 | -------------------------------------------------------------------------------- /ByD.GetReportDataIDs.pq: -------------------------------------------------------------------------------- 1 | /* 2 | Get report data from SAP Business ByDesign using Power Query (through OData) 3 | Example: 4 | ConnectionString = https://myXXXXXX.sapbydesign.com/sap/byd/odata/cc_home_analytics.svc/RPCRMCIVIB_Q0001QueryResults?$top=100000& 5 | $select=CDOC_YEAR,CDOC_MONTH,KCNT_VAL_INV,CDOC_CANC_IND&$filter=CDOC_YEAR eq '2015' and CDOC_STA_RELEASE eq '3' 6 | */ 7 | 8 | (ConnectionString) => 9 | let 10 | start = Json.Document(Binary.Buffer(Web.Contents(ConnectionString & "&$format=json"))), 11 | d = start[d], 12 | results = d[results], 13 | 14 | transformation = () => 15 | let 16 | table = Table.FromList(results, Splitter.SplitByNothing(), null, null, ExtraValues.Error), 17 | expand = Table.ExpandRecordColumn(table, "Column1", List.RemoveItems(Record.FieldNames(table{0}[Column1]), {"__metadata"}) ) 18 | in 19 | expand, 20 | 21 | output = if List.IsEmpty(results) then null 22 | else transformation() 23 | in 24 | output 25 | -------------------------------------------------------------------------------- /Web.Curl.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Get a curl command string for a given url and options (as used in Web.Contents()) for debugging purposes. 3 | //Usage: 4 | Web.Curl = Load("Web.Curl"), 5 | Web.Curl("http://item.taobao.com/item.htm", [Query=[id="16390081398"]]) 6 | //Result: 'curl "http://item.taobao.com/item.htm?id=16390081398" -v' 7 | */ 8 | 9 | (url as text, optional options as record) as text => 10 | let 11 | //url = "http://item.taobao.com/item.htm?id=16390081398", 12 | //options = [Query=null], 13 | 14 | query = options[Query], 15 | headers = options[Headers], 16 | qList = List.Transform(Record.FieldNames(query), each _ & "=" & Record.Field(query, _)), 17 | hList = List.Transform(Record.FieldNames(headers), each " -H """ & _ & ": " & Record.Field(headers, _) & """"), 18 | qJoined = try "?" & Text.Combine(qList, "&") otherwise "", 19 | hJoined = try Text.Combine(hList, "") otherwise "", 20 | Return = "curl """ & url & qJoined & """" & hJoined & " -v" 21 | in 22 | Return 23 | 24 | -------------------------------------------------------------------------------- /Text.RemoveSymbols.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Remove all uicode symbols from text 3 | //Originally written by Chris Webb: https://cwebbbi.wordpress.com/2014/08/18/removing-punctuation-from-text-in-power-query/ 4 | //Usage: 5 | Text.RemoveSymbols = Load("Text.RemoveSymbols"), 6 | newText = Text.RemoveSymbols("a,b,c") 7 | newText 8 | //Result: newText = "abc" 9 | */ 10 | (inputtext as text) as text => 11 | let 12 | //get a list of lists containing the numbers of Unicode punctuation characters 13 | numberlists = {{0..31},{33..47},{58..64},{91..96},{123..191}}, 14 | //turn this into a single list 15 | combinedlist = List.Combine(numberlists), 16 | //get a list of all the punctuation characters that these numbers represent 17 | punctuationlist = List.Transform(combinedlist, each Character.FromNumber(_)), 18 | //some text to test this on 19 | //inputtext = "Hello! My name is Chris, and I'm hoping that this *cool* post will help you!", 20 | //the text with punctuation removed 21 | outputtext = Text.Remove(inputtext, punctuationlist) 22 | in 23 | outputtext 24 | -------------------------------------------------------------------------------- /Table.CrossJoin.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Returns the Cartesian product (i.e. crossjoin) of two arguments (can be lists or tables). 3 | //Usage: 4 | Table.CrossJoin = Load("Table.CrossJoin"), 5 | Table.CrossJoin({"A","B"},{1..3}) //list version 6 | TableA = #table({"A"},{{"A"},{"B"}}), 7 | TableB = #table({"B"},{{1},{2},{3}}), 8 | Table.CrossJoin(TableA, TableB) //table version 9 | //Result: #table({"A","B"},{{"A",1},{"A",2},{"A",3},{"B",1},{"B",2},{"B",3}}) 10 | */ 11 | 12 | (A as any, B as any) as any => 13 | 14 | let 15 | TableA = if A is table then A else Table.FromValue(A), 16 | TableB = if B is table then B else Table.FromValue(B), 17 | Renamed = if Table.HasColumns(TableA, "Value") 18 | then Table.RenameColumns(TableA, {"Value", "Original"}) 19 | else TableA, 20 | Merged = Table.AddColumn(Renamed, "Table", each TableB), 21 | ColumnsToExpand = List.Distinct(List.Combine(List.Transform(Table.Column(Merged, "Table"), each if _ is table then Table.ColumnNames(_) else {}))), 22 | Expand = Table.ExpandTableColumn(Merged, "Table", ColumnsToExpand) 23 | in 24 | Expand 25 | 26 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | The MIT License (MIT) 2 | 3 | Copyright (c) 2014 tycho01 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. -------------------------------------------------------------------------------- /M.library.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = Table.Sort(Record.ToTable(#shared),{{"Name", Order.Ascending}}), 3 | Categorized = Table.AddColumn(Source, "Status", each if Record.HasFields(#sections[Section1], [Name]) then "User defined" else "Built in"), 4 | // Annoying I need to filter out user defined stuff, but this resolves a cyclic reference caused if both F and this refer to all custom functions (which includes each other) 5 | Filtered = Table.SelectRows(Categorized, each [Status] = "Built in"), 6 | AddType = Table.AddColumn(Filtered, "Type", each Value_TypeToText([Value])), 7 | AddTypeRec = Table.AddColumn(AddType, "TypeRecurs", each Value_TypeToText([Value], true)), 8 | AddCat = Table.AddColumn(AddTypeRec, "Category", each 9 | let 10 | cut = Text.Split(Text.Replace([Name],"_","."),".") 11 | in 12 | (try 13 | if 14 | List.Contains({"Database", "Type"}, cut{1}) 15 | then 16 | cut{1} 17 | else 18 | cut{0} 19 | otherwise 20 | "Custom" 21 | ) 22 | ), 23 | Return = AddCat 24 | in 25 | Return 26 | 27 | -------------------------------------------------------------------------------- /Files.SheetsInFolder.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Create a table with info on all sheets in any Excel files in a particular folder. 3 | //Usage: 4 | Files.SheetsInFolder = Load("Files.SheetsInFolder"), 5 | Source = Files.SheetsInFolder("C:\path\to\my\folder\") 6 | //Result: [a table containing the binary file content, file names, sheet tables, and sheet names for each sheet in each spreadsheet in the given folder] 7 | */ 8 | 9 | (folderPath as text) as table => 10 | let 11 | Source = Folder.Files(folderPath), 12 | FilteredRows = Table.SelectRows(Source, each Text.Start([Extension],3) = ".xl"), 13 | RemovedOtherColumns = Table.SelectColumns(FilteredRows,{"Content", "Name"}), 14 | NoTemps = Table.SelectRows(RemovedOtherColumns, each not Text.StartsWith([Name], "~$")), 15 | InsertedCustom = Table.AddColumn(NoTemps, "Sheets", each Excel.Workbook([Content])), 16 | Expanded = Table.ExpandTableColumn(InsertedCustom, "Sheets", {"Data", "Name","Kind"}, {"D","N","K"}), 17 | NoPrintAreas = Table.SelectRows(Expanded, each not Text.Contains([N], "$")), 18 | OnlySheets = Table.SelectRows(NoPrintAreas, each Text.Contains([K], "Sheet")) 19 | in 20 | OnlySheets 21 | -------------------------------------------------------------------------------- /Web.TimeAndDateCom.GetCountries.pq: -------------------------------------------------------------------------------- 1 | /* 2 | Function returns a table with ID and Country Name used on service http://timeanddate.com 3 | */ 4 | 5 | let 6 | Source = Table.FromColumns({Lines.FromBinary(Web.Contents("http://www.timeanddate.com/calendar/"))}), 7 | #"Filtered Rows" = Table.SelectRows(Source, each Text.Contains([Column1], "select id")), 8 | FullText = #"Filtered Rows"{0}[Column1], 9 | SelectText = Text.Range( FullText, Text.PositionOf( FullText, "<","",Replacer.ReplaceText), 13 | #"Converted to Table" = Table.FromList(#"Replaced Closing Tag", Splitter.SplitByNothing(), null, null, ExtraValues.Error), 14 | #"Split ID and Name" = Table.SplitColumn(#"Converted to Table","Column1",Splitter.SplitTextByEachDelimiter({">"}, QuoteStyle.Csv, false),{"ID", "Country"}), 15 | #"Replaced 'selected'" = Table.ReplaceValue(#"Split ID and Name"," selected","",Replacer.ReplaceText,{"ID"}), 16 | #"Replaced Last Closing Tag" = Table.ReplaceValue(#"Replaced 'selected'","","",Replacer.ReplaceText,{"Country"}), 17 | #"Removed Duplicates" = Table.Distinct(#"Replaced Last Closing Tag"), 18 | #"Sorted Rows" = Table.Sort(#"Removed Duplicates",{{"Country", Order.Ascending}}) 19 | in 20 | #"Sorted Rows" 21 | -------------------------------------------------------------------------------- /Table.CrossJoinTables.pq: -------------------------------------------------------------------------------- 1 | /* 2 | // Cross-join a list of tables into one super table containing every combination of rows of its constituents 3 | // Usage: 4 | Table.CrossJoinTables = Load("Table.CrossJoinTables"), 5 | Table.CrossJoinTables({ 6 | #table({"A","B"},{{"A",1},{"B",2}}), 7 | #table({"C","D"},{{"E",3},{"F",4}}) 8 | }) 9 | // Result: a cross-joined version of all the tables. beware of performance, the result could get big! 10 | */ 11 | 12 | ( 13 | tables as list, 14 | optional TableNames as list, // names to append as prefixes on clash or if desired, default {1, 2, 3, ...} 15 | optional AlwaysPrefix as logical //whether to use append table names if without column name clashes 16 | ) as table => let 17 | CrossJoin = List.Accumulate( 18 | List.Positions(tables), 19 | #table({},{}), 20 | (state, current) => let 21 | CurrentTable = tables{current}, // need check for table type? 22 | CurrentNames = Table.ColumnNames(state), 23 | OldNames = Table.ColumnNames(CurrentTable), 24 | Prefix = if TableNames <> null then try TableNames{current} otherwise Text.From(current+1) else Text.From(current+1), 25 | NewNames = List.Transform(OldNames, each if AlwaysPrefix or List.Contains(CurrentNames, _) then Prefix & "_" & _ else _), 26 | Renamed = Table.RenameColumns(CurrentTable, List.Zip({OldNames, NewNames})) 27 | in 28 | Table.Join(state, {}, Renamed, {}, JoinKind.FullOuter) 29 | ) 30 | in 31 | if List.IsEmpty(tables) 32 | then #table({},{}) 33 | else CrossJoin 34 | -------------------------------------------------------------------------------- /ByD.GetReportMetadataIdName.pq: -------------------------------------------------------------------------------- 1 | /* 2 | Get report data from SAP Business ByDesign using Power Query (through OData) 3 | ByD.GetReportMetadataIdName pulls two columns Id and Name from report metadata 4 | 5 | */ 6 | 7 | (TenantId as text, ReportId as text) => 8 | let 9 | Source = Binary.Buffer(Web.Contents("https://my" & TenantId & ".sapbydesign.com/sap/byd/odata/cc_home_analytics.svc/$metadata?entityset=RP" & ReportId & "QueryResults")), 10 | Content = Xml.Tables(Source), 11 | DataServices = Content{0}[DataServices], 12 | #"http://schemas microsoft com/ado/2008/09/edm" = DataServices{0}[#"http://schemas.microsoft.com/ado/2008/09/edm"], 13 | #"Expand Schema" = Table.ExpandTableColumn(#"http://schemas microsoft com/ado/2008/09/edm", "Schema", {"EntityType"}, {"Schema.EntityType"}), 14 | #"Expand Schema.EntityType2" = Table.ExpandTableColumn(#"Expand Schema", "Schema.EntityType", {"Property"}, {"Property"}), 15 | #"Expand Property" = Table.ExpandTableColumn(#"Expand Schema.EntityType2", "Property", 16 | {"Attribute:Name", "http://www.sap.com/Protocols/SAPData"}, {"Attribute:Name", "http://www.sap.com/Protocols/SAPData"}), 17 | #"Expand http://www.sap.com/Protocols/SAPData" = Table.ExpandTableColumn(#"Expand Property", "http://www.sap.com/Protocols/SAPData", {"Attribute:label"}, {"Attribute:label"}), 18 | #"Renamed Columns" = Table.RenameColumns(#"Expand http://www.sap.com/Protocols/SAPData",{{"Attribute:Name", "Id"}, {"Attribute:label", "Name"}}), 19 | res = Table.SelectRows(#"Renamed Columns", each ([Id] <> "ID" and [Id] <> "TotaledProperties")) 20 | in 21 | res 22 | -------------------------------------------------------------------------------- /M.functions.pq: -------------------------------------------------------------------------------- 1 | let 2 | Type.ToText = Load("Type.ToText"), 3 | Value.ToText = Load("Value.ToText"), 4 | Text.Count = Load("Text.Count"), 5 | Source = M_library, 6 | Functions = Table.SelectRows(Source, each Value.Is([Value], type function)), 7 | AddFType = Table.AddColumn(Functions, "FType", each Value.Type([Value])), 8 | AddReturn = Table.AddColumn(AddFType, "Returns", each Type.FunctionReturn([FType])), 9 | AddRetTxt = Table.AddColumn(AddReturn, "RetText", each Type.ToText([Returns])), 10 | AddRetRec = Table.AddColumn(AddRetTxt, "RetRecursive", each Type.ToText([Returns], true)), 11 | AddRetNull = Table.AddColumn(AddRetRec, "RetNullable", each Type.IsNullable([Returns])), 12 | AddRetType = Table.AddColumn(AddRetNull, "RetType", each let Type = Type.ToText(Type.NonNullable([Returns])) in if Type = "anynonnull" and [RetNullable] then "any" else Type), 13 | AddParams = Table.AddColumn(AddRetType, "Parameters", each Type.FunctionParameters([FType])), 14 | AddNumPars = Table.AddColumn(AddParams, "NumParams", each Record.FieldCount([Parameters])), 15 | AddReqd = Table.AddColumn(AddNumPars, "Required", each Type.FunctionRequiredParameters([FType])), 16 | AddSig = Table.AddColumn(AddReqd, "Signature", each Value.ToText([Value])), 17 | AddSigRec = Table.AddColumn(AddSig, "SigRecursive", each [Name] & " => " & Value.ToText([Value], true)), 18 | AddTally = Table.AddColumn(AddSigRec, "Times Used", each Text.Count(Text_Queries, [Name])), 19 | GoodCols = Table.RemoveColumns(AddTally, {"Type", "TypeRecurs"}), 20 | Return = GoodCols 21 | in 22 | Return 23 | 24 | -------------------------------------------------------------------------------- /Table.ExpandRecords.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Fully expands any nested records within a table 3 | //Originally written by Chris Webb: https://cwebbbi.wordpress.com/2014/05/21/expanding-all-columns-in-a-table-in-power-query/ 4 | //Usage: 5 | Table.ExpandRecords = Load("Table.ExpandRecords"), 6 | tbl = Table.FromColumns({ {1}, {[c=0,d=2]} }, {"a", "b"}), 7 | Table.ExpandRecords(tbl) //, null, true 8 | //Result: [an expanded version of the given table with nested records] 9 | */ 10 | 11 | ( 12 | TableToExpand as table, //the table you wish to expand 13 | optional ColumnNames as list, //the columns to expand 14 | optional AppendParentNames as logical //whether to use append parent column names e.g. "ul.li", or just keep "li" where possible (reverting to the qualified name in case of a colum name clash) 15 | ) as table => 16 | let 17 | ColumnNames = if (ColumnNames=null) then Table.ColumnNames(TableToExpand) else ColumnNames, 18 | count = List.Count(ColumnNames), 19 | AppendParentNames = if (AppendParentNames=null) then false else AppendParentNames 20 | in 21 | 22 | List.Accumulate(ColumnNames, TableToExpand, (tbl, col) => let 23 | ColumnsToExpand = List.Distinct(List.Combine(List.Transform(Table.Column(tbl, col), 24 | each if _ is record then Record.FieldNames(_) else {}))), 25 | NewColumnNames = List.Transform(ColumnsToExpand, each if (AppendParentNames or List.Contains(ColumnNames,_)) then col & "." & _ else _), 26 | CanExpandCol = List.Count(ColumnsToExpand) > 0 27 | in if CanExpandCol 28 | then Table.ExpandRecordColumn(tbl, col, ColumnsToExpand, NewColumnNames) 29 | else tbl 30 | ) 31 | -------------------------------------------------------------------------------- /Table.RowsCombination2.pq: -------------------------------------------------------------------------------- 1 | (tables as list) => 2 | let 3 | // tables = { Table1, Table2, Table3, Table4, Table5 }, 4 | 5 | add_tables = List.Last( 6 | List.Generate( ()=> 7 | [i=0, T=tables{0}], 8 | each [i] <= List.Count( tables ) - 1, 9 | each [i=[i]+1, 10 | T= Table.AddColumn( [T], "Custom." & Text.From( i ), each tables{ i } ) ], 11 | each [T] ) ), 12 | 13 | expand_tables = List.Last( 14 | List.Generate( ()=> 15 | [i=0, T=add_tables], 16 | each [i] <=List.Count( tables ) - 1, 17 | each [i=[i]+1, 18 | T= Table.ExpandTableColumn( [T], 19 | "Custom." & Text.From( i ), 20 | Table.ColumnNames( tables{0} ), 21 | List.Transform( Table.ColumnNames( tables{0} ), each Text.From(_) & "." & Text.From( i ) ) ) ], 22 | each [T] ) ), 23 | 24 | #"Added Index" = Table.AddIndexColumn(expand_tables, "Index", 1, 1), 25 | #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Added Index", {"Index"}, "Attribute", "NewValue"), 26 | #"Split Column by Delimiter" = Table.SplitColumn(#"Unpivoted Other Columns","Attribute",Splitter.SplitTextByEachDelimiter({"."}, QuoteStyle.Csv, false),{"Attribute.1", "Attribute.2"}), 27 | #"Pivoted Column" = Table.Pivot(#"Split Column by Delimiter", List.Distinct(#"Split Column by Delimiter"[Attribute.1]), "Attribute.1", "NewValue"), 28 | #"Removed Columns" = Table.RemoveColumns(#"Pivoted Column",{"Attribute.2"}) 29 | in 30 | #"Removed Columns" 31 | -------------------------------------------------------------------------------- /Vlookup.pq: -------------------------------------------------------------------------------- 1 | // originally created by Ken Puls 2 | // http://www.excelguru.ca/blog/2015/01/28/creating-a-vlookup-function-in-power-query/ 3 | 4 | (lookup_value as any, table_array as table, col_index_number as number, optional approximate_match as logical ) as any => 5 | 6 | let 7 | /*Provide optional match if user didn't */ 8 | matchtype = if approximate_match = null then true else approximate_match, 9 | 10 | /*Get name of return column */ 11 | Cols = Table.ColumnNames(table_array), 12 | ColTable = Table.FromList(Cols, Splitter.SplitByNothing(), null, null, ExtraValues.Error), 13 | ColName_match = Record.Field(ColTable{0},"Column1"), 14 | ColName_return = Record.Field(ColTable{col_index_number - 1},"Column1"), 15 | 16 | /*Find closest match */ 17 | SortData = Table.Sort(table_array,{{ColName_match, Order.Descending}}), 18 | RenameLookupCol = Table.RenameColumns(SortData,{{ColName_match, "Lookup"}}), 19 | RemoveExcess = Table.SelectRows(RenameLookupCol, each [Lookup] <= lookup_value), 20 | ClosestMatch= 21 | if Table.IsEmpty(RemoveExcess)=true 22 | then "#N/A" 23 | else Record.Field(RemoveExcess{0},"Lookup"), 24 | 25 | /*What should be returned in case of approximate match? */ 26 | ClosestReturn= 27 | if Table.IsEmpty(RemoveExcess)=true 28 | then "#N/A" 29 | else Record.Field(RemoveExcess{0},ColName_return), 30 | 31 | /*Modify result if we need an exact match */ 32 | Return = 33 | if matchtype=true 34 | then ClosestReturn 35 | else if lookup_value = ClosestMatch 36 | then ClosestReturn 37 | else "#N/A" 38 | 39 | in 40 | Return 41 | 42 | -------------------------------------------------------------------------------- /Value.TypeToText.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Returns a simple string representation of a value's type, which allows easy filtering, unlike the built-in Value.Type() 3 | //Usage: 4 | let 5 | Value.TypeToText = Load("Value.TypeToText") 6 | in 7 | Value.TypeToText({1,2,3}) 8 | //Result: "list" 9 | */ 10 | 11 | (Value as any, optional Recurs as logical) as text => 12 | let 13 | Recurs = if (Recurs<>null) then Recurs else false, 14 | Type.ToText = Load("Type.ToText"), 15 | 16 | Type = Value.Type(Value), 17 | ToText = if Value.Is(Value, type type) and Recurs then 18 | "type " & Type.ToText(Value, Recurs) 19 | else 20 | Type.ToText(Type, Recurs), 21 | /* 22 | CaseValues = { 23 | { (x)=> (try x)[HasError], "error" }, 24 | { (x)=> x = null, "null" }, 25 | { (x)=> Value.Is(x, type type), "type"}, 26 | { (x)=> Value.Is(x, type function), "function"}, 27 | { (x)=> Value.Is(x, type table), "table"}, 28 | { (x)=> Value.Is(x, type record), "record"}, 29 | { (x)=> Value.Is(x, type list), "list"}, 30 | { (x)=> Value.Is(x, type binary), "binary"}, 31 | { (x)=> Value.Is(x, type logical), "logical"}, 32 | { (x)=> Value.Is(x, type number), "number"}, 33 | { (x)=> Value.Is(x, type text), "text"}, 34 | { (x)=> Value.Is(x, type date), "date"}, 35 | { (x)=> Value.Is(x, type time), "time"}, 36 | { (x)=> Value.Is(x, type datetime), "datetime"}, 37 | { (x)=> Value.Is(x, type datetimezone), "datetimezone"}, 38 | { (x)=> Value.Is(x, type duration), "duration"}, 39 | { (x)=> true, "?"} 40 | }, 41 | Return = List.First(List.Select(CaseValues, each _{0}(Value))){1} 42 | */ 43 | Return = ToText 44 | in Return 45 | 46 | -------------------------------------------------------------------------------- /Table.ExpandTables.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Fully expands any nested tables within a table 3 | //Originally written by Chris Webb: https://cwebbbi.wordpress.com/2014/05/21/expanding-all-columns-in-a-table-in-power-query/ 4 | //Usage: 5 | Table.ExpandTables = Load("Table.ExpandTables"), 6 | xml = Xml.Tables("Book1123Book2123"), 7 | Table.ExpandTables(xml) //, null, true 8 | //Result: [an expanded version of the given table with nested tables] 9 | */ 10 | 11 | ( 12 | TableToExpand as table, //the table you wish to expand 13 | optional ColumnNames as list, //the columns to expand 14 | optional AppendParentNames as logical //whether to use append parent column names e.g. "ul.li", or just keep "li" where possible (reverting to the qualified name in case of a colum name clash) 15 | ) as table => 16 | let 17 | ColumnNames = if (ColumnNames=null) then Table.ColumnNames(TableToExpand) else ColumnNames, 18 | count = List.Count(ColumnNames), 19 | AppendParentNames = if (AppendParentNames=null) then false else AppendParentNames 20 | in 21 | 22 | List.Accumulate(ColumnNames, TableToExpand, (tbl, col) => let 23 | ColumnsToExpand = List.Distinct(List.Combine(List.Transform(Table.Column(tbl, col), 24 | each if _ is table then Table.ColumnNames(_) else {}))), 25 | NewColumnNames = List.Transform(ColumnsToExpand, each if (AppendParentNames or List.Contains(ColumnNames,_)) then col & "." & _ else _), 26 | CanExpandCol = List.Count(ColumnsToExpand) > 0 27 | in if CanExpandCol 28 | then Table.ExpandTableColumn(tbl, col, ColumnsToExpand, NewColumnNames) 29 | else tbl) 30 | -------------------------------------------------------------------------------- /Stat.Trend.pq: -------------------------------------------------------------------------------- 1 | // Calculates a trend according to Excel's TREND-function but without the option to define your own slope and intercept. 2 | // Slope and intercept will be calculated according to the input data. 3 | // Use: Just pass the values from the past that shall be considered (YList) and the number of intervalls (NoOfIntervalls) to be calculated for the future. 4 | //Argument_1// YList: The set of y-values you already know in the relationship y = mx + b 5 | //Argument_2// NoOfIntervalls: New x-values for which you want TREND to return corresponding y-values// Suggested improvement: Completely harmonize to EXCEL-TREND: 6 | // a) Options to omitt intercept ([CONST]=FALSE) 7 | // b) Use specific [known_x's] instead of default {0...n} 8 | // c) Harmonize input parameter syntax 9 | 10 | 11 | (YList as list, NoOfIntervalls as number) => 12 | let 13 | Source = Table.FromColumns({YList}), 14 | xAxis = Table.AddIndexColumn(Source, "Index", 1, 1), 15 | Rename1 = Table.RenameColumns(xAxis,{{"Column1", "y"}, {"Index", "x"}}), 16 | AvgX = List.Average(Rename1[x]), 17 | AvgY = List.Average(Rename1[y]), 18 | x = Table.AddColumn(Rename1, "xX", each [x]-List.Average(Rename1[x])), 19 | y = Table.AddColumn(x, "yY", each [y]-List.Average(x[y])), 20 | xy = Table.AddColumn(y, "xy", each [xX]*[yY]), 21 | xXx = Table.AddColumn(xy, "xXx", each [xX]*[xX]), 22 | a = List.Sum(xXx[xy])/List.Sum(xXx[xXx]), 23 | b = AvgY-(a*AvgX), 24 | ListIntervalls = {List.Max(Rename1[x])+1..List.Max(Rename1[x])+NoOfIntervalls}, 25 | TableIntervalls = Table.FromList(ListIntervalls, Splitter.SplitByNothing(), null, null, ExtraValues.Error), 26 | Rename = Table.RenameColumns(TableIntervalls,{{"Column1", "x"}}), 27 | Values = Table.AddColumn(Rename, "y", each [x]*a+b), 28 | TREND = Table.Combine({Rename1,Values}) 29 | in 30 | TREND 31 | -------------------------------------------------------------------------------- /Web.FetchSequentially.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Sequentially scrape a given list of URLs with a given minimum delay between fetches 3 | //Usage: 4 | 5 | let 6 | Web.FetchSequentially = Load("Web.FetchSequentially"), 7 | BaseUrl = "http://example.com/?p=", 8 | Pages = List.Numbers(1, 5), 9 | Urls = List.Transform(Pages, each BaseUrl & Number.ToText(_)) 10 | in 11 | Web.FetchSequentially(Urls) 12 | 13 | //Result: [a list of decoded contents for each of the input URLs] 14 | */ 15 | 16 | ( 17 | Urls as list, //type {text} 18 | optional Delay as number, //in seconds, default 1 19 | optional Encoding as number, //https://msdn.microsoft.com/en-us/library/windows/desktop/dd317756(v=vs.85).aspx 20 | optional Options //see options below 21 | ) as list => 22 | 23 | let 24 | Web.Scrape = Load("Web.Scrape"), 25 | Delay = if (Delay<>null) then Delay else 1, 26 | Encoding = if (Encoding<>null) then Encoding else TextEncoding.Utf8, 27 | Options = if (Options<>null) then Options else [ 28 | //ApiKeyName = "", 29 | //Content = "", 30 | Query = [], 31 | Headers = [] 32 | ], 33 | Count = List.Count(Urls) 34 | in 35 | 36 | List.Buffer( 37 | List.Skip( 38 | List.Generate( 39 | () => [ 40 | i = 0, 41 | Page = null 42 | ], 43 | each [i] <= Count, 44 | each let 45 | Url = Urls{[i]}, 46 | GetPage = (uri as text) => Text.FromBinary( 47 | //Binary.Buffer(Web.Contents(uri, Options)) 48 | Web.Scrape(uri, Options) 49 | , Encoding) 50 | in [ 51 | i = [i] + 1, 52 | Page = Function.InvokeAfter(()=>GetPage(Url), #duration(0,0,0,Delay)) 53 | ], 54 | each [Page] 55 | ) 56 | ) 57 | ) 58 | 59 | -------------------------------------------------------------------------------- /Table.AddScrape.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Add a column based on sequentially scraped results to a table. It's like Table.AddColumn() + Web.Contents(), except combining those directly would rape the server rather than inserting proper politeness delays. 3 | //Usage: 4 | 5 | let 6 | Web.AddScrape = Load("Web.AddScrape"), 7 | BaseUrl = "http://example.com/?p=", 8 | Pages = List.Numbers(1, 5), 9 | Tbl = Table.FromList(Pages), 10 | in 11 | Web.AddScrape(Tbl, "Value", BaseUrl) 12 | 13 | //Result: [a table with the response bodies of the URLs with the given variables added into a new column] 14 | */ 15 | 16 | ( 17 | Tbl as table, //the table in question to add scrape results to 18 | Col as text, //the column of variable content to append to the base URL 19 | BaseUrl as text, //the base URL 20 | optional newColName as text, //the name of the new column to be added, default Content 21 | optional Delay as number, //in seconds, default 1 22 | optional Encoding as number, //https://msdn.microsoft.com/en-us/library/windows/desktop/dd317756(v=vs.85).aspx 23 | optional Options //see options in Web.FetchSequentially 24 | ) as table => 25 | let 26 | newColName = if (newColName<>null) then newColName else "Content", 27 | Web.FetchSequentially = Load("Web.FetchSequentially"), 28 | 29 | InputList = Table.Column(Tbl, Col), 30 | DedupedList = List.Distinct(InputList), 31 | InputUrls = List.Transform(DedupedList, each BaseUrl & Expression.Constant(_)), 32 | ScrapedList = Web.FetchSequentially(InputUrls, Delay, Encoding, Options), 33 | ScrapedRecord = Record.FromList(ScrapedList, DedupedList), 34 | Merged = Table.AddColumn(Tbl, newColName, each Record.Field(ScrapedRecord, Record.Field(_, Col))), 35 | Buffered = Table.Buffer(Merged), 36 | 37 | Return = Buffered 38 | in 39 | Return 40 | 41 | -------------------------------------------------------------------------------- /Table.ExpandAll.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Fully expands any nested records and tables within a table 3 | //Originally written by Chris Webb: https://cwebbbi.wordpress.com/2014/05/21/expanding-all-columns-in-a-table-in-power-query/ 4 | //Usage: 5 | Table.ExpandAll = Load("Table.ExpandAll"), 6 | xml = Xml.Tables("Book1123Book2123"), 7 | Table.ExpandAll(xml) //, null, true 8 | //Result: [an expanded version of the given table with nested records/tables] 9 | */ 10 | 11 | ( 12 | TableToExpand as table, //the table you wish to expand 13 | optional ColumnNumber as number, //the column number to expand 14 | optional AppendParentNames as logical //whether to use append parent column names e.g. "ul.li", or just keep "li" where possible (reverting to the qualified name in case of a colum name clash) 15 | ) as table => 16 | let 17 | ColumnNumber = if (ColumnNumber=null) then 0 else ColumnNumber, 18 | AppendParentNames = if (AppendParentNames=null) then false else AppendParentNames 19 | in 20 | 21 | List.Last( 22 | List.Generate( 23 | ()=>[ 24 | col = ColumnNumber, 25 | Tbl = TableToExpand 26 | ], 27 | each [col]<=(Table.ColumnCount([Tbl])-1), 28 | each let 29 | ColumnNames = Table.ColumnNames([Tbl]), 30 | ColumnName = ColumnNames{[col]}, 31 | ColumnsToExpand = List.Distinct(List.Combine(List.Transform(Table.Column([Tbl], ColumnName), 32 | each if _ is table then Table.ColumnNames(_) else {}))), 33 | NewColumnNames = List.Transform(ColumnsToExpand, each if (AppendParentNames or List.Contains(ColumnNames,_)) then ColumnName & "." & _ else _), 34 | CanExpandCol = List.Count(ColumnsToExpand)>0 35 | in [ 36 | Tbl = if CanExpandCol 37 | then Table.ExpandTableColumn([Tbl], ColumnName, ColumnsToExpand, NewColumnNames) 38 | else [Tbl], 39 | col = if CanExpandCol 40 | then [col] 41 | else [col]+1 42 | ], 43 | each [Tbl] 44 | ) 45 | ) 46 | -------------------------------------------------------------------------------- /Type.ToText.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Returns a simple string representation of a type, which allows easy filtering 3 | //Usage: 4 | Type.ToText = Load("Type.ToText"), 5 | Type.ToText(type list) 6 | //Result: "list" 7 | */ 8 | 9 | let Type.ToText = 10 | (Type as any, optional Recurs as logical) as text => 11 | let 12 | Record.TransformJoin = Load("Record.TransformJoin"), 13 | Recurs = if (Recurs<>null) then Recurs else false, 14 | 15 | CaseValues = { 16 | { (x)=> (try x)[HasError], "error" }, 17 | { (x)=> Type.Is(x, type type), "type"}, //if Recurs then else 18 | { (x)=> Type.Is(x, type function), "function"}, 19 | { (x)=> Type.Is(x, type table), if Recurs then "table " & @Type.ToText(Type.TableRow(NonNull), Recurs) else "table"}, 20 | { (x)=> Type.Is(x, type record), if Recurs then 21 | let 22 | Record = Type.RecordFields(NonNull) 23 | in "[" & Record.TransformJoin(Record, (k,v) => 24 | (if v[Optional] then "optional " else "") & Expression.Identifier(k) & " = " & @Type.ToText(v[Type], Recurs) 25 | ) & "]" 26 | else "record"}, 27 | { (x)=> Type.Is(x, type list), if Recurs then "{" & @Type.ToText(Type.ListItem(NonNull), Recurs) & "}" else "list"}, 28 | { (x)=> Type.Is(x, type binary), "binary"}, 29 | { (x)=> Type.Is(x, type logical), "logical"}, 30 | { (x)=> Type.Is(x, type number), "number"}, 31 | { (x)=> Type.Is(x, type text), "text"}, 32 | { (x)=> Type.Is(x, type date), "date"}, 33 | { (x)=> Type.Is(x, type time), "time"}, 34 | { (x)=> Type.Is(x, type datetime), "datetime"}, 35 | { (x)=> Type.Is(x, type datetimezone), "datetimezone"}, 36 | { (x)=> Type.Is(x, type duration), "duration"}, 37 | { (x)=> Type.Is(type anynonnull, x), "anynonnull"}, 38 | { (x)=> Type.Is(type null, x), "null"}, 39 | { (x)=> Type.Is(None.Type, x), "none"}, 40 | // { (x)=> Type.Is(type any, x), "any"}, 41 | { (x)=> true, "?"} 42 | }, 43 | NonNull = Type.NonNullable(Type), 44 | Return = if Type.Is(type any, Type) then "any" 45 | else (if Type.IsNullable(Type) then "nullable " else "") 46 | & List.First(List.Select(CaseValues, each _{0}(NonNull))){1} 47 | in Return 48 | in Type.ToText 49 | -------------------------------------------------------------------------------- /Table.ExpandTablesRecursive.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Fully expands any nested tables within a table 3 | //Originally written by Chris Webb: https://cwebbbi.wordpress.com/2014/05/21/expanding-all-columns-in-a-table-in-power-query/ 4 | //Usage: 5 | Table.ExpandTablesRecursive = Load("Table.ExpandTablesRecursive"), 6 | xml = Xml.Tables("Book1123Book2123"), 7 | Table.ExpandTablesRecursive(xml) //, null, true 8 | //Result: [an expanded version of the given table with nested tables] 9 | */ 10 | 11 | ( 12 | TableToExpand as table, //the table you wish to expand 13 | optional ColumnNumber as number, //the column number to expand 14 | optional AppendParentNames as logical //whether to use append parent column names e.g. "ul.li", or just keep "li" where possible (reverting to the qualified name in case of a colum name clash) 15 | ) as table => 16 | let 17 | ColumnNumber = if (ColumnNumber=null) then 0 else ColumnNumber, 18 | AppendParentNames = if (AppendParentNames=null) then false else AppendParentNames 19 | in 20 | 21 | List.Last( 22 | List.Generate( 23 | ()=>[ 24 | col = ColumnNumber, 25 | Tbl = TableToExpand 26 | ], 27 | each [col]<=(Table.ColumnCount([Tbl])-1), 28 | each let 29 | ColumnNames = Table.ColumnNames([Tbl]), 30 | ColumnName = ColumnNames{[col]}, 31 | ColumnsToExpand = List.Distinct(List.Combine(List.Transform(Table.Column([Tbl], ColumnName), 32 | each if _ is table then Table.ColumnNames(_) else {}))), 33 | NewColumnNames = List.Transform(ColumnsToExpand, each if (AppendParentNames or List.Contains(ColumnNames,_)) then ColumnName & "." & _ else _), 34 | CanExpandCol = List.Count(ColumnsToExpand)>0 35 | in [ 36 | Tbl = if CanExpandCol 37 | then Table.ExpandTableColumn([Tbl], ColumnName, ColumnsToExpand, NewColumnNames) 38 | else [Tbl], 39 | col = if CanExpandCol 40 | then [col] 41 | else [col]+1 42 | ], 43 | each [Tbl] 44 | ) 45 | ) 46 | 47 | -------------------------------------------------------------------------------- /Table.RemoveBlankColumns.pq: -------------------------------------------------------------------------------- 1 | /* 2 | // Allows to remove blank (empty) columns from a table like "Remove Empty Rows" UI option. 3 | // Optional parameter for empty strings ("") removing (also as nulls) 4 | 5 | // Usage: 6 | Table.RemoveBlankColumns = Load("Table.RemoveBlankColumns"), 7 | 8 | // remove column with nulls AND empty strings: 9 | Table.RemoveBlankColumns(Table.FromRecords({[A = null, B = 1],[A = null, B = 2],[A = "", B = 3]}), true) 10 | // Result: Table.FromRecords({[B = 1],[B = 2],[B = 3]}) 11 | 12 | // remove column with nulls only: 13 | Table.RemoveBlankColumns(Table.FromRecords({[A = null, B = 1],[A = null, B = 2],[A = "", B = 3]})) 14 | // Result: Table.FromRecords({[A = null, B = 1],[A = null, B = 2],[A = "", B = 3]}) 15 | 16 | */ 17 | 18 | ( 19 | tab as table, // table to clean 20 | optional EmptStr as nullable logical // flag to remove columns which contains nulls OR empty strings - only 21 | ) as table => 22 | 23 | let 24 | ToRemove = {null} & (if EmptStr = true then {""} else {}), // list of "blank" values 25 | tabDemoted = Table.DemoteHeaders(tab), 26 | tabTransposed = Table.Transpose(tabDemoted), 27 | RowsRemoved = Table.SelectRows( 28 | tabTransposed, 29 | each not List.IsEmpty( 30 | List.RemoveMatchingItems( 31 | Record.FieldValues(Record.RemoveFields(_, "Column1")), // after demote+transpose first column is allways with columns headers 32 | ToRemove) 33 | ) 34 | ), 35 | tabTransposedAgain = Table.Transpose(RowsRemoved) 36 | 37 | in 38 | Table.PromoteHeaders(tabTransposedAgain) 39 | 40 | /* 41 | // Alternative version (performance didn't checked between versions): 42 | 43 | let 44 | ToRemove = {null} & (if EmptStr = true then {""} else {}) // list of "blank" values 45 | 46 | in 47 | List.Accumulate( 48 | Table.ColumnNames(tab), 49 | tab, 50 | (state, current)=> 51 | if List.IsEmpty( 52 | List.RemoveMatchingItems( 53 | Table.Column(state, current), 54 | ToRemove) 55 | ) 56 | then Table.RemoveColumns(state, current) 57 | else state 58 | ) 59 | */ 60 | -------------------------------------------------------------------------------- /F.pq: -------------------------------------------------------------------------------- 1 | /* 2 | F (short for function), like Load(), provides one calling interface to access functions either imported (faster) or loaded (fallback), so code could be left agnostic to whether the queries are available locally, though whether this is really necessary is left up to the user to decide. One reasonable use case would be allowing many workbooks to access a shared library of queries from their files without needing to import them to each workbook after every change. 3 | 4 | Imported or loadable functions could be referenced as any of the following: 5 | Load("Text.ReplaceAll") 6 | Load("Text_ReplaceAll") 7 | F[Text.ReplaceAll] 8 | F[Text_ReplaceAll] 9 | 10 | Intended benefits of F over Load(): 11 | - shorter 12 | - may help avoiding duplicate executions of file imports (if applicable) -- needs further testing though. 13 | */ 14 | 15 | let 16 | Shared = #shared, 17 | 18 | 19 | //Record.Rename = Load("Record.Rename"), 20 | //Record.Rename = Record_Rename, 21 | /* 22 | Record.Rename = (Rec as record, Lambda as function) as record => 23 | let 24 | Keys = Record.FieldNames(Rec), 25 | Values = Record.FieldValues(Rec), 26 | Renamed = List.Transform(Keys, each Lambda(_, Record.Field(Rec, _))), 27 | Recorded = Record.FromList(Values, Renamed) 28 | in 29 | Recorded, 30 | */ 31 | //cyclic reference...? 32 | //SharedPeriods = Record.Rename(Shared, (k,v) => Text.Replace(k, "_", ".")), 33 | 34 | SharedPeriods = Record.FromList(Record.FieldValues(Shared), List.Transform(Record.FieldNames(Shared), each Text.Replace(_, "_", "."))), 35 | 36 | SharedMerged = Record.Combine({Shared, SharedPeriods}), 37 | //If I can make a wrapper function to enable profiling/persistence, wrap these as well 38 | 39 | Files = Folder.Files(LoadPath), 40 | MFiles = Table.SelectRows(Files, each Text.Lower([Extension]) = ".m" 41 | // and [Folder Path] = LoadPath // non-recursive 42 | ), 43 | NoExt = Table.TransformColumns(MFiles, {"Name", each Text.Start(_, Text.Length(_)-2)}), 44 | CustomNames = Table.Column(NoExt, "Name"), 45 | Underscored = List.Transform(CustomNames, each Text.Replace(_, ".", "_")), 46 | CustomBoth = List.Union({CustomNames, Underscored}), 47 | CustomLoaded = Record.FromList(List.Transform(CustomBoth, Load), CustomBoth), 48 | SharedAndLoaded = Record.Combine({CustomLoaded, SharedMerged}), 49 | 50 | Return = SharedAndLoaded 51 | in 52 | Return 53 | 54 | -------------------------------------------------------------------------------- /Table.RowsCombination.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Returns the Cartesian product of rows of list of tables having same structure 3 | // Usage: 4 | Table.RowsCombination( {Table1, Table2} ) 5 | 6 | //Result: all possible combination of rows from Table1 and Table2 7 | // How it was created: 8 | // https://bondarenkoivan.wordpress.com/2016/09/20/combination-of-rows-of-tables-list-in-power-query/ 9 | */ 10 | 11 | (tables as list)=> 12 | let 13 | tableslist = List.Buffer( tables ), 14 | list_as_numbers = List.Buffer( List.Transform( tableslist, each { 1 .. Table.RowCount(_) } ) ), 15 | 16 | // Tycho's function 17 | // https://github.com/tycho01/pquery/blob/master/List.CrossJoin.m 18 | 19 | list_crossjoin = (A as list, B as list) as table => 20 | let 21 | firstList = List.RemoveNulls(A), 22 | secondList = List.RemoveNulls(B), 23 | firstLength = List.Count(firstList), 24 | secondLength = List.Count(secondList), 25 | resultFirstList = List.Generate( () => 0, 26 | each _ < firstLength * secondLength, 27 | each _ + 1, 28 | each firstList{ Number.IntegerDivide(_, secondLength) }), 29 | 30 | resultSecondList = List.Repeat( secondList, firstLength), 31 | list_to_table = Table.FromColumns( {resultFirstList, resultSecondList} ), 32 | // my adjustment - merge and leave only merged column 33 | add_merged = Table.AddColumn(list_to_table, "Merged", each Text.Combine({Text.From([Column1]), Text.From([Column2])}, ""), type text), 34 | remove_other = Table.SelectColumns( add_merged,{"Merged"}) 35 | in 36 | remove_other, 37 | 38 | // loop through list of numbers (each element is qty of table rows) 39 | generator = List.Accumulate(list_as_numbers, null, (acc, x) => if acc = null then x else Table.Column(list_crossjoin(acc, x), "Merged")), 40 | 41 | // function that collects corresponding records (rows) from initial tables - loop through combination of indices 42 | get_tables_rows = (combination as text) => List.Last( List.Generate( 43 | ()=> [i=0, L={}], 44 | each [i] <= List.Count( tableslist ), 45 | each [i=[i]+1, 46 | L = List.Combine( { [L], { tableslist{ [i] }{ Number.From( Text.Range( combination, [i], 1) )-1 } } } ) ], 47 | each [L] ) ), 48 | 49 | resulting_list = List.Transform( generator, each Table.FromRecords( get_tables_rows(_) ) ), 50 | list_to_table = Table.FromList(resulting_list, Splitter.SplitByNothing(), null, null, ExtraValues.Error), 51 | result = Table.ExpandTableColumn( list_to_table, "Column1", Table.ColumnNames( tableslist{0} ), Table.ColumnNames( tableslist{0} ) ) 52 | in 53 | result 54 | -------------------------------------------------------------------------------- /Text.Like.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Allows doing fuzzy string comparisons akin to SQL's LIKE 3 | //Usage: 4 | Text.Like = Load("Text.Like"), 5 | Text.Like("the cat sat on the mat", "%cat%sat%mat%") 6 | //Result: true 7 | */ 8 | 9 | //Originally written by Chris Webb: https://cwebbbi.wordpress.com/2014/05/27/implementing-a-basic-likewildcard-search-function-in-power-query/ 10 | (Phrase as text, Pattern as text) as logical => 11 | let 12 | //Split pattern up into a list using % as a delimiter 13 | PatternList = Text.Split(Pattern, "%"), 14 | //if the first character in the pattern is % then the first item in the list is an empty string 15 | StartsWithWc = (List.First(PatternList)=""), 16 | //if the last character in the pattern is % then the last item in the list is an empty string 17 | EndsWithWc = (List.Last(PatternList)=""), 18 | //if the first character is not % then we have to match the first string in the pattern with the opening characters of the phrase 19 | StartsTest = if (StartsWithWc=false) 20 | then Text.StartsWith(Phrase, List.First(PatternList)) 21 | else true, 22 | //if the last item is not % then we have to match the final string in the pattern with the final characters of the phrase 23 | EndsText = if (EndsWithWc=false) 24 | then Text.EndsWith(Phrase, List.Last(PatternList)) 25 | else true, 26 | //now we also need to check that each string in the pattern appears in the correct order in the phrase and to do this we need to declare a function PhraseFind 27 | PhraseFind = (Phrase as text, SearchString as list) => 28 | let 29 | //does the first string in the pattern appear in the phrase? 30 | StringPos = Text.PositionOf(Phrase, SearchString{0}, Occurrence.First), 31 | PhraseFindOutput = 32 | if 33 | //if string not find then return false 34 | (StringPos=-1) 35 | then false 36 | else if 37 | //we have found the string in the pattern, and if this is the last string in the pattern, return true 38 | List.Count(SearchString)=1 39 | then true 40 | else 41 | //if it isn't the last string in the pattern test the next string in the pattern by removing the first string from the pattern list and all text up to and including the string we have found in the phrase 42 | (true and 43 | @PhraseFind( 44 | Text.RemoveRange(Phrase, 0, StringPos + Text.Length(SearchString{0})), 45 | List.RemoveRange(SearchString, 0, 1))) 46 | in 47 | PhraseFindOutput, 48 | //return true if we have passed all tests 49 | Output = StartsTest and EndsText and PhraseFind(Phrase, PatternList) 50 | in 51 | Output 52 | -------------------------------------------------------------------------------- /ByD.GetReportData.pq: -------------------------------------------------------------------------------- 1 | /* 2 | Get report data from SAP Business ByDesign using Power Query (through OData) 3 | Pulls firstly report as OData send it, then get metadata of report, and rename IDs to Names 4 | 5 | ConnectionString = https://myXXXXXX.sapbydesign.com/sap/byd/odata/cc_home_analytics.svc/RPCRMCIVIB_Q0001QueryResults?$top=100000& 6 | $select=CDOC_YEAR,CDOC_MONTH,KCNT_VAL_INV,CDOC_CANC_IND&$filter=CDOC_YEAR eq '2015' and CDOC_STA_RELEASE eq '3' 7 | TenantId = "XXXXXX" 8 | ReportId = "CRMCIVIB_Q0001" // Invoice Volume 9 | */ 10 | 11 | (TenantId as text, ReportId as text, ConnectionString) => 12 | let 13 | start = Json.Document(Binary.Buffer(Web.Contents(ConnectionString & "&$format=json"))), 14 | d = start[d], 15 | results = d[results], 16 | 17 | transformation = () => 18 | let 19 | table = Table.FromList(results, Splitter.SplitByNothing(), null, null, ExtraValues.Error), 20 | expand = Table.ExpandRecordColumn(table, "Column1", List.RemoveItems(Record.FieldNames(table{0}[Column1]), {"__metadata"}) ), 21 | names = 22 | let 23 | Source = Binary.Buffer(Web.Contents("https://my" & TenantId & ".sapbydesign.com/sap/byd/odata/cc_home_analytics.svc/$metadata?entityset=RP" & ReportId & "QueryResults")), 24 | Content = Xml.Tables(Source), 25 | DataServices = Content{0}[DataServices], 26 | #"http://schemas microsoft com/ado/2008/09/edm" = DataServices{0}[#"http://schemas.microsoft.com/ado/2008/09/edm"], 27 | #"Expand Schema" = Table.ExpandTableColumn(#"http://schemas microsoft com/ado/2008/09/edm", "Schema", {"EntityType"}, {"Schema.EntityType"}), 28 | #"Expand Schema.EntityType2" = Table.ExpandTableColumn(#"Expand Schema", "Schema.EntityType", {"Property"}, {"Property"}), 29 | #"Expand Property" = Table.ExpandTableColumn(#"Expand Schema.EntityType2", "Property", {"Attribute:Name", "http://www.sap.com/Protocols/SAPData"}, {"Attribute:Name", "http://www.sap.com/Protocols/SAPData"}), 30 | #"Expand http://www.sap.com/Protocols/SAPData" = Table.ExpandTableColumn(#"Expand Property", "http://www.sap.com/Protocols/SAPData", {"Attribute:label"}, {"Attribute:label"}), 31 | #"Renamed Columns" = Table.RenameColumns(#"Expand http://www.sap.com/Protocols/SAPData",{{"Attribute:Name", "Id"}, {"Attribute:label", "Name"}}), 32 | res = Table.SelectRows(#"Renamed Columns", each ([Id] <> "ID" and [Id] <> "TotaledProperties")) 33 | in 34 | res, 35 | result = Table.RenameColumns(expand, Table.ToColumns(Table.Transpose(names)), MissingField.Ignore) 36 | in 37 | result, 38 | 39 | output = if List.IsEmpty(results) then null 40 | else transformation() 41 | in 42 | output 43 | -------------------------------------------------------------------------------- /Table.JoinMany.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Join 3+ tables at once 3 | //Usage: 4 | Table.JoinMany = Load("Table.JoinMany"), 5 | TableA = #table({"country","language"},{{"US", "English"},{"Netherlands", "Dutch"},{"Japan", "Japanese"}}), 6 | TableB = #table({"country","continent"},{{"US", "Americas"},{"Netherlands", "Europe"},{"Japan", "Asia"}}), 7 | TableC = #table({"country","population"},{{"US", 316148990},{"Netherlands", 16770000},{"Japan", 127600000}}), 8 | Table.JoinMany({TableA,TableB,TableC},"country") //,{"lang","cont","pop"} 9 | //Result: #table({"country","language","continent","population"},{{"US", "English", "Americas", 316148990},{"Netherlands", "Dutch", "Europe", 16770000},{"Japan", "Japanese", "Asia", 127600000}}) 10 | */ 11 | 12 | ( 13 | tables as list, //the tables you wish to join 14 | key as any, //the key(s) to join them by, either as single string or as a list with 1 key per table 15 | //names as list, //names of the tables used for prefixing identically named columns 16 | optional joinKind as nullable number //how to join the tables: JoinKind.Inner (default), JoinKind.LeftOuter, JoinKind.RightOuter, JoinKind.FullOuter, JoinKind.LeftAnti, JoinKind.RightAnti 17 | ) as table => 18 | let 19 | joinKind = if (joinKind=null) then JoinKind.Inner else joinKind, 20 | count = List.Count(tables), 21 | Combined = List.Last( 22 | List.Generate( 23 | ()=>[ 24 | i = 1, 25 | Tbl = tables{0} 26 | ], 27 | each [i]<=count, 28 | each let 29 | i1 = [i]-1, //index 30 | i2 = [i], 31 | n1 = "JoinCol1", //names{i1}, //table name for prefixing 32 | n2 = "JoinCol2", //names{i2}, 33 | k1 = if key is list then key{i1} else key, //column key 34 | k2 = if key is list then key{i2} else key, 35 | key1 = n1 & "." & k1, //qualified key (because PQ Join doesn't allow joining tables with identical column names) 36 | key2 = n2 & "." & k2, 37 | t1 = [Tbl], 38 | t2 = tables{i2}, 39 | tab1 = Table.RenameColumns(t1,{k1,key1}), 40 | tab2 = Table.RenameColumns(t2,{k2,key2}), 41 | Merged = Table.Join(tab1, key1, tab2, key2, joinKind), 42 | AddCol = Table.AddColumn(Merged, k2, each let 43 | r1 = Record.Field(_,key1), 44 | r2 = Record.Field(_,key2) 45 | in if r1 = null then r2 else r1), 46 | Removed = Table.RemoveColumns(AddCol, {key1, key2}) 47 | in [ 48 | Tbl = Removed, 49 | i = [i]+1 50 | ], 51 | each [Tbl] 52 | ) 53 | ), 54 | KeyColName = if key is list then key{count} else key, 55 | MergedColNames = Table.ColumnNames(Combined), 56 | KeyToFront = List.Combine({{KeyColName},List.RemoveItems(MergedColNames,{KeyColName})}), 57 | Reordered = Table.ReorderColumns(Combined, KeyToFront) 58 | 59 | in 60 | Reordered 61 | -------------------------------------------------------------------------------- /Table.UnpivotByNumbers.pq: -------------------------------------------------------------------------------- 1 | let func = 2 | /* The header rows to be unpivoted must sit in the first rows of your table and NOT in the header itself. 3 | The header will be ignored, so if it shall be unpivoted as well, demote it first.*/ 4 | (Table as table, FirstNColumnsToKeep as number, FirstNRowsToKeep as number) => 5 | 6 | let 7 | Source = Table, 8 | // Determine column names to keep 9 | FirstColumnsToKeep = List.FirstN(Table.ColumnNames(Source), FirstNColumnsToKeep), 10 | 11 | // Those columns who are not to keep shall be unpivoted 12 | UnpivotColumns = List.Difference(Table.ColumnNames(Source), FirstColumnsToKeep), 13 | 14 | // Create list of lists with one row per header row 15 | Headers = if FirstNRowsToKeep=0 then {UnpivotColumns} else List.Buffer(Table.ToRows(Table.FirstN(Table.SelectColumns(Source, UnpivotColumns),FirstNRowsToKeep))), 16 | 17 | // This step effectively unpivots the values of every row of the table and creates one table per row with an index column indicating the values relative positions. 18 | ValuesRecord = Table.AddColumn(Source, "Custom", each Table.AddIndexColumn(Table.FromColumns(List.Union({Headers, {Record.FieldValues(Record.SelectFields(_, UnpivotColumns))}})), "IndexUnpivot",1,1)), 19 | Cleanup = Table.RemoveColumns(ValuesRecord, UnpivotColumns), 20 | 21 | // Remove the first rows who hold the "to-be-unpivoted" headers. 22 | RemoveTopNRows = Table.Skip(Cleanup,FirstNRowsToKeep), 23 | 24 | // Retrieve the column names of the unpivoted columns-table 25 | ColsToExpand = List.Union(List.Transform(RemoveTopNRows[Custom], each Table.ColumnNames(_))), 26 | 27 | // Expand the columns and add ".1" to now columns to avoid duplicate column names 28 | fnUnpivotByNumbers = Table.ExpandTableColumn(RemoveTopNRows, "Custom", ColsToExpand, List.Transform(ColsToExpand, each _&".1") ) 29 | in 30 | fnUnpivotByNumbers 31 | 32 | // Documentation 33 | , documentation = [ 34 | Documentation.Name = " fnTable.UnpivotByNumbers 35 | ", Documentation.Description = " Unpivots a table according to the number of columns and header rows passed on in the parameters 36 | " , Documentation.LongDescription = " Unpivots a table according to the number of columns and header rows passed on in the parameters 37 | ", Documentation.Category = " Table functions 38 | ", Documentation.Source = " local 39 | ", Documentation.Author = " Imke Feldmann: www.TheBIccountant.com 40 | ", Documentation.Examples = {[Description = " 41 | " , Code = " Check this blogpost explaining how it works: http://wp.me/p6lgsG-zW 42 | ", Result = " 43 | "]}] 44 | in 45 | Value.ReplaceType(func, Value.ReplaceMetadata(Value.Type(func), documentation)) 46 | 47 | -------------------------------------------------------------------------------- /List.Dates.HolidaysRU.pq: -------------------------------------------------------------------------------- 1 | // Function gets list of non-working days (weekends and official holidays) 2 | // from official source "Open Data" managed by Analytical Center of Russian Federation 3 | // 4 | // Function has two arguments - From_Year, To_Year 5 | // which allows to restrict period of time that you need for your data model. 6 | // 7 | // Usage: 8 | // List.Dates.HolidaysRU( 2015, 2016 ) 9 | // Response: 10 | // List of non-working days in Russian Federations for years 2015 and 2016 11 | 12 | (from_year as number, to_year as number) => 13 | let 14 | fGetLatestURL = 15 | let 16 | Source = Table.FromColumns({Lines.FromBinary(Web.Contents("http://data.gov.ru/node/19107/code-passport"))}), 17 | #"Filtered Rows" = Table.SelectRows(Source, each Text.Contains([Column1], "Гиперссылка (URL) на набор")), 18 | #"Get Text with URL" = #"Filtered Rows"{0}[Column1], 19 | #"Position of HTTP" = Text.PositionOf(#"Get Text with URL", "http"), 20 | #"Position of CSV" = Text.PositionOf( #"Get Text with URL", ".csv" ), 21 | URL = Text.Range( #"Get Text with URL", #"Position of HTTP", #"Position of CSV" - #"Position of HTTP" + 4 ) 22 | in 23 | URL, 24 | 25 | Source = Csv.Document(Web.Contents( fGetLatestURL ),[Delimiter=",", Columns=13, Encoding=65001, QuoteStyle=QuoteStyle.None]), 26 | #"Promoted Headers" = Table.PromoteHeaders( Source ), 27 | #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"Год/Месяц", Int64.Type}}), 28 | #"Filtered Rows1" = Table.SelectRows(#"Changed Type", each [#"Год/Месяц"] >= from_year and [#"Год/Месяц"] <= to_year ), 29 | #"Renamed Columns1" = Table.RenameColumns(#"Filtered Rows1",{{"Январь", "1"}, {"Февраль", "2"}, {"Март", "3"}, {"Апрель", "4"}, {"Май", "5"}, {"Июнь", "6"}, {"Июль", "7"}, {"Август", "8"}, {"Сентябрь", "9"}, {"Октябрь", "10"}, {"Ноябрь", "11"}, {"Декабрь", "12"}, {"Год/Месяц", "Год"}}), 30 | #"Unpivoted Other Columns" = Table.UnpivotOtherColumns(#"Renamed Columns1", {"Год"}, "Attribute", "Value"), 31 | #"Split Column by Delimiter" = Table.SplitColumn(#"Unpivoted Other Columns","Value",Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv) ), 32 | #"Unpivoted Other Columns1" = Table.UnpivotOtherColumns(#"Split Column by Delimiter", {"Год", "Attribute"}, "Attribute.1", "Value"), 33 | #"Removed Columns" = Table.RemoveColumns(#"Unpivoted Other Columns1",{"Attribute.1"}), 34 | #"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Attribute", "Месяц"}, {"Value", "День"}}), 35 | #"Filtered Rows" = Table.SelectRows(#"Renamed Columns", each not Text.Contains([День], "*")), 36 | #"Changed Type1" = Table.TransformColumnTypes(#"Filtered Rows",{{"Месяц", Int64.Type}, {"День", Int64.Type}}), 37 | #"Added Custom" = Table.AddColumn(#"Changed Type1", "Date", each #date( [Год], [Месяц], [День] ), type date), 38 | #"Removed Other Columns1" = Table.SelectColumns(#"Added Custom",{"Date"}) 39 | 40 | in 41 | #"Removed Other Columns1" 42 | -------------------------------------------------------------------------------- /LoadFunctionFromGithub.pq: -------------------------------------------------------------------------------- 1 | /* 2 | Allows dynamically loading an M function from a text file (extension: .pq) for use in Power Query. 3 | This allows you to easily reuse a set of functions in multiple workbooks without having to sync each change to 4 | all files using it. 5 | 6 | The point here is that by separating universally useful functions from an individual workbook, 7 | you will feel encouraged to use more modular code, solving each common sub-problem only once, 8 | rather than remaining stuck in 'vanilla' M and resolving the same problems repeatedly. 9 | 10 | Moreover, coding this way will also further facilitate sharing code with other Power Query users, 11 | allowing for a more collaborative environment, gradually pushing forward the Power Query community as a whole. 12 | 13 | Nevertheless, if the function in question has already been imported into the workbook, 14 | the local copy will be used. This would allow you to either call the function locally right away, 15 | or Load() the existing function again. 16 | 17 | Using Load() would not only allow you to use functions in their intended naming conventions 18 | (i.e. Text.ReplaceAll rather than with the period replaced by an underscore), but would technically 19 | also allow you to add additional wrapper functions around your code, which could be used to enable 20 | persistent memoization (using say Redis) or code profiling calls... though presumably no-one has done this so far yet. 21 | 22 | Parameters: 23 | fnName: name of the text file you wish to load without the .pq extension 24 | optional BasePath: the file path to look in for the text file; default path hardcoded 25 | 26 | Usage: 27 | // loads the function Type.ToText from file 'Type.ToText.pq' in the load path 28 | let 29 | Type.ToText = Load("Type.ToText") 30 | in 31 | Type.ToText(type {number}) 32 | 33 | // Result: "list" 34 | 35 | Warning: this function may triggers a Formula.Firewall error for referencing both an external query 36 | (LoadPath) as well as external files. 37 | 38 | If you run into this, you can get around this by enabling the FastCombine option, in Power Query Options -> 39 | Privacy -> Fast Combine -> 'Ignore the Privacy levels and potentially improve performance'. 40 | 41 | If you'd prefer not to do this however, you could also just replace the LoadPath reference below with a static 42 | absolute path reference. 43 | 44 | */ 45 | 46 | (fnName as text, optional BasePath as text) as function => 47 | let 48 | //If you wish to hardcode the path to load the queries from, you can edit the following line: 49 | DefaultPath = "C:\PQuery\", 50 | GitHubPath = "https://raw.githubusercontent.com/IvanBond/pquery/master/", 51 | 52 | BasePath = if (BasePath <> null) then BasePath else DefaultPath, 53 | Path = BasePath & (if Text.End(BasePath, 1) <> "\" then "\" else ""), 54 | File = Path & fnName & ".pq", 55 | 56 | Function = try Expression.Evaluate(Text.FromBinary(Binary.Buffer(File.Contents(File))), #shared) 57 | otherwise Expression.Evaluate( Text.FromBinary(Binary.Buffer(Web.Contents(GitHubPath & fnName & ".pq"))), #shared) 58 | in 59 | Function 60 | -------------------------------------------------------------------------------- /Old.Load.pq: -------------------------------------------------------------------------------- 1 | /* 2 | Allows dynamically loading an M function from a text file (extension: .pq) in a given folder for use in Power Query. This allows you to easily reuse a set of functions in multiple workbooks without having to sync each change to all files using it. 3 | 4 | The point here is that by separating universally useful functions from an individual workbook, you will feel encouraged to use more modular code, solving each common sub-problem only once, rather than remaining stuck in 'vanilla' M and resolving the same problems repeatedly. 5 | 6 | Moreover, coding this way will also further facilitate sharing code with other Power Query users, allowing for a more collaborative environment, gradually pushing forward the Power Query community as a whole. 7 | 8 | Nevertheless, if the function in question has already been imported into the workbook, the local copy will be used. This would allow you to either call the function locally right away, or Load() the existing function again. 9 | 10 | Using Load() would not only allow you to use functions in their intended naming conventions (i.e. Text.ReplaceAll rather than with the period replaced by an underscore), but would technically also allow you to add additional wrapper functions around your code, which could be used to enable persistent memoization (using say Redis) or code profiling calls... though presumably no-one has done this so far yet. 11 | 12 | Parameters: 13 | fnName: name of the text file you wish to load without the .pq extension 14 | optional BasePath: the file path to look in for the text file; defaults to the path specified in the LoadPath query. 15 | 16 | Usage: 17 | // loads the function Type.ToText from file 'Type.ToText.pq' in the load path 18 | let 19 | Type.ToText = Load("Type.ToText") 20 | in 21 | Type.ToText(type {number}) 22 | 23 | // Result: "list" 24 | 25 | Warning: this function may triggers a Formula.Firewall error for referencing both an external query (LoadPath) as well as external files. 26 | 27 | If you run into this, you can get around this by enabling the FastCombine option, in Power Query Options -> Privacy -> Fast Combine -> 'Ignore the 28 | Privacy levels and potentially improve performance'. 29 | 30 | If you'd prefer not to do this however, you could also just replace the LoadPath reference below with a static absolute path reference. 31 | 32 | */ 33 | 34 | (fnName as text, optional BasePath as text) as function => 35 | let 36 | //If you wish to hardcode the path to load the queries from, you can edit the following line: 37 | DefaultPath = LoadPath, 38 | //DefaultPath = "D:\pquery", 39 | BasePath = if (BasePath<>null) then BasePath else DefaultPath, 40 | Path = BasePath & (if Text.End(BasePath, 1) <> "\" then "\" else ""), 41 | File = Path & fnName & ".pq", 42 | AltFile = Path & Text.Replace(fnName, "_", ".") & ".pq", //just in case... 43 | Source = Text.FromBinary(Binary.Buffer( 44 | try File.Contents(File) 45 | otherwise File.Contents(AltFile) 46 | )), 47 | Function = try Expression.Evaluate(Text.Replace(fnName, ".", "_"), #shared) //if already imported into the workbook just use the existing one 48 | otherwise Expression.Evaluate(Source, #shared) //if not imported yet try loading it from the text file in the folder 49 | in 50 | Function 51 | 52 | -------------------------------------------------------------------------------- /Web.TimeAndDateCom.GetCountryCalendar.pq: -------------------------------------------------------------------------------- 1 | /* 2 | Function returns a table with list of dates for specified years, and indicator for each day 3 | is it a working or non-working day in specified country. 4 | Argument Country requires specific ID, which can be received by another function 5 | https://github.com/IvanBond/pquery/blob/master/Web.TimeAndDateCom.GetCountries.m 6 | 7 | Sample Excel file:https://1drv.ms/x/s!AsARcUyPYj4LgqMAHv8GM3pe3ZE_Ug 8 | */ 9 | 10 | ( Country as text, 11 | Year1 as number, 12 | Year2 as nullable number) => 13 | 14 | let 15 | 16 | Y2 = if Year2 = null then Year1 else Year2, 17 | 18 | Source = Table.FromColumns({Lines.FromBinary(Web.Contents("https://www.timeanddate.com/calendar/custom.html?mty=1&ctf=4&hol=9&typ=3&hod=7&holmark=1&display=2&cdt=1&wdf=3&mtm=2&cols=1&country=" & 19 | Country & "&year=" & Text.From(Year1) & "&y2=" & Text.From(Y2) ))}), 20 | 21 | #"Filtered Rows" = Table.SelectRows(Source, each Text.Contains([Column1], "
")), 22 | CalAreaText = #"Filtered Rows"{0}[Column1], 23 | Custom1 = Text.PositionOf( CalAreaText, "", Occurrence.Last ), 25 | TableAsText = Text.Range( CalAreaText, Custom1, Custom2 - Custom1 + 8 ), 26 | CalTableAsList = Text.Split( TableAsText, "" ), 27 | #"Replaced Closing tr" = List.ReplaceValue(CalTableAsList,"","",Replacer.ReplaceText), 28 | #"Converted to Table" = Table.FromList(#"Replaced Closing tr", Splitter.SplitByNothing(), null, null, ExtraValues.Error), 29 | #"Filtered Target Rows" = Table.SelectRows(#"Converted to Table", each Text.Contains([Column1], "
") ), 30 | #"Added Headers" = Table.AddColumn(#"Filtered Target Rows", "Titles", each if Text.Contains( [Column1], "") then [Column1] else null), 31 | #"Added Days rows" = Table.AddColumn(#"Added Headers", "Day Rows", each if not Text.Contains( [Column1], "") then [Column1] else null), 32 | #"Added Working Days Ind" = Table.AddColumn(#"Added Days rows", "Working Day", each if Text.Contains( [Column1], "cn minititle") then "N" else "Y"), 33 | #"Added MM YYYY" = Table.AddColumn(#"Added Working Days Ind", "MM YYYY", each try Text.Range([Titles], Text.PositionOf([Titles], """>")+2, 7) otherwise null), 34 | #"Added Days Dirty" = Table.AddColumn(#"Added MM YYYY", "Days Dirty", each if [Day Rows] <> null then Text.Range([Day Rows], Text.PositionOf([Day Rows], ">")+1,2) else null), 35 | #"Clean Days Dirty" = Table.ReplaceValue(#"Added Days Dirty","<","",Replacer.ReplaceText,{"Days Dirty"}), 36 | #"Filled Down MM YYYY" = Table.FillDown(#"Clean Days Dirty",{"MM YYYY"}), 37 | #"Removed Other Columns" = Table.SelectColumns(#"Filled Down MM YYYY",{"Working Day", "MM YYYY", "Days Dirty"}), 38 | #"Filtered nulls" = Table.SelectRows(#"Removed Other Columns", each ([Days Dirty] <> null)), 39 | #"Convert to Date" = Table.AddColumn(#"Filtered nulls", "Date", each #date( Number.From(Text.End([MM YYYY],4)), Number.From(Text.Start([MM YYYY],2)), Number.From([Days Dirty]))), 40 | #"Removed Other Columns1" = Table.SelectColumns(#"Convert to Date",{"Date", "Working Day"}), 41 | #"Added Country" = Table.AddColumn(#"Removed Other Columns1", "Country", each Country), 42 | #"Reordered Columns" = Table.ReorderColumns(#"Added Country",{"Country", "Date", "Working Day"}), 43 | #"Changed Type" = Table.TransformColumnTypes(#"Reordered Columns",{{"Date", type date}, {"Working Day", type text}, {"Country", type text}}), 44 | #"Sorted Rows" = Table.Sort(#"Changed Type",{{"Date", Order.Ascending}}) 45 | in 46 | #"Sorted Rows" 47 | -------------------------------------------------------------------------------- /Value.ToText.pq: -------------------------------------------------------------------------------- 1 | /* 2 | //Returns a string representation of a value, which works even on containers, unlike the built-in Text.From() 3 | //Usage: 4 | Value.ToText = Load("Value.ToText"), 5 | Value.ToText({1,2,3}) 6 | //Result: "{1, 2, 3}" 7 | */ 8 | 9 | let Value.ToText = 10 | (Val as any, optional RecursTypes as logical) as text => 11 | let 12 | Record.TransformJoin = Load("Record.TransformJoin"), 13 | Type.ToText = Load("Type.ToText"), 14 | RecursTypes = if (RecursTypes<>null) then RecursTypes else false, 15 | Tried = (try Val), 16 | Value = if Tried[HasError] then Tried[Error] else Tried[Value], 17 | /* 18 | DurationVals = {Duration.Days, Duration.Hours, Duration.Minutes, Duration.Seconds}, 19 | DateVals = {Date.Year, Date.Month, Date.Day}, 20 | TimeVals = {Time.Hour, Time.Minute, Time.Second}, 21 | ZoneVals = {DateTimeZone.ZoneHours, DateTimeZone.ZoneMinutes}, 22 | GetNumbers = (vals as list, obj as any) as text => Text.Combine(List.Transform(vals, each Number.ToText(Function.Invoke(_, {obj}))), ","), 23 | */ 24 | CaseValues = { 25 | //{ (x)=> (try x)[HasError], "error " & @Value.ToText((try Value)[Error], RecursTypes) }, 26 | { (x)=> Value.Is(x, type type), Type.ToText(Value, RecursTypes) }, 27 | { (x)=> Value.Is(x, type function), 28 | let 29 | Type = Value.Type(Value), 30 | Params = Type.FunctionParameters(Type), 31 | Reqd = Type.FunctionRequiredParameters(Type), 32 | Ret = Type.FunctionReturn(Type) 33 | in 34 | "function (" & 35 | Record.TransformJoin(Params, (k,v) => 36 | (if List.PositionOf(Record.FieldNames(Params), k) >= Reqd then "optional " else "") & 37 | k & " as " & @Value.ToText(v, RecursTypes) 38 | ) 39 | & ") as " & @Value.ToText(Ret, RecursTypes) 40 | }, 41 | { (x)=> Value.Is(x, type table), "#table(" & @Value.ToText(Table.ColumnNames(Value), RecursTypes) & ", " & @Value.ToText(Table.ToRows(Value), RecursTypes) & ")"}, 42 | { (x)=> Value.Is(x, type record), "[" & 43 | Record.TransformJoin(Value, (k,v) => k & "=" & @Value.ToText(v, RecursTypes)) 44 | & "]" }, 45 | { (x)=> Value.Is(x, type list), "{" & Text.Combine(List.Transform(Value, each @Value.ToText(_, RecursTypes)), ", ") & "}" }, 46 | { (x)=> x = null, "null" }, 47 | /* 48 | { (x)=> Value.Is(x, type text), """" & Value & """" }, 49 | { (x)=> Value.Is(x, type binary), "#binary(""" & Binary.ToText(Value) & """)" }, 50 | { (x)=> Value.Is(x, type date), "#date(" & GetNumbers(DateVals, Value) & ")" }, //alt: Date.ToText(Value) 51 | { (x)=> Value.Is(x, type time), "#time(" & GetNumbers(TimeVals, Value) & ")" }, //alt: Time.ToText(Value) 52 | { (x)=> Value.Is(x, type datetime), 53 | let 54 | Date = DateTime.Date(Value), 55 | Time = DateTime.Time(Value) 56 | in 57 | "#datetime(" & GetNumbers(DateVals, Date) & ", " & GetNumbers(TimeVals, Time) & ")" 58 | }, //alt: DateTime.ToText(Value) 59 | { (x)=> Value.Is(x, type datetimezone), 60 | let 61 | DateTime = DateTimeZone.RemoveZone(Value), 62 | Date = DateTime.Date(DateTime), 63 | Time = DateTime.Time(DateTime) 64 | in 65 | "#datetimezone(" & GetNumbers(DateVals, Date) & ", " & GetNumbers(TimeVals, Time) & ", " & GetNumbers(ZoneVals, Value) & ")" 66 | }, //alt: DateTimeZone.ToText(Value) 67 | { (x)=> Value.Is(x, type duration), "#duration(" & GetNumbers(DurationVals, Value) & ")" }, //alt: Duration.ToText(Value) 68 | // { (x)=> Value.Is(x, type logical), Logical.ToText(Value) }, 69 | // { (x)=> Value.Is(x, type number), Number.ToText(Value) }, 70 | { (x)=> true, Text.From(Value) } 71 | */ 72 | { (x)=> true, Expression.Constant(Value) } 73 | }, 74 | Return = List.First(List.Select(CaseValues, each _{0}(Value))){1} 75 | in Return 76 | in Value.ToText 77 | -------------------------------------------------------------------------------- /Load.pq: -------------------------------------------------------------------------------- 1 | /* 2 | Allows dynamically loading an M function from a text file (extension: .pq) in a given folder for use in Power Query. This allows you to easily reuse a set of functions in multiple workbooks without having to sync each change to all files using it. 3 | 4 | The point here is that by separating universally useful functions from an individual workbook, you will feel encouraged to use more modular code, solving each common sub-problem only once, rather than remaining stuck in 'vanilla' M and resolving the same problems repeatedly. 5 | 6 | Moreover, coding this way will also further facilitate sharing code with other Power Query users, allowing for a more collaborative environment, gradually pushing forward the Power Query community as a whole. 7 | 8 | Nevertheless, if the function in question has already been imported into the workbook, the local copy will be used. This would allow you to either call the function locally right away, or Load() the existing function again. 9 | 10 | Using Load() would not only allow you to use functions in their intended naming conventions (i.e. Text.ReplaceAll rather than with the period replaced by an underscore), but would technically also allow you to add additional wrapper functions around your code, which could be used to enable persistent memoization (using say Redis) or code profiling calls... though presumably no-one has done this so far yet. 11 | 12 | Parameters: 13 | fnName: name of the text file you wish to load without the .pq extension 14 | optional BasePath: the file path to look in for the text file; default path hardcoded 15 | 16 | Usage: 17 | // loads the function Type.ToText from file 'Type.ToText.pq' in the load path 18 | let 19 | Type.ToText = Load("Type.ToText") 20 | in 21 | Type.ToText(type {number}) 22 | 23 | // Result: "list" 24 | 25 | Warning: this function may triggers a Formula.Firewall error for referencing both an external query (LoadPath) as well as external files. 26 | 27 | If you run into this, you can get around this by enabling the FastCombine option, in Power Query Options -> Privacy -> Fast Combine -> 'Ignore the 28 | Privacy levels and potentially improve performance'. 29 | 30 | If you'd prefer not to do this however, you could also just replace the LoadPath/DefaultPath reference below with a static 31 | absolute path reference. 32 | 33 | */ 34 | 35 | (fnName as text, optional BasePath as text) as function => 36 | // IvanBond version 37 | let 38 | //If you wish to hardcode the path to load the queries from, you can edit the following line: 39 | DefaultPath = "C:\PQuery\", 40 | GitHubPath = "https://raw.githubusercontent.com/hohlick/pquery/master/", 41 | 42 | BasePath = if (BasePath <> null) then BasePath else DefaultPath, 43 | Path = BasePath & (if Text.End(BasePath, 1) <> "\" then "\" else ""), 44 | File = Path & fnName & ".pq", 45 | 46 | Function = try Expression.Evaluate(Text.Replace(fnName, ".", "_"), #shared) //if already imported into the workbook just use the existing one 47 | otherwise try Expression.Evaluate(Text.FromBinary(Binary.Buffer(File.Contents(File))), #shared) //if not imported yet try loading it from the text file in the folder 48 | otherwise Expression.Evaluate( Text.FromBinary(Binary.Buffer(Web.Contents(GitHubPath & fnName & ".pq"))), #shared) // if folder not found - take from GitHubPath 49 | in 50 | Function 51 | /* 52 | Here comes old Load.pq function: 53 | 54 | (fnName as text, optional BasePath as text) as function => 55 | 56 | let 57 | //If you wish to hardcode the path to load the queries from, you can edit the following line: 58 | DefaultPath = LoadPath, 59 | //DefaultPath = "D:\pquery", 60 | BasePath = if (BasePath<>null) then BasePath else DefaultPath, 61 | Path = BasePath & (if Text.End(BasePath, 1) <> "\" then "\" else ""), 62 | File = Path & fnName & ".pq", 63 | AltFile = Path & Text.Replace(fnName, "_", ".") & ".pq", //just in case... 64 | Source = Text.FromBinary(Binary.Buffer( 65 | try File.Contents(File) 66 | otherwise File.Contents(AltFile) 67 | )), 68 | Function = try Expression.Evaluate(Text.Replace(fnName, ".", "_"), #shared) //if already imported into the workbook just use the existing one 69 | otherwise Expression.Evaluate(Source, #shared) //if not imported yet try loading it from the text file in the folder 70 | in 71 | Function 72 | */ 73 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # pquery 2 | 3 | This is a collection of functions written in the M language for use in Microsoft Excel's [Power Query plugin](http://office.microsoft.com/en-us/excel/download-microsoft-power-query-for-excel-FX104018616.aspx). 4 | 5 | ## Introduction 6 | 7 | Rather than manually adding the functions to different Excel workbooks, users can instead leave their files in any directory, and either batch import them into your workbook using Excel 2016 VBA (see my sample workbook [here](http://1drv.ms/1GmrhDl)), or by dynamically loading them into Power Query using something like the `Load()` function (see `Load.pq`). To use Load() you'll need to add it to every applicable workbook though. You can hard-code in the path to the folder where you put the functions from this repository, or set it in the specified cell in the above-mentioned sample workbook for use in that. 8 | 9 | To manually add the Load query, click 'From Other Sources' in the Power Query ribbon tab, select 'Blank Query' (bottom option), open the Advanced Editor in the View tab, and paste in the below snippet (after adjusting file path). Click Done, name the query 'Load', and click 'Apply & Close' in the Home tab. 10 | 11 | If you have your M queries in files, you may well prefer to edit them from a text editor like Notepad++. With Matt Mason's [language file](http://www.mattmasson.com/2014/11/notepad-language-file-for-the-power-query-formula-language-m/) for this you will get nice color coding too! 12 | 13 | The main point here is that by separating universally useful functions from an individual workbook, you will feel encouraged to use more modular code, solving each common sub-problem only once, rather than remaining stuck in 'vanilla' M and resolving the same problems repeatedly. 14 | 15 | Moreover, coding this way will also further facilitate sharing code with other Power Query users, allowing for a more collaborative environment. 16 | 17 | Admittedly, Microsoft languages have rarely been known for encouraging open-source collaboration, and the Power Query community is currently small. But will that mean we cannot assemble a powerful code library like those of the JavaScript community? 18 | 19 | ## Usage 20 | 21 | ### to use M code in workbooks without having to import every query/function: 22 | 23 | * [get](https://github.com/tycho01/pquery/archive/master.zip) and unzip this repo, or in case you'd like to contribute back, open a command prompt in your desired location (in Windows Explorer type `cmd` in the address bar) and run command `git clone https://github.com/tycho01/pquery.git`. 24 | * copy [`LoadPath.example.pq`](https://github.com/tycho01/pquery/blob/master/LoadPath.example.pq) as `LoadPath.pq` and replace its entire content with the path where you put the query files; e.g. `"D:\pquery\"`. 25 | * manually import the `Load.pq` and `LoadPath.pq` functions into your workbook, keeping their names as `Load` and `LoadPath`. 26 | * now use the Load function to load queries from the folder you specified. i.e. if you write `Text_Between = Load("Text.Between"),`, it's going to give you the function located at `YOUR_PATH\Text.Between.pq`. 27 | 28 | ### to allow sharing your workbook: 29 | 30 | * use [my Power Query workbook](http://1drv.ms/1GmrhDl) (requires Excel 2016) to batch import the desired queries into your workbook. Chris Webb also posted the used [VBA code](http://1drv.ms/1KUxm9g), and did an introductory [blog post](https://blog.crossjoin.co.uk/2015/06/10/power-queryexcel-2016-vba-examples/) about it. 31 | 32 | ## Related Projects (feel free to add!) 33 | - [`Power-BI-Desktop-Query-Extensions`](https://github.com/tnclark8012/Power-BI-Desktop-Query-Extensions) - newer library including in-app function documentation 34 | - [`PowerQueryExtensions`](https://github.com/Hugoberry/PowerQueryExtensions) - library using the recent [`DataConnectors`](https://github.com/Microsoft/DataConnectors) API to expose the functions from this and the above library 35 | - [`m-tools`](https://github.com/acaprojects/m-tools) - functional programming helpers 36 | - [`PowerQueryFunctional`](https://github.com/Hugoberry/PowerQueryFunctional) - `DataConnectors` port of the above library 37 | - [`atom-language-m`](https://github.com/jaykilleen/atom-language-m) - Atom support for M 38 | - [`LibPQ`](https://github.com/sio/LibPQ) - a collection of reusable modules for Power Query M Language 39 | 40 | For more Power Query related repos check out some of the following users (sorted alphabetically, feel free to add!): 41 | - [@acaprojects](https://github.com/acaprojects?tab=repositories) 42 | - [@hohlick](https://github.com/hohlick?tab=repositories) 43 | - [@Hugoberry](https://github.com/Hugoberry?tab=repositories) 44 | - [@ImkeF](https://github.com/ImkeF/M/tree/master/Library) 45 | - [@IvanBond](https://github.com/IvanBond?tab=repositories) 46 | - [@maxim-uvarov](https://github.com/maxim-uvarov?tab=repositories) 47 | --------------------------------------------------------------------------------