drop schema if exists bank cascade; create schema bank; set search_path TO bank; /* * Holder : table commune à tous les titulaires */ create type holder_type as enum ('BANK', 'PERSON', 'COMPANY'); create table holder ( "id" bigint primary key generated always as identity, -- identifiant unique "type" holder_type not null, "created_at" timestamp not null default current_timestamp -- date et heure de création ); /* * Bank */ create table bank ( "id" bigint primary key references holder(id), -- identifiant unique "name" text not null ); /* * Person */ 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 ); /* * Company */ create table company ( "id" bigint primary key references holder(id) on delete cascade, "name" text not null, "registration_number" text unique not null, "created_at" date not null ); create table currency ( "code" text primary key ); create table exchange_rate ( "currency_code" text references currency(code) on delete cascade, "date" date, "rate" decimal, primary key (currency_code, date) ); /* * 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 check (balance >= 0), "currency_code" text 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) 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 default current_timestamp, amount decimal check (amount > 0) ); create table operation ( "id" bigint primary key generated always as identity, "transaction_id" bigint references transaction(id), "account_id" bigint references account(id), amount decimal check (amount > 0), direction text check (direction in ('DEBIT', 'CREDIT')) );