aboutsummaryrefslogtreecommitdiffstats
path: root/data/schema.sql
blob: 8c28292f080152c06367dbd1616e9f83ebb77628 (plain) (blame)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
DROP TABLE IF EXISTS scheduled_subtransactions;
DROP TABLE IF EXISTS scheduled_transactions;
DROP TABLE IF EXISTS subtransactions;
DROP TABLE IF EXISTS transactions;
DROP TABLE IF EXISTS payees;
DROP TABLE IF EXISTS categories_by_month;
DROP TABLE IF EXISTS months;
DROP TABLE IF EXISTS categories;
DROP TABLE IF EXISTS category_groups;
DROP TABLE IF EXISTS accounts;
DROP TYPE IF EXISTS cleared_t;
DROP TYPE IF EXISTS flag_color_t;

CREATE TABLE accounts (
    id text PRIMARY KEY,
    name text NOT NULL,
    on_budget boolean NOT NULL,
    closed boolean NOT NULL,
    balance bigint NOT NULL,
    cleared_balance bigint NOT NULL,
    uncleared_balance bigint NOT NULL
);

CREATE TABLE category_groups (
    id text PRIMARY KEY,
    name text NOT NULL,
    hidden boolean NOT NULL
);

CREATE TABLE categories (
    id text PRIMARY KEY,
    category_group_id text REFERENCES category_groups(id) NOT NULL,
    name text NOT NULL,
    hidden boolean NOT NULL,
    budgeted bigint NOT NULL,
    activity bigint NOT NULL,
    balance bigint NOT NULL
);

CREATE TABLE months (
    month date PRIMARY KEY
);

CREATE TABLE categories_by_month (
    month date REFERENCES months(month),
    id text REFERENCES categories(id),
    category_group_id text REFERENCES category_groups(id) NOT NULL,
    name text NOT NULL,
    hidden boolean NOT NULL,
    budgeted bigint NOT NULL,
    activity bigint NOT NULL,
    balance bigint NOT NULL,
    PRIMARY KEY (month, id)
);

CREATE TABLE payees (
    id text PRIMARY KEY,
    name text NOT NULL,
    transfer_account_id text REFERENCES accounts(id)
);

CREATE TYPE cleared_t AS ENUM ('reconciled', 'cleared', 'uncleared');
CREATE TYPE flag_color_t AS ENUM('red', 'orange', 'yellow', 'green', 'blue', 'purple');

CREATE TABLE transactions (
    id text PRIMARY KEY,
    transaction_date date NOT NULL,
    amount bigint NOT NULL,
    memo text,
    cleared cleared_t NOT NULL,
    approved boolean NOT NULL,
    flag_color flag_color_t,
    account_id text REFERENCES accounts(id) NOT NULL,
    payee_id text REFERENCES payees(id),
    category_id text REFERENCES categories(id),
    transfer_account_id text REFERENCES accounts(id)
);

CREATE TABLE subtransactions (
    id text PRIMARY KEY,
    transaction_id text REFERENCES transactions(id) NOT NULL,
    amount bigint NOT NULL,
    memo text,
    payee_id text REFERENCES payees(id),
    category_id text REFERENCES categories(id),
    transfer_account_id text REFERENCES accounts(id)
);

CREATE TYPE frequency_t AS ENUM (
    'never',
    'daily',
    'weekly',
    'everyOtherWeek',
    'twiceAMonth',
    'every4Weeks',
    'monthly',
    'everyOtherMonth',
    'every3Months',
    'every4Months',
    'twiceAYear',
    'yearly',
    'everyOtherYear'
);
CREATE TABLE scheduled_transactions (
    id text PRIMARY KEY,
    date_next date NOT NULL,
    frequency frequency_t NOT NULL,
    amount bigint NOT NULL,
    memo text,
    flag_color flag_color_t,
    account_id text REFERENCES accounts(id) NOT NULL,
    payee_id text REFERENCES payees(id),
    category_id text REFERENCES categories(id),
    transfer_account_id text REFERENCES accounts(id)
);

CREATE TABLE scheduled_subtransactions (
    id text PRIMARY KEY,
    scheduled_transaction_id text REFERENCES scheduled_transactions(id) NOT NULL,
    amount bigint NOT NULL,
    memo text,
    payee_id text REFERENCES payees(id),
    category_id text REFERENCES categories(id),
    transfer_account_id text REFERENCES accounts(id)
);