b
This commit is contained in:
@@ -28,6 +28,9 @@ create table bank (
|
||||
"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
|
||||
@@ -60,6 +63,9 @@ 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
|
||||
@@ -72,6 +78,26 @@ 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 or replace function latest_exchange_rate (
|
||||
p_code text,
|
||||
p_date date
|
||||
)
|
||||
returns decimal
|
||||
language sql
|
||||
as $$
|
||||
select rate
|
||||
from exchange_rate
|
||||
where currency_code = p_code
|
||||
and date < p_date
|
||||
order by date desc
|
||||
limit 1;
|
||||
$$;
|
||||
|
||||
/*
|
||||
* Account
|
||||
* La contrainte check (balance >= 0) empêche les soldes négatifs
|
||||
@@ -96,7 +122,6 @@ create table account_holder (
|
||||
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,
|
||||
@@ -110,3 +135,178 @@ create table operation (
|
||||
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_created_at 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, created_at)
|
||||
values (v_holder_id, p_name, p_registration_number, p_created_at);
|
||||
|
||||
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]);
|
||||
|
||||
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]);
|
||||
|
||||
create view holder_detail 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.created_at)
|
||||
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 view account_detail as
|
||||
select a.balance,
|
||||
a.balance * ah.share as balance_currency,
|
||||
a.currency_code,
|
||||
hd.nom
|
||||
from account a
|
||||
join account_holder ah on ah.account_id = a.id
|
||||
join holder_detail hd on ah.holder_id = hd.id
|
||||
|
||||
insert into transaction (amount) values (100);
|
||||
|
||||
insert into operation (transaction_id, account_id, amount, direction)
|
||||
values (1, 4, 100, 'CREDIT');
|
||||
|
||||
insert into operation (transaction_id, account_id, amount, direction)
|
||||
values (1, 1, 100, 'DEBIT');
|
||||
|
||||
insert into transaction (amount) values (10000);
|
||||
|
||||
insert into operation (transaction_id, account_id, amount, direction)
|
||||
values (2, 5, 10000, 'CREDIT');
|
||||
|
||||
insert into operation (transaction_id, account_id, amount, direction)
|
||||
values (2, 3, 10000, 'DEBIT');
|
||||
|
||||
Reference in New Issue
Block a user