This commit is contained in:
2025-11-18 19:45:27 +01:00
parent 7885f0ff65
commit cf620b1450
4 changed files with 90 additions and 63 deletions

View File

@@ -1,4 +1,3 @@
drop table if exists eurofxref; drop table if exists eurofxref;
SELECT rand_account(2);

View File

@@ -25,12 +25,12 @@ Pour les entités vous utiliserez le singuler et écrirez le tout en minuscule.
- Séance 1 : [Le schéma Entités-Relations](banque.erd.md) - Séance 1 : [Le schéma Entités-Relations](banque.erd.md)
- Séance 2 : - Séance 2 :
- [Implémentation du modèle](banques.tables.md) - [Implémentation du modèle](banque.tables.md)
- [Les procédures](banques.procedures.md) - [Les procédures](banque.procedures.md)
- Séance 3 : - Séance 3 :
- [Les vues](banques.vues.md) - [Les vues](banque.vues.md)
- [Les fonctions](banques.functions.md) - [Les fonctions](banque.functions.md)
Voir les adresses des serveurs [postgreSQL](https://sources.neotech.fr/Universite/tp/src/branch/main/geii3_2025.md) Voir les adresses des serveurs [postgreSQL](https://sources.neotech.fr/Universite/tp/src/branch/main/geii3_2025.md)

View File

@@ -1,6 +1,9 @@
drop schema if exists public cascade; drop schema if exists public cascade;
create schema public; 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 type holder_type as enum ('BANK', 'PERSON', 'COMPANY');
create table holder ( create table holder (
@@ -71,8 +74,10 @@ create table exchange_rate (
primary key (currency_code, date) primary key (currency_code, date)
); );
create temporary table eurofxref ( drop table if exists eurofxref;
"date" date,
create temporary table if not exists eurofxref (
"date" date primary key,
USD decimal, JPY decimal, BGN text, CYP text, CZK decimal, USD decimal, JPY decimal, BGN text, CYP text, CZK decimal,
DKK decimal, EEK text, GBP decimal, HUF decimal, LTL text, DKK decimal, EEK text, GBP decimal, HUF decimal, LTL text,
LVL text, MTL text, PLN decimal, ROL text, RON text, LVL text, MTL text, PLN decimal, ROL text, RON text,
@@ -114,21 +119,56 @@ select rate
limit 1; limit 1;
$$; $$;
/* -- Jeu de caractères utilisé
* Account CREATE OR REPLACE FUNCTION chars36()
* La contrainte check (balance >= 0) empêche les soldes négatifs 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) CREATE OR REPLACE FUNCTION rand_account(n integer)
RETURNS text RETURNS text
LANGUAGE plpgsql LANGUAGE plpgsql
AS $$ AS $$
DECLARE DECLARE
chars text := '0123456789ABCDEFGHIJKLMNOPQRSTUVWXYZ'; chars text := chars36();
out text := ''; 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; i int;
idx int; idx int;
check_char text;
begin begin
IF n <= 0 THEN IF n <= 0 THEN
RAISE EXCEPTION 'La longueur doit être > 0'; RAISE EXCEPTION 'La longueur doit être > 0';
@@ -139,10 +179,45 @@ begin
out := out || substr(chars, idx, 1); out := out || substr(chars, idx, 1);
END LOOP; END LOOP;
RETURN out; RETURN out || compute_checksum(out);
END; 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 ( create table account (
"id" bigint primary key generated always as identity, "id" bigint primary key generated always as identity,
"opened_at" date not null default current_date, "opened_at" date not null default current_date,

View File

@@ -128,54 +128,7 @@ services:
# Web API # Web API
# #
# ---------------------------------------------------------------------- # ----------------------------------------------------------------------
# PostgREST
# Serve a fully RESTful API from any existing PostgreSQL database.
# It provides a cleaner, more standards-compliant, faster API than you are likely to write from scratch.
# https://docs.postgrest.org/en/v13/
postgrest:
image: postgrest/postgrest:v13.0.7
restart: "no"
depends_on:
database:
condition: service_healthy
caddy:
condition: service_started
command: postgrest
environment:
PGRST_DB_URI: postgres://${POSTGREST_USER:-postgrest}:${POSTGREST_PASSWORD}@${POSTGREST_HOST:-database}:${POSTGREST_DB_PORT:-5432}/${COMPOSE_PROJECT_NAME}
PGRST_DB_SCHEMAS: ${POSTGREST_DB_SCHEMAS:-public}
PGRST_DB_ANON_ROLE: ${POSTGREST_DB_ANON_ROLE:-anonyme}
PGRST_JWT_SECRET: ${POSTGREST_JWT_SECRET:-ChangeMeChangeMeChangeMeChangeMe}
PGRST_ADMIN_SERVER_PORT: 3055
PGRST_SERVER_PORT: 80
PGRST_OPENAPI_SERVER_PROXY_URI: https://postgrest.localhost
networks:
- caddy_net
labels:
caddy: postgrest.localhost
caddy.reverse_proxy: "{{upstreams 80}}"
caddy.tls: internal
# Scalar
# Create world-class API Docs with a built-in interactive playground
# which seamlessly turns to a full featured API Client
scalar:
image: scalarapi/api-reference:0.4.2
restart: "no"
environment:
API_REFERENCE_CONFIG: |
{
"sources":[
{ "url": "https://postgrest.localhost" }
],
"theme": "purple"
}
networks:
- caddy_net
labels:
caddy: scalar.localhost
caddy.reverse_proxy: "{{upstreams 8080}}"
caddy.tls: internal