Skip to content

Commit

Permalink
Update Spreadsheet metadata
Browse files Browse the repository at this point in the history
  • Loading branch information
charl-potgieter committed May 19, 2020
1 parent dd04398 commit e7b256f
Show file tree
Hide file tree
Showing 22 changed files with 608 additions and 0 deletions.
10 changes: 10 additions & 0 deletions SpreadsheetMetadata/PowerQueries/ChartOfAccounts.m
Original file line number Diff line number Diff line change
@@ -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
4 changes: 4 additions & 0 deletions SpreadsheetMetadata/PowerQueries/DataAccess_AdHocJnls.m
Original file line number Diff line number Diff line change
@@ -0,0 +1,4 @@
let
Source = Excel.CurrentWorkbook(){[Name="tbl_InputAdHocJnls"]}[Content]
in
Source
5 changes: 5 additions & 0 deletions SpreadsheetMetadata/PowerQueries/DataAccess_ChartOfAccounts.m
Original file line number Diff line number Diff line change
@@ -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
5 changes: 5 additions & 0 deletions SpreadsheetMetadata/PowerQueries/DataAccess_JnlMetaData.m
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
let
Source = Excel.CurrentWorkbook(){[Name="tbl_InputJnlMetaData"]}[Content],
FilteredOutNulls = Table.SelectRows(Source, each ([Jnl Prefix] <> null))
in
FilteredOutNulls
Original file line number Diff line number Diff line change
@@ -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
Original file line number Diff line number Diff line change
@@ -0,0 +1,4 @@
let
Source = Excel.CurrentWorkbook(){[Name="tbl_InputOpeningBalalances"]}[Content]
in
Source
86 changes: 86 additions & 0 deletions SpreadsheetMetadata/PowerQueries/Journals.m
Original file line number Diff line number Diff line change
@@ -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
114 changes: 114 additions & 0 deletions SpreadsheetMetadata/PowerQueries/TrialBalance.m
Original file line number Diff line number Diff line change
@@ -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
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
(PercentageAnnuaised as number)=>
let
MonthlyPercentage = Number.Power((1 + PercentageAnnuaised), (1/12)) - 1
in
MonthlyPercentage
64 changes: 64 additions & 0 deletions SpreadsheetMetadata/PowerQueries/fn_std_DatesBetween.m
Original file line number Diff line number Diff line change
@@ -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

0 comments on commit e7b256f

Please sign in to comment.