Source

flowrate / flowrate / flowrate.sql

Full commit
  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
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
--
-- PostgreSQL database dump
--

SET statement_timeout = 0;
SET client_encoding = 'UTF8';
SET standard_conforming_strings = off;
SET check_function_bodies = false;
SET client_min_messages = warning;
SET escape_string_warning = off;

SET search_path = public, pg_catalog;

SET default_tablespace = '';

SET default_with_oids = false;

--
-- Name: accounts; Type: TABLE; Schema: public; Owner: postgres; Tablespace: 
--

CREATE TABLE accounts (
    id integer NOT NULL,
    name text,
    type text
);


ALTER TABLE public.accounts OWNER TO postgres;

--
-- Name: flows; Type: TABLE; Schema: public; Owner: postgres; Tablespace: 
--

CREATE TABLE flows (
    id integer NOT NULL,
    credit_account integer NOT NULL,
    debit_account integer NOT NULL,
    description text,
    period integer,
    unit text,
    days integer[],
    -- An array of the variable names this flow refers to in any formulas below.
    variables text[] NOT NULL DEFAULT '{}',
    -- Any of the following may be a formula if it starts with "=":
    amount text NOT NULL,
    range_start text NOT NULL,
    range_end text NOT NULL
);


ALTER TABLE public.flows OWNER TO postgres;

--
-- Name: flows_id_seq; Type: SEQUENCE; Schema: public; Owner: postgres
--

CREATE SEQUENCE flows_id_seq
    START WITH 1
    INCREMENT BY 1
    NO MAXVALUE
    NO MINVALUE
    CACHE 1;


ALTER TABLE public.flows_id_seq OWNER TO postgres;

--
-- Name: flows_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: postgres
--

ALTER SEQUENCE flows_id_seq OWNED BY flows.id;


--
-- Name: flows_id_seq; Type: SEQUENCE SET; Schema: public; Owner: postgres
--

SELECT pg_catalog.setval('flows_id_seq', 1, true);


--
-- Name: id; Type: DEFAULT; Schema: public; Owner: postgres
--

ALTER TABLE flows ALTER COLUMN id SET DEFAULT nextval('flows_id_seq'::regclass);


--
-- Name: fulfillments; Type: TABLE; Schema: public; Owner: postgres; Tablespace: 
--

CREATE TABLE fulfillments (
    transactionid integer NOT NULL,
    obligationid integer NOT NULL,
    amount numeric(10, 2) NOT NULL
);


ALTER TABLE public.fulfillments OWNER TO postgres;

--
-- Name: obligations; Type: TABLE; Schema: public; Owner: postgres; Tablespace: 
--

CREATE TABLE obligations (
    id integer NOT NULL,
    flowid integer NOT NULL,
    postdate date NOT NULL,
    dategroupformat text,
    credit_account integer NOT NULL,
    debit_account integer NOT NULL,
    description text,
    amount numeric(10, 2) NOT NULL,
    remaining numeric(10, 2) NOT NULL,
    -- Denormalized for ledger:
    credit_mult numeric(10, 2) NOT NULL,
    debit_mult numeric(10, 2) NOT NULL
);


ALTER TABLE public.obligations OWNER TO postgres;

--
-- Name: obligations_id_seq; Type: SEQUENCE; Schema: public; Owner: postgres
--

CREATE SEQUENCE obligations_id_seq
    START WITH 1
    INCREMENT BY 1
    NO MAXVALUE
    NO MINVALUE
    CACHE 1;


ALTER TABLE public.obligations_id_seq OWNER TO postgres;

--
-- Name: obligations_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: postgres
--

ALTER SEQUENCE obligations_id_seq OWNED BY obligations.id;


--
-- Name: obligations_id_seq; Type: SEQUENCE SET; Schema: public; Owner: postgres
--

SELECT pg_catalog.setval('obligations_id_seq', 1, false);


--
-- Name: id; Type: DEFAULT; Schema: public; Owner: postgres
--

ALTER TABLE obligations ALTER COLUMN id SET DEFAULT nextval('obligations_id_seq'::regclass);


--
-- Name: transactions; Type: TABLE; Schema: public; Owner: postgres; Tablespace: 
--

CREATE TABLE transactions (
    id integer NOT NULL,
    postdate date NOT NULL,
    credit_account integer NOT NULL,
    debit_account integer NOT NULL,
    description text,
    amount numeric(10, 2) NOT NULL,
    -- Denormalized for ledger:
    credit_mult numeric(10, 2) NOT NULL,
    debit_mult numeric(10, 2) NOT NULL
);


ALTER TABLE public.transactions OWNER TO postgres;

--
-- Name: transactions_id_seq; Type: SEQUENCE; Schema: public; Owner: postgres
--

CREATE SEQUENCE transactions_id_seq
    START WITH 1
    INCREMENT BY 1
    NO MAXVALUE
    NO MINVALUE
    CACHE 1;


ALTER TABLE public.transactions_id_seq OWNER TO postgres;

--
-- Name: transactions_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: postgres
--

ALTER SEQUENCE transactions_id_seq OWNED BY transactions.id;


--
-- Name: transactions_id_seq; Type: SEQUENCE SET; Schema: public; Owner: postgres
--

SELECT pg_catalog.setval('transactions_id_seq', 1, false);


--
-- Name: id; Type: DEFAULT; Schema: public; Owner: postgres
--

ALTER TABLE transactions ALTER COLUMN id SET DEFAULT nextval('transactions_id_seq'::regclass);


--
-- Name: variables; Type: TABLE; Schema: public; Owner: postgres; Tablespace: 
--

CREATE TABLE variables (
    name text NOT NULL,
    source text
);


ALTER TABLE public.variables OWNER TO postgres;

--
-- Name: accounts_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: 
--

ALTER TABLE ONLY accounts
    ADD CONSTRAINT accounts_pkey PRIMARY KEY (id);


--
-- Name: flows_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: 
--

ALTER TABLE ONLY flows
    ADD CONSTRAINT flows_pkey PRIMARY KEY (id);


--
-- Name: obligations_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: 
--

ALTER TABLE ONLY obligations
    ADD CONSTRAINT obligations_pkey PRIMARY KEY (id);


--
-- Name: transactions_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: 
--

ALTER TABLE ONLY transactions
    ADD CONSTRAINT transactions_pkey PRIMARY KEY (id);


--
-- Name: variables_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres; Tablespace: 
--

ALTER TABLE ONLY variables
    ADD CONSTRAINT variables_pkey PRIMARY KEY (name);


--
-- Name: fki_flows_credit_account; Type: INDEX; Schema: public; Owner: postgres; Tablespace: 
--

CREATE INDEX fki_flows_credit_account ON flows USING btree (credit_account);


--
-- Name: fki_flows_debit_account; Type: INDEX; Schema: public; Owner: postgres; Tablespace: 
--

CREATE INDEX fki_flows_debit_account ON flows USING btree (debit_account);


--
-- Name: flows_credit_account_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres
--

ALTER TABLE ONLY flows
    ADD CONSTRAINT flows_credit_account_fkey FOREIGN KEY (credit_account) REFERENCES accounts(id);


--
-- Name: flows_debit_account_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres
--

ALTER TABLE ONLY flows
    ADD CONSTRAINT flows_debit_account_fkey FOREIGN KEY (debit_account) REFERENCES accounts(id);


--
-- Name: fki_fulfillments_transactionid; Type: INDEX; Schema: public; Owner: postgres; Tablespace: 
--

CREATE INDEX fki_fulfillments_transactionid ON fulfillments USING btree (transactionid);


--
-- Name: fki_fulfillments_obligationid; Type: INDEX; Schema: public; Owner: postgres; Tablespace: 
--

CREATE INDEX fki_fulfillments_obligationid ON fulfillments USING btree (obligationid);


--
-- Name: fulfillments_transactionid_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres
--

ALTER TABLE ONLY fulfillments
    ADD CONSTRAINT fulfillments_transactionid_fkey FOREIGN KEY (transactionid) REFERENCES transactions(id);


--
-- Name: fulfillments_obligationid_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres
--

ALTER TABLE ONLY fulfillments
    ADD CONSTRAINT fulfillments_obligationid_fkey FOREIGN KEY (obligationid) REFERENCES obligations(id);


--
-- Name: obligations_credit_account_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres
--

ALTER TABLE ONLY obligations
    ADD CONSTRAINT obligations_credit_account_fkey FOREIGN KEY (credit_account) REFERENCES accounts(id);


--
-- Name: obligations_debit_account_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres
--

ALTER TABLE ONLY obligations
    ADD CONSTRAINT obligations_debit_account_fkey FOREIGN KEY (debit_account) REFERENCES accounts(id);


--
-- Name: fki_obligations_flowid; Type: INDEX; Schema: public; Owner: postgres; Tablespace: 
--

CREATE INDEX fki_obligations_flowid ON obligations USING btree (flowid);


--
-- Name: obligations_flowid_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres
--

ALTER TABLE ONLY obligations
    ADD CONSTRAINT obligations_flowid_fkey FOREIGN KEY (flowid) REFERENCES flows(id);


--
-- Name: transactions_credit_account_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres
--

ALTER TABLE ONLY transactions
    ADD CONSTRAINT transactions_credit_account_fkey FOREIGN KEY (credit_account) REFERENCES accounts(id);


--
-- Name: transactions_debit_account_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres
--

ALTER TABLE ONLY transactions
    ADD CONSTRAINT transactions_debit_account_fkey FOREIGN KEY (debit_account) REFERENCES accounts(id);


CREATE OR REPLACE FUNCTION isSubAccount(child integer, parent integer) RETURNS boolean AS $$
  -- Return true if the given child is a subaccount of the given parent.
  SELECT $1 >= $2 AND $1 < $2 + (CASE WHEN $2 % 1000 = 0 THEN 1000
                                      WHEN $2 % 100 = 0 THEN 100
                                      WHEN $2 % 10 = 0 THEN 10
                                      ELSE 1
                                 END);
$$ LANGUAGE sql;


-- View: ledger

CREATE OR REPLACE VIEW ledger AS
    SELECT postdate,
           credit_account AS account,
           amount * credit_mult as amount
    FROM transactions t1
    UNION ALL
    SELECT postdate,
           debit_account AS account,
           amount * debit_mult as amount
    FROM transactions t2
    ORDER BY 1, 2;

ALTER TABLE ledger OWNER TO postgres;


-- View: flowledger

CREATE OR REPLACE VIEW flowledger AS
    SELECT postdate, credit_account AS account,
           amount * credit_mult AS total, remaining * credit_mult AS amount
    FROM obligations
    UNION ALL
    SELECT postdate, debit_account AS account,
           amount * debit_mult AS total, remaining * debit_mult AS amount
    FROM obligations
    ORDER BY 1, 2;

ALTER TABLE flowledger OWNER TO postgres;


-- View: fullledger

CREATE OR REPLACE VIEW fullledger AS
    SELECT postdate, account, amount FROM ledger

    UNION ALL

    SELECT postdate, account, amount FROM flowledger
    -- Since this table is used for balances, don't include
    -- flow activity in the past (we include last month because
    -- we assume some transactions haven't been posted yet).
    WHERE flowledger.postdate >= (CURRENT_DATE - '1 month'::interval)

    ORDER BY 1, 2;

ALTER TABLE fullledger OWNER TO postgres;


--
-- Name: public; Type: ACL; Schema: -; Owner: postgres
--

REVOKE ALL ON SCHEMA public FROM PUBLIC;
REVOKE ALL ON SCHEMA public FROM postgres;
GRANT ALL ON SCHEMA public TO postgres;
GRANT ALL ON SCHEMA public TO PUBLIC;


--
-- PostgreSQL database dump complete
--