From 928c94e9c894b67f7be98e7be414849d6b995a02 Mon Sep 17 00:00:00 2001 From: medina5 Date: Sun, 2 Nov 2025 09:24:15 +0100 Subject: [PATCH] TP bank --- banque.md | 7 + compose.yaml | 225 ++++++------------- postgresql-entrypoint-initdb.d/01_initdb.sql | 130 +++++++---- postgresql-entrypoint-initdb.d/02_seed.sql | 7 + 4 files changed, 165 insertions(+), 204 deletions(-) create mode 100644 banque.md diff --git a/banque.md b/banque.md new file mode 100644 index 0000000..f4a22a7 --- /dev/null +++ b/banque.md @@ -0,0 +1,7 @@ +# Travaux pratiques + +L’objectif est de modéliser et manipuler la base de données d’un système bancaire simplifié, dans lequel : + +- Un compte bancaire (_account_) appartient à un ou plusieurs titulaires (_holders_). +- Un titulaire peut être un individu (_person_) ou une société (_company_). +- Chaque compte dispose d’un numéro de compte (_account number_) unique et d’un solde. diff --git a/compose.yaml b/compose.yaml index 4b57091..42bc114 100644 --- a/compose.yaml +++ b/compose.yaml @@ -86,27 +86,6 @@ services: caddy.reverse_proxy: "{{upstreams 80}}" caddy.tls: internal -# Redis -# In-memory key-value database -# https://redis.io/fr/ - redis: - image: redis:8.2 - command: - - 'redis-server' - - '--save 60 1' - - '--loglevel verbose' - - '--requirepass ${REDIS_PASSWORD}' - ports: - - "6379:6379" - healthcheck: - test: ["CMD", "redis-cli", "-a", "${REDIS_PASSWORD}", "--raw", "incr", "ping" ] - interval: 30s - timeout: 5s - retries: 3 - start_period: 20s - volumes: - - redis_data:/data - # ---------------------------------------------------------------------- # Graphes @@ -198,91 +177,76 @@ services: caddy.reverse_proxy: "{{upstreams 8080}}" caddy.tls: internal -# ---------------------------------------------------------------------- -# Mock Web API -# -# ---------------------------------------------------------------------- - smocker: - image: thiht/smocker:0.18.5 - restart: "no" - networks: - - caddy_net - ports: - - 8080:8080 - - 8081:8081 - toxiproxy: - image: ghcr.io/shopify/toxiproxy - restart: "no" # ---------------------------------------------------------------------- # Business Intelligence # # ---------------------------------------------------------------------- - superset: - image: apache/superset:3.1.3 - depends_on: - database: - condition: service_healthy - environment: - SUPERSET_CONFIG_PATH: /app/pythonpath/superset_config.py - SUPERSET_SECRET_KEY: ${SUPERSET_SECRET:-YOUR_OWN_RANDOM_GENERATED_SECRET_KEY} - SUPERSET_LOAD_EXAMPLES: no - volumes: - - superset_home:/app/superset_home - - ./superset_config.py:/app/pythonpath/superset_config.py:Z - command: > - sh -c " - superset db upgrade && - superset fab create-admin --username admin --firstname Admin --lastname User --email admin@superset.com --password admin && - superset init && - superset run -h 0.0.0.0 -p 80 --with-threads --reload --debugger - " - networks: - - caddy_net - labels: - caddy: superset.localhost - caddy.reverse_proxy: "{{upstreams 80}}" - caddy.tls: internal + # superset: + # image: apache/superset:3.1.3 + # depends_on: + # database: + # condition: service_healthy + # environment: + # SUPERSET_CONFIG_PATH: /app/pythonpath/superset_config.py + # SUPERSET_SECRET_KEY: ${SUPERSET_SECRET:-YOUR_OWN_RANDOM_GENERATED_SECRET_KEY} + # SUPERSET_LOAD_EXAMPLES: no + # volumes: + # - superset_home:/app/superset_home + # - ./superset_config.py:/app/pythonpath/superset_config.py:Z + # command: > + # sh -c " + # superset db upgrade && + # superset fab create-admin --username admin --firstname Admin --lastname User --email admin@superset.com --password admin && + # superset init && + # superset run -h 0.0.0.0 -p 80 --with-threads --reload --debugger + # " + # networks: + # - caddy_net + # labels: + # caddy: superset.localhost + # caddy.reverse_proxy: "{{upstreams 80}}" + # caddy.tls: internal - metabase: - image: metabase/metabase:v0.56.5.5 - depends_on: - database: - condition: service_healthy - volumes: - - /dev/urandom:/dev/random:ro - environment: - MB_DB_TYPE: postgres - MB_DB_HOST: ${MB_DB_HOST:-database} - MB_DB_PORT: 5432 - MB_DB_USER: metabase_user - MB_DB_PASS: ${DB_ROOT_PASSWORD:-supermotdepasse} - MB_DB_DBNAME: metabase - MB_SITE_LOCALE: fr - MB_ADMIN_EMAIL: etudiant@univ-lorraine.fr - MB_ANON_TRACKING_ENABLED: false - MB_CHECK_FOR_UPDATES: false - MB_NO_SURVEYS: yes - MB_START_OF_WEEK: monday - MB_CUSTOM_FORMATTING: '{"type/Temporal":{"time_style":"HH:mm","date_style":"D MMMM, YYYY","date_abbreviate":true},"type/Currency":{"currency":"EUR"},"type/Number":{"number_separators":", "}}' - MB_EMAIL_SMTP_HOST: mailpit - MB_EMAIL_SMTP_PORT: 1025 - MB_EMAIL_FROM_ADDRESS: metabase@univ-lorraine.fr - networks: - - caddy_net - labels: - caddy: metabase.localhost - caddy.reverse_proxy: "{{upstreams 3000}}" - caddy.tls: internal + # metabase: + # image: metabase/metabase:v0.56.5.5 + # depends_on: + # database: + # condition: service_healthy + # volumes: + # - /dev/urandom:/dev/random:ro + # environment: + # MB_DB_TYPE: postgres + # MB_DB_HOST: ${MB_DB_HOST:-database} + # MB_DB_PORT: 5432 + # MB_DB_USER: metabase_user + # MB_DB_PASS: ${DB_ROOT_PASSWORD:-supermotdepasse} + # MB_DB_DBNAME: metabase + # MB_SITE_LOCALE: fr + # MB_ADMIN_EMAIL: etudiant@univ-lorraine.fr + # MB_ANON_TRACKING_ENABLED: false + # MB_CHECK_FOR_UPDATES: false + # MB_NO_SURVEYS: yes + # MB_START_OF_WEEK: monday + # MB_CUSTOM_FORMATTING: '{"type/Temporal":{"time_style":"HH:mm","date_style":"D MMMM, YYYY","date_abbreviate":true},"type/Currency":{"currency":"EUR"},"type/Number":{"number_separators":", "}}' + # MB_EMAIL_SMTP_HOST: mailpit + # MB_EMAIL_SMTP_PORT: 1025 + # MB_EMAIL_FROM_ADDRESS: metabase@univ-lorraine.fr + # networks: + # - caddy_net + # labels: + # caddy: metabase.localhost + # caddy.reverse_proxy: "{{upstreams 3000}}" + # caddy.tls: internal - metabase-init: - build: - context: ./metabase - depends_on: - - metabase - networks: - - caddy_net + # metabase-init: + # build: + # context: ./metabase + # depends_on: + # - metabase + # networks: + # - caddy_net #rabbitmq: # image: rabbitmq:4.1.4-management @@ -309,55 +273,10 @@ services: # Observabilité - Télémétrie # # ---------------------------------------------------------------------- -# Grafana -# Open source analytics & monitoring solution for every database. -# https://grafana.com/ - grafana: - image: grafana/grafana-oss:12.1.0 - restart: no - deploy: - resources: - limits: - memory: 100M - configs: - - source: grafana_provisioning - target: /etc/grafana/provisioning - - source: grafana_dashboards - target: /etc/grafana/dashboards - volumes: - - grafana:/var/lib/grafana - environment: - #GF_SECURITY_ADMIN_EMAIL: ${ADMIN_EMAIL} - #GF_SECURITY_ADMIN_PASSWORD: ${ADMIN_PASSWORD} - GF_AUTH_ANONYMOUS_ENABLED: true # Enabled the Anonymous user no user/pass needed - GF_AUTH_ANONYMOUS_ORG_ROLE: Admin - GF_AUTH_DISABLE_LOGIN_FORM: true - GF_USERS_DEFAULT_THEME: light - GF_USERS_ALLOW_SIGN_UP: false - GF_FEATURE_TOGGLES_ENABLE: traceQLStreaming metricsSummary lokiFormatQuery alertmanagerRemoteOnly - GF_INSTALL_PLUGINS: yesoreyeram-infinity-datasource - networks: - - caddy_net - labels: - caddy: grafana.localhost - caddy.reverse_proxy: "{{upstreams 3000}}" - caddy.tls: internal -# Prometheus -# Prometheus is an open-source systems monitoring and alerting toolkit -# https://prometheus.io/ - prometheus: - image: prom/prometheus:v3.6.0 - configs: - - source: prometheus_config - target: /etc/prometheus/prometheus.yml - volumes: - - prometheus:/prometheus - - /var/run/docker.sock:/var/run/docker.sock:ro - ports: - - 9090:9090 - #extra_hosts: - # - host.docker.internal=host-gateway + + + gatus: image: twinproduction/gatus:v5.26.0 @@ -389,14 +308,6 @@ volumes: caddy_data: pgadmin: database_data: - couchdb_data: - mongodb_data: - mongodb_configdb: - redis_data: - neo4j_data: - neo4j_logs: - prometheus: - grafana: superset_home: rabbitmq_data: mailpit: @@ -404,12 +315,6 @@ volumes: configs: pgadmin_config: file: ./pgadmin-servers.json - grafana_provisioning: - file: ./grafana/provisioning - grafana_dashboards: - file: ./grafana/dashboards - prometheus_config: - file: ./prometheus.yml networks: caddy_net: diff --git a/postgresql-entrypoint-initdb.d/01_initdb.sql b/postgresql-entrypoint-initdb.d/01_initdb.sql index 8f632f6..812282e 100644 --- a/postgresql-entrypoint-initdb.d/01_initdb.sql +++ b/postgresql-entrypoint-initdb.d/01_initdb.sql @@ -341,19 +341,19 @@ CREATE TABLE emplois ( */ -- ---------------------------------------------------------------------- --- Banque +-- Banque (Bank) -- ---------------------------------------------------------------------- -create schema banque; +create schema bank; -- Générateur de numéro aléatoire -- ---------------------------------------------------------------------- -CREATE OR REPLACE FUNCTION banque.rand_account(n integer) +CREATE OR REPLACE FUNCTION bank.rand_account(n integer) RETURNS text AS $$ DECLARE - chars text := '0123456789ABCDEFGHJKLMNPRSTUWXYZ'; + chars text := '1234ABCD'; out text := ''; - b bytea := gen_random_bytes(n); -- n octets aléatoires + b bytea := ext.gen_random_bytes(n); -- n octets aléatoires i int; idx int; BEGIN @@ -372,7 +372,7 @@ $$ LANGUAGE plpgsql; -- Devises (Currencies) -- ---------------------------------------------------------------------- -create table banque.currency ( +create table bank.currency ( code text not null, num4217 integer default null, symbole character varying(5) default null, @@ -382,7 +382,7 @@ create table banque.currency ( minors text default null ); -alter table banque.currency +alter table bank.currency add check (code ~ '^[A-Z]{3}$'); create table pays_devises ( @@ -398,13 +398,13 @@ alter table pays_devises add check (devise_code ~ '^[A-Z]{3}$'); create unique index currency_pk - on banque.currency + on bank.currency using btree (code); -alter table banque.currency +alter table bank.currency add primary key using index currency_pk; -\copy banque.currency from '/tmp/banque/devises.csv' (FORMAT CSV, header, delimiter ',', ENCODING 'UTF8'); +\copy bank.currency from '/tmp/banque/devises.csv' (FORMAT CSV, header, delimiter ',', ENCODING 'UTF8'); \copy pays_devises from '/tmp/banque/devises_pays.csv' (FORMAT CSV, header, delimiter ',', ENCODING 'UTF8'); -- pays_devises -> pays @@ -415,13 +415,13 @@ alter table only pays_devises -- pays_devises -> devises alter table only pays_devises add foreign key (devise_code) - references banque.currency (code); + references bank.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), +CREATE TABLE bank.exchange_rate ( + from_currency CHAR(3) references bank.currency(code), + to_currency CHAR(3) references bank.currency(code), rate DECIMAL(12,6) NOT NULL, fee_percent DECIMAL(5,2) DEFAULT 0, last_updated TIMESTAMP DEFAULT NOW(), @@ -440,7 +440,7 @@ DECLARE BEGIN -- Liste des devises à importer FOR rec IN - SELECT code FROM banque.currency WHERE code <> 'EUR' + SELECT code FROM bank.currency WHERE code <> 'EUR' LOOP path := format('/tmp/webstat/Webstat_Export_fr_EXR.M.%s.EUR.SP00.E.csv', rec.code); @@ -455,7 +455,7 @@ BEGIN -- Insertion dans la table principale EXECUTE format( $sql$ - INSERT INTO banque.exchange_rate (from_currency, to_currency, rate, fee_percent, last_updated) + INSERT INTO bank.exchange_rate (from_currency, to_currency, rate, fee_percent, last_updated) SELECT 'EUR', %L, rate, 0, jour FROM exchange $sql$, rec.code @@ -472,7 +472,7 @@ DROP table exchange; -- Titulaires -- ---------------------------------------------------------------------- -CREATE TABLE banque.titulaire ( +CREATE TABLE bank.titulaire ( id bigint primary key generated always as identity, type_titulaire TEXT CHECK (type_titulaire IN ('individu', 'société')) NOT NULL, created_at timestamp with time zone not null default now() @@ -484,7 +484,7 @@ DECLARE new_titulaire_id INTEGER; BEGIN IF NEW.id IS NULL THEN - INSERT INTO banque.titulaire (type_titulaire) VALUES ('individu') + INSERT INTO bank.titulaire (type_titulaire) VALUES ('individu') RETURNING id INTO new_titulaire_id; NEW.id := new_titulaire_id; END IF; @@ -503,7 +503,7 @@ DECLARE new_titulaire_id INTEGER; BEGIN IF NEW.id IS NULL THEN - INSERT INTO banque.titulaire (type_titulaire) VALUES ('société') + INSERT INTO bank.titulaire (type_titulaire) VALUES ('société') RETURNING id INTO new_titulaire_id; NEW.id := new_titulaire_id; END IF; @@ -520,7 +520,7 @@ EXECUTE FUNCTION auto_titulaire_morale(); -- Comptes (Accounts) -- ---------------------------------------------------------------------- -create table banque.account ( +create table bank.account ( id bigint primary key generated always as identity, account_number text unique not null, balance numeric(18,6) not null default 0, @@ -528,32 +528,74 @@ create table banque.account ( 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, +create table bank.account_holders ( + account_id bigint NOT NULL REFERENCES bank.account(id) ON DELETE CASCADE, + titulaire_id int NOT NULL REFERENCES bank.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 OR REPLACE FUNCTION bank.insert_account_random( + person_ids int[], -- liste d'identifiants de personnes + currency text default 'EUR', -- la devise du compte + n int DEFAULT 2 -- longueur du numéro de compte +) +RETURNS text AS $$ +DECLARE + candidate text; + retry_count int := 0; + new_account_id bigint; + person_id int; +BEGIN + IF array_length(person_ids, 1) IS NULL THEN + RAISE EXCEPTION 'La liste des personnes ne peut pas être vide'; + END IF; + LOOP + candidate := bank.rand_account(n); + BEGIN + INSERT INTO bank.account(account_number, currency) VALUES (candidate, currency) + RETURNING id INTO new_account_id; -CREATE TABLE banque."transaction" ( + -- Lier chaque personne au compte + FOREACH person_id IN ARRAY person_ids LOOP + INSERT INTO bank.account_holders(account_id, titulaire_id, share) + VALUES (new_account_id, person_id, (100.0 / array_length(person_ids, 1))); + END LOOP; + + RETURN candidate; + + EXCEPTION WHEN unique_violation THEN + retry_count := retry_count + 1; + IF retry_count > 20 THEN + RAISE EXCEPTION 'Trop de collisions après % tentatives', retry_count; + END IF; + CONTINUE; + END; + END LOOP; +END; +$$ LANGUAGE plpgsql; + +-- Transactions +-- ---------------------------------------------------------------------- + +CREATE TABLE bank."transaction" ( id UUID PRIMARY KEY DEFAULT uuidv7(), reference TEXT, 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), + from_account BIGINT NOT NULL REFERENCES bank.account(id), + to_account BIGINT NOT NULL REFERENCES bank.account(id), created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), processed BOOLEAN NOT NULL DEFAULT FALSE -- indique si ledger + soldes ont été appliqués ); -- ledger (écritures comptables immuables) : append-only -CREATE TABLE banque.ledger_entry ( +CREATE TABLE bank.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), + transaction_id UUID NOT NULL REFERENCES bank."transaction"(id), + account_id BIGINT NOT NULL REFERENCES bank.account(id), 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 @@ -561,10 +603,10 @@ CREATE TABLE banque.ledger_entry ( -- index pour performance et idempotence par transaction/account CREATE UNIQUE INDEX ux_ledger_tx_account - ON banque.ledger_entry(transaction_id, account_id); + ON bank.ledger_entry(transaction_id, account_id); -- outbox pour publisher reliable (pattern outbox) -CREATE TABLE banque.outbox_event ( +CREATE TABLE bank.outbox_event ( id bigint primary key generated always as identity, occurrenced_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), topic TEXT NOT NULL, @@ -575,7 +617,7 @@ CREATE TABLE banque.outbox_event ( ); -- table very simple de blockchain / chain d'audit -CREATE TABLE banque.block_chain ( +CREATE TABLE bank.block_chain ( id bigint primary key generated always as identity, block_time TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(), tx_id UUID NOT NULL, -- transaction incluse dans ce bloc (ou multiple selon choix) @@ -584,7 +626,7 @@ CREATE TABLE banque.block_chain ( block_data JSONB NOT NULL -- stockage lisible des éléments du bloc (pour audit) ); -CREATE INDEX idx_block_chain_txid ON banque.block_chain(tx_id); +CREATE INDEX idx_block_chain_txid ON bank.block_chain(tx_id); CREATE OR REPLACE FUNCTION perform_transaction( from_account_id INT, @@ -603,13 +645,13 @@ DECLARE prev_hash TEXT; new_hash TEXT; BEGIN - SELECT currency_code INTO from_currency FROM banque.account WHERE id = from_account_id; - SELECT currency_code INTO to_currency FROM banque.account WHERE id = to_account_id; + SELECT currency_code INTO from_currency FROM bank.account WHERE id = from_account_id; + SELECT currency_code INTO to_currency FROM bank.account WHERE id = to_account_id; - SELECT hash INTO prev_hash FROM banque.transaction ORDER BY id DESC LIMIT 1; + SELECT hash INTO prev_hash FROM bank.transaction ORDER BY id DESC LIMIT 1; -- Création de la transaction principale - INSERT INTO banque.transaction (description, previous_hash) + INSERT INTO bank.transaction (description, previous_hash) VALUES (description, prev_hash) RETURNING id INTO tx_id; @@ -619,27 +661,27 @@ BEGIN converted_amount := amount; ELSE SELECT rate, fee_percent INTO rate, fee - FROM banque.exchange_rate + FROM bank.exchange_rate WHERE from_currency = from_currency AND to_currency = to_currency ORDER BY last_updated desc LIMIT 1; converted_amount := amount * rate * (1 - fee / 100); END IF; -- Débit - INSERT INTO banque.ledger_entry (transaction_id, account_id, amount, currency_code, entry_type, rate_to_base, converted_amount) + INSERT INTO bank.ledger_entry (transaction_id, account_id, amount, currency_code, entry_type, rate_to_base, converted_amount) VALUES (tx_id, from_account_id, -amount, from_currency, 'debit', rate, amount * rate); -- Crédit - INSERT INTO banque.ledger_entry (transaction_id, account_id, amount, currency_code, entry_type, rate_to_base, converted_amount) + INSERT INTO bank.ledger_entry (transaction_id, account_id, amount, currency_code, entry_type, rate_to_base, converted_amount) VALUES (tx_id, to_account_id, converted_amount, to_currency, 'credit', rate, converted_amount); -- Mise à jour des soldes - UPDATE banque.account SET balance = balance - amount WHERE id = from_account_id; - UPDATE banque.account SET balance = balance + converted_amount WHERE id = to_account_id; + UPDATE bank.account SET balance = balance - amount WHERE id = from_account_id; + UPDATE bank.account SET balance = balance + converted_amount WHERE id = to_account_id; -- Génération du hash blockchain SELECT encode(digest(concat(tx_id, description, prev_hash, NOW()::text), 'sha256'), 'hex') INTO new_hash; - UPDATE banque.transaction SET hash = new_hash WHERE id = tx_id; + UPDATE bank.transaction SET hash = new_hash WHERE id = tx_id; END; $$ LANGUAGE plpgsql; @@ -660,7 +702,7 @@ END; $$ LANGUAGE plpgsql; CREATE TRIGGER tr_notify_transaction -AFTER INSERT ON banque.transaction +AFTER INSERT ON bank.transaction FOR EACH ROW EXECUTE FUNCTION notify_transaction(); diff --git a/postgresql-entrypoint-initdb.d/02_seed.sql b/postgresql-entrypoint-initdb.d/02_seed.sql index b10ddf9..e4274cf 100644 --- a/postgresql-entrypoint-initdb.d/02_seed.sql +++ b/postgresql-entrypoint-initdb.d/02_seed.sql @@ -18,3 +18,10 @@ truncate table fournisseur; \COPY personne(prenom, nom, telephone, ville) FROM '/tmp/personne1.csv' (FORMAT CSV, header, ENCODING 'UTF8'); \COPY societe(societe) FROM '/tmp/societe1.csv' (FORMAT CSV, header, ENCODING 'UTF8'); + +SELECT bank.insert_account_random(ARRAY[1]); +SELECT bank.insert_account_random(ARRAY[2]); +SELECT bank.insert_account_random(ARRAY[3]); +SELECT bank.insert_account_random(ARRAY[4]); +SELECT bank.insert_account_random(ARRAY[5],'USD'); +SELECT bank.insert_account_random(ARRAY[6,11]);