From 46939c265c0760041c2960aadbb52df79c5065c7 Mon Sep 17 00:00:00 2001 From: medina5 Date: Sun, 2 Nov 2025 07:35:49 +0100 Subject: [PATCH] banque --- compose.yaml | 40 +++--- data/banque/devises.csv | 8 ++ data/banque/devises_pays.csv | 8 ++ data/banque/extra/devises.csv | 46 ++++++ data/{geo => banque/extra}/devises_pays.csv | 10 +- data/geo/devises.csv | 52 ------- postgresql-entrypoint-initdb.d/01_initdb.sql | 144 ++++++++++++------- postgresql-entrypoint-initdb.d/02_seed.sql | 10 +- postgresql-entrypoint-initdb.d/03_views.sql | 10 +- 9 files changed, 183 insertions(+), 145 deletions(-) create mode 100644 data/banque/devises.csv create mode 100644 data/banque/devises_pays.csv create mode 100644 data/banque/extra/devises.csv rename data/{geo => banque/extra}/devises_pays.csv (93%) delete mode 100644 data/geo/devises.csv diff --git a/compose.yaml b/compose.yaml index 6ff4f9e..4b57091 100644 --- a/compose.yaml +++ b/compose.yaml @@ -284,26 +284,26 @@ services: networks: - caddy_net - rabbitmq: - image: rabbitmq:4.1.4-management - ports: - - "5672:5672" # AMQP - - "1883:1883" # MQTT - networks: - - caddy_net - environment: - RABBITMQ_DEFAULT_USER: admin - RABBITMQ_DEFAULT_PASS: admin - RABBITMQ_SERVER_ADDITIONAL_ERL_ARGS: "-rabbitmq_mqtt tcp_listeners [1883]" - volumes: - - rabbitmq_data:/var/lib/rabbitmq - command: > - sh -c "rabbitmq-plugins enable --offline rabbitmq_mqtt rabbitmq_management && - rabbitmq-server" - labels: - caddy: rabbitmq.localhost - caddy.reverse_proxy: "{{upstreams 15672}}" - caddy.tls: internal + #rabbitmq: + # image: rabbitmq:4.1.4-management + # ports: + # - "5672:5672" # AMQP + # - "1883:1883" # MQTT + # networks: + # - caddy_net + # environment: + # RABBITMQ_DEFAULT_USER: admin + # RABBITMQ_DEFAULT_PASS: admin + # RABBITMQ_SERVER_ADDITIONAL_ERL_ARGS: "-rabbitmq_mqtt tcp_listeners [1883]" + # volumes: + # - rabbitmq_data:/var/lib/rabbitmq + # command: > + # sh -c "rabbitmq-plugins enable --offline rabbitmq_mqtt rabbitmq_management && + # rabbitmq-server" + # labels: + # caddy: rabbitmq.localhost + # caddy.reverse_proxy: "{{upstreams 15672}}" + # caddy.tls: internal # ---------------------------------------------------------------------- # Observabilité - Télémétrie diff --git a/data/banque/devises.csv b/data/banque/devises.csv new file mode 100644 index 0000000..66ce36b --- /dev/null +++ b/data/banque/devises.csv @@ -0,0 +1,8 @@ +devise_code,num4217,symbole,nom,division,minor,minors +EUR,978,€,Euro,100,centime,centimes +CHF,756,CHf,Franc suisse,100,centime,centimes +GBP,826,£,Livre sterling,100,penny,pence +JPY,392,¥,Yen japonais,1,, +TRY,949,₺,Nouvelle livre turque,100,kuruş,kuruş +USD,840,$,Dollar des Etats-Unis,100,cent,cents +ZAR,710,R,Rand sud-africain,100,cent,cents diff --git a/data/banque/devises_pays.csv b/data/banque/devises_pays.csv new file mode 100644 index 0000000..2073b7f --- /dev/null +++ b/data/banque/devises_pays.csv @@ -0,0 +1,8 @@ +pays_code,devise,valide +FR,EUR,"[1999-01-01,)" +CH,CHF,"(,)" +JP,JPY,"(,)" +GB,GBP,"(,)" +US,USD,"(,)" +TR,TRY,"[2005-01-01,)" +ZA,ZAR,"(,)" diff --git a/data/banque/extra/devises.csv b/data/banque/extra/devises.csv new file mode 100644 index 0000000..1ff60de --- /dev/null +++ b/data/banque/extra/devises.csv @@ -0,0 +1,46 @@ +devise_code,num4217,symbole,nom,division,minor,minors +ATS,40,,Schilling autrichien,100,Groschen, +AUD,36,,Dollar australien,100,cent,cents +BEF,56,,Franc belge,100,centime,centimes +BGN,975,Лв.,Lev bulgare,100,stotinki, +CAD,124,,Dollar canadien,100,cent,cents +CYP,196,,Livre chypriote,100,cent,cents +CZK,203,Kč,Couronne tchèque,100,haléřů, +DEM,276,,Mark allemand,100,Pfennig, +DKK,208,,Couronne danoise,100,øre, +EEK,233,,Couronne estonienne,100,sents, +ESP,724,,Peseta espagnole,100,céntimos, +FIM,246,,Mark finlandais,100,penni, +FRF,250,,Franc français,100,centimes,centime +GRD,300,,Drachme grecque,100,leptae, +HUF,348,Ft,Forint hongrois,100,fillér, +IEP,372,,Livre irlandaise,100,penny,pence +ILS,376,₪,Nouveau sheqel israélien,100,agorots, +INR,356,₹,Roupie indienne,100,paise, +ISK,352,,Couronne islandaise,100,eyrir,aurar +ITL,380,₤,Lire italienne,100,centesimi, +KRW,410,₩,Won coréen,100,jeon, +LTL,440,,Litas lituanien,,, +LUF,442,,Franc luxembourgeois,100,centime,centimes +LVL,428,,Lats letton,100,santimes, +MTL,470,,Livre maltaise,100,cents / 1000 mils, +NLG,528,,Florin néerlandais,100,cents, +NOK,578,kr,Couronne norvégienne,100,øre, +NZD,554,,Dollar néo-zélandais,100,cents, +PLN,985,zł,Zloty,,, +PTE,620,,Escudo portugais,100,centavo,centavos +ROL,642,leu,Leu roumain,100,ban,bani +RON,946,leu,Leu roumain,100,ban,bani +SEK,752,kr,Couronne suédoise,100,öre, +SIT,705,,Tolar slovène,100,haliers, +SKK,703,,Couronne slovaque,100,haliers, +THB,764,฿,Baht thaïlandais,100,satang, +TRL,792,,Livre turque,100,kuruş, +TWD,901,,Nouveau dollar de Taïwan,,, +UAH,980,₴,Hryvnia ukrainien,100,kopiykas, +XOF,952,F.CFA,Franc CFA Ouest BCEAO,,, +HKD,344,,Dollar de Hong Kong,,, +SGD,702,,Dollar de Singapour,100,cent,cents +MXN,484,,Peso mexicain,100,centavo,centavos +MAD,504,,Dirham marocain,100,centime,centimes +BRL,986,,Real brésilien,100,centavo,centavos diff --git a/data/geo/devises_pays.csv b/data/banque/extra/devises_pays.csv similarity index 93% rename from data/geo/devises_pays.csv rename to data/banque/extra/devises_pays.csv index 74ab4d1..28df784 100644 --- a/data/geo/devises_pays.csv +++ b/data/banque/extra/devises_pays.csv @@ -7,7 +7,6 @@ NL,EUR,"[1999-01-01,)" NL,NLG,"(,1999-01-01)" FI,EUR,"[1999-01-01,)" FI,FIM,"(,1999-01-01)" -FR,EUR,"[1999-01-01,)" FR,FRF,"[1960-01-01,1999-01-01)" DE,EUR,"[1999-01-01,)" DE,DEM,"(,1999-01-01)" @@ -40,7 +39,8 @@ LT,LTL,"(,2015-01-01)" HR,EUR,"[2023-01-01,)" AD,EUR,"[1999-01-01,)" MC,EUR,"[1999-01-01,)" -US,USD,"(,)" +SG,SGD,"(,)" +HK,HKD,"(,)" EC,USD,"(,)" SV,USD,"(,)" HT,USD,"(,)" @@ -54,8 +54,6 @@ ML,XOF,"(,)" NE,XOF,"(,)" SN,XOF,"(,)" TG,XOF,"(,)" -JP,JPY,"(,)" -CH,CHF,"(,)" LI,CHF,"(,)" SE,SEK,"(,)" NO,NOK,"(,)" @@ -68,15 +66,11 @@ NZ,NZD,"(,)" UA,UAH,"(,)" BG,BGN,"(,)" CZ,CZK,"(,)" -GB,GBP,"(,)" TR,TRL,"(,2005-01-01)" -TR,TRY,"[2005-01-01,)" DK,DKK,"(,)" HU,HUF,"(,)" IS,ISK,"(,)" TW,TWD,"(,)" MX,MXN,"(,)" -SG,SGD,"(,)" -HK,HKD,"(,)" UA,UAH,"(,)" BR,BRL,"(,)" diff --git a/data/geo/devises.csv b/data/geo/devises.csv deleted file mode 100644 index 97323f5..0000000 --- a/data/geo/devises.csv +++ /dev/null @@ -1,52 +0,0 @@ -devise_code,num4217,symbole,nom,format,division,minor,minors -ATS,40,,Schilling autrichien,"S #.###,##",100,Groschen, -AUD,36,,Dollar australien,$# ###.##,100,cent,cents -BEF,56,,Franc belge,BEF #.###,100,centime,centimes -BGN,975,Лв.,Lev bulgare,#,100,stotinki, -CAD,124,,Dollar canadien,"$#,###.##",100,cent,cents -CHF,756,CHf,Franc suisse,#,100,centime,centimes -CYP,196,,Livre chypriote,"?#.###,##",100,cent,cents -CZK,203,Kč,Couronne tchèque,"#.###,## Kč",100,haléřů, -DEM,276,,Mark allemand,"#.###,##DM",100,Pfennig, -DKK,208,,Couronne danoise,"kr.#.###,##",100,øre, -EEK,233,,Couronne estonienne,"# ###,## EEK",100,sents, -ESP,724,,Peseta espagnole,#,100,céntimos, -EUR,978,€,Euro,#,100,centime,centimes -FIM,246,,Mark finlandais,"# ###,## mk",100,penni, -FRF,250,,Franc français,"# ###,## FRF",100,centimes,centime -GBP,826,£,Livre sterling,#,100,penny,pence -GRD,300,,Drachme grecque,#,100,leptae, -HUF,348,Ft,Forint hongrois,#,100,fillér, -IEP,372,,Livre irlandaise,#,100,penny,pence -ILS,376,₪,Nouveau sheqel israélien,#,100,agorots, -INR,356,₹,Roupie indienne,#,100,paise, -ISK,352,,Couronne islandaise,#,100,eyrir,aurar -ITL,380,₤,Lire italienne,₤ #,100,centesimi, -JPY,392,¥,Yen japonais,#,,, -KRW,410,₩,Won coréen,#,100,jeon, -LTL,440,,Litas lituanien,#,,, -LUF,442,,Franc luxembourgeois,#,100,centime,centimes -LVL,428,,Lats letton,#,100,santimes, -MTL,470,,Livre maltaise,#,100,cents / 1000 mils, -NLG,528,,Florin néerlandais,"f #.###,##",100,cents, -NOK,578,kr,Couronne norvégienne,#,100,øre, -NZD,554,,Dollar néo-zélandais,#,100,cents, -PLN,985,zł,Zloty,#,,, -PTE,620,,Escudo portugais,##,100,centavo,centavos -ROL,642,leu,Leu roumain,#,100,ban,bani -RON,946,leu,Leu roumain,#,100,ban,bani -SEK,752,kr,Couronne suédoise,#,100,öre, -SIT,705,,Tolar slovène,#,100,haliers, -SKK,703,,Couronne slovaque,#,100,haliers, -THB,764,฿,Baht thaïlandais,#,100,satang, -TRL,792,,Livre turque,#,100,kuruş, -TRY,949,₺,Nouvelle livre turque,#,100,kuruş, -TWD,901,,Nouveau dollar de Taïwan,#,,, -UAH,980,₴,Hryvnia ukrainien,#,100,kopiykas, -USD,840,$,Dollar des Etats-Unis,"$#,###.##",100,cent,cents -XOF,952,F.CFA,Franc CFA Ouest BCEAO,#,,, -HKD,344,,Dollar de Hong Kong,#,,, -SGD,702,,Dollar de Singapour,#,100,cent,cents -MXN,484,,Peso mexicain,#,100,centavo,centavos -MAD,504,,Dirham marocain,#,100,centime,centimes -BRL,986,,Real brésilien,"R$ #.###,##",100,centavo,centavos diff --git a/postgresql-entrypoint-initdb.d/01_initdb.sql b/postgresql-entrypoint-initdb.d/01_initdb.sql index 61cc6cd..bd9256c 100644 --- a/postgresql-entrypoint-initdb.d/01_initdb.sql +++ b/postgresql-entrypoint-initdb.d/01_initdb.sql @@ -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; diff --git a/postgresql-entrypoint-initdb.d/02_seed.sql b/postgresql-entrypoint-initdb.d/02_seed.sql index 6af5756..3619720 100644 --- a/postgresql-entrypoint-initdb.d/02_seed.sql +++ b/postgresql-entrypoint-initdb.d/02_seed.sql @@ -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'); diff --git a/postgresql-entrypoint-initdb.d/03_views.sql b/postgresql-entrypoint-initdb.d/03_views.sql index 6b38b4f..16d1541 100644 --- a/postgresql-entrypoint-initdb.d/03_views.sql +++ b/postgresql-entrypoint-initdb.d/03_views.sql @@ -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;