-
Notifications
You must be signed in to change notification settings - Fork 0
/
energyLedger0.1.sql
381 lines (304 loc) · 13.3 KB
/
energyLedger0.1.sql
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
-- Copyright (c) 2023 - 2024 Open Risk (https://www.openriskmanagement.com)
-- PostgreSQL database dump of energyLedger
-- Version 0.1
--
SET statement_timeout = 0;
SET lock_timeout = 0;
SET idle_in_transaction_session_timeout = 0;
SET client_encoding = 'UTF8';
SET standard_conforming_strings = on;
SELECT pg_catalog.set_config('search_path', '', false);
SET check_function_bodies = false;
SET xmloption = content;
SET client_min_messages = warning;
SET row_security = off;
CREATE EXTENSION IF NOT EXISTS plpython3u WITH SCHEMA pg_catalog;
COMMENT ON EXTENSION plpython3u IS 'PL/Python3U untrusted procedural language';
--
-- Checking the First Law of Thermodynamics
--
CREATE FUNCTION public.check_first_law() RETURNS trigger
LANGUAGE plpgsql
AS $$
DECLARE
energy_sum DECIMAL(13, 2);
t_type INTEGER;
BEGIN
IF (TG_OP = 'INSERT') THEN
SELECT type INTO t_type FROM transaction WHERE NEW.transaction_id = id;
IF (t_type = 1) THEN
SELECT SUM(ENERGY) INTO energy_sum FROM (
SELECT sum(transaction_leg.physical_energy) AS ENERGY
FROM transaction_leg, account WHERE transaction_id = NEW.transaction_id AND account_id = account.id AND (account.type = 'AS')
UNION
SELECT sum(transaction_leg.embodied_energy) AS ENERGY
FROM transaction_leg, account WHERE transaction_id = NEW.transaction_id AND account_id = account.id AND (account.type = 'AS')
) AS TMP1;
ELSE
energy_sum = 0;
END IF;
ELSE
SELECT type INTO t_type FROM transaction WHERE OLD.transaction_id = id;
IF (t_type = 1) THEN
SELECT SUM(ENERGY) INTO energy_sum FROM (
SELECT sum(transaction_leg.physical_energy) AS ENERGY
FROM transaction_leg, account WHERE transaction_id = OLD.transaction_id AND account_id = account.id AND (account.type = 'AS')
UNION
SELECT sum(transaction_leg.embodied_energy) AS ENERGY
FROM transaction_leg, account WHERE transaction_id = OLD.transaction_id AND account_id = account.id AND (account.type = 'AS')
) AS TMP2;
ELSE
energy_sum = 0;
END IF;
END IF;
IF energy_sum != 0 THEN
RAISE EXCEPTION 'Energy conservation violation for internal transaction: %', energy_sum;
END IF;
RETURN NEW;
END;
$$;
ALTER FUNCTION public.check_first_law() OWNER TO postgres;
--
-- Checking Balance Equations
--
CREATE FUNCTION public.check_kirchhoff_law() RETURNS trigger
LANGUAGE plpgsql
AS $$
DECLARE
monetary_sum DECIMAL(13, 2);
physical_sum DECIMAL(13, 2);
embodied_sum DECIMAL(13, 2);
BEGIN
IF (TG_OP = 'INSERT') THEN
SELECT SUM(monetary_amount) INTO monetary_sum FROM transaction_leg WHERE transaction_id = NEW.transaction_id;
SELECT SUM(physical_energy) INTO physical_sum FROM transaction_leg WHERE transaction_id = NEW.transaction_id;
SELECT SUM(embodied_energy) INTO embodied_sum FROM transaction_leg WHERE transaction_id = NEW.transaction_id;
ELSE
SELECT SUM(monetary_amount) INTO monetary_sum FROM transaction_leg WHERE transaction_id = OLD.transaction_id;
SELECT SUM(physical_energy) INTO physical_sum FROM transaction_leg WHERE transaction_id = OLD.transaction_id;
SELECT SUM(embodied_energy) INTO embodied_sum FROM transaction_leg WHERE transaction_id = OLD.transaction_id;
END IF;
IF monetary_sum != 0 THEN
RAISE EXCEPTION 'Sum of transaction monetary amounts must be 0, not %', monetary_sum;
END IF;
IF physical_sum != 0 THEN
RAISE EXCEPTION 'Sum of transaction physical energy amounts must be 0, not %', physical_sum;
END IF;
IF embodied_sum != 0 THEN
RAISE EXCEPTION 'Sum of transaction embodied energy amounts must be 0, not %', embodied_sum;
END IF;
RETURN NEW;
END;
$$;
ALTER FUNCTION public.check_kirchhoff_law() OWNER TO postgres;
--
-- Check Entropy Law
--
CREATE FUNCTION public.check_second_law() RETURNS trigger
LANGUAGE plpgsql
AS $$
DECLARE
embodied_energy_sum DECIMAL(13, 2);
t_type INTEGER;
BEGIN
IF (TG_OP = 'INSERT') THEN
SELECT type INTO t_type FROM transaction WHERE NEW.transaction_id = id;
IF (t_type = 1) THEN
SELECT SUM(ENERGY) INTO embodied_energy_sum FROM (
SELECT sum(transaction_leg.embodied_energy) AS ENERGY
FROM transaction_leg, account WHERE transaction_id = NEW.transaction_id AND account_id = account.id AND (account.type = 'AS')
) AS TMP1;
ELSE
embodied_energy_sum = 0;
END IF;
ELSE
SELECT type INTO t_type FROM transaction WHERE OLD.transaction_id = id;
IF (t_type = 1) THEN
SELECT SUM(ENERGY) INTO embodied_energy_sum FROM (
SELECT sum(transaction_leg.embodied_energy) AS ENERGY
FROM transaction_leg, account WHERE transaction_id = OLD.transaction_id AND account_id = account.id AND (account.type = 'AS')
) AS TMP2;
ELSE
embodied_energy_sum = 0;
END IF;
END IF;
IF embodied_energy_sum < 0 THEN
RAISE EXCEPTION 'Embodied Energy decrease for internal transaction: %', embodied_energy_sum;
END IF;
RETURN NEW;
END;
$$;
ALTER FUNCTION public.check_second_law() OWNER TO postgres;
SET default_tablespace = '';
SET default_table_access_method = heap;
--
-- Name: account; Type: TABLE
--
CREATE TABLE public.account (
id integer NOT NULL,
name text,
code text,
symbol text,
type text NOT NULL
);
ALTER TABLE public.account OWNER TO postgres;
CREATE SEQUENCE public.account_id_seq
AS integer
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
ALTER TABLE public.account_id_seq OWNER TO postgres;
ALTER SEQUENCE public.account_id_seq OWNED BY public.account.id;
--
-- Name: transaction; Type: TABLE
--
CREATE TABLE public.transaction (
id integer NOT NULL,
type integer NOT NULL,
"timestamp" timestamp without time zone,
date date,
descriptions text
);
ALTER TABLE public.transaction OWNER TO postgres;
CREATE SEQUENCE public.transaction_id_seq
AS integer
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
ALTER TABLE public.transaction_id_seq OWNER TO postgres;
ALTER SEQUENCE public.transaction_id_seq OWNED BY public.transaction.id;
--
-- Name: transaction_leg; Type: TABLE
--
CREATE TABLE public.transaction_leg (
id integer NOT NULL,
monetary_amount double precision,
physical_energy double precision,
embodied_energy double precision,
account_id integer,
transaction_id integer,
description text
);
ALTER TABLE public.transaction_leg OWNER TO postgres;
--
-- Name: transaction_leg_id_seq; Type: SEQUENCE
--
CREATE SEQUENCE public.transaction_leg_id_seq
AS integer
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
ALTER TABLE public.transaction_leg_id_seq OWNER TO postgres;
ALTER SEQUENCE public.transaction_leg_id_seq OWNED BY public.transaction_leg.id;
ALTER TABLE ONLY public.account ALTER COLUMN id SET DEFAULT nextval('public.account_id_seq'::regclass);
ALTER TABLE ONLY public.transaction ALTER COLUMN id SET DEFAULT nextval('public.transaction_id_seq'::regclass);
ALTER TABLE ONLY public.transaction_leg ALTER COLUMN id SET DEFAULT nextval('public.transaction_leg_id_seq'::regclass);
--
-- Data for Name: account; Type: TABLE DATA
--
COPY public.account (id, name, code, symbol, type) FROM stdin;
1 Cash A01 C AS
2 Factory A02 F AS
3 Energy Stock A03 S AS
4 Raw Materials A04 M AS
5 Inventory A05 I AS
6 Accounts Payable A06 P LI
7 Bank Loan A07 L LI
8 Equity A08 K EQ
\.
--
-- Data for Name: transaction; Type: TABLE DATA
--
COPY public.transaction (id, type, "timestamp", date, descriptions) FROM stdin;
1 0 2023-05-17 21:23:52.470828 2023-01-02 Initial Equity Transaction
2 0 2023-05-17 21:23:52.470836 2023-01-03 Acquire Facilities
3 0 2023-05-17 21:23:52.470837 2023-01-04 Acquire Raw Materials on Credit
4 0 2023-05-17 21:23:52.470838 2023-01-05 Self-Produce Solar Energy
5 0 2023-05-17 21:23:52.470839 2023-01-06 Procure Grid Electrical Energy
6 1 2023-05-17 21:23:52.47084 2023-01-07 Produce Widgets (Material Processes)
7 1 2023-05-17 21:23:52.470841 2023-01-08 Produce Widgets (Energy Processes)
8 0 2023-05-17 21:23:52.470842 2023-01-09 Widget Sale
9 0 2023-05-17 21:23:52.470843 2023-01-10 Debt Repayment
10 0 2023-05-17 21:23:52.470844 2023-01-11 New Bank Loan
\.
--
-- Data for Name: transaction_leg; Type: TABLE DATA
--
COPY public.transaction_leg (id, monetary_amount, physical_energy, embodied_energy, account_id, transaction_id, description) FROM stdin;
859247 50 0 0 1 1 Credit Cash Account
164114 -50 0 0 8 1 Credit Equity Account
162218 -10 0 0 1 2 Debit Cash Account
175965 10 0 100 2 2 Credit Facility Account
981974 0 0 -100 8 2 Credit Equity Account
534663 15 0 150 4 3 Credit Materials Account
911946 -15 0 -45 6 3 Credit Payables Account
351063 0 0 -105 8 3 Credit Equity Account
480586 -5 0 0 1 4 Debit Cash Account
361799 20 30 0 3 4 Credit Energy Stock Account
966174 -15 -30 0 8 4 Credit Equity Account
693193 -12 0 0 1 5 Debit Cash Account
508398 12 60 0 3 5 Credit Energy Stock Account
935170 0 -60 0 8 5 Credit Equity Account
289994 -32 -90 0 3 6 Debit Energy Stock
467727 -15 0 -150 4 6 Debit Material Stock
67649 47 90 150 5 6 Credit Inventory Account
926470 0 -90 0 5 7 Debit Inventory Physical Energy
809936 0 0 90 5 7 Credit Inventory Embodied Energy
112822 0 90 0 8 7 Credit Equity Physical Energy
23231 0 0 -90 8 7 Debit Equity Embodied Energy
280646 60 0 0 1 8 Credit Widget Cash Receipts
855569 -47 0 -240 5 8 Debit Inventory Sale
573488 -13 0 240 8 8 Debit Equity Cash Receipt
430011 -15 0 0 1 9 Debit Cash for Debt Repayment
708639 15 0 45 6 9 Credit Accounts Payable
170095 0 0 -45 8 9 Debit Equity Cash Receipt
925153 32 0 0 1 10 Credit Cash from Loan
152243 -32 0 -41.02564102564102 7 10 Credit Loan Liability
928018 0 0 41.02564102564102 8 10 Debit Equity Cash Receipt
\.
SELECT pg_catalog.setval('public.account_id_seq', 8, true);
SELECT pg_catalog.setval('public.transaction_id_seq', 1, false);
SELECT pg_catalog.setval('public.transaction_leg_id_seq', 7, true);
--
-- Name: account account_pkey; Type: CONSTRAINT
--
ALTER TABLE ONLY public.account
ADD CONSTRAINT account_pkey PRIMARY KEY (id);
--
-- Name: transaction_leg transaction_leg_pkey; Type: CONSTRAINT
--
ALTER TABLE ONLY public.transaction_leg
ADD CONSTRAINT transaction_leg_pkey PRIMARY KEY (id);
--
-- Name: transaction transaction_pkey; Type: CONSTRAINT
--
ALTER TABLE ONLY public.transaction
ADD CONSTRAINT transaction_pkey PRIMARY KEY (id);
--
-- Name: transaction_leg balance_trigger; Type: TRIGGER
--
CREATE CONSTRAINT TRIGGER balance_trigger AFTER INSERT OR DELETE OR UPDATE ON public.transaction_leg DEFERRABLE INITIALLY DEFERRED FOR EACH ROW EXECUTE FUNCTION public.check_kirchhoff_law();
--
-- Name: transaction_leg energy_trigger; Type: TRIGGER
--
CREATE CONSTRAINT TRIGGER energy_trigger AFTER INSERT OR DELETE OR UPDATE ON public.transaction_leg DEFERRABLE INITIALLY DEFERRED FOR EACH ROW EXECUTE FUNCTION public.check_first_law();
--
-- Name: transaction_leg entropy_trigger; Type: TRIGGER
--
CREATE CONSTRAINT TRIGGER entropy_trigger AFTER INSERT OR DELETE OR UPDATE ON public.transaction_leg DEFERRABLE INITIALLY DEFERRED FOR EACH ROW EXECUTE FUNCTION public.check_second_law();
--
-- Name: transaction_leg fk_account; Type: FK CONSTRAINT
--
ALTER TABLE ONLY public.transaction_leg
ADD CONSTRAINT fk_account FOREIGN KEY (account_id) REFERENCES public.account(id);
--
-- Name: transaction_leg fk_transaction; Type: FK CONSTRAINT
--
ALTER TABLE ONLY public.transaction_leg
ADD CONSTRAINT fk_transaction FOREIGN KEY (transaction_id) REFERENCES public.transaction(id);