liens
This commit is contained in:
@@ -1,6 +1,9 @@
|
||||
drop schema if exists public cascade;
|
||||
create schema public;
|
||||
|
||||
create schema if not exists ext;
|
||||
create extension if not exists pgcrypto schema ext;
|
||||
|
||||
create type holder_type as enum ('BANK', 'PERSON', 'COMPANY');
|
||||
|
||||
create table holder (
|
||||
@@ -71,8 +74,10 @@ create table exchange_rate (
|
||||
primary key (currency_code, date)
|
||||
);
|
||||
|
||||
create temporary table eurofxref (
|
||||
"date" date,
|
||||
drop table if exists eurofxref;
|
||||
|
||||
create temporary table if not exists eurofxref (
|
||||
"date" date primary key,
|
||||
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,
|
||||
@@ -114,21 +119,56 @@ select rate
|
||||
limit 1;
|
||||
$$;
|
||||
|
||||
/*
|
||||
* Account
|
||||
* La contrainte check (balance >= 0) empêche les soldes négatifs
|
||||
*/
|
||||
-- Jeu de caractères utilisé
|
||||
CREATE OR REPLACE FUNCTION chars36()
|
||||
RETURNS text AS $$
|
||||
SELECT '12345ABCDE';
|
||||
$$ LANGUAGE sql IMMUTABLE;
|
||||
|
||||
CREATE OR REPLACE FUNCTION char_to_int(c text)
|
||||
RETURNS int AS $$
|
||||
DECLARE
|
||||
pos int;
|
||||
BEGIN
|
||||
pos := position(c IN chars36()) - 1;
|
||||
IF pos < 0 THEN
|
||||
RAISE EXCEPTION 'Invalid base36 character: %', c;
|
||||
END IF;
|
||||
RETURN pos;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
CREATE OR REPLACE FUNCTION compute_checksum(code5 text)
|
||||
RETURNS text AS $$
|
||||
DECLARE
|
||||
chars text := chars36();
|
||||
weights int[] := ARRAY[7, 3, 1, 9, 11, 5];
|
||||
total int := 0;
|
||||
c text;
|
||||
i int;
|
||||
BEGIN
|
||||
|
||||
FOR i IN 1..length(code5) LOOP
|
||||
c := substr(code5, i, 1);
|
||||
total := total + char_to_int(c) * weights[i];
|
||||
END LOOP;
|
||||
|
||||
total := total % length(chars);
|
||||
RETURN substr(chars, total + 1, 1);
|
||||
END;
|
||||
$$ LANGUAGE plpgsql IMMUTABLE;
|
||||
|
||||
CREATE OR REPLACE FUNCTION rand_account(n integer)
|
||||
RETURNS text
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE
|
||||
chars text := '0123456789ABCDEFGHIJKLMNOPQRSTUVWXYZ';
|
||||
chars text := chars36();
|
||||
out text := '';
|
||||
b bytea := gen_random_bytes(n); -- n octets aléatoires
|
||||
b bytea := ext.gen_random_bytes(n); -- n octets aléatoires
|
||||
i int;
|
||||
idx int;
|
||||
check_char text;
|
||||
begin
|
||||
IF n <= 0 THEN
|
||||
RAISE EXCEPTION 'La longueur doit être > 0';
|
||||
@@ -139,10 +179,45 @@ begin
|
||||
out := out || substr(chars, idx, 1);
|
||||
END LOOP;
|
||||
|
||||
RETURN out;
|
||||
END;
|
||||
RETURN out || compute_checksum(out);
|
||||
end;
|
||||
$$;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION is_valid_account_number(code text)
|
||||
RETURNS boolean AS $$
|
||||
DECLARE
|
||||
base5 text;
|
||||
given_checksum text;
|
||||
expected_checksum text;
|
||||
BEGIN
|
||||
-- 1. vérification format
|
||||
IF code IS NULL OR length(code) <> 6 THEN
|
||||
RETURN false;
|
||||
END IF;
|
||||
|
||||
-- 2. séparation
|
||||
base5 := upper(substr(code, 1, 5)); -- normalisation
|
||||
given_checksum := upper(substr(code, 6, 1));
|
||||
|
||||
-- 3. validation caractères autorisés
|
||||
IF base5 ~ '[^0-9A-Z]' OR given_checksum ~ '[^0-9A-Z]' THEN
|
||||
RETURN false;
|
||||
END IF;
|
||||
|
||||
-- 4. recalcul de la vraie clé de contrôle
|
||||
expected_checksum := compute_checksum36(base5);
|
||||
|
||||
-- 5. comparaison
|
||||
RETURN expected_checksum = given_checksum;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
/*
|
||||
* 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,
|
||||
|
||||
Reference in New Issue
Block a user