-
Notifications
You must be signed in to change notification settings - Fork 923
/
Copy pathinit.sql
73 lines (63 loc) · 1.64 KB
/
init.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
CREATE UNLOGGED TABLE clientes (
id SERIAL PRIMARY KEY,
nome VARCHAR(50) NOT NULL,
limite INTEGER NOT NULL,
saldo INTEGER
);
CREATE UNLOGGED TABLE transacoes (
id SERIAL PRIMARY KEY,
cliente_id INTEGER NOT NULL,
valor INTEGER NOT NULL,
tipo CHAR(1) NOT NULL,
descricao VARCHAR(10) NOT NULL,
realizada_em TIMESTAMP NOT NULL DEFAULT NOW()
);
ALTER TABLE
transacoes
ADD
CONSTRAINT fk_cliente_id FOREIGN KEY (cliente_id) REFERENCES clientes (id),
SET
(autovacuum_enabled = off);
CREATE INDEX ON transacoes (cliente_id, realizada_em DESC);
INSERT INTO clientes (nome, limite, saldo)
VALUES
('o barato sai caro', 1000 * 100, 0),
('zan corp ltda', 800 * 100, 0),
('les cruders', 10000 * 100, 0),
('padaria joia de cocaia', 100000 * 100, 0),
('kid mais', 5000 * 100, 0);
CREATE TYPE result_transacao AS (saldo_atual INT, limite INT);
CREATE OR REPLACE FUNCTION transacao(cliente_id_tx INTEGER, valor_tx INTEGER, tipo_tx VARCHAR(1), descricao_tx VARCHAR(10)) RETURNS result_transacao AS $$
DECLARE
saldo INTEGER;
limite INTEGER;
saldo_atual INTEGER;
BEGIN
PERFORM pg_advisory_xact_lock(cliente_id_tx);
SELECT
COALESCE(c.saldo, 0),
c.limite
INTO
saldo,
limite
FROM clientes c
WHERE c.id = cliente_id_tx;
IF tipo_tx = 'd' THEN
saldo_atual := saldo - valor_tx;
IF saldo_atual + limite < 0 THEN
RETURN (0, -1);
END IF;
ELSE
saldo_atual := saldo + valor_tx;
END IF;
UPDATE clientes c
SET
saldo = saldo_atual
WHERE
c.id = cliente_id_tx;
INSERT INTO
transacoes (cliente_id, valor, tipo, descricao)
VALUES (cliente_id_tx, valor_tx, tipo_tx, descricao_tx);
RETURN (saldo_atual, limite);
END;$$
LANGUAGE plpgsql;