Relational Data Model for Double-Entry Accounting
Asked Answered
S

2

61

Assume there is a bank, a large shop, etc, that wants the accounting to be done correctly, for both internal accounts, and keeping track of customer accounts. Rather than implementing that which satisfies the current simple and narrow requirement, which would a 'home brew': those turn out to be a temporary crutch for the current simple requirement, and difficult or impossible to extend when new requirements come it.

As I understand it, Double-Entry Accounting is a method that is well-established, and serves all Accounting and Audit requirements, including those that are not contemplated at the current moment. If that is implemented, it would:

  • eliminate the incremental enhancements that would occur over time, and the expense,
  • there will not be a need for future enhancement.

I have studied this Answer to another question: Derived account balance vs stored account balance for a simple bank account?, it provides good information, for internal Accounts. A data model is required, so that one can understand the entities; their interaction; their relations, and @PerformanceDBA has given that. This model is taken from that Answer:

Whereas that is satisfactory for simple internal accounts, I need to see a data model that provides the full Double-Entry Accounting method.

The articles are need to be added are Journal; internal vs external Transactions; etc..

Ideally I would like to see what those double entry rows look like in database terms, what the whole process will look like in SQL, which entities are affected in each case, etc. Cases like:

  1. A Client deposits cash to his account
  2. The Bank charges fees once a month to all Clients accounts (sample batch job),
  3. A Client does some operation over the counter, and the Bank charges a fee (cash withdrawal + withdrawal fee),
  4. Mary sends some money from her account, to John's account, which is in the same bank

Let's just call it System instead of Bank, Bank may be too complex to model, and let the question be about imaginary system which operates with accounts and assets. Customers perform a set of operations with system (deposits, withdrawals, fee for latter, batch fees), and with each other (transfer).

Schorl answered 21/12, 2019 at 1:54 Comment(4)
Comments are not for extended discussion; this conversation has been moved to chat.Betteann
Great edit, thank you. There was Batch mentioned, I don't know if it makes sense to bring it back, perhaps it only exist in my current understanding that it must be a special table.Schorl
1) Batch does not need a data table for anything regarding the data content that the batch is processing. 2) Separately, one may have a Batch table for the purpose of administering the batch queue; controlling restart points; parallel processing (Threads); etc. All of which I have. But that is an Utility table, with no data content from the database proper. 3) Check my Answer to see if the batch issue is covered to your satisfaction. If not, please comment, and I will edit the Answer.Maas
This guy wanted to leave a comment but didn't have enough rep: https://mcmap.net/q/219882/-report-from-double-entry-accounting-closed/6456163Autogiro
M
185

A. Preliminary

Your Approach

First and foremost, I must commend your attitude. It is rare to find someone who not only thinks and works from a solid grounding, and who wishes to understand and implement a Double-Entry Accounting system, instead of:

  • either not implementing DEA, thus suffering multiple re-writes, and pain at each increment, each new requirement,

  • or implementing DEA, but re-inventing the wheel from scratch, by figuring it out for oneself, and suffering the pain at each exposure of error, and the demanded bug fixes, a sequence that never ends.

To avoid all that, and to seek the standard Method, is highly commended.

Further, you want that in the form of a Relational data model, you are not enslaved by the Date; Darwen; Fagin; et al views that prescribes a Record ID based Record Filing Systems, that cripples both the modelling exercise and the resulting "database". These days, some people are obsessed with primitive RFS and suppress Dr E F Codd's Relational Model.

1. Approach for the Answer

If you do not mind, I will explain things from the top, in logical order, so that I can avoid repeats, rather than just answering your particular requests. I apologise if you have complete knowledge of any of these points.

Obstacle

Ideally I would like to see what those double entry rows look like in database terms

That is an obstacle to the proper approach that is required for modelling or defining anything.

  • In the same way that stamping an ID field on every file, and making it the "key", cripples the modelling exercise, because it prevents analysis of the data (what the thing that the data represents actually is), expecting two rows for a Credit/Debit pair at the start will cripple the understanding of what the thing is; what the accounting actions are; what effect those actions have; and most important, how the data will be modelled. Particularly when one is learning.

Aristotle teaches us that:

the least initial deviation from the truth is multiplied later a thousandfold ... a principle is great, rather in power, than in extent; hence that which was small [mistake] at the start turns out a giant [mistake] at the end.

Paraphrased as, a small mistake at the beginning (eg. principles; definitions) turns out to be a large mistake at the end.

Therefore the intellectual requirement, the first thing, is to clear your mind regarding what it will be at the end of the modelling exercise. Of course, that is also required when one is learning what it is, in accounting terms.

2. Scope for the Answer

Assume there is a bank, a large shop, etc, that wants the accounting to be done correctly, for both internal accounts, and keeping track of customer accounts.
Let's just call it System instead of Bank, Bank may be too complex to model ...
Customers perform a set of operations with system (deposits, withdrawals, fee for latter, batch fees), and with each other (transfer).

To be clear, I have determined the scope to be as follows. Please correct me if it is not:

  • Not a small business with a General Ledger only, with no Customer Accounts
  • But a small community Bank, with no branches (the head office is the branch)
  • You want both the internal Accounts, which consists of:
  • a simple General Ledger,
  • as well as external Accounts, one for each Customer
  • The best concept that I have in mind is a small community Bank, or a business that operates like one. An agricultural cooperative, where each farmer has an Account that he purchases against, and is billed and paid monthly, and the cooperative operates like a small bank, with a full General Ledger, and offers some simple bank facilities.
  • A single Casino (not a chain) has the same requirement.
  • Not a large Bank with multiple branches; various financial products; etc.
  • Instead of System or Bank, I will call it House. The relevance of that will be clear later.

Anyone seeking the Double-Entry method for just the Ledger, without the external Customer Account, can glean that easily from this Answer.

In the same vein, the data model given here is easy to expand, the Ledger can be larger than the simple one given.


B. Solution

1. Double-Entry Accounting

1.1. Concept

To know what that it is by name; that it has great value; that it is better than a roll-your-own system, is one thing, knowing what it is deeply enough to implement it, is another.

  1. First, one needs to have a decent understanding of a General Ledger, and general Accounting principles.

  2. Second, understand the concept that money represents value. Value cannot be created or destroyed, it can only be moved. From one bucket in the accounts to another bucket, otherwise known as Debit (the from-account) and Credit (the to-account).

  3. While it is true that the SUM( all Credits ) = SUM( all Debits ), and one can obtain such a report from a DEA system, that is not the understanding required for implementation, that is just one end result. There is more to it.

  • While it is true that every transaction consists of a pair: one Credit and one Debit for the same amount, there is more to that as well.

  • Each leg of the pair; the Credit and Debit, is not in the same Account or Ledger, they are in different Accounts, or Ledgers, or Accounts-and-Ledgers.

  • The SUM( all Credits ) is not simple, because they are in those different places (sets). They are not in two rows in the same table (they could be, more later). Likewise, the SUM( all Debits ).

  • Thus each of the two SUM()s cover quite different sets (Relational Sets), and have to be obtained first, before the two SUM()s can be compared.

1.2. Understanding Double-Entry Accounting

Before attempting a DEA implementation, we need to understand the thing that we are implementing, properly. I advise the following:

  1. You are right, the first principle is to hold the perspective of the Credit/Debit Pair, when dealing with anything in the books, the General Ledger; the Customer Accounts; the bank Accounts; etc.
  • This is the overarching mindset to hold, separate to whatever needs to be done in this or that Account or Ledger.

  • I have positioned it at the top; left, in the data model, such that the subordination of all articles to it is rendered visually.

  1. The purpose or goal of a Double-Entry Accounting system is:
  • Eliminate (not just reduce) what is known as:

    • "lost" money

    • "lost" Transactions (one or the other side of the Credit/Debit pair)

    • and the time wasted in chasing it down.

    • Not only can money be found easily, but exactly what happened to it, and where it is now, can be determined quickly.

  • Full Audit functionality
    It is not good enough to keep good Accounts, it is imperative for a business that accounts for other people's money, to be readily audit-able. That is, any accountant or auditor must be able to examine the books without let or hindrance.

    • This is why the first thing an outsider, eg. an auditor, wants to know is, does the SUM( all Credits ) = SUM( all Debits ). This also explains why the DEA concept is above any Accounts or accounting system that the company may be keeping.
  • The great benefit, although tertiary, is that the everyday or month end tasks, such as a Trial Balance or closing the books, can be closed easily and quickly. All reports; Statements; Balance Sheets; etc, can be obtained simply (and with a single SELECT if the database is Relation).

  1. Then ready the Wikipedia entry for Double-Entry Bookkeeping.
  • The internet has plenty of misleading information, and Wikipedia is particularly awful that is forever changing (truth does not change, falsity changes with the weather), but sorry, that is all we have. Use it only to obtain an overview, it has no structural or logical descriptions, despite its length. Follow the links for better info.

  • I do not entirely agree with the terminology in the Wikipedia article. Nevertheless, in order to avoid avoidable confusion, I will use those terms.

  • There are tutorials available on the web, some better than others. These are recommended for anyone who is implementing a proper Accounting system, with or without DEA. That takes time, it is not relevant to an answer such as this, and that is why I have linked the Wikipedia article.

2. Business Transaction

Ideally I would like to see what those double entry rows looks like in database terms, what the whole process will look like in SQL, which entities are affected in each case, etc.

Ok. Let's go with the Transactions first, then build up to understanding the data model that supports them, then inspect the example rows. Any other order would be counter-productive, and cause unnecessary back-and-forth.

Your numbering. Green is House in the General Ledger, blue is external Customer Account, black is neutral.

  • This is the first increment of Treatment, how a thing is treated, in different scenarios (your concern, and your request for specific examples, is precisely correct).

  • Credit/Debit Pairs
    This is the first principle of DEA, understand the pair, as the pair, and nothing but the pair.

Do not worry about how the General Ledger or the Account is set up, or what the data model looks like. Think in terms of an accountant (what has to be done in the books), not in terms of a developer (what has to be done in the system).

Notice that the each leg of the pair is in the one set (the Ledger), or in two sets (one leg in the Ledger, the other leg in Account). There are no pairs in which both legs are in Account.

  • Because DEA is implemented, each Business Transaction (as distinct from a database Transaction), consists of two actions, one for each Credit/Debit leg. The two actions are two entries in a paper-based account book.
  1. A Client deposits cash to his account

Op11 Op12

  • During the DayEnd procedure, among other tasks, all cash is accounted for and checked. The day is closed. All cash sitting in HouseCash that is beyond whatever the bank deems necessary for everyday cash Transactions, is moved to HouseReserve.

Op13

  1. The Bank charges fees once a month to all Clients accounts (sample batch job)

Op2

  • This charges each Account with the Fee
  • Fee is dependent on AccountType_Ext
  • This is the simple case. If the Fee is dependent on something else, such as the number of transactions in the Account; or the CurrentBalance being below or above some limit; etc, that is not shown. I am sure you can figure that out.
  1. A Client does some operation over the counter, and the Bank charges a fee (cash withdrawal + withdrawal fee),
  • Simple Transactions do not incur fees, and Deposit/Withdrawal has already been given. Let's examine a business Transaction that actually attracts a fee.

Op3

  • Mary sends $500 USD to her son Fred, who is travelling overseas looking for whales to save, and has run out of money. The bank charges $30 for an Overseas Bank Transfer. Fred can collect the funds (in local currency equivalent of $500 USD) at any partner bank branch.
  • To actually transfer the money to the foreign bank, the House has to interact with a local big bank that provides international settlement and currency exchange services. That is not relevant to us, and not shown. In any case, all those types of Interbank transactions are batched and dealt with once per day, not once per AccountTransaction.
  • In this simple DEA system, the House does not have currency accounts in the Ledger. That is easy enough to implement.
  1. Mary sends some money from her account, to John's account, which is in the same bank

Op4

  • The money is currently in Mary's account (deposited on a day prior to today), that is why it is in HouseReserve, not HouseCash
  • The money is moved from HouseReserve into HouseCash because John may come into the bank today and withdraw it.
  • As described in example [1.3] above, at the DayEnd procedure, any money sitting in HouseCash in all Accounts will be moved to HouseReserve. Not shown.

3. Relational Data Model • Initial

Now let's see what the data modeller has done, to support the accountant's needs, the business Transactions.

  • This is of course, the second increment of Treatment, what the modeller has understood the real world business Transactions to be, expressed in Relational terms (FOPC; RM; Logic; Normalisation)

  • This is not the simplest data model that is required to satisfy the restated scope.

  • There are simpler models (more later), but they have problems that this one does not have, problems that are desirable, if not imperative, to avoid.

  • The image is too large for in-line viewing. Open the image in a new tab, to appreciate it in full size.

TA

3.1. Notation

  • All my data models are rendered in IDEF1X, the Standard for modelling Relational databases since 1993.

  • My IDEF1X Introduction is essential reading for those who are new to the Relational Model, or its modelling method. Note that IDEF1X models are rich in detail and precision, showing all required details, whereas home-grown models, being unaware of the imperatives of the Standard, have far less definition. Which means, the notation needs to be fully understood.

3.2. Content

  • The main difference between a genuine Relational data model produced by someone else, and mine, is:
    a business Transaction (always two actions; two legs, one per Credit/Debit) is affected by a single row with two sides, one per Credit/Debit,
    in AccountTransaction or LedgerTransaction.

  • Most modellers will model two rows for the Credit/Debit pair, one for each leg or side (hey, one leg is a Credit, and the other leg is a Debit, if I Normalise that, I get two rows).

  • Wrong. If I tell you that Fred is Sally's father, you know, from that single Fact, that Sally is Fred's daughter.

  • A FOREIGN KEY needs to be declared just once, not once for each side.

  • Likewise, the Credit/Debit pair is a single Business Transaction,
    a single Atomic article, that can be perceived from either Side, like two sides of one coin. Modelled as such.

  • All manner of preventable bugs are prevented, the search for the "missing" leg is eliminated.

  • Even for those with sub-standard OLTP code, which causes quite preventable concurrency problems, if this method is implemented, this is one article wherein those problems will not arise.

  • Further, the number of rows in the %Transaction tables is halved.

  • I have arranged the articles such that the
    External Account
    Internal Ledger and LedgerTransaction
    Internal-External AccountTransaction
    are clear.

  • Along with a nugget of definition from the Wikipedia entry.

  • Having familiarised yourself with the DEA Credit/Debit pairs, now study the Treatment of the pair. Notice that the Treatment is different, it is based on a number of criteria (three account types; six Ledger types; etc), which in turn is based on the complexity of the General Ledger.

  • This Ledger is simple, with Asset/Liability accounts only. Of course, you are free to expand that.

  • The eagle-eyed will notice that AccountStatement.ClosingBalance and LedgerStatement.ClosingBalance can actually be derived, and thus (on the face of it), should not be stored. However, these are published figures, eg. the Monthly Bank Statement for each Account, and thus subject to Audit, and therefore it must be stored.

For a full treatment of that issue, including considerations; definition; treatment, refer to this Q & A:

3.3. Summary

In closing this section, we should have reached this understanding:

  • The overarching principle of DEA, the Credit/Debit pairs, purely intellectual

  • The typical business Transactions, always a Credit/Debit pair, two legs, two entries in the accounting books

  • A deeper understanding of the Treatment of said Transactions

  • The environment that the House (small bank; cooperative; casino) manages (internal Ledger and external customer Account)

  • A first look at a data model that is proposed to handle all that.


4. Relational Data Model • Full

Here it is again, with a full set of sample data.

  • Re the Primary Keys:

  • Note that LedgerNo and AccountNo are not surrogates, they have meaning for the organisation, in ordering and structuring the Ledger, etc. They are stable numbers, not an AUTOINCREMENT or IDENTITY or anything of the sort.

  • The Primary Keys for LedgerTransaction and AccountTransaction are pure, composite Relational Keys.

  • It is not a Transaction Number of some kind that is beloved of paper-based accountants.

  • It is not a crippling Record ID either.

  • The Alternate Keys are more meaningful to humans, hence I have used them in the examples (Business Transactions, above [2], and below [5]). This Answer is already layered, it would be a nightmare trying to relate hundreds of 1's, 2's and 3’s to each other.

  • If we wish to understand what something means, we need to hold onto the meaning that exists in the thing, rather than excising the meaning by giving it a number.

  • In the example data, the Primary Keys are bold.

TAdata


5. Business Transaction with Row

Ideally I would like to see what those double entry rows looks like in database terms, what the whole process will look like in SQL, which entities are affected in each case, etc.

Now that we understand the Business Transactions, and the data model that services the requirement, we can examine the Business Transactions along with affected rows.

  • Each Business Transaction, in DEA terms, has two legs, two entries in the paper-based account books, for each of the Credit/Debit pair,
    is yet a single Business Transaction, and now:
    it is affected by a single row with two sides, for each of the Credit/Debit pair.

  • This is the third increment in understanding Treatment: the business Transactions; data model to implement them; and now, the affected rows

  • The example database rows are prefixed with the table name in short form.
    Plus means INSERT
    Minus means DELETE
    Equal means UPDATE.

  1. A Client deposits cash to his account

Row11 Row12 Row13

  1. The Bank charges fees once a month to all Clients accounts (sample batch job)

Row2

  • This, too, is a batch job, just one task in the MonthEnd procedure.
  • Notice the date is the first day of the month.
  1. A Client does some operation over the counter, and the Bank charges a fee (cash withdrawal + withdrawal fee),

Row3

  • To be clear, that is three Business Transactions; two entries each, one for each side of the Credit/Debit pair; affected by one database row each.
  1. Mary sends some money from her account, to John's account, which is in the same bank

Row4


6. SQL Code

There are usually several ways to skin a cat (code), but very few if the cat is alive (code for a high concurrency system).

  • The Relational Model is founded on First Order Predicate Calculus (aka First Order Logic), all definitions (DDL) and thus all queries (DML) are entirely Logical.

  • A data model that conforms to that understanding, is therefore entirely Logical.

  • The queries against such a data model are dead easy: Logical and straight-forward. They have none of the convoluted code that is required for Record ID based filing systems.

Therefore, out of the several methods that are possible for the SQL code requests, I give the most direct and logical.

The code examples are that which is appropriate for SO, it is imperative that you trap and recover from errors; that you do not attempt anything that will fail (check the validity of the action before using a verb), and follow OLTP Standards for ACID Transactions, etc. The example code given here are the relevant snippets only.

6.1. SQL View • Account Current Balance

Since this code segment gets used in many places, let's do the right thing and create a View.

  • Note that on genuine SQL platforms, source code is compiled and run when it is submitted, Stored Procs and Views are stored in their compiled form, thus eliminating the compilation on every execution. Unlike the mickey mouse NONsql suites.

  • High-end commercial SQL platforms do a lot more, such as caching the Query Plans for Views, and the queries in Stored Procs.

CREATE VIEW Account_Current_V
    AS 
SELECT  AccountNo, 
    Date = DATEADD( DD, -1, GETDATE() ),     -- show /as of/ previous day 
    ASS.ClosingBalance,                      -- 1st of this month
    TotalCredit = ( 
        SELECT SUM( Amount ) 
            FROM AccountTransaction  ATT
            WHERE ATT.AccountNo = ASS.AccountNo 
                AND XactTypeCode_Ext IN ( "AC", "Dp" ) 
                -- >= 1st day of this month yy.mm.01  /AND <= current date/
                AND DateTime >= CONVERT( CHAR(6), GETDATE(), 2 ) + "01" 
            ), 
    TotalDebit = ( 
        SELECT SUM( Amount ) 
            FROM AccountTransaction ATT
            WHERE ATT.AccountNo = ASS.AccountNo 
                AND XactTypeCode_Ext NOT IN ( "AC", "Dp" ) 
                AND DateTime >= CONVERT( CHAR(6), GETDATE(), 2 ) + "01" 
                ),
    CurrentBalance = ClosingBalance + 
        <TotalCredit> -   -- subquery above 
        <TotalDebit>      -- subquery above 
    FROM AccountStatement  ASS
                                             -- 1st day of this month
    WHERE ASS.Date = CONVERT( CHAR(6), GETDATE(), 2 ) + "01"

6.2. SQL Transaction • [1.2] Withdraw from [External] Account

A proc for another DEA business Transaction.

CREATE PROC Account_Withdraw_tr ( 
    @AccountNo, 
    @Amount
    ) AS
    IF EXISTS ( SELECT 1                       -- validate before verb
            FROM AccountCurrent_V 
            WHERE AccountNo = @AccountNo 
                AND CurrentBalance >= @Amount  -- withdrawal is possible
            )
        BEGIN
        SELECT @LedgerNo = LedgerNo 
            FROM Ledger 
            WHERE Name = "HouseCash"
        BEGIN TRAN
        INSERT AccountTransaction 
            VALUES ( @LedgerNo, GETDATE(), "Cr", "Wd", @AccountNo, @Amount )
        COMMIT TRAN
        END

6.3. SQL Transaction • [1.1] Deposit to [External] Account

A proc, set up as an SQL Transaction, to execute a DEA business Transaction.

CREATE PROC Account_Deposit_tr ( 
    @AccountNo, 
    @Amount
    ) AS
    ... IF EXISTS, etc ...                   -- validate before verb
        BEGIN
        SELECT @LedgerNo ...
        BEGIN TRAN
        INSERT AccountTransaction 
            VALUES ( @LedgerNo, GETDATE(), "Dr", "Dp", @AccountNo, @Amount )
        COMMIT TRAN
        END

6.4. SQL Transaction • [Internal] Ledger Account Transfer

A proc to add any business Transaction to LedgerAccount. It is always:

  • one LedgerTransaction.LedgerNo, which is the Credit leg
  • one LedgerTransaction.LedgerNo_Dr, which is the Debit leg.
  • given by the caller.
CREATE PROC Ledger_Xact_tr ( 
    @LedgerNo,    -- Credit Ledger Account
    @LedgerNo_Dr, -- Debit  Ledger Account
    @Amount 
    ) AS
    ... IF EXISTS, etc ...
        BEGIN
        SELECT @LedgerNo ...
        BEGIN TRAN
        INSERT LedgerTransaction  
            VALUES ( @LedgerNo, GETDATE(), @LedgerNo_Dr, @Amount )
        COMMIT TRAN
        END

6.5. SQL Batch Task • Account Month End

This uses a View that is similar to [6.1 Account Current Balance], for any month (views are generic), with the values constrained to the month. The caller selects the previous month.

  • This Answer now exceeds the SO limit, thus it is provided in a link Account_Month_V.

Just one Task, in a stored proc, to process the Month End for AccountStatement, which is executed as a batch job. Again, just the essential code, the infrastructure needs to be added.

CREATE PROC Account_MonthEnd_btr ( ... )
    AS    
... begin loop
... batch transaction control (eg. 500 rows per xact), etc ...
INSERT AccountStatement
    SELECT  ACT.AccountNo,
            CONVERT( CHAR(6), GETDATE(), 2 ) + "01",  -- 1st day THIS month
            AMV.ClosingBalance,                       -- for PREVIOUS month
            AMV.TotalCredit,
            AMV.TotalDebit
        FROM Account ACT 
            JOIN Account_Month_V AMV               -- follow link for code
                ON ACT.AccountNo = AMV.AccountNo
                                                   -- 1st day PREVIOUS month
        WHERE AMV.OpeningDate = DATEADD( MM, -1, ACT.Date ) 
... end loop
... batch transaction control, etc ...

6.6. SQL Report • SUM( Credit ) vs SUM( Debit )

While it is true that the SUM( all Credits ) = SUM( all Debits ), and one can obtain such a report from a DEA system, that is not the understanding. There is more to it.

Hopefully, I have given the Method and details, and covered the understanding and the more, such that you can now write the required SELECT to produce the required report with ease.

Or perhaps the Monthly Statement for external Accounts, with a running total AccountBalance column. Think: a Bank Statement.

  • One of the many, great efficiencies of a genuine Relational database is, any report can be serviced via a single SELECT command.

One PDF

Last but not least, it is desirable to have the Data Model; the example Transactions; the code snippets, all organised in a single PDF, in A3 (11x17 for my American friends). For studying and annotation, print in A2 (17x22).


Maas answered 24/12, 2019 at 7:11 Comment(92)
@Alex. For errors and specific questions, please leave comments here, so that there is a record with the Answer. For discussion, the mods have opened a chat, which has less restrictions than the comments. They delete the comments.Maas
This answer is remarkable for two things (apart from its length): a) there are no citations to established practice/textbooks; b) the design of "a business Transaction is a single row" is not used by any ERP or accounting package, and for a good reason: it is inadequate. It's true that many transactions (especially in banking) consist of only two legs, debit and credit (equal and opposite). But in general there might be several legs -- typically with tax and/or charges, multiple distributions from one account to several others.Snuggery
So 'single-entry' bookkeeping is a naieve approach which simply won't scale. The claim "Further, the number of rows is halved." is bogus. (And as if anybody these days worries about saving disk space.) You need to index both the credit account and the debit account (and declare both with Foreign Key references to the 'Account master'). Seems to me Derek has made up this whole thing out of thin air. I'd be interested to know any example of a database design using 'single-entry' bookkeeping like this. Nobody should follow this example.Snuggery
Oh, I should add: a typical requirement in a fully-featured account system is to hold 'pending' or 'registered not complete' transactions (sometimes called an 'inbox'). For example we've received an invoice for $100; we know the vendor's account (and we want to show the $100 against that vendor in an enquiry/balance owing); but we don't know our account coding for the line items/expenses (not all of them). So we post a 'one-sided' transaction, at a pending status to distinguish it from fully-posted/balancing transactions. 'Single-entry' bookkeeping is inadequate to meet this requirement.Snuggery
Perhaps a business Transaction is a single row is a bit wrong since OTC transfer consist of 3 rows. I guess you mean a doubly entry is a single row, and there are many double-entries per business transaction.Schorl
@Alex. 1) I did not state that (please do not follow the comments of those who are confused). A Business Transaction is two entries in paper-based accounts; one entry for each Credit/Debit leg. That is affected by a single row in my database. 2) OTC_Transfer is three business Transactions in the DEA sense, not one. As long as that is understood, it can be viewed as one large Business Transaction. 3) Nevertheless, I have added a few words of clarity throughout. And one additional code segment. Happy New Year.Maas
@user806. 1) Yes. In [5 [1.1] ] the customer AccountNo 123 Alex is Credited, the Ledger[Account]No 990 HouseCash is Debited. The customer Account is external, HouseCash is external. 2) It is no problem at all to expand the simple Ledger I have given, by adding whatever Ledger.Ledger[Account]Nos to suit your needs.Maas
@Alex. This Answer is of course complete for the purpose. However, someone else asked for an expansion of the Ledger, which I provided here. You may be interested.Maas
Please correct if I am wrong: The [661] FeeRegular (also [662] FeeTransaction) are RR (aka revenue), 'Cr' increases it, so we apply Cr. The '[990] HouseCash` is AA (Asset) so we have to increase it when deposit happens, we apply Dr because it increases Asset. But why it's an Asset? House owes that money to ext. account holders. I could treat [990] vice versa: it's AL and we decrease it by applying Dr. So what is it then?Schorl
@Alex. 1) Money represents value, it cannot be created or destroyed, only moved. I do not use "increase/decrease" due to the implication. A DEA Cr leg is credit, Dr leg is debit. 2) 661,662 is RR . 3) 990 is AL Liability because that money needs to be paid to the Ext Acct holder on demand. 4) As detailed in § 5.1.1, a Dp deposit is an AccountTransaction that Dr debits LedgerNo 990 (Income=Dr) and Cr credits external AccountNo 123 (Giver=Cr). In a naïve sense only, both are "increased", because money moved into the system.Maas
@Alex. I have upgraded all the graphics to show that further level of detail, and the PDF. Note that it is not an error to move money from one Liability/Expense Ledger Account to another Liability/Expense, or to an Asset/Revenue.Maas
Sounds reasonable, but it's kinda contradicts with TransactionLedger_IsValid_ck CHECK ( TransactionLedger_IsValid_fn( LedgerNo, LedgerNo_Dr ) = 1 ) -- check one is Asset and the other is Liability from another answer?Schorl
Also, the comment from @Snuggery is interesting, usually in a more complex system you not only have pending, but I would call it long running transactions with several states, where one large transaction affects many ledgers and ext. accounts, where you can "rollback" (+ add new) all the multi ext. account/ledgers transactions when state changes. You have to keep references to Transactions. (Here I am already referring to extended ledger model where Transaction is further normalised). It's obviously a material for another referred Q which is in progress ATM.Schorl
and in to another Account, via a single business transaction. Therefore there never is one transaction that affects many Ext Accounts (or other Ledger Accounts): each is a separate business transaction. There is no rollback, no need to keep "references".Maas
I am guessing your point is to create a LedgerAccount per instance of such operation. So if one of dozens operations in a system is to Sell a building to a group of people (ext. accounts) there will be a LedgerAccount per each building. Building could be in process of construction and if something goes wrong you refund participants, pay penalty, etc. That trade could be cancelled one day due to some reason, you move funds back, penalty, etc. Transaction table accumulates track of transfers/buyers by current design.Schorl
Let us continue this discussion in chat.Maas
A single Debit (e.g. Payroll Expenses) can balance with two or more Credits (e.g. Salaries, Taxes). There is not a one to one match between debit and credit entries but rather a constraint that all debits and credits balance. I would model LedgerTransaction with LedgerNo, Date, Type (Cr,Dr), and Amount.Geisha
Does this model support complex ("compound") transactions that involve more than two accounts? E.g. "Purchase land for $15,000 by giving $5,000 cash and promising to pay the rest in 90 days". This would be a debit to Land for $15,000, credit to Cash for $5,000 and credit to Notes Payable for $10,000. If so, what would the DB rows look like?Memorize
@Edward. In the Accounting sense, that would be two ordinary Transactions, as per the examples, there is no need for your suggested "complex" Transaction. The "cash" Account would be an External Account. The whole point of DEA is to keep the Transactions simple and Double Entry. Not quadruple or octuple entry.Maas
@RexBloom. No. 1) Read the notes in the DM. LedgerTransaction is a single Transaction with two sides. LedgerNo is the CR side, LedgerNo_Dr is the DR side. 2) If you do not understand that there is a 1-to-1 match of the Credit side vs the Debit side in every Accounting Transaction, you have missed the point of DEA completely. Especially for payroll, when there is a discrepancy between the total Credit vs total Debit, in your model you would not find it.Maas
Thanks for your reply. My example was "in the accounting sense" from an accounting course - they refer to it as a 'complex' or 'compound' transaction. I was just trying to match it up with your model. I'm still not sure how this looks in your model... which examples are you referring to?Memorize
@Memorize My experience in banking is that complex transactions like you mention are common. The important thing is that the Ledger is in balance not that each transaction has a matching credit and debit. Payroll, Credit Card Bills,Settlements, all have large credits and debits that may offset to more than one ledger account. Even Quick Books has a Split function for this same purpose. If I deposit 1,000 (credit) and need to assign that to two invoices (debit) I don't create two credit transactions - it is one credit with two debits that balance.Geisha
@RexBloom Thanks, Rex, I think I understand that part, I just wanted to see the table entries in this model because it looks like each table row has the 2 parts in it (Dr and Cr) and assumes the amount for each is equal, so I'm just getting confused somewhere. How many rows would I need to insert and do I leave the Cr part null in some of them if it's multiple rows? A simple table image like the many in this answer would quickly clear it up.Memorize
in my model I do not store both ledgers together. I always insert two records (minimum). In your complex example you would insert 3. I use a transaction and check that debits and credits balance before inserting. With this I never insert data that unbalances the GL.Geisha
@Memorize The question then remains in the Accounting sense, nothing to do with this model, which implements DEA. There is no such thing as a "compound" or "complex" Transaction. There is only a DEA Transaction or a non-DEA (mickey mouse) Transaction. You can't do what you describe because it is anti-DEA. You have to execute two DEA Transactions: Land/Cash $5,000 [DR, CR]; Land/NotePayable $10,000 [DR, CR] .. and a prior Transaction to get the Cash into the Cash Account.Maas
@RexBloom QuickBooks is not DEA. QuickBooks cannot be used in Banking (which demands DEA). You are performing a process (balancing) which is manual, outside the system, before entering your non-DEA 'transactions". You don't need to do that under DEA, because the system is always balanced, because each Transaction is balanced. No manual control required. It is not "two credit transactions", it is two DEA Transactions, each a Credit and a Debit.Maas
Ok, thanks for clearing that up. I now understand where you're coming from. The textbook doesn't treat it that way - they do Land $15,000 [DR]; Notes Payable $10,000 [CR]; Cash $5,000 [CR]. Perhaps the "double" in DEA refers to there being balanced amounts in CR and DR sides, as opposed to a single DR, CR pair? In any event, you've answered my question - I see how your model works now.Memorize
@RexBloom That makes sense, thanks. Do you have details of your model somewhere? Sounds like it's what I'm looking for.Memorize
@Edward. I found this helpful: github.com/apache/fineract. If you dig into the fineract codebase you will see how they handle a GL account and Journal Entry (github.com/apache/fineract/blob/develop/fineract-provider/src/…). They have some FK relationships I would not use but as we see in this thread to each his own and there is more than one way to create a balanced GL.Geisha
@Edward. 1) Re there is more than one way to create a balanced GL. If you want your db to pass an IT Audit, or your Accounts to pass an Accounting Audit, no there is not. There is one correct way, and all others are incorrect. I did not write the standard, the CPA did, I merely comply. 2) You cannot compare freeware (which has no compliance with standards) against fee-paid software that complies with standards. My fault is providing this Answer in a freeware platform, where it is perceived as just another freeware method. Only the seeker can appreciate what he asked for.Maas
The price of the software is not relevant. In many systems there is someone you must answer to. So you do need to figure that out and comply. The Auditor of any system is the one who can say how that system must be designed. Rest assured apart from that there is more than one way to balance a GL. @Maas says as much when they acknowledge above that there is a "main difference between models others design and mine".Geisha
@RexBloom 1) You get what you pay for. Whether it is freeware "DBMS" or Accounting. 2) Auditor: ok, see if your CPA accredited Auditor approves your multi-transaction non-DEA method, that is supposed to balance the GL.Maas
@Maas There is no such thing as a "compound" or "complex" Transaction. Do you have a reliable source for this claim? The Wikipedia article just says: In double-entry bookkeeping, a transaction always affects at least two accountsSaw
@Saw 1) I did not say that, I said There is no such thing as a "compound" or "complex" Transaction. There is only a DEA Transaction or a non-DEA (mickey mouse) Transaction. If you read my Answer, you may find that it goes way beyond wiki, it clarifies two sides vs two accounts. 2) Wiki is a cesspool, guaranteed to confuse. When I warn against it, SO censors my Answers. I can't argue against a cesspool.Maas
So, do DEA transactions allow more than two accounts or not and who says that?Saw
@taffer. 1) I have not said that DEA transactions allow more than two accounts, thus I cannot defend it. If it is more than two accounts, it is not DEA. 2) the cesspool article says at least two accounts, you need to chase them (not me) for a reference. And a method.Maas
If it is more than two accounts, it is not DEA. Who says so? I don't see any reliable source for your claim.Saw
@Saw 1) I say so, based on Standards & knowledge. 2) For the Accounting side, refer to any textbook for Chartered Practising Account (wiki is not a textbook). 3) For both the CPA side and the database side, anyone who reads & understands the Answer and the Data Model, will realise that anything other than two sides (two accounts, one account for each side) fails the definition of Double Entry Accounting. 4) I have already explained: if multiple purchases/sales are required, that should be in the External Account, with a single DEA AccountTransaction.Maas
There you go, now I've done your homework: Dauber, Shim, Siegel (2012). The Complete CPA Reference. Wiley. There is a compound entry on page 42, another one on page 46, and another one on page 111.Saw
thank you @taffer, and well done for persisting. Typically a receivables-invoice transaction (entered to a Double-Entry Accounting system) uses at least three accounts within the one transaction: Customer (receivable total); tax (for transfer to the government); product sold (revenue for us). In American jurisdictions, we must account separately for Federal vs State vs City/local taxes -- so at least 5 account entries within the one transaction. Legally we must not represent the tax as 'our' revenue -- because we're merely collecting it on behalf of the government.Snuggery
I have asked you several times to support your claims with sources, but you have been unable to do so. Instead, you just pointend to CPA textbooks. These, in turn, refute your interpretation that a journal entry in double-entry accounting can only contain two accounts. And no, double-entry accounting simply means that there must be a debt and a credit in each journal entry, which cancel each other out. It does not mean that only one account can be debited and only one account can be credited. It is called double-entry bookkeeping, not bookkeeping with at most two accounts.Saw
@taffer. 1) You keep changing, but thank God, your understanding of DEA has progressed, finally we agree on the definition of DEA. You did not quote a CPA textbook, just a book. 2) What other implementations say they can do. is irrelevant, I have answered the original Q (not yours). 3) I have not changed my Answer, nothing is "refuted". 4) Now try and understand Transactions within DEA. Since you cannot read & understand the explicit transactions I have given in §5, & apply them to your "compound" or "composite" or 3 or 42 accounts, I cannot help you. Hint: [4] has four Accounts.Maas
@Saw it is called double-entry bookkeeping, not bookkeeping with at most two accounts. Oh good. Actually it is DEA not DEB. Now in that DEA, which you say consists of two matching CR/DB entries, what is the no of accounts that can be referenced in those two entries (min; max) ??? If your answer is anything other than 2, you have totally missed the point of DEA, and you seek to pervert it, due to your misunderstanding of another context (the Transaction at the business & database level). You are unable to separate the two contexts, you have them nicely confused.Maas
@Maas Two questions that are not clarified here: 1) What if we have statuses for transactions (like scheduled, pending, rejected) - should we store them in accounting system and AccountTransaction table or should it be stored outside of accounting tool? 2) What if we need to calculate different balances based on different statuses (e.g. pending transaction influence available balance) - what is your recommendation here?Agar
@borN_free. 1) This is a template for the accounting side (the status is accounted). Other statuses; etc (your list) are beyond Accounting, which may be deployed in a separate table, which is a queue, not submitted to Accounting. 2) The balance is in Accounting, the Ledger cluster. There can be no balance outside accounting (if there is, it is fiction). 3) You could set up a Suspense account in Account, read up on it.Maas
@Maas re "multi-line" transactions. Say I did a transaction where I bought a piggy bank for my child for $5 (which attracts sales tax of 10%) as well as paid a setup fee for a savings account of $10. Are you saying these would all be separate transactions? What if I wanted to issue an invoice/receipt to a customer that had both items on it, as well as the tax?Chammy
@Chammy 1) Yes. It is two real (physical) accounting transactions, each with different parties (one at the shop; one at the bank) 2) Who would the Invoice be sent to, your child ? Ok, one Invoice with two invoice line items. 3) Tax has to be managed correctly: open one external Account for each State, and one for Federal. Any taxable item therefore has two accounting transactions. Then the Invoice Line item is easy.Maas
@Maas thank you for this in-depth answer! A couple questions: 1) RE month end: Is your SQL meant to be run on the 1st of the month or the very end of the month? If the former, won't Account_Current_V return nothing since there's no statement for the new month yet? And, if the latter, wouldn't the date being inserted into AccountStatement be wrong (since the current balance calcs in the new month need a statement dated for that month)? 2) Can you explain more the purpose of the WHERE clause in the ACV/ASS join for the month end SQL? Thank you again!Stockjobber
@Stockjobber 1) You are most welcome. 2) I have added Account_Month_V to provide more explicit code, and changed Account_MonthEnd_btr to suit. Month End procedure is now explicit. Please check.Maas
I had a first look and it looks good and makes total sense. Thank you one more time!Stockjobber
@Stockjobber Great. If your Ledger is a tree structure, you may be interested in this answerMaas
Hi. Thanks for writing this comprehensive answer. I am currently building an online marketplace and wondering if using a DEA type system would make sense. I have to track purchases, payments to sellers, payments in and out of paypal, payments VAT in different countries and all in multiple currencies. Would implementing a DEA make sense? How does one tie the DAE tables to the orders and products typically. Do you just transfer the payment amounts after the orders are complete? Thanks!Knipe
Additionally, a couple of questions regarding the examples in the answer. 1) What is the difference between ledger and account - why are the ledgers not just represented as accounts. 2) When transferring from user account to user account, why the need for the transfer to the ledger first? If ledgers were just accounts (as in my first question), could it not just be represented as account -> account? Thanks!Knipe
@Knipe The Answer is for the Seeker, (0) who understands accounting basics, re (1) how to implement DEA on top of that, and (2) a Relational db for DEA. Your questions are about (0) the basics of accounting, they are outside the scope of (1) (2). You are best advised to learn (0) accounting basics, before trying to understand (1) (2). Sorry I can't help you.Maas
@Maas thank you for this answer. I can see the merits in this approach as you're eliminating accounting ambiguity for complex "business events". As a follow-up, are there specific textbooks/sources you would recommend for an authoritative definition of a "DEA business transaction"? When there's say a "business event" (what online is referred to as a "compound/split/complex transaction"), where we want to reference 2 or more DEA transactions and call them X, is my understanding correct that you'd handle this through a new set of tables to avoid "polluting" the core DEA functionality?Parimutuel
@Parimutuel 1) You can't pollute the DEA core, same as any standard, you can only comply xor fail. 2) What you are describing is Distribution or Allocation of some incoming (payable) or outgoing (receivable) that is one DEA transaction on the Ledger & Account structure, but multiple "business events" (your term, not mine) externally. So, yes, you need a separate set of tables for that. 3) "Online" is a cesspool, the notion of referring to 2 or more things as 1 thing is hysterical, I cannot respond to that. I wrote this answer for people who want the alternative; the standard; sanity.Maas
@Maas how can this be modelled to Inventory Management? Are there any resources available that you reccommend? Thanks in advanceSilva
@Silva Most resources especially on the web, are confused or incorrect, hence my Answer. There are no resources for this level of implementation detail. For DEA on Inventory movements, refer to the Inventory model in this Answer.Maas
@Maas First of all, thank you very much for the detailed and thoughtful answer. Database-wise, everything checks out and I am 100% sold on the answer on a technical/engineering level. What I'm absolutely perplexed about is the your definition of double entry accounting vs double entry bookkeeping, because I can't find a single reference anywhere that says that there should only be 1 debit and 1 credit per transaction. Everywhere else says a compound transaction is possible where in there are more than 2 rows in a given transaction. Could you provide any references to your definition?Visual
@だらんぎんじょん 1) I do not make a distinction between DE Accounting and DE Bookkeeping (Bookkeeping is merely the clerical side of Accounting). 2) For defns you need to identify and use an authority, the internet is a cesspool, there are very few. Try this defn What is the Double Entry System. 3) Now for the rows. It is usually implemented as two rows, which demands proper ACID Transactions (no freeware), and becomes problematic when many references are required.Maas
3) AFAIK, only I give a solution that uses one row, which is simple, unlimited references, and allows a freeware "sql" implementation. 4) If everywhere else has some value, please go there. "Compound transactions" is insanity. I do not accept the cancer in the first place, and I do not need the medication is the second place, I simply reject insanity. You should place whatever is "compound" is a separate cluster of tables: refer my comment to Optimae above re Distribution or Allocation.Maas
Ohh wow. Thanks a lot for such a detailed explanation.Tristichous
When Alex deposits $50, for a bank (or bank-like sort of business) you're crediting a Liability (Customer Deposits) and debiting an Asset (whichever asset it was - cash etc). I don't understand the logic for a deposit to be Cr Asset / Dr Liability.Shrewd
@Shrewd First, you have to dismiss your mindset re Cr-L & Dr-A. Second, it is not about logic, it is the Accounting Method & terminology. That $50 cash was not previously in the bank, it walked into the bank. Therefore the Bank-Asset-Cash was Credited (cash increased). Now we owe Alex $50. That is Bank-Liability to Alex. The other side of the DEA Transaction[ Bank-Asset-Cash-Cr ] is of course a Dr [ Bank-Liability-Account[ Alex ] Dr ]. Another way of stating that, from bank pov, is, Alex' account was debited $50, and the bank-cash was credited $50.Maas
There are a few ways that I like to think about this. The first is mechanical, you look into the nature of the accounts (Asset has a Debit nature / Liability a Credit nature), and just figure what should increase (we need to increase both the asset and the liabilities), hence you Credit 50 Liability and Debit 50 Asset. The second is more "logical", if "credit" is "source", then money came from Alex (for whom we owe), hence you Credit Liability and Debit Asset. This is the correct entry for this specific transaction in this specific case. Actually, AccountingCoach even has this exact example.Shrewd
Linking a third party article that does a great job of explaining this specific transaction: accountingcoach.com/debits-and-credits/explanation/4. It would be worth to edit the answer so other folks that read this are not confused by the accounting logic / what sort of transaction this actually is. At last, when using account number for examples, it's always a good practice to use standard logic (Assets are 1xxx and Liabilities are 2xxx). Using 9xxx as a number for a liability account is confusing.Shrewd
@Shrewd Thanks. I provided a Relational database Answer on SO, it is not an Accounting tutorial. For the Accounting side, feel free to use the Accounting authority of your choice ... obviously, I used a different authority, which is a bit less confused.Maas
I've spent a month in full-time work, diving deep into @PerformanceDBA's answers and diagrams, as well as other related posts. I've also read numerous comments from others. There were times when I felt desperate, thinking that I was approaching everything the wrong way. But. Result was worth it. I now have the most robust and beautifully structured accounting system that operates solely by INSERT. There are no updates at all. This is what I call a high level of architecture. You have my utmost respect and gratitude. I want to express my sincere appreciation for sharing this knowledge with us.Chibouk
I apologize if I am misunderstanding you, but I am confused by your statement that ledger_no is credit and ledger_no_dr is debit. In accounting, debits are typically recorded on the left side of a ledger account, and credits are recorded on the right side. So, if ledger_no is a credit, then it should be on the right side of the ledger account, and ledger_no_dr should be on the left side. However, you are saying that ledger_no is on the left side and ledger_no_dr is on the right side. Can you please clarify what you mean?Americano
@Americano There is no LHS/RHS, I have not said "ledger_no is on the left side and ledger_no_dr is on the right side". CR/DR is explicitly named.Maas
@Maas I apologize for any confusion. My reference was directed towards the LedgerTransaction table, where the columns are arranged in the subsequent order: LedgerNo, DateTime, LedgerNo_Dr, Amount. It is important to note that the provided description clarifies the roles of these columns as follows: LedgerNo signifies a credit (Cr), while LedgerNo_Dr signifies a debit (Dr). You may verify this information in the document located at the following URL:softwaregems.com.au/Documents/Student_Resolutions/Alex/…Americano
@Maas Furthermore, it is important for me to mention that I possess a certain degree of inexperience when it comes to accounting concepts, although I do possess a notable level of proficiency in the realm of software architecture. I wish to convey my sincere appreciation for your explanations, which I have diligently and devotedly studied over the course of the past four weeks.Americano
@Americano Thanks. Column order is not relevant, it does not signify Left/Right. I could have, just as easily and legitimately, declared LedgerNo_Dr, DateTime, LedgerNo, Amount with the PK & AK switched. I could have drawn AccountTransaction on the left of Ledger and LedgerTransaction on the right. There is no Left and Right in this model.Maas
@Maas I appreciate your clarification. It's reassuring to know that column order doesn't imply a strict left/right significance in our model. Your explanation about the flexibility and lack of a definitive "Left" or "Right" orientation is enlightening. Thanks for sharing your expertise.Americano
@Maas thanks for this very detailed and extensive answer. I totally agree that 1 row should represent 1 transaction for both sides of an entry if you want DEA. Would the ERD that you present here work for a small service business that does not have branches, and works with multiple clients (who would be in the account table and get invoiced)? Would the data model change if the house became multi-branch?Allopath
@Allopath 0) it is not an ERD, it is an IDEF1X Data Model. 1) Small service business, multiple clients, no branches: Yes, it works as is. 2) Multiple branches: (Most accounting systems I have corrected have poor Ledger definition, which is the source of many problems, but Accountants are unaware.) I would implement each branch as a separate Tree in the Ledger (notice the indented sample data). Therefore yes, it works but not as is. To implement a full-blown Ledger that supports Trees, use my Hierarchy.Maas
@Maas I learned a lot reading your example, while I was implementing a personal small ledger for myself. As I don't have an internal/external structure I do not have HouseCash etc. and my ledger is transfering between accounts. But I have a question regarding your transactions: I assume in your transfer example you left out a transfer id because this is an example. Else I don't really get how you track money in a larger context where transaction with the same amount, may occur in the same time. Am I right with this assumption?Incisure
@Incisure my ledger is transfering between accounts: Clarification - that means Ledger.LedgerNos not Account.AccountNos. No transfer id: I have left out nothing. The data model is Relational, Id fields are prohibited in the Relational Model, the additional field & index are simply not necessary here. The LedgerTransaction.PK (and AK) does prevent duplicates (transactions that occur "at the same time", 3 ms precision) regardless of Amount. Money is tracked due to DEA, not merely due to good Keys.Maas
@Maas I just implemented accounts and transactions between them. I see the necessity for the ledger transactions in something like a bank, but in fact I don't have something like this in personal finance. I just wanted to build up my knowledge about DEA. Regarding tracking: You have to track two account xacts and one ledger xact by time and amount. That would be something that I would handle by a single transaction-id as it's not based on timing. Else this id may be implemented by setting it beforehand for all rows. Finding a transaction would then be a simple = and not fuzzy.Incisure
Hi @Maas . thanks for the detailed answer. while implementing, I noticed that Account_Current_V's where clause depends on AccountStatement which is causing the view to not return anything for accounts that do not have a AccountStatement. do you insert a row for new accounts into AccountStatement with previous month and zero values whenever a new account is inserted ? or do you take a different approach? or am I missing something ?Anthology
And there's one issue with LedgerNo and DateTime being primary keys, which is 2 transactions cannot be inserted at the same time, even if they are against different accounts, which does not sound great, unless that is the point itself, which I'm not sureAnthology
@Incisure 1) You are fixated on some form of tracking which you have not identified, and that may require your "transaction-id". Btw, you do not need it. It looks like you do not understand that DEA is the tracking 2) My Answer serves the Question, not your tracking requirement 3) You have to track two account xacts and one ledger xact by time and amount No, please study the DM and the Transactions, you have either a DEA Ledger-Ledger Transaction in LedgerTransaction xor a DEA Ledger-Account Transaction in AccountTransaction.Maas
@Anthology No AccontStatement row: Yes (it is pseudo-code not final code). Dummy rows are for dummies. Use ISNULL(ASS.ClosingBalance, 0) PK: That is the point. The purpose of the PK is to serialise rows by LedgerNo & DateTime, it additionally prevents accidental dupes (DATETIME datatype precision is 3 millisecs). So non-dupes at the same time will succeed.Maas
@Chibouk You are welcome & thank you. accounting system that operates solely by INSERT. There are no updates at all: Yes, by design. To pass an Audit, one must not update [rewrite] history, an error in a previous period is corrected by a Transaction (Adjustment) in the current period.Maas
@Maas Thanks for the answer. but still the problem of AccountTransaction remains. if we have 2+ different AccountNo doing none dupe transactions with the same LedgerNo at the same time, it fails. an ex. from your ex.: (AccountXact+,990,2019.12.23,Dr,Dp,234,200) and (AccountXact+,990,2019.12.23,Dr,Dp,123,100), assuming 2019.12.23 is the datetime type at the same millisecond. also from what I remember times provided by the server may also be rounded to the nearest hundredth ms to prevent recent vulnerabilities from getting exploited, which may increase the chance of failingAnthology
@Anthology No. 1) The point is DATETIME datatype is given in ms precision, and values are at least 3 ms apart (rounded to 3 ms), not hundredth ms. 2) In reality, in server time, a few operations, but certainly not 1 complete SQL xact, let alone 2, can be performed in a single 3ms interval. Which means no 2 xacts will have the same DateTime (regardless of same or diff LedgerNo). 3) In reality, in client-side time, 2 xacts, even on the same LedgerNo & AccountNo, cannot be performed in even 1/10 or 1/100 sec, so the ms in the Datetimes will be vastly diff.Maas
@Anthology 4) Fourth, to justify this degree of concern, you must implement ACID (IL SERIALIZABLE) & genuine OLTP Transaction Standards, wherein the LedgerNo would be locked by the first user, & not available to the second user, until the first COMMITS. Which makes consideration [2][3] irrelevant. 5) I do not recommend it for the above reasons, but instead of DateTime column, you are free to use SequenceNo, or instead of DATETIME datatype use BIGDATETIME.Maas
@Maas either a DEA Ledger-Ledger Transaction in LedgerTransaction xor a DEA Ledger-Account Transaction in AccountTransaction I'm refering to your example 4, the transfer of 100$ between Mary and John. By the DEA example given, I can track amounts in total, so I know, that the housecash grew 100$ and mary's amount shrank 100$, for the other side vice versa. But to know, that mary send 100$ to john, requires both AccountXact and the one ledgerXact (or only the two account Xacts) to be matched by time (fuzzy) and amount. By Tracking I mean having a connection between Mary and JohnIncisure
@Incisure That is an additional requirement, it needs a Data Model that is a bit more advanced, which is this related Answer, and a new table. I have answered your question in detail in the Comments section (bottom) of that Answer.Maas
@Maas I will have a look at this, and really appreciate your work here, thanks for that.Incisure
how is the closing balance or a current balance of a ledger is calculated? does it involves sums of only ledgertransactions(sum(cr)-sum(dr)) or both ledgertransactions and accountttransactions?Referent
@Referent Both. LedgerTransaction is a Ledger-Ledger transaction (note PK LedgerNo, FK LedgerNo_Dr); AccountTransaction is a Ledger-Account transaction (note PK LedgerNo, FK AccountNo).Maas
P
6

Here is my schema (using sqlite as an example) with 2 tables:

Tables

-- This is a list of your chart of accounts
CREATE TABLE "accounts" (
    "name"      TEXT,
    "number"    INTEGER,
    "normal"    INTEGER
)

-- This is a table of each transaction
CREATE TABLE "transactions"
  (
     "id"        INTEGER, 
     "date"      TEXT,
     "amount"    REAL,
     "account"   INTEGER,
     "direction" INTEGER
  ) 

With this convention, the accounts.normal and transaction.direction fields are set to 1 for debit and -1 for credit. The end user never sees this but it makes arithmetic easy.

When you create a journal entry, it will have at least 2 rows in the transactions table - a debit and a credit. They should share the same id.

To see your balances, you can run this query:

select
  (account) as a,
  name,
  sum(amount * direction * normal) as balance
from
  transactions
  left join accounts on a = accounts.number
group by
  name
order by
  a,
  name;

To view the ledger, you can run this:

select
  id,
  date,
  name,
  case when direction == 1 then amount end as DR,
  case when direction == -1 then amount end as CR
from
  transactions
  left join accounts on account = accounts.number
order by
  id,
  date,
  CR,
  DR;

I have a much more detailed post of different queries you can run, along with example data. But, with the above two tables, you can create a working double-entry system.

Pshaw answered 24/10, 2022 at 0:46 Comment(2)
In this scenario, your Transaction table does not have a primary key?Conducive
In this example, each row does not have a unique ID. However, you could add one.Pshaw

© 2022 - 2025 — McMap. All rights reserved.