banque
This commit is contained in:
@@ -30,7 +30,7 @@ create extension if not exists pgtap schema pgtap;
|
||||
-- ----------------------------------------------------------------------
|
||||
create schema geo;
|
||||
|
||||
select 'Pays -------------------' as msg;
|
||||
select 'Pays --------------------' as msg;
|
||||
|
||||
create table geo.pays (
|
||||
code2 text not null,
|
||||
@@ -221,6 +221,12 @@ create table adherent (
|
||||
codepostal text
|
||||
);
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- Marché (Market)
|
||||
-- ----------------------------------------------------------------------
|
||||
|
||||
create schema market;
|
||||
|
||||
create table famille (
|
||||
code text primary key,
|
||||
famille text,
|
||||
@@ -238,22 +244,22 @@ create table article (
|
||||
suivistock int
|
||||
);
|
||||
|
||||
create table ticket (
|
||||
create table market.ticket (
|
||||
id int primary key,
|
||||
date_ticket timestamp,
|
||||
adherent_id int, -- references adherent(id)
|
||||
adherent_id int, -- references adherent(id)
|
||||
mode_rglt int
|
||||
);
|
||||
|
||||
create table ligne (
|
||||
create table market.ligne (
|
||||
id int primary key,
|
||||
ticket_id int, --references ticket (id),
|
||||
ticket_id int, -- references ticket (id),
|
||||
article_code text, -- references article (code)
|
||||
prix_unitaire decimal,
|
||||
quantite decimal
|
||||
);
|
||||
|
||||
alter table ligne
|
||||
alter table market.ligne
|
||||
add column total decimal
|
||||
generated always as (prix_unitaire * quantite) stored;
|
||||
|
||||
@@ -307,7 +313,7 @@ insert into region values
|
||||
|
||||
|
||||
create table personne (
|
||||
id bigint primary key generated always as identity,
|
||||
id bigint,
|
||||
prenom text,
|
||||
nom text,
|
||||
telephone text,
|
||||
@@ -315,41 +321,10 @@ create table personne (
|
||||
);
|
||||
|
||||
create table societe (
|
||||
id bigint primary key generated always as identity,
|
||||
id bigint,
|
||||
societe text
|
||||
);
|
||||
|
||||
insert into societe
|
||||
OVERRIDING SYSTEM VALUE
|
||||
values
|
||||
(1, 'Supérette'),
|
||||
(2, 'Boulangerie Lagarde'),
|
||||
(3, 'Pharmacie Martin'),
|
||||
(4, 'Diminutif'),
|
||||
(5, 'Vélocité'),
|
||||
(6, 'Café du Marché'),
|
||||
(7, 'La Maison Fleurie'),
|
||||
(8, 'Librairie des Tilleuls'),
|
||||
(9, 'MétalTech SARL'),
|
||||
(10, 'BoisDesign'),
|
||||
(11, 'Les Délices du Terroir'),
|
||||
(12, 'VitiVerte'),
|
||||
(13, 'ÉlectroServ'),
|
||||
(14, 'Ateliers du Moulin'),
|
||||
(15, 'Comptexpert'),
|
||||
(16, 'Assur O'' Poil'),
|
||||
(17, 'Banque Régionale du Centre'),
|
||||
(18, 'ImmoVilla'),
|
||||
(19, 'ITLink Solutions'),
|
||||
(20, 'Studio Graphica '),
|
||||
(21, 'Mairie de Batz'),
|
||||
(22, 'Hôtel du rivage'),
|
||||
(23, 'Collège Marie Curie'),
|
||||
(24, 'École primaire des Lilas'),
|
||||
(25, 'Maison de retraite Les Acacias'),
|
||||
(26, 'Cabinet Médical du Parc'),
|
||||
(27, 'Banque de l''Étoile'),
|
||||
(28, 'Pizzeria Geppetto');
|
||||
|
||||
/*
|
||||
CREATE TABLE emplois (
|
||||
@@ -376,7 +351,7 @@ create schema banque;
|
||||
CREATE OR REPLACE FUNCTION banque.rand_account(n integer)
|
||||
RETURNS text AS $$
|
||||
DECLARE
|
||||
chars text := '0123456789ABCDEFGHIJKLMNOPQRSTUVWXYZ';
|
||||
chars text := '0123456789ABCDEFGHJKLMNPRSTUWXYZ';
|
||||
out text := '';
|
||||
b bytea := gen_random_bytes(n); -- n octets aléatoires
|
||||
i int;
|
||||
@@ -395,14 +370,13 @@ BEGIN
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Devises (currencies)
|
||||
-- Devises (Currencies)
|
||||
-- ----------------------------------------------------------------------
|
||||
create table banque.currency (
|
||||
code text not null,
|
||||
num4217 integer default null,
|
||||
symbole character varying(5) default null,
|
||||
nom text default null,
|
||||
format text default null,
|
||||
division integer default 0,
|
||||
minor text default null,
|
||||
minors text default null
|
||||
@@ -443,6 +417,8 @@ alter table only pays_devises
|
||||
add foreign key (devise_code)
|
||||
references banque.currency (code);
|
||||
|
||||
-- Taux de change ()
|
||||
-- ----------------------------------------------------------------------
|
||||
CREATE TABLE banque.exchange_rate (
|
||||
from_currency CHAR(3) references banque.currency(code),
|
||||
to_currency CHAR(3) references banque.currency(code),
|
||||
@@ -457,8 +433,6 @@ create temporary table exchange (
|
||||
rate decimal(12,6)
|
||||
);
|
||||
|
||||
-- CHF
|
||||
|
||||
DO $$
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
@@ -494,20 +468,80 @@ END $$;
|
||||
|
||||
DROP table exchange;
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- Titulaires
|
||||
-- ----------------------------------------------------------------------
|
||||
|
||||
CREATE TABLE banque.account (
|
||||
CREATE TABLE banque.titulaire (
|
||||
id bigint primary key generated always as identity,
|
||||
account_number TEXT UNIQUE NOT NULL,
|
||||
balance NUMERIC(18,2) NOT NULL DEFAULT 0,
|
||||
currency CHAR(3) NOT NULL,
|
||||
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now()
|
||||
type_titulaire TEXT CHECK (type_titulaire IN ('individu', 'société')) NOT NULL,
|
||||
created_at timestamp with time zone not null default now()
|
||||
);
|
||||
|
||||
CREATE FUNCTION auto_titulaire_physique()
|
||||
RETURNS TRIGGER AS $$
|
||||
DECLARE
|
||||
new_titulaire_id INTEGER;
|
||||
BEGIN
|
||||
IF NEW.id IS NULL THEN
|
||||
INSERT INTO banque.titulaire (type_titulaire) VALUES ('individu')
|
||||
RETURNING id INTO new_titulaire_id;
|
||||
NEW.id := new_titulaire_id;
|
||||
END IF;
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE TRIGGER trg_auto_titulaire_physique
|
||||
BEFORE INSERT ON personne
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION auto_titulaire_physique();
|
||||
|
||||
CREATE OR REPLACE FUNCTION auto_titulaire_morale()
|
||||
RETURNS TRIGGER AS $$
|
||||
DECLARE
|
||||
new_titulaire_id INTEGER;
|
||||
BEGIN
|
||||
IF NEW.id IS NULL THEN
|
||||
INSERT INTO banque.titulaire (type_titulaire) VALUES ('morale')
|
||||
RETURNING id INTO new_titulaire_id;
|
||||
NEW.id := new_titulaire_id;
|
||||
END IF;
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE TRIGGER trg_auto_titulaire_morale
|
||||
BEFORE INSERT ON societe
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION auto_titulaire_morale();
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- Comptes (Accounts)
|
||||
-- ----------------------------------------------------------------------
|
||||
|
||||
create table banque.account (
|
||||
id bigint primary key generated always as identity,
|
||||
account_number text unique not null,
|
||||
balance numeric(18,6) not null default 0,
|
||||
currency char(3) not null,
|
||||
created_at timestamp with time zone not null default now()
|
||||
);
|
||||
|
||||
create table banque.account_holders (
|
||||
account_id bigint NOT NULL REFERENCES banque.account(id) ON DELETE CASCADE,
|
||||
titulaire_id int NOT NULL REFERENCES banque.titulaire(id) ON DELETE CASCADE,
|
||||
share numeric(5,2) CHECK (share >= 0 AND share <= 100),
|
||||
role text DEFAULT 'Titulaire',
|
||||
PRIMARY KEY (account_id, titulaire_id)
|
||||
);
|
||||
|
||||
|
||||
|
||||
CREATE TABLE banque."transaction" (
|
||||
id UUID PRIMARY KEY DEFAULT uuidv7(),
|
||||
reference TEXT,
|
||||
amount NUMERIC(18,2) NOT NULL,
|
||||
amount NUMERIC(18,6) NOT NULL,
|
||||
currency CHAR(3) NOT NULL,
|
||||
from_account BIGINT NOT NULL REFERENCES banque.account(id),
|
||||
to_account BIGINT NOT NULL REFERENCES banque.account(id),
|
||||
@@ -520,7 +554,7 @@ CREATE TABLE banque.ledger_entry (
|
||||
id bigint primary key generated always as identity,
|
||||
transaction_id UUID NOT NULL REFERENCES banque."transaction"(id),
|
||||
account_id BIGINT NOT NULL REFERENCES banque.account(id),
|
||||
amount NUMERIC(18,2) NOT NULL, -- convention: positif = crédit, négatif = débit (ici from = -amount, to = +amount)
|
||||
amount NUMERIC(18,6) NOT NULL, -- convention: positif = crédit, négatif = débit (ici from = -amount, to = +amount)
|
||||
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
|
||||
description TEXT
|
||||
);
|
||||
@@ -555,16 +589,16 @@ CREATE INDEX idx_block_chain_txid ON banque.block_chain(tx_id);
|
||||
CREATE OR REPLACE FUNCTION perform_transaction(
|
||||
from_account_id INT,
|
||||
to_account_id INT,
|
||||
amount DECIMAL(18,2),
|
||||
amount DECIMAL(18,6),
|
||||
description TEXT
|
||||
) RETURNS VOID AS $$
|
||||
DECLARE
|
||||
from_currency CHAR(3);
|
||||
to_currency CHAR(3);
|
||||
rate DECIMAL(12,6);
|
||||
fee DECIMAL(18,2);
|
||||
base_amount DECIMAL(18,2);
|
||||
converted_amount DECIMAL(18,2);
|
||||
fee DECIMAL(18,6);
|
||||
base_amount DECIMAL(18,6);
|
||||
converted_amount DECIMAL(18,6);
|
||||
tx_id INT;
|
||||
prev_hash TEXT;
|
||||
new_hash TEXT;
|
||||
|
||||
@@ -1,19 +1,19 @@
|
||||
truncate table adherent;
|
||||
truncate table famille;
|
||||
truncate table article;
|
||||
truncate table ticket;
|
||||
truncate table ligne;
|
||||
truncate table market.ticket;
|
||||
truncate table market.ligne;
|
||||
truncate table marque;
|
||||
truncate table fournisseur;
|
||||
|
||||
\COPY adherent FROM '/tmp/adherent.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||
\COPY famille FROM '/tmp/famille.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||
\COPY article FROM '/tmp/article.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||
\COPY ticket FROM '/tmp/ticket.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||
\COPY ligne FROM '/tmp/ligne.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||
\COPY market.ticket FROM '/tmp/ticket.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||
\COPY market.ligne FROM '/tmp/ligne.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||
|
||||
\COPY marque FROM '/tmp/marque.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||
\COPY fournisseur FROM '/tmp/fournisseur.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||
\COPY produit FROM '/tmp/produits/cereales_petitdejeuner.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||
|
||||
\COPY personne FROM '/tmp/personne.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||
\COPY personne FROM '/tmp/personne1.csv' (FORMAT CSV, header, ENCODING 'UTF8');
|
||||
|
||||
@@ -5,7 +5,7 @@ create view nb_total_articles as
|
||||
select count(*) as nb_total_articles from article;
|
||||
|
||||
create view nb_total_tickets as
|
||||
select count(*) as nb_total_tickets from ticket;
|
||||
select count(*) as nb_total_tickets from market.ticket;
|
||||
|
||||
create view nb_total_adherents as
|
||||
select count(*) as nb_total_adherents from adherent;
|
||||
@@ -14,8 +14,8 @@ create materialized view detail_ticket as
|
||||
select t.id as ticket_id, t.date_ticket, t.mode_rglt,
|
||||
h.id as adherent_id, h.codepostal, h.genre,
|
||||
round(sum(l.total), 2) as total
|
||||
from ticket t
|
||||
join ligne l on l.ticket_id = t.id
|
||||
from market.ticket t
|
||||
join market.ligne l on l.ticket_id = t.id
|
||||
join adherent h on h.id = t.adherent_id
|
||||
group by t.id, h.id;
|
||||
|
||||
@@ -24,8 +24,8 @@ select t.id as ticket_id, t.date_ticket, t.mode_rglt,
|
||||
h.id as adherent_id, h.codepostal, h.genre,
|
||||
l.article_code, a.famille_code,
|
||||
round(sum(l.total), 2) as total
|
||||
from ticket t
|
||||
join ligne l on l.ticket_id = t.id
|
||||
from market.ticket t
|
||||
join market.ligne l on l.ticket_id = t.id
|
||||
join adherent h on h.id = t.adherent_id
|
||||
join article a on a.code = l.article_code
|
||||
group by t.id, h.id, l.article_code, a.famille_code;
|
||||
|
||||
Reference in New Issue
Block a user