1
0

ms-20250502-coopshares-coopassets-positive-total-constraint (#176)

Co-authored-by: Marc O. Sandlus <marc.o.sandlus@hostsharing.net>
Reviewed-on: https://dev.hostsharing.net/hostsharing/hs.hsadmin.ng/pulls/176
Reviewed-by: Michael Hoennig <michael.hoennig@hostsharing.net>
This commit is contained in:
Marc Sandlus
2025-05-09 01:01:09 +02:00
parent 44ba3b2fef
commit d4d3d42b2d
3 changed files with 50 additions and 38 deletions

View File

@@ -49,37 +49,37 @@ CREATE UNIQUE INDEX unique_partner_relation
--// --//
-- ===================================================================================== -- =====================================================================================
--changeset timotheus.pokorra:hs-office-relation-debitor-anchor-CONSTRAINT endDelimiter:--// --changeset marc.sandlus:hs-office-relation-debitor-anchor-CONSTRAINT-BY-TRIGGER endDelimiter:--//
-- ------------------------------------------------------------------------------------- -- -------------------------------------------------------------------------------------
alter table hs_office.relation
drop constraint if exists relation_check_debitor_anchor_person;
-- drop function if exists hs_office.relation_check_debitor_anchor_partner cascade;
-- Name: relation_check_debitor_anchor_partner(RelationType, uuid); Type: FUNCTION; Schema: hs_office; Owner: test
--
CREATE FUNCTION hs_office.relation_check_debitor_anchor_partner(mytype hs_office.RelationType, debitoranchoruuid uuid) RETURNS boolean CREATE FUNCTION hs_office.relation_enforce_debitor_anchor_partner()
LANGUAGE plpgsql returns trigger as $$
AS '
declare declare
countPartner integer; countPartner integer;
begin begin
if mytype = ''DEBITOR'' then if NEW.type = 'DEBITOR' then
SELECT COUNT(*) FROM hs_office.relation r SELECT COUNT(*) FROM hs_office.relation r
WHERE r.type = ''PARTNER'' AND r.holderuuid = debitoranchoruuid WHERE r.type = 'PARTNER' AND r.holderuuid = NEW.anchorUuid
INTO countPartner; INTO countPartner;
if countPartner < 1 then if countPartner < 1 then
raise exception ''[400] invalid debitor relation: anchor person must have a PARTNER relation''; raise exception '[400] invalid debitor relation: anchor person must have a PARTNER relation';
end if; end if;
end if; end if;
return true; return NEW;
end; '; end;
$$ LANGUAGE plpgsql;;
ALTER TABLE hs_office.relation ADD CONSTRAINT check_debitor_anchor_person CHECK (hs_office.relation_check_debitor_anchor_partner(type, anchorUuid)); create trigger relation_enforce_debitor_anchor_partner_tg before insert
on hs_office.relation
for each row execute function hs_office.relation_enforce_debitor_anchor_partner();
--// --//
-- ============================================================================ -- ============================================================================
--changeset michael.hoennig:hs-office-relation-MAIN-TABLE-JOURNAL endDelimiter:--// --changeset michael.hoennig:hs-office-relation-MAIN-TABLE-JOURNAL endDelimiter:--//
-- ---------------------------------------------------------------------------- -- ----------------------------------------------------------------------------

View File

@@ -33,30 +33,36 @@ alter table hs_office.coopsharetx
--// --//
-- ============================================================================ -- ============================================================================
--changeset michael.hoennig:hs-office-coopshares-SHARE-COUNT-CONSTRAINT endDelimiter:--// --changeset marc.sandlus:hs-office-coopshares-SHARE-COUNT-CONSTRAINT-BY-TRIGGER endDelimiter:--//
-- ---------------------------------------------------------------------------- -- ----------------------------------------------------------------------------
create or replace function hs_office.coopsharestx_check_positive_total(forMembershipUuid UUID, newShareCount integer) alter table hs_office.coopsharetx drop constraint if exists check_positive_total_shares_count;
returns boolean
language plpgsql as $$ drop function if exists hs_office.coopsharestx_check_positive_total cascade;
create or replace function hs_office.coopsharetx_enforce_positive_total()
returns trigger as $$
declare declare
currentShareCount integer; currentShareCount integer;
totalShareCount integer; totalShareCount integer;
begin begin
select sum(cst.shareCount) select sum(cst.shareCount)
from hs_office.coopsharetx cst from hs_office.coopsharetx cst
where cst.membershipUuid = forMembershipUuid where cst.membershipUuid = NEW.membershipUuid
into currentShareCount; into currentShareCount;
totalShareCount := currentShareCount + newShareCount; totalShareCount := currentShareCount + NEW.shareCount;
if totalShareCount < 0 then if totalShareCount < 0 then
raise exception '[400] coop shares transaction would result in a negative number of shares'; raise exception '[400] coop shares transaction would result in a negative number of shares';
end if; end if;
return true; return NEW;
end; $$; end;
$$ LANGUAGE plpgsql;;
alter table hs_office.coopsharetx
add constraint check_positive_total_shares_count create trigger positive_total_shares_count_tg before insert
check ( hs_office.coopsharestx_check_positive_total(membershipUuid, shareCount) ); on hs_office.coopsharetx
for each row execute function hs_office.coopsharetx_enforce_positive_total();
--// --//

View File

@@ -73,33 +73,39 @@ CREATE TRIGGER enforce_transaction_constraints
--// --//
-- ============================================================================ -- ============================================================================
--changeset michael.hoennig:hs-office-coopassets-ASSET-VALUE-CONSTRAINT endDelimiter:--// --changeset marc.sandlus:hs-office-coopassets-ASSET-VALUE-CONSTRAINT-BY-TRIGGER endDelimiter:--//
-- ---------------------------------------------------------------------------- -- ----------------------------------------------------------------------------
create or replace function hs_office.coopassetstx_check_positive_total(forMembershipUuid UUID, newAssetValue numeric(12, 5)) alter table hs_office.coopassettx
returns boolean drop constraint if exists coopassetstx_check_positive_total;
language plpgsql as $$
drop function if exists hs_office.coopassetstx_check_positive_total cascade;
create or replace function hs_office.coopassettx_enforce_positive_total()
returns trigger as $$
declare declare
currentAssetValue numeric(12,2); currentAssetValue numeric(12,2);
totalAssetValue numeric(12,2); totalAssetValue numeric(12,2);
begin begin
select sum(cat.assetValue) select sum(cat.assetValue)
from hs_office.coopassettx cat from hs_office.coopassettx cat
where cat.membershipUuid = forMembershipUuid where cat.membershipUuid = NEW.membershipUuid
into currentAssetValue; into currentAssetValue;
totalAssetValue := currentAssetValue + newAssetValue; totalAssetValue := currentAssetValue + NEW.assetValue;
if totalAssetValue::numeric < 0 then if totalAssetValue::numeric < 0 then
raise exception '[400] coop assets transaction would result in a negative balance of assets'; raise exception '[400] coop assets transaction would result in a negative balance of assets';
end if; end if;
return true; return NEW;
end; $$; end;
$$ LANGUAGE plpgsql;;
create trigger positive_total_assets_count_tg before insert
on hs_office.coopassettx
for each row execute function hs_office.coopassettx_enforce_positive_total();
alter table hs_office.coopassettx
add constraint check_positive_total
check ( hs_office.coopassetstx_check_positive_total(membershipUuid, assetValue) );
--// --//
-- ============================================================================ -- ============================================================================
--changeset michael.hoennig:hs-office-coopassets-MAIN-TABLE-JOURNAL endDelimiter:--// --changeset michael.hoennig:hs-office-coopassets-MAIN-TABLE-JOURNAL endDelimiter:--//
-- ---------------------------------------------------------------------------- -- ----------------------------------------------------------------------------