From 7885f0ff65b4595af421e58d1e4b2542c9aaabef Mon Sep 17 00:00:00 2001 From: medina5 Date: Sun, 16 Nov 2025 18:43:04 +0100 Subject: [PATCH] exchange rate --- banque.correction.sql | 346 +------------------------------------ banque/banque.1.tables.sql | 151 +++++++++++++++- 2 files changed, 144 insertions(+), 353 deletions(-) diff --git a/banque.correction.sql b/banque.correction.sql index a387a73..6f08e3d 100644 --- a/banque.correction.sql +++ b/banque.correction.sql @@ -1,348 +1,4 @@ -/************************************************************************ - * Holder : table commune à tous les titulaires - * bigint : entier sur 64 bits - * primary key : clé primaire, identification unique de l'enregistrement - * generated always as identity : numéro incrément automatique 1, 2, 3 ... - * Le type est forcé aux 3 valeurs de l'énumération holder_type - * current_timestamp date et heure courante. Version moderne de now() - ************************************************************************/ -create type holder_type as enum ('BANK', 'PERSON', 'COMPANY'); - -create table holder ( - "id" bigint primary key generated always as identity, - "type" holder_type not null, - "created_at" timestamp not null default current_timestamp -); - -/************************************************************************ - * Bank - * Liée par références à titulaire (holder) pas d'incrément automatique - * puisque c'est celui de titulaire - ************************************************************************/ -create table bank ( - "id" bigint primary key references holder(id), - "name" text not null -); - -insert into holder (type) values ('BANK') returning holder; -insert into bank (id, name) values (1, 'Banque de l''Est'); - -/************************************************************************ - * Person - * Liée par références à titulaire (holder) pas d'incrément automatique - * on delete cascade : Lors de la suppression du titualaire, person est - * supprimé aussi. Sans cela la suppression est interdite. - ************************************************************************/ -create table person ( - "id" bigint primary key references holder(id) on delete cascade, - "firstname" text not null, - "lastname" text not null, - "birthdate" date not null check (birthdate <= current_date - interval '15 years') -); - -/************************************************************************ - * Company - * - ************************************************************************/ -create table company ( - "id" bigint primary key references holder(id) on delete cascade, - "name" text not null, - "registration_number" text unique not null, - "creation_date" date not null -); - -/************************************************************************ - * Company - * - ************************************************************************/ -create table currency ( - "code" text primary key -); - -insert into currency - values ('EUR'), ('YEN'), ('USD'); - -/************************************************************************ - * Exchange Rate - * La clé primaire est sur les deux colonnes currency_code et date - * Il n'y a qu'un seul taux de change par monnaie ET par jour - ************************************************************************/ -create table exchange_rate ( - "currency_code" text references currency(code) on delete cascade, - "date" date , - "rate" decimal not null, - primary key (currency_code, date) -); - -insert into exchange_rate values - ('EUR', '1999-01-04', 1), - ('USD', '1999-01-04', 1.1789), - ('YEN', '1999-01-04', 133.73); - -/* - * Account - * La contrainte check (balance >= 0) empêche les soldes négatifs - */ -create table account ( - "id" bigint primary key generated always as identity, - "opened_at" date not null default current_date, - "balance" numeric(18,6) not null default 0, - "currency_code" text not null references currency (code) -); - -/* - * Account -> Holder - * Cette table établit la relation n–n entre account et holder. - * Un compte joint correspond donc à plusieurs lignes dans cette table. - * La contrainte share assure que les parts sont comprises entre 0 et 1. - */ -create table account_holder ( - "account_id" int not null references account(id) on delete cascade, - "holder_id" int not null references holder(id) on delete cascade, - "share" decimal(4,3) not null default 1 check (share > 0 and share <= 1), - primary key (account_id, holder_id) -); - -create table transaction ( - "id" bigint primary key generated always as identity, - "transaction_date" timestamp not null default current_timestamp, - amount decimal not null check (amount > 0) -); - -create table operation ( - "id" bigint primary key generated always as identity, - "transaction_id" bigint not null references transaction(id), - "account_id" bigint not null references account(id), - amount decimal not null check (amount > 0), - direction text not null check (direction in ('DEBIT', 'CREDIT')) -); - -/************************************************************************ - * Procédures - * Permet dans un bloc de code d'exécuter plusieurs opérations d'un seul coup - * Si une erreur survient RIEN n'est enregistré - ************************************************************************/ -create or replace procedure add_bank ( - name text -) -language plpgsql -as $$ -declare - v_holder_id bigint; -begin - - insert into holder(type) values ('BANK') - returning id into v_holder_id; - - insert into bank(id, name) - values (v_holder_id, name); - - raise notice 'Titulaire créé : % = %', - v_holder_id, name; -end; -$$; - -create or replace procedure add_person ( - p_firstname text, - p_lastname text, - p_birthdate date -) -language plpgsql -as $$ -declare - v_holder_id bigint; -begin - - insert into holder(type) values ('PERSON') - returning id into v_holder_id; - - insert into person(id, firstname, lastname, birthdate) - values (v_holder_id, p_firstname, p_lastname, p_birthdate); - - raise notice 'Titulaire créé : % = % %', - v_holder_id, p_firstname, p_lastname; -end; -$$; - -call add_person('Françoise', 'Zanetti', '1995-04-12'); -call add_person('Justin', 'Hébrard', '1993-03-11'); - -create or replace procedure add_company ( - p_name text, - p_registration_number text, - p_creation_date date -) -language plpgsql -as $$ -declare - v_holder_id bigint; -begin - - insert into holder(type) values ('COMPANY') - returning id into v_holder_id; - - insert into company(id, name, registration_number, creation_date) - values (v_holder_id, p_name, p_registration_number, p_creation_date); - - raise notice 'Titulaire créé : % = % %', - v_holder_id, p_name, p_registration_number; -end; -$$; - -call add_company('Boulangerie de Valorgue', 'FR19803269968', '2014-08-19'); - -create or replace procedure add_account( - p_currency text, - p_holders int[], - p_shares numeric[] -) -language plpgsql -as $$ -declare - v_account_id int; - v_sum numeric(6,4) := 0; - v_count int; -begin - -- Vérification des tailles - if array_length(p_holders, 1) is null or array_length(p_shares, 1) is null then - raise exception 'Les tableaux de titulaires et de parts ne peuvent pas être vides.'; - end if; - - if array_length(p_holders, 1) <> array_length(p_shares, 1) then - raise exception 'Les tableaux de titulaires et de parts doivent avoir la même taille.'; - end if; - - -- Calcul de la somme des parts - -- select sum(unnest(p_shares)) into v_sum; - for i in 1..array_length(p_shares, 1) loop - v_sum := v_sum + p_shares[i]; - end loop; - - if abs(v_sum - 1.0) > 0.0001 then - raise exception 'La somme des parts (%.4f) doit être égale à 1.0000', v_sum; - end if; - - -- Vérification des titulaires - select count(*) into v_count from holder where id = any(p_holders); - if v_count <> array_length(p_holders, 1) then - raise exception 'Un ou plusieurs titulaires n''existent pas.'; - end if; - - -- Création du compte - insert into account(currency_code, balance) - values (p_currency, 0) - returning id into v_account_id; - - -- Association des titulaires - for i in 1..array_length(p_holders, 1) loop - insert into account_holder(account_id, holder_id, share) - values (v_account_id, p_holders[i], p_shares[i]); - end loop; - - raise notice 'Compte créé avec succès (ID=%) avec % titulaires.', - v_account_id, array_length(p_holders, 1); -end; -$$; - -call add_account('EUR', array[1], array[1]); -call add_account('USD', array[1], array[1]); -call add_account('YEN', array[1], array[1]); - -update account set balance = 100000 where id = 1; -update account set balance = 50000 where id = 2; -update account set balance = 2000000 where id = 3; - -call add_account('EUR', array[2, 3], array[0.6, 0.4]); - -call add_person('Kaneda', 'Shōtarō', '1982-12-20'); -call add_account('YEN', array[5], array[1]); - -call add_company('Boucherie Sanzot', 'FR68487684235', '2014-08-14'); -call add_account('EUR', array[6], array[1]); - -call add_company('America Logistics', '95-4524149', '1996-09-24'); -call add_account('EUR', array[7], array[1]); -call add_account('USD', array[7], array[1]); - -/************************************************************************ - * Dépôts et retraits - ************************************************************************/ -create or replace procedure add_depot ( - p_account_id bigint, - p_amount decimal -) -language plpgsql -as $$ -declare - v_id bigint; -begin - insert into transaction (amount) - values (p_amount) - returning id into v_id; - - insert into operation (transaction_id, account_id, amount, direction) - values (v_id, p_account_id, p_amount, 'CREDIT'); - - raise notice 'Dépôt de % sur le compte %', p_amount, p_account_id; -end; -$$; - -create or replace procedure add_retrait ( - p_account_id bigint, - p_amount decimal -) -language plpgsql -as $$ -declare - v_id bigint; -begin - insert into transaction (amount) - values (p_amount) - returning id into v_id; - - insert into operation (transaction_id, account_id, amount, direction) - values (v_id, p_account_id, p_amount, 'DEBIT'); - - raise notice 'Retrait de % sur le compte %', p_amount, p_account_id; -end; -$$; - -call add_depot(4, 100); -call add_retrait(4, 20); - -call add_depot(5, 150); -call add_depot(6, 200); -call add_depot(7, 180); -call add_depot(8, 300); - -call add_retrait(5, 30); -call add_depot(5, 10); -call add_depot(5, 60); +drop table if exists eurofxref; -/************************************************************************ - * Vues - ************************************************************************/ -create or replace view holder_details as -select h.id, h.type, - case - when type = 'PERSON' then firstname || ' ' || lastname - else name - end as nom, - case - when type = 'PERSON' then age(birthdate) - when type = 'COMPANY' then age(c.creation_date) - end as age -from holder h - left join person p on p.id = h.id - left join company c on c.id = h.id; - -create or replace view account_details as -select - a.balance, - a.currency_code, - hd.nom, hd.age -from account a -join account_holder ah on ah.account_id = a.id -join holder_details hd on ah.holder_id = hd.id; diff --git a/banque/banque.1.tables.sql b/banque/banque.1.tables.sql index 0d88e33..6d6d48e 100644 --- a/banque/banque.1.tables.sql +++ b/banque/banque.1.tables.sql @@ -1,3 +1,6 @@ +drop schema if exists public cascade; +create schema public; + create type holder_type as enum ('BANK', 'PERSON', 'COMPANY'); create table holder ( @@ -48,11 +51,13 @@ create table company ( * ************************************************************************/ create table currency ( - "code" text primary key + "code" text primary key, + "name" text ); insert into currency - values ('EUR'), ('YEN'), ('USD'); + values ('EUR', 'Euro'), ('JPY', 'Yen'), ('USD', 'US Dollar'), + ('GBP', 'Livre Sterling'), ('KRW', 'Won'); /************************************************************************ * Exchange Rate @@ -66,10 +71,33 @@ create table exchange_rate ( primary key (currency_code, date) ); -insert into exchange_rate values - ('EUR', '1999-01-04', 1), - ('USD', '1999-01-04', 1.1789), - ('YEN', '1999-01-04', 133.73); +create temporary table eurofxref ( + "date" date, + USD decimal, JPY decimal, BGN text, CYP text, CZK decimal, + DKK decimal, EEK text, GBP decimal, HUF decimal, LTL text, + LVL text, MTL text, PLN decimal, ROL text, RON text, + SEK decimal, SIT text, SKK text, CHF decimal, ISK text, + NOK decimal, HRK text, RUB text, TRL text, TRY text, + AUD decimal, BRL text, CAD decimal, CNY text, HKD decimal, + IDR text, ILS text, INR text, KRW decimal, MXN text, + MYR text, NZD decimal, PHP text, SGD decimal, THB text, + ZAR decimal, + dumb text +); + +copy eurofxref FROM '/docker-entrypoint-initdb.d/banque/eurofxref-hist.csv' (FORMAT CSV, header, delimiter ',', ENCODING 'UTF8'); + +insert into exchange_rate +select 'USD', date, USD from eurofxref; + +insert into exchange_rate +select 'JPY', date, JPY from eurofxref; + +insert into exchange_rate +select 'GBP', date, GBP from eurofxref; + +insert into exchange_rate +select 'KRW', date, KRW from eurofxref; create or replace function latest_exchange_rate ( p_code text, @@ -90,6 +118,31 @@ $$; * Account * La contrainte check (balance >= 0) empêche les soldes négatifs */ + +CREATE OR REPLACE FUNCTION rand_account(n integer) +RETURNS text +LANGUAGE plpgsql +AS $$ +DECLARE + chars text := '0123456789ABCDEFGHIJKLMNOPQRSTUVWXYZ'; + out text := ''; + b bytea := gen_random_bytes(n); -- n octets aléatoires + i int; + idx int; +begin + IF n <= 0 THEN + RAISE EXCEPTION 'La longueur doit être > 0'; + END IF; + + FOR i IN 0..(n - 1) LOOP + idx := (get_byte(b, i) % length(chars)) + 1; + out := out || substr(chars, idx, 1); + END LOOP; + + RETURN out; +END; +$$; + create table account ( "id" bigint primary key generated always as identity, "opened_at" date not null default current_date, @@ -253,7 +306,7 @@ $$; call add_account('EUR', array[1], array[1]); call add_account('USD', array[1], array[1]); -call add_account('YEN', array[1], array[1]); +call add_account('JPY', array[1], array[1]); update account set balance = 100000 where id = 1; update account set balance = 50000 where id = 2; @@ -262,7 +315,7 @@ update account set balance = 2000000 where id = 3; call add_account('EUR', array[2, 3], array[0.6, 0.4]); call add_person('Kaneda', 'Shōtarō', '1982-12-20'); -call add_account('YEN', array[5], array[1]); +call add_account('JPY', array[5], array[1]); call add_company('Boucherie Sanzot', 'FR68487684235', '2014-08-14'); call add_account('EUR', array[6], array[1]); @@ -271,6 +324,61 @@ call add_company('America Logistics', '95-4524149', '1996-09-24'); call add_account('EUR', array[7], array[1]); call add_account('USD', array[7], array[1]); +/************************************************************************ + * Dépôts et retraits + ************************************************************************/ +create or replace procedure add_depot ( + p_account_id bigint, + p_amount decimal +) +language plpgsql +as $$ +declare + v_id bigint; +begin + insert into transaction (amount) + values (p_amount) + returning id into v_id; + + insert into operation (transaction_id, account_id, amount, direction) + values (v_id, p_account_id, p_amount, 'CREDIT'); + + raise notice 'Dépôt de % sur le compte %', p_amount, p_account_id; +end; +$$; + +create or replace procedure add_retrait ( + p_account_id bigint, + p_amount decimal +) +language plpgsql +as $$ +declare + v_id bigint; +begin + insert into transaction (amount) + values (p_amount) + returning id into v_id; + + insert into operation (transaction_id, account_id, amount, direction) + values (v_id, p_account_id, p_amount, 'DEBIT'); + + raise notice 'Retrait de % sur le compte %', p_amount, p_account_id; +end; +$$; + +call add_depot(4, 100); +call add_retrait(4, 20); + +call add_depot(5, 150); +call add_depot(6, 200); +call add_depot(7, 180); +call add_depot(8, 300); + +call add_retrait(5, 30); +call add_depot(5, 10); +call add_depot(5, 60); + create or replace view holder_detail as select h.id, h.type, case @@ -315,3 +423,30 @@ insert into operation (transaction_id, account_id, amount, direction) insert into operation (transaction_id, account_id, amount, direction) values (2, 3, 10000, 'DEBIT'); + +/************************************************************************ + * Vues + ************************************************************************/ + +create or replace view holder_details as +select h.id, h.type, + case + when type = 'PERSON' then firstname || ' ' || lastname + else name + end as nom, + case + when type = 'PERSON' then age(birthdate) + when type = 'COMPANY' then age(c.creation_date) + end as age +from holder h + left join person p on p.id = h.id + left join company c on c.id = h.id; + +create or replace view account_details as +select + a.balance, + a.currency_code, + hd.nom, hd.age +from account a +join account_holder ah on ah.account_id = a.id +join holder_details hd on ah.holder_id = hd.id;