exchange rate

This commit is contained in:
2025-11-16 18:43:04 +01:00
parent e55c60504e
commit 7885f0ff65
2 changed files with 144 additions and 353 deletions

View File

@@ -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;