- Understanding Journals
- Excel Tables and Dynamic Range Names
- Understanding Ledgers
- Getting a Current Liabilities Balance
- Summary
Excel Tables and Dynamic Range Names
Before continuing with the topics of journals and ledgers, it's useful to take a detour into the topics of Excel tables and named ranges. The reason is that tables and ranges can help you manage your journals and ledgers (and other data groupings).
Prior to the 2007 version, Excel used what were called lists. A list is not a formal structure such as a pivot table or an embedded chart. It is a way of organizing data that conforms to certain Excel requirements. A list is a rectangular grouping of adjacent cells, with different records (for example, people, accounts, or transactions) in different rows, and with different fields (for example, person's first name, account balance, or transaction date) in different columns. The name of each field is in the list's first row.
There was never an Excel command to insert or build or convert or name a list. However, certain tasks such as building pivot tables and using the built-in Data Form required that basic data layout, and they still do.
Excel 2007 made a formal object of the informal list and called it a table. This creates some confusion with other, different structures such as pivot tables and data tables (the latter are used in so-called "What-If Analysis"), and Microsoft documentation repeatedly warns the reader about that sort of misunderstanding.
Tables in Excel 2007 and 2010 have some capabilities that lists do not:
- They have formal names: by default, Table1, Table2, and so on. You can change the default name if you want.
- Their number of rows and columns automatically grows as you add data adjacent to the rightmost column or bottommost row.
- They have optional total rows, shown at the bottom of the table, that show column statistics such as Sum or Count.
- Their columns can behave like range names.
For example, if the range A1:E6 in Figure 4.3 were an Excel table named Table1, you could use this formula
=SUM(Table1[Credit])
to get the total of the values in cells E2:E6. If the formula is in a cell that is part of the table, you don't need to use the table name as a qualifier. That is, again in Figure 4.3, this formula would work in a cell in or adjacent to a table in A1:E6:
=SUM([Credit])
If you have a range of data laid out like the data in Figure 4.3, you can convert it to a table in Excel 2007 or 2010. Just select a cell in the range, click the Ribbon's Insert tab, and click Table in the Tables group.
Having done so, you can show the total of the credits in the purchases journal using
=SUM(Table1[Credit])
or, if you've renamed the table, using something like this:
=SUM(PurchaseJournal[Credit])
Notice that the formula works much like using the SUM function with a named range. If the range E2:E6 in Figure 4.3 were named CreditAmounts, you could get the total of those cells with either this:
=SUM(E2:E6)
or this:
=SUM(CreditAmounts)
The basic structure of =SUM(CreditAmounts) is similar to the function as applied to a column in a table: =SUM(Table1[Credit]). But if a range name refers directly and specifically to, say, E2:E6, problems can arise. Those are discussed next.
Building Dynamic Range Names
Each of the first three chapters of this book discussed range names. You have seen how to specify a particular range of cells using a name that you provide: Inventory_Product_Code, for example. Those range names were static. The name always refers to the same set of cells unless you change the address that the name refers to.
Using static range names has several advantages but also some drawbacks. Suppose that you have five values in the range A1:A5. These values represent your company's revenues for the first five months of the year, and you have given the range A1:A5 the name Revenues. Elsewhere on the worksheet, you use the formula =SUM(Revenues) to display your total year-to-date revenues.
At the end of June, you enter June's revenue figure in cell A6. Now, to get the correct result for =SUM(Revenues), you need to click the Formulas tab and select Name Manager in the Defined Names group, and include A6 in the Revenues range (prior to Excel 2007, use Insert, Name, Define).
That's a headache you don't need every month—actually, the real headache is remembering to do it.
Using the OFFSET Function in Dynamic Range Names
What you need is a way to make the name Revenues respond by expanding its own address when you add new values: You need a dynamic range name, not a static one. You can create a dynamic range name by using Excel's OFFSET function. When you define a name, you're not required to enter a specific worksheet address in the Refers To box. You can enter a value or a formula. For example, you could use this formula:
=OFFSET($A$1,0,0,COUNT($A:$A),1)
This formula illustrates the OFFSET function. It returns a reference to a range of cells and contains these arguments:
- An anchor cell (or range of cells)—In the example, it's one cell: $A$1. The anchor cell informs OFFSET which cell to use as its basis.
- A Rows argument—In the example, this is the first zero. The reference that OFFSET returns is shifted (or offset) that number of rows from the anchor cell. In this case, the reference is shifted from $A$1 by zero rows.
- A Columns argument—In the example, this is the second zero. OFFSET shifts the reference by that number of columns from $A$1. Again, this example shifts the reference by zero columns. So far, the OFFSET function is just returning a reference to its own anchor cell, $A$1.
- A Height argument—In this example, this is COUNT($A:$A). Using the COUNT function informs OFFSET of how many numeric values exist in a range of cells, which is column A in this example. This is the heart of the dynamic range definition. When the number of numeric values in column A changes, it causes COUNT to recalculate. In turn, the OFFSET function recalculates and returns a reference with a different number of rows.
- A Width argument—In this example, this is the number 1. It defines the number of columns in the range that OFFSET returns.
So this formula returns a reference that depends on the number of numeric values in column A:
=OFFSET($A$1,0,0,COUNT($A:$A),1)
Suppose that column A contains six numbers. The formula returns a reference that is offset from $A$1 by zero rows and zero columns. The reference is six rows high and one column wide. So it returns the reference A1:A6.
As soon as a seventh number is entered in column A, the COUNT and OFFSET functions combine to make the reference one row larger. The reference would then be A1:A7. The name Revenues, defined in this way, is not a static range name, but a dynamic one.
The dynamic range name isn't subject to the drawback to static range names mentioned at the beginning of this section. You no longer need to manually redefine the name Revenues when a new revenue figure is included with the existing values. Your formula =SUM(Revenues) automatically recalculates and returns the sum of all the values in the Revenues range.
One further point: You must keep formulas that refer to the dynamic range outside of that range. Suppose that you put your =SUM(Revenues) formula in column A. The formula gets counted as one of the values that define the extent of the range, which means that the Revenues range in the SUM function is helping to define itself. That's a circular reference error, and Excel won't let you get away with it unscathed—at the very least, you'll need to resolve an error message.
Using Dynamic Range Names in the Journals
The sales and the purchases journals use several dynamic range names. Each range name is sheet level. For example, there is a range named 'Purchases Journal'!Amount and one named 'Sales Journal'!Amount. Each journal has these names and definitions:
-
TransactionDate—In the case of the sales journal, this range refers to the following:
=OFFSET('Sales Journal'!$A$1,1,0,COUNT('Sales Journal'!$A:$A),1)
-
Account—It's useful and convenient to make this name, as well as the names Posted and Amount, dependent on the size of the TransactionDate range. On the Sales worksheet, the name Account is defined as follows:
=OFFSET('Sales Journal'!TransactionDate,0,1)
The reference it returns is offset from TransactionDate by zero rows and one column. When you do not supply a Height or a Width argument for the OFFSET function, as in this example, it defaults to the Height and Width of the anchor argument. In this case, that corresponds to the TransactionDate range, so the Account reference has as many rows and columns as the TransactionDate. -
Posted—This name is defined as follows:
=OFFSET('Sales Journal'!TransactionDate,0,3)
It is offset from TransactionDate by zero rows and three columns.
-
SJDebitsCash—The definition is as follows:
=OFFSET('Sales Journal'!TransactionDate,0,4)
The name SJDebitsCash uses a naming convention for the journals in the Financial Reports.xlsm workbook: the initials of the sheet name (here, SJ for sales journal), followed by either Debits or Credits, followed by the name of the account that has been debited or credited. The corresponding name in the purchases journal is PJCreditsCash.
The names TransactionDate, Amount, and Posted on the purchases journal use the sheet named 'Purchases Journal' instead of 'Sales Journal' before the exclamation point in the OFFSET function, but they are defined identically otherwise.
Choosing Between Tables and Dynamic Range Names
Both tables and dynamic range names have one particularly valuable advantage over static range names in Excel: They automatically redefine their size when you add new data. That means that if there's another part of the workbook—a chart, for example, or even just a formula—that takes its data from the named range or table, it will automatically update when the table updates or when the range is redefined.
So, how do you decide whether to use a dynamic range name or a table? It's largely a matter of personal preference, and my own is to use dynamic range names. But there's no reason that you should follow my personal preference. Instead, consider the following drawbacks.
If you have more than one column in a table, you need to specify both the table name and the column header that you want to use. For example:
=SUM(SalesJournal[Debits])
whereas if Debits were a dynamic range name, you could use this:
=SUM(Debits)
It's marginally easier for me to remember the name of a range than to remember the name of a table and the field header.
Furthermore, if I use the name of a table in the definition of a charted data series, Excel converts the table name to a worksheet reference. Thus, =SERIES(,,Sheet1!Table3[Credits],1) would get changed to something like =SERIES(,,Sheet1!$D$2:$D$20,1).
However, if you subsequently add data to the table, the charted series definition is updated to show the new data. For example, =SERIES(,,Sheet1!$D$2:$D$20,1) might automatically become something like =SERIES(,,Sheet1!$D$2:$D$25,1).
Dynamic range names have drawbacks, too. A dynamic range name determines the number of rows in the range by using COUNT or COUNTA to get the number of values already present, usually in a column. Therefore, if you have extraneous values in the column, say in A100 when the range you're interested in occupies A1:A20, the COUNT function can easily return one value too many and make the range one row too big.
The other side of that problem is missing values. If you have values in A1:A20 except for one empty cell in, say, A11, the count will be too small by one, and so will the range. This is one reason that I define names such as Debits as offsets from a transaction date range. There will be a transaction date for each transaction, but not necessarily a value in the Debits column for each transaction.
Using tables avoids both these problems at the cost of having to qualify the table's column name by the name of the table itself, and of losing the table name in a chart series definition.