drop schema if exists bank cascade; create schema bank; set search_path TO bank; /************************************************************************ * 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 ); /************************************************************************ * 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, "created_at" date not null ); /************************************************************************ * Company * ************************************************************************/ create table currency ( "code" text primary key ); /************************************************************************ * 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) ); /* * 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')) );