From e7b256f055aeaa273ff6a0b98740bb0465586783 Mon Sep 17 00:00:00 2001 From: Charl Potgieter Date: Tue, 19 May 2020 21:34:46 +1000 Subject: [PATCH] Update Spreadsheet metadata --- .../PowerQueries/ChartOfAccounts.m | 10 + .../PowerQueries/DataAccess_AdHocJnls.m | 4 + .../PowerQueries/DataAccess_ChartOfAccounts.m | 5 + .../PowerQueries/DataAccess_JnlMetaData.m | 5 + .../DataAccess_JnlsfromOutputTab.m | 9 + .../DataAccess_OpeningBalalances.m | 4 + SpreadsheetMetadata/PowerQueries/Journals.m | 86 +++++++++ .../PowerQueries/TrialBalance.m | 114 +++++++++++ .../fn_MonthlyFromAnnualisedPercentage.m | 5 + .../PowerQueries/fn_std_DatesBetween.m | 64 +++++++ .../PowerQueries/fn_std_Parameters.m | 46 +++++ .../PowerQueries/param_DateEnd.m | 4 + .../PowerQueries/param_DateStart.m | 4 + .../param_NumberOfAccountDigits.m | 4 + .../param_RetainedEarningsAccountCode.m | 4 + .../param_StartOfPandLAccountCode.m | 4 + .../VBA_Code/m000_EntryPoints.bas | 54 ++++++ .../VBA_Code/m020_FileUtilities.bas | 181 ++++++++++++++++++ .../ListObjectFieldValues.txt | 0 .../ListObjectFields.txt | 0 .../WorksheetStructure/ListObjectFormat.txt | 1 + .../MetadataWorksheets.txt | 0 22 files changed, 608 insertions(+) create mode 100644 SpreadsheetMetadata/PowerQueries/ChartOfAccounts.m create mode 100644 SpreadsheetMetadata/PowerQueries/DataAccess_AdHocJnls.m create mode 100644 SpreadsheetMetadata/PowerQueries/DataAccess_ChartOfAccounts.m create mode 100644 SpreadsheetMetadata/PowerQueries/DataAccess_JnlMetaData.m create mode 100644 SpreadsheetMetadata/PowerQueries/DataAccess_JnlsfromOutputTab.m create mode 100644 SpreadsheetMetadata/PowerQueries/DataAccess_OpeningBalalances.m create mode 100644 SpreadsheetMetadata/PowerQueries/Journals.m create mode 100644 SpreadsheetMetadata/PowerQueries/TrialBalance.m create mode 100644 SpreadsheetMetadata/PowerQueries/fn_MonthlyFromAnnualisedPercentage.m create mode 100644 SpreadsheetMetadata/PowerQueries/fn_std_DatesBetween.m create mode 100644 SpreadsheetMetadata/PowerQueries/fn_std_Parameters.m create mode 100644 SpreadsheetMetadata/PowerQueries/param_DateEnd.m create mode 100644 SpreadsheetMetadata/PowerQueries/param_DateStart.m create mode 100644 SpreadsheetMetadata/PowerQueries/param_NumberOfAccountDigits.m create mode 100644 SpreadsheetMetadata/PowerQueries/param_RetainedEarningsAccountCode.m create mode 100644 SpreadsheetMetadata/PowerQueries/param_StartOfPandLAccountCode.m create mode 100644 SpreadsheetMetadata/VBA_Code/m000_EntryPoints.bas create mode 100644 SpreadsheetMetadata/VBA_Code/m020_FileUtilities.bas rename SpreadsheetMetadata/{ => WorksheetStructure}/ListObjectFieldValues.txt (100%) rename SpreadsheetMetadata/{ => WorksheetStructure}/ListObjectFields.txt (100%) create mode 100644 SpreadsheetMetadata/WorksheetStructure/ListObjectFormat.txt rename SpreadsheetMetadata/{ => WorksheetStructure}/MetadataWorksheets.txt (100%) diff --git a/SpreadsheetMetadata/PowerQueries/ChartOfAccounts.m b/SpreadsheetMetadata/PowerQueries/ChartOfAccounts.m new file mode 100644 index 0000000..943dd11 --- /dev/null +++ b/SpreadsheetMetadata/PowerQueries/ChartOfAccounts.m @@ -0,0 +1,10 @@ +let + ChartOfAccountsRaw = DataAccess_ChartOfAccounts, + AddAccountCode = Table.AddColumn(ChartOfAccountsRaw, "Account Code", each Text.Start([Account Code and Description], param_NumberOfAccountDigits), type text), + AddAccountDescription = Table.AddColumn(AddAccountCode, "Account Description", each Text.End( + [Account Code and Description], + Text.Length([Account Code and Description]) -param_NumberOfAccountDigits -1) + , type text), + Reorder = Table.ReorderColumns(AddAccountDescription,{"Account Code", "Account Description", "Account Code and Description", "Account Category 1", "Account Category 2", "Account Category 3", "Account Category 4", "Account Category 5"}) +in + Reorder \ No newline at end of file diff --git a/SpreadsheetMetadata/PowerQueries/DataAccess_AdHocJnls.m b/SpreadsheetMetadata/PowerQueries/DataAccess_AdHocJnls.m new file mode 100644 index 0000000..0080872 --- /dev/null +++ b/SpreadsheetMetadata/PowerQueries/DataAccess_AdHocJnls.m @@ -0,0 +1,4 @@ +let + Source = Excel.CurrentWorkbook(){[Name="tbl_InputAdHocJnls"]}[Content] +in + Source \ No newline at end of file diff --git a/SpreadsheetMetadata/PowerQueries/DataAccess_ChartOfAccounts.m b/SpreadsheetMetadata/PowerQueries/DataAccess_ChartOfAccounts.m new file mode 100644 index 0000000..e8903c0 --- /dev/null +++ b/SpreadsheetMetadata/PowerQueries/DataAccess_ChartOfAccounts.m @@ -0,0 +1,5 @@ +let + Source = Excel.CurrentWorkbook(){[Name="tbl_InputChartOfAccounts"]}[Content], + ChangedType = Table.TransformColumnTypes(Source,{{"Account Code and Description", type text}, {"Account Category 1", type text}, {"Account Category 2", type text}, {"Account Category 3", type text}, {"Account Category 4", type text}, {"Account Category 5", type text}}) +in + ChangedType \ No newline at end of file diff --git a/SpreadsheetMetadata/PowerQueries/DataAccess_JnlMetaData.m b/SpreadsheetMetadata/PowerQueries/DataAccess_JnlMetaData.m new file mode 100644 index 0000000..720953f --- /dev/null +++ b/SpreadsheetMetadata/PowerQueries/DataAccess_JnlMetaData.m @@ -0,0 +1,5 @@ +let + Source = Excel.CurrentWorkbook(){[Name="tbl_InputJnlMetaData"]}[Content], + FilteredOutNulls = Table.SelectRows(Source, each ([Jnl Prefix] <> null)) +in + FilteredOutNulls \ No newline at end of file diff --git a/SpreadsheetMetadata/PowerQueries/DataAccess_JnlsfromOutputTab.m b/SpreadsheetMetadata/PowerQueries/DataAccess_JnlsfromOutputTab.m new file mode 100644 index 0000000..35c6985 --- /dev/null +++ b/SpreadsheetMetadata/PowerQueries/DataAccess_JnlsfromOutputTab.m @@ -0,0 +1,9 @@ +let + /* + This query exists to prevent recalling the Journals function in TB process as this will generate + new random numbers that will not align to the original journals + */ + + Source = Excel.CurrentWorkbook(){[Name="tbl_Journals"]}[Content] +in + Source \ No newline at end of file diff --git a/SpreadsheetMetadata/PowerQueries/DataAccess_OpeningBalalances.m b/SpreadsheetMetadata/PowerQueries/DataAccess_OpeningBalalances.m new file mode 100644 index 0000000..2692042 --- /dev/null +++ b/SpreadsheetMetadata/PowerQueries/DataAccess_OpeningBalalances.m @@ -0,0 +1,4 @@ +let + Source = Excel.CurrentWorkbook(){[Name="tbl_InputOpeningBalalances"]}[Content] +in + Source \ No newline at end of file diff --git a/SpreadsheetMetadata/PowerQueries/Journals.m b/SpreadsheetMetadata/PowerQueries/Journals.m new file mode 100644 index 0000000..1e8b798 --- /dev/null +++ b/SpreadsheetMetadata/PowerQueries/Journals.m @@ -0,0 +1,86 @@ +let + + + /************************************************************************************************************************* + Get add hoc journals + *************************************************************************************************************************/ + + AdHocJnlsRaw = DataAccess_AdHocJnls, + ChangedType0 = Table.TransformColumnTypes(AdHocJnlsRaw,{{"EndOfMonth", type date}, {"Jnl ID", type text}, {"Account Code and Description", type text}, {"Jnl Description", type text}, {"Jnl Amount", type number}}), + AdHocJnls = Table.SelectRows(ChangedType0, each + [EndOfMonth] <> null and + [EndOfMonth] >= param_DateStart and + [EndOfMonth] <= param_DateEnd), + + + + /************************************************************************************************************************* + Get list of recurring journals + *************************************************************************************************************************/ + + //Get generate list of month ends and index + MonthEndList = fn_std_DatesBetween(param_DateStart, param_DateEnd, "Month"), + ConvertToTable = Table.FromList(MonthEndList, Splitter.SplitByNothing(), {"EndOfMonth"}), + ChangedType = Table.TransformColumnTypes(ConvertToTable,{{"EndOfMonth", type date}}), + AddMonthIndex = Table.AddColumn(ChangedType, "Month Index", each + (Date.Year([EndOfMonth]) * 12 + Date.Month([EndOfMonth])) - + (Date.Year(List.Min(ChangedType[EndOfMonth])) * 12 + Date.Month(List.Min(ChangedType[EndOfMonth]))), + Int64.Type), + + //For each month end add the list of recurring journal id prefixes + JnlPrefixList = Table.AddColumn(AddMonthIndex, "Jnl Prefix", each DataAccess_JnlMetaData[Jnl Prefix], type list), + ExpandedJnlPrefixList = Table.ExpandListColumn(JnlPrefixList, "Jnl Prefix"), + ChangedType2 = Table.TransformColumnTypes(ExpandedJnlPrefixList,{{"Jnl Prefix", type text}}), + + // Add the required number of journal tables and expand + AddJnlMetaDataTable = Table.NestedJoin(ChangedType2, "Jnl Prefix", DataAccess_JnlMetaData, "Jnl Prefix", "JnlMetaDataTable", JoinKind.LeftOuter), + AddNumberOfTablesCol = Table.AddColumn(AddJnlMetaDataTable, "NumberOfTablesRequired", each [JnlMetaDataTable][Number of instances per month]{0}, Int64.Type), + AddListOfTablesCol = Table.AddColumn(AddNumberOfTablesCol, "AddMultiTableCol", each List.Accumulate({1..[NumberOfTablesRequired]}, {}, (state, current)=> state & {[JnlMetaDataTable]}), type list), + ExpandedListOfTables = Table.ExpandListColumn(AddListOfTablesCol, "AddMultiTableCol"), + ExpandedTables = Table.ExpandTableColumn(ExpandedListOfTables, "AddMultiTableCol", + { + "Debit Account Code and Description", "Credit Account Code and Description", "Jnl Description", "Base Amount Total For Month", + "Is recurring", "Annual growth percentage", "Number of instances per month", "Randomise", "Random Variation around base"}, + { + "Debit Account Code and Description", "Credit Account Code and Description", "Jnl Description", "Base Amount Total For Month", + "Is recurring", "Annual growth percentage", "Number of instances per month", "Randomise", "Random Variation around base"}), + + //Calculate amount by adding random number factor and percentage growth + AddRandomAdjCol = Table.AddColumn(ExpandedTables, "Random Number Factor", each if [Randomise] then + 1 + Number.RandomBetween(-[Random Variation around base], [Random Variation around base]) + else + 1, + type number), + + AddMonthlyGrowthPercentage = Table.AddColumn(AddRandomAdjCol, "Monthly growth percentage", each fn_MonthlyFromAnnualisedPercentage([Annual growth percentage]),type number), + AddGrowthAdjCol = Table.AddColumn(AddMonthlyGrowthPercentage, "Growth Factor", each Number.Power(1 + [Monthly growth percentage], [Month Index]), type number), + AddAmountCol = Table.AddColumn(AddGrowthAdjCol, "Absolute Amount", + each Number.Round( + [Base Amount Total For Month] / [Number of instances per month] * [Random Number Factor] * [Growth Factor], + 2), + type number), + + //Add unique jnl ID and select columns + AddIndexCol = Table.AddIndexColumn(AddAmountCol, "Index", 0, 1), + AddJnlIDCol = Table.AddColumn(AddIndexCol, "Jnl ID", each [Jnl Prefix] & "-" & Text.PadStart(Text.From([Index]), 10, "0"), type text), + SelectCols = Table.SelectColumns(AddJnlIDCol,{"EndOfMonth", "Jnl ID", "Debit Account Code and Description", "Credit Account Code and Description", "Jnl Description", "Absolute Amount"}), + + //Unpivot debit and credit accounts and clean up + UnpivotAccountNumbers = Table.UnpivotOtherColumns(SelectCols, {"EndOfMonth", "Jnl ID", "Jnl Description", "Absolute Amount"}, "Account Number Type", "Account Code and Description"), + AddJnlAmountCol = Table.AddColumn(UnpivotAccountNumbers, "Jnl Amount", each if [Account Number Type] = "Debit Account Code and Description" then + [Absolute Amount] + else + -[Absolute Amount], + type number), + /************************************************************************************************************************* + Combine ad-hoc and recurring journals + *************************************************************************************************************************/ + + Combined = Table.Combine({AdHocJnls, AddJnlAmountCol}), + AddAccountCodeCol = Table.AddColumn(Combined, "Account Code", each Text.Start([Account Code and Description], param_NumberOfAccountDigits), type text), + SelectColsAndReorder = Table.SelectColumns(AddAccountCodeCol,{"EndOfMonth", "Jnl ID", "Account Code", "Jnl Description", "Jnl Amount"}), + ChangedType3 = Table.TransformColumnTypes(SelectColsAndReorder,{{"EndOfMonth", type date}, {"Jnl ID", type text}, {"Account Code", type text}, {"Jnl Description", type text}}), + SortedRows = Table.Sort(ChangedType3,{{"EndOfMonth", Order.Ascending}, {"Jnl ID", Order.Ascending}}) + +in + SortedRows \ No newline at end of file diff --git a/SpreadsheetMetadata/PowerQueries/TrialBalance.m b/SpreadsheetMetadata/PowerQueries/TrialBalance.m new file mode 100644 index 0000000..368b6ef --- /dev/null +++ b/SpreadsheetMetadata/PowerQueries/TrialBalance.m @@ -0,0 +1,114 @@ +let + + /********************************************************************************************************************* + Function - return balance sheet portion of TB + *********************************************************************************************************************/ + + fn_BsPortionOfTb = + (tbl_Jnls as table, dte_EndOfMonth as date)=> + let + FilterTable = Table.SelectRows(tbl_Jnls, each [EndOfMonth] <= dte_EndOfMonth and [Account type] = "Balance Sheet Account"), + GroupedByAccount = Table.Group(FilterTable, {"Account Code"}, {{"Amount", each List.Sum([Amount]), type number}}), + AddMonthEnd = Table.AddColumn(GroupedByAccount, "EndOfMonth", each dte_EndOfMonth, type date), + ReorderCols = Table.ReorderColumns(AddMonthEnd,{"EndOfMonth", "Account Code", "Amount"}) + in + ReorderCols, + + + /********************************************************************************************************************* + Function - return P&L portion of TB + *********************************************************************************************************************/ + + fn_PandLPortionOfTb = + (tbl_Jnls as table, dte_EndOfMonth as date)=> + let + FilterTable = Table.SelectRows(tbl_Jnls, each + [EndOfMonth] <= dte_EndOfMonth and + Date.Year([EndOfMonth]) = Date.Year(dte_EndOfMonth) and + [Account type] = "P&L account"), + + GroupedByAccount = Table.Group(FilterTable, {"Account Code"}, {{"Amount", each List.Sum([Amount]), type number}}), + AddMonthEnd = Table.AddColumn(GroupedByAccount, "EndOfMonth", each dte_EndOfMonth, type date), + ReorderCols = Table.ReorderColumns(AddMonthEnd,{"EndOfMonth", "Account Code", "Amount"}) + in + ReorderCols, + + + /********************************************************************************************************************* + Function - return retained earnings TB + *********************************************************************************************************************/ + + fn_RetainedEarningsPortionOfTb = + (tbl_Jnls as table, dte_EndOfMonth as date)=> + let + + FilterTable = Table.SelectRows(tbl_Jnls, each + ( + [EndOfMonth] <= dte_EndOfMonth and + [Account type] = "Retained Earnings" + ) + or + ( + [EndOfMonth] <= #date(Date.Year(dte_EndOfMonth)-1, 12, 31) and + [Account type] = "P&L account" + ) + ), + + RemovedOldMonthEndCol = Table.RemoveColumns(FilterTable,{"EndOfMonth"}), + AddNewMonthEndCol = Table.AddColumn(RemovedOldMonthEndCol, "EndOfMonth", each dte_EndOfMonth, type date), + GroupedByMonthEnd = Table.Group(AddNewMonthEndCol, {"EndOfMonth"}, {{"Amount", each List.Sum([Amount]), type number}}), + AddAccountCodeCol = Table.AddColumn(GroupedByMonthEnd, "Account Code", each param_RetainedEarningsAccountCode, type text), + ReorderCols = Table.ReorderColumns(AddAccountCodeCol,{"EndOfMonth", "Account Code", "Amount"}) + in + ReorderCols, + + /********************************************************************************************************************* + Create a buffered table of opening balances and journals + *********************************************************************************************************************/ + + //Note - need to pick up from the output tab otherwise the random number generator will change number versus original journals! + JournalsSelectedCols = Table.SelectColumns(DataAccess_JnlsfromOutputTab, {"EndOfMonth", "Account Code", "Jnl Amount"}), + JournalsChangedType = Table.TransformColumnTypes(JournalsSelectedCols,{{"EndOfMonth", type date}, {"Account Code", type text}, {"Jnl Amount", type number}}), + JournalsRenamedCol = Table.RenameColumns(JournalsChangedType,{{"Jnl Amount", "Amount"}}), + + OpeningBalancesRaw = DataAccess_OpeningBalalances, + OpeningBalanceChangedType = Table.TransformColumnTypes(OpeningBalancesRaw,{{"Account Code and Description", type text}, {"Amount", type number}}), + OpeningBalanceAddAccountCodeCol = Table.AddColumn(OpeningBalanceChangedType, "Account Code", each Text.Start([Account Code and Description], param_NumberOfAccountDigits), type text), + OpeningBalanceAddDateCol = Table.AddColumn(OpeningBalanceAddAccountCodeCol, "Date", each param_DateStart, type date), + OpeningBalanceSelectCols = Table.SelectColumns(OpeningBalanceAddDateCol, {"Date", "Account Code", "Amount"}), + OpeningBalanceRenameCols = Table.RenameColumns(OpeningBalanceSelectCols,{{"Date", "EndOfMonth"}}), + CombineJournalAndOpeningBalance = Table.Combine({OpeningBalanceRenameCols, JournalsRenamedCol}), + GroupedRows = Table.Group(CombineJournalAndOpeningBalance, {"EndOfMonth", "Account Code"}, {{"Amount", each List.Sum([Amount]), type number}}), + AddAccountType = Table.AddColumn(GroupedRows, "Account type", each + if Number.From([Account Code]) = Number.From(param_RetainedEarningsAccountCode) then + "Retained Earnings" + else if Number.From([Account Code]) >= Number.From(param_StartOfPandLAccountCode) then + "P&L account" + else + "Balance Sheet Account", + type text), + + BufferedTransactions = Table.Buffer(AddAccountType), + + /********************************************************************************************************************* + Generate a table of month ends and generate tb per month + *********************************************************************************************************************/ + + MonthEndList = fn_std_DatesBetween(param_DateStart, param_DateEnd, "Month"), + ConvertToTable = Table.FromList(MonthEndList, Splitter.SplitByNothing(), {"EndOfMonth"}), + ChangedType = Table.TransformColumnTypes(ConvertToTable,{{"EndOfMonth", type date}}), + + + AddTbTable = Table.AddColumn(ChangedType, "TB as table", + each fn_BsPortionOfTb(BufferedTransactions, [EndOfMonth]) & + fn_RetainedEarningsPortionOfTb(BufferedTransactions, [EndOfMonth]) & + fn_PandLPortionOfTb(BufferedTransactions, [EndOfMonth]), + type table), + + ExpandedTBTable = Table.ExpandTableColumn(AddTbTable, "TB as table", {"Account Code", "Amount"}, {"Account Code", "Amount"}), + ChangedType2 = Table.TransformColumnTypes(ExpandedTBTable,{{"Account Code", type text}, {"Amount", type number}}) + + + +in + ChangedType2 \ No newline at end of file diff --git a/SpreadsheetMetadata/PowerQueries/fn_MonthlyFromAnnualisedPercentage.m b/SpreadsheetMetadata/PowerQueries/fn_MonthlyFromAnnualisedPercentage.m new file mode 100644 index 0000000..b882c6a --- /dev/null +++ b/SpreadsheetMetadata/PowerQueries/fn_MonthlyFromAnnualisedPercentage.m @@ -0,0 +1,5 @@ +(PercentageAnnuaised as number)=> +let + MonthlyPercentage = Number.Power((1 + PercentageAnnuaised), (1/12)) - 1 +in + MonthlyPercentage \ No newline at end of file diff --git a/SpreadsheetMetadata/PowerQueries/fn_std_DatesBetween.m b/SpreadsheetMetadata/PowerQueries/fn_std_DatesBetween.m new file mode 100644 index 0000000..b9755f9 --- /dev/null +++ b/SpreadsheetMetadata/PowerQueries/fn_std_DatesBetween.m @@ -0,0 +1,64 @@ +// **************************************************************************************** +// Credit for below code = Imke Feldman Imke Feldmann: www.TheBIccountant.com +// **************************************************************************************** + + +let +// ----------------------- Documentation ----------------------- + + documentation_ = [ + Documentation.Name = " Dates.DatesBetween", + Documentation.Description = " Creates a list of dates according to the chosen interval between Start and End. Allowed values for 3rd parameter: ""Year"", ""Quarter"", ""Month"", ""Week"" or ""Day""." , + Documentation.LongDescription = " Creates a list of dates according to the chosen interval between Start and End. The dates created will always be at the end of the interval, so could be in the future if today is chosen.", + Documentation.Category = " Table", + Documentation.Source = " http://www.thebiccountant.com/2017/12/11/date-datesbetween-retrieve-dates-between-2-dates-power-bi-power-query/ . ", + Documentation.Author = " Imke Feldmann: www.TheBIccountant.com . ", + Documentation.Examples = {[Description = " Check this blogpost: http://www.thebiccountant.com/2017/12/11/date-datesbetween-retrieve-dates-between-2-dates-power-bi-power-query/ ." , + Code = "", + Result = ""]} + ], + + // ----------------------- Function Code ----------------------- + + function_ = (From as date, To as date, optional Selection as text ) => + let + + // Create default-value "Day" if no selection for the 3rd parameter has been made + TimeInterval = if Selection = null then "Day" else Selection, + + // Table with different values for each case + CaseFunctions = #table({"Case", "LastDateInTI", "TypeOfAddedTI", "NumberOfAddedTIs"}, + { {"Day", Date.From, Date.AddDays, Number.From(To-From)+1}, + {"Week", Date.EndOfWeek, Date.AddWeeks, Number.RoundUp((Number.From(To-From)+1)/7)}, + {"Month", Date.EndOfMonth, Date.AddMonths, (Date.Year(To)*12+Date.Month(To))-(Date.Year(From)*12+Date.Month(From))+1}, + {"Quarter", Date.EndOfQuarter, Date.AddQuarters, (Date.Year(To)*4+Date.QuarterOfYear(To))-(Date.Year(From)*4+Date.QuarterOfYear(From))+1}, + {"Year", Date.EndOfYear, Date.AddYears,Date.Year(To)-Date.Year(From)+1} + } ), + + // Filter table on selected case + Case = CaseFunctions{[Case = TimeInterval]}, + + // Create list with dates: List with number of date intervals -> Add number of intervals to From-parameter -> shift dates at the end of each respective interval + DateFunction = List.Transform({0..Case[NumberOfAddedTIs]-1}, each Function.Invoke(Case[LastDateInTI], {Function.Invoke(Case[TypeOfAddedTI], {From, _})})) + in + DateFunction, + + // ----------------------- New Function Type ----------------------- + + type_ = type function ( + From as (type date), + To as (type date), + optional Selection as (type text meta [ + Documentation.FieldCaption = "Select Date Interval", + Documentation.FieldDescription = "Select Date Interval, if nothing selected, the default value will be ""Day""", + Documentation.AllowedValues = {"Day", "Week", "Month", "Quarter", "Year"} + ]) + ) + as table meta documentation_, + + // Replace the extisting type of the function with the individually defined + Result = Value.ReplaceType(function_, type_) + + in + +Result \ No newline at end of file diff --git a/SpreadsheetMetadata/PowerQueries/fn_std_Parameters.m b/SpreadsheetMetadata/PowerQueries/fn_std_Parameters.m new file mode 100644 index 0000000..cca4132 --- /dev/null +++ b/SpreadsheetMetadata/PowerQueries/fn_std_Parameters.m @@ -0,0 +1,46 @@ +let + + + // ----------------------------------------------------------------------------------------------------------------------------------------- + // Documentation + // ----------------------------------------------------------------------------------------------------------------------------------------- + + Documentation_ = [ + Documentation.Name = " fn_std_Parameters", + Documentation.Description = " Returns parameter value set out in tbl_Parameters" , + Documentation.LongDescription = " Returns parameter value set out in tbl_Parameters", + Documentation.Category = "Text", + Documentation.Author = " Charl Potgieter" + ], + + + // ----------------------------------------------------------------------------------------------------------------------------------------- + // Function code + // ----------------------------------------------------------------------------------------------------------------------------------------- + + fn_= + (parameter as text)=> + let + Source = Excel.CurrentWorkbook(){[Name = "tbl_Parameters"]}[Content], + FilteredRows = Table.SelectRows(Source, each [Parameter] = parameter), + ReturnValue = FilteredRows[Value]{0} + in + ReturnValue, + + + + +// ----------------------------------------------------------------------------------------------------------------------------------------- +// Output +// ----------------------------------------------------------------------------------------------------------------------------------------- + + type_ = type function ( + parameter as (type text) + ) + as text meta Documentation_, + + // Replace the extisting type of the function with the individually defined + Result = Value.ReplaceType(fn_, type_) + + in + Result \ No newline at end of file diff --git a/SpreadsheetMetadata/PowerQueries/param_DateEnd.m b/SpreadsheetMetadata/PowerQueries/param_DateEnd.m new file mode 100644 index 0000000..59bafda --- /dev/null +++ b/SpreadsheetMetadata/PowerQueries/param_DateEnd.m @@ -0,0 +1,4 @@ +let + Source = Date.From(fn_std_Parameters("DateEnd")) +in + Source \ No newline at end of file diff --git a/SpreadsheetMetadata/PowerQueries/param_DateStart.m b/SpreadsheetMetadata/PowerQueries/param_DateStart.m new file mode 100644 index 0000000..97a01ea --- /dev/null +++ b/SpreadsheetMetadata/PowerQueries/param_DateStart.m @@ -0,0 +1,4 @@ +let + Source = Date.From(fn_std_Parameters("DateStart")) +in + Source \ No newline at end of file diff --git a/SpreadsheetMetadata/PowerQueries/param_NumberOfAccountDigits.m b/SpreadsheetMetadata/PowerQueries/param_NumberOfAccountDigits.m new file mode 100644 index 0000000..22fc5c6 --- /dev/null +++ b/SpreadsheetMetadata/PowerQueries/param_NumberOfAccountDigits.m @@ -0,0 +1,4 @@ +let + Source = fn_std_Parameters("Number of account code digits") +in + Source \ No newline at end of file diff --git a/SpreadsheetMetadata/PowerQueries/param_RetainedEarningsAccountCode.m b/SpreadsheetMetadata/PowerQueries/param_RetainedEarningsAccountCode.m new file mode 100644 index 0000000..27dd758 --- /dev/null +++ b/SpreadsheetMetadata/PowerQueries/param_RetainedEarningsAccountCode.m @@ -0,0 +1,4 @@ +let + Source = Text.From(fn_std_Parameters("Retained earnings account code")) +in + Source \ No newline at end of file diff --git a/SpreadsheetMetadata/PowerQueries/param_StartOfPandLAccountCode.m b/SpreadsheetMetadata/PowerQueries/param_StartOfPandLAccountCode.m new file mode 100644 index 0000000..ad5b636 --- /dev/null +++ b/SpreadsheetMetadata/PowerQueries/param_StartOfPandLAccountCode.m @@ -0,0 +1,4 @@ +let + Source = fn_std_Parameters("Start of P&L account code") +in + Source \ No newline at end of file diff --git a/SpreadsheetMetadata/VBA_Code/m000_EntryPoints.bas b/SpreadsheetMetadata/VBA_Code/m000_EntryPoints.bas new file mode 100644 index 0000000..31961c2 --- /dev/null +++ b/SpreadsheetMetadata/VBA_Code/m000_EntryPoints.bas @@ -0,0 +1,54 @@ +Attribute VB_Name = "m000_EntryPoints" +Option Explicit + +Sub RefreshOutputQueries() + + 'Setup + Application.ScreenUpdating = False + Application.EnableEvents = False + Application.Calculation = xlCalculationManual + Application.DisplayAlerts = False + + + ThisWorkbook.Sheets("OutputJournals").ListObjects("tbl_Journals").QueryTable.Refresh BackgroundQuery:=False + ThisWorkbook.Sheets("OutputChartOfAccounts").ListObjects("tbl_ChartOfAccounts").QueryTable.Refresh BackgroundQuery:=False + + 'Pause to ensure above are refreshed as TB is dependent on output journal tb + Application.Wait Now + #12:00:05 AM# + ThisWorkbook.Sheets("OutputTB").ListObjects("tbl_TrialBalance").QueryTable.Refresh BackgroundQuery:=False + + 'Cleanup + Application.ScreenUpdating = True + Application.EnableEvents = True + Application.Calculation = xlCalculationAutomatic + Application.DisplayAlerts = True + + MsgBox ("Queries refreshed") + + + +End Sub + + +Sub ExportOutputToFiles() + + 'Setup + Application.ScreenUpdating = False + Application.EnableEvents = False + Application.Calculation = xlCalculationManual + Application.DisplayAlerts = False + + ExportTableToPipeDelimtedText ThisWorkbook.Sheets("OutputJournals").ListObjects("tbl_Journals") + ExportTableToPipeDelimtedText ThisWorkbook.Sheets("OutputChartOfAccounts").ListObjects("tbl_ChartOfAccounts") + ExportTableToPipeDelimtedText ThisWorkbook.Sheets("OutputTB").ListObjects("tbl_TrialBalance") + + 'Cleanup + Application.ScreenUpdating = True + Application.EnableEvents = True + Application.Calculation = xlCalculationAutomatic + Application.DisplayAlerts = True + + MsgBox ("Output files created") + + +End Sub diff --git a/SpreadsheetMetadata/VBA_Code/m020_FileUtilities.bas b/SpreadsheetMetadata/VBA_Code/m020_FileUtilities.bas new file mode 100644 index 0000000..6ef44a1 --- /dev/null +++ b/SpreadsheetMetadata/VBA_Code/m020_FileUtilities.bas @@ -0,0 +1,181 @@ +Attribute VB_Name = "m020_FileUtilities" +Option Explicit +Option Private Module + +'----------------------------------------------------------------------------------------------------- +' Requires reference to Microsoft Scripting runtime +'----------------------------------------------------------------------------------------------------- + + +Function NumberOfFilesInFolder(ByVal sFolderPath As String) As Integer +'Requires refence: Microsoft Scripting Runtime +'This is non-recursive + + + Dim oFSO As FileSystemObject + Dim oFolder As Folder + + Set oFSO = New FileSystemObject + Set oFolder = oFSO.GetFolder(sFolderPath) + NumberOfFilesInFolder = oFolder.Files.Count + + +End Function + +Function FolderExists(ByVal sFolderPath) As Boolean +'Requires reference to Microsoft Scripting runtime +'An alternative solution exists using the DIR function but this seems to result in memory leak and folder is +'not released by VBA + + Dim FSO As Scripting.FileSystemObject + Dim FolderPath As String + + Set FSO = New Scripting.FileSystemObject + + If Right(sFolderPath, 1) <> Application.PathSeparator Then + FolderPath = FolderPath & Application.PathSeparator + End If + + FolderExists = FSO.FolderExists(sFolderPath) + Set FSO = Nothing + +End Function + + +Sub CreateFolder(ByVal sFolderPath As String) +' Requires reference to Microsoft Scripting runtime + + Dim FSO As FileSystemObject + + If FolderExists(sFolderPath) Then + MsgBox ("Folder already exists, new folder not created") + Else + Set FSO = New FileSystemObject + FSO.CreateFolder sFolderPath + End If + + Set FSO = Nothing + +End Sub + + +Function FileExists(ByVal sFilePath) As Boolean +'Requires reference to Microsoft Scripting runtime +'An alternative solution exists using the DIR function but this seems to result in memory leak and file is +'not released by VBA + + Dim FSO As Scripting.FileSystemObject + Dim FolderPath As String + + Set FSO = New Scripting.FileSystemObject + + FileExists = FSO.FileExists(sFilePath) + Set FSO = Nothing + + +End Function + +Sub ExportTableToPipeDelimtedText(lo As ListObject) +'Saves list object as pipe delimited text files in active workbook path subfolder OutputFiles +'File name equals to table name, excl "tbl_" prefix if applicable +'Any existing file will be overwritten + + + Dim sFolderPath As String + Dim sFolderPathAndName As String + Dim sht As Worksheet + + + sFolderPath = ThisWorkbook.Path & Application.PathSeparator & "OutputFiles" + + + If Not FolderExists(sFolderPath) Then + CreateFolder sFolderPath + End If + + + If Left(lo.Name, 4) = "tbl_" Then + sFolderPathAndName = sFolderPath & Application.PathSeparator & Right(lo.Name, Len(lo.Name) - 4) & ".txt" + sFolderPathAndName = GetNextAvailableFileName(sFolderPathAndName) + Else + sFolderPathAndName = sFolderPath & Application.PathSeparator & lo.Name & ".txt" + sFolderPathAndName = GetNextAvailableFileName(sFolderPathAndName) + End If + ExportListObjectToPipeDelimtedText lo, sFolderPathAndName + + +End Sub + + +Sub ExportListObjectToPipeDelimtedText(ByRef lo As ListObject, ByVal sFilePathAndName As String) +'Requires reference to Microsoft Scripting Runtime +'Saves sht as a pipe delimted text file +'Existing files will be overwritten + + Dim dblNumberOfRows As Double + Dim dblNumberOfCols As Double + Dim iFileNo As Integer + Dim i As Double + Dim j As Double + Dim sRowStringToWrite As String + + 'Get first free file number + iFileNo = FreeFile + + + Open sFilePathAndName For Output As #iFileNo + + dblNumberOfRows = lo.Range.Rows.Count + dblNumberOfCols = lo.Range.Columns.Count + + + For j = 1 To dblNumberOfRows + sRowStringToWrite = "" + For i = 1 To dblNumberOfCols + If i < dblNumberOfCols Then + sRowStringToWrite = sRowStringToWrite & lo.Range.Cells(j, i) & "|" + Else + sRowStringToWrite = sRowStringToWrite & lo.Range.Cells(j, i) + End If + Next i + If j < dblNumberOfRows Then + Print #iFileNo, sRowStringToWrite + Else + 'note the semi-colon at end to avoid the newline + Print #iFileNo, sRowStringToWrite; + End If + Next j + + Close #iFileNo + +End Sub + + + +Function GetNextAvailableFileName(ByVal sFilePath As String) As String +'Requires refence: Microsoft Scripting Runtime +'Returns next available file name. Can be utilised to ensure files are not overwritten + + Dim oFSO As FileSystemObject + Dim sFolder As String + Dim sFileName As String + Dim sFileExtension As String + Dim i As Long + + Set oFSO = CreateObject("Scripting.FileSystemObject") + + With oFSO + sFolder = .GetParentFolderName(sFilePath) + sFileName = .GetBaseName(sFilePath) + sFileExtension = .GetExtensionName(sFilePath) + + Do While .FileExists(sFilePath) + i = i + 1 + sFilePath = .BuildPath(sFolder, sFileName & "(" & i & ")." & sFileExtension) + Loop + + End With + + GetNextAvailableFileName = sFilePath + +End Function diff --git a/SpreadsheetMetadata/ListObjectFieldValues.txt b/SpreadsheetMetadata/WorksheetStructure/ListObjectFieldValues.txt similarity index 100% rename from SpreadsheetMetadata/ListObjectFieldValues.txt rename to SpreadsheetMetadata/WorksheetStructure/ListObjectFieldValues.txt diff --git a/SpreadsheetMetadata/ListObjectFields.txt b/SpreadsheetMetadata/WorksheetStructure/ListObjectFields.txt similarity index 100% rename from SpreadsheetMetadata/ListObjectFields.txt rename to SpreadsheetMetadata/WorksheetStructure/ListObjectFields.txt diff --git a/SpreadsheetMetadata/WorksheetStructure/ListObjectFormat.txt b/SpreadsheetMetadata/WorksheetStructure/ListObjectFormat.txt new file mode 100644 index 0000000..6c63424 --- /dev/null +++ b/SpreadsheetMetadata/WorksheetStructure/ListObjectFormat.txt @@ -0,0 +1 @@ +SheetName|ListObjectName|ListObjectHeader|NumberFormat|FontColour Parameters|tbl_Parameters|Parameter|General|0 Parameters|tbl_Parameters|Comments|General|0 Parameters|tbl_Parameters|Value|m/d/yyyy|12673797 ChartOfAccounts|tbl_InputChartOfAccounts|Account Code and Description|General|0 ChartOfAccounts|tbl_InputChartOfAccounts|Account Category 1|General|0 ChartOfAccounts|tbl_InputChartOfAccounts|Account Category 2|General|0 ChartOfAccounts|tbl_InputChartOfAccounts|Account Category 3|General|0 ChartOfAccounts|tbl_InputChartOfAccounts|Account Category 4|General|0 ChartOfAccounts|tbl_InputChartOfAccounts|Account Category 5|General|0 OpeningBalances|tbl_InputOpeningBalalances|Account Code and Description|General|0 OpeningBalances|tbl_InputOpeningBalalances|Amount|#,##0_);(#,##0);-??|0 JnlMetaData|tbl_InputJnlMetaData|Jnl Prefix|@|0 JnlMetaData|tbl_InputJnlMetaData|Debit Account Code and Description|General|0 JnlMetaData|tbl_InputJnlMetaData|Credit Account Code and Description|General|0 JnlMetaData|tbl_InputJnlMetaData|Jnl Description|General|0 JnlMetaData|tbl_InputJnlMetaData|Base Amount Total For Month|#,##0_);(#,##0);-??|0 JnlMetaData|tbl_InputJnlMetaData|Is recurring|General|0 JnlMetaData|tbl_InputJnlMetaData|Annual growth percentage|0.00%|0 JnlMetaData|tbl_InputJnlMetaData|Number of instances per month|General|0 JnlMetaData|tbl_InputJnlMetaData|Randomise|General|0 JnlMetaData|tbl_InputJnlMetaData|Random Variation around base|0.0%|0 AdHocJnls|tbl_InputAdHocJnls|EndOfMonth|d-mmm-yy|0 AdHocJnls|tbl_InputAdHocJnls|Jnl ID|General|0 AdHocJnls|tbl_InputAdHocJnls|Account Code and Description|General|0 AdHocJnls|tbl_InputAdHocJnls|Jnl Description|General|0 AdHocJnls|tbl_InputAdHocJnls|Jnl Amount|#,##0_);(#,##0);-??|0 OutputChartOfAccounts|tbl_ChartOfAccounts|Account Code|General|0 OutputChartOfAccounts|tbl_ChartOfAccounts|Account Description|General|0 OutputChartOfAccounts|tbl_ChartOfAccounts|Account Code and Description|General|0 OutputChartOfAccounts|tbl_ChartOfAccounts|Account Category 1|General|0 OutputChartOfAccounts|tbl_ChartOfAccounts|Account Category 2|General|0 OutputChartOfAccounts|tbl_ChartOfAccounts|Account Category 3|General|0 OutputChartOfAccounts|tbl_ChartOfAccounts|Account Category 4|General|0 OutputChartOfAccounts|tbl_ChartOfAccounts|Account Category 5|General|0 OutputJournals|tbl_Journals|EndOfMonth|d-mmm-yy|0 OutputJournals|tbl_Journals|Jnl ID|General|0 OutputJournals|tbl_Journals|Account Code|General|0 OutputJournals|tbl_Journals|Jnl Description|General|0 OutputJournals|tbl_Journals|Jnl Amount|#,##0_);(#,##0);-??|0 OutputTB|tbl_TrialBalance|EndOfMonth|d-mmm-yy|0 OutputTB|tbl_TrialBalance|Account Code|General|0 OutputTB|tbl_TrialBalance|Amount|#,##0_);(#,##0);-??|0 \ No newline at end of file diff --git a/SpreadsheetMetadata/MetadataWorksheets.txt b/SpreadsheetMetadata/WorksheetStructure/MetadataWorksheets.txt similarity index 100% rename from SpreadsheetMetadata/MetadataWorksheets.txt rename to SpreadsheetMetadata/WorksheetStructure/MetadataWorksheets.txt