Skip to content

Commit

Permalink
merge SQL changes to get a nice diff
Browse files Browse the repository at this point in the history
  • Loading branch information
Changaco committed Oct 22, 2018
1 parent 509df03 commit 80cfe17
Showing 1 changed file with 105 additions and 34 deletions.
139 changes: 105 additions & 34 deletions sql/currencies.sql
Original file line number Diff line number Diff line change
Expand Up @@ -292,31 +292,62 @@ CREATE OPERATOR <= (

-- Basket type: amounts in multiple currencies

CREATE TYPE currency_basket AS (EUR numeric, USD numeric);
CREATE TYPE currency_basket AS (EUR numeric, USD numeric, amounts jsonb);

CREATE FUNCTION empty_currency_basket() RETURNS currency_basket AS $$
BEGIN RETURN ('0.00'::numeric, '0.00'::numeric); END;
BEGIN RETURN (NULL::numeric,NULL::numeric,jsonb_build_object()); END;
$$ LANGUAGE plpgsql;

CREATE FUNCTION coalesce_currency_basket(currency_basket) RETURNS currency_basket AS $$
BEGIN
IF (coalesce($1.EUR, 0) > 0 OR coalesce($1.USD, 0) > 0) THEN
IF ($1.amounts ? 'EUR' OR $1.amounts ? 'USD') THEN
RAISE 'got an hybrid currency basket: %', $1;
END IF;
RETURN _wrap_amounts(
jsonb_build_object('EUR', $1.EUR::text, 'USD', $1.USD::text)
);
ELSIF (jsonb_typeof($1.amounts) = 'object') THEN
RETURN $1;
ELSIF ($1.amounts IS NULL OR jsonb_typeof($1.amounts) <> 'null') THEN
RETURN (NULL::numeric,NULL::numeric,jsonb_build_object());
ELSE
RAISE 'unexpected JSON type: %', jsonb_typeof($1.amounts);
END IF;
END;
$$ LANGUAGE plpgsql IMMUTABLE;

CREATE FUNCTION _wrap_amounts(jsonb) RETURNS currency_basket AS $$
BEGIN
IF ($1 IS NULL) THEN
RETURN (NULL::numeric,NULL::numeric,jsonb_build_object());
ELSE
RETURN (NULL::numeric,NULL::numeric,$1);
END IF;
END;
$$ LANGUAGE plpgsql IMMUTABLE;

CREATE FUNCTION make_currency_basket(currency_amount) RETURNS currency_basket AS $$
BEGIN RETURN (CASE
WHEN $1.currency = 'EUR' THEN ($1.amount, '0.00'::numeric)
ELSE ('0.00'::numeric, $1.amount)
END); END;
BEGIN RETURN (NULL::numeric,NULL::numeric,jsonb_build_object($1.currency::text, $1.amount::text)); END;
$$ LANGUAGE plpgsql IMMUTABLE STRICT;

CREATE CAST (currency_amount as currency_basket) WITH FUNCTION make_currency_basket(currency_amount);

CREATE FUNCTION currency_basket_add(currency_basket, currency_amount)
RETURNS currency_basket AS $$
DECLARE
r currency_basket;
BEGIN
IF ($2.currency = 'EUR') THEN
RETURN ($1.EUR + $2.amount, $1.USD);
ELSIF ($2.currency = 'USD') THEN
RETURN ($1.EUR, $1.USD + $2.amount);
ELSE
RAISE 'unknown currency %', $2.currency;
r := coalesce_currency_basket($1);
IF ($2.amount IS NULL OR $2.amount = 0 OR $2.currency IS NULL) THEN
RETURN r;
END IF;
r.amounts := jsonb_set(
r.amounts,
string_to_array($2.currency::text, ' '),
(coalesce((r.amounts->>$2.currency::text)::numeric, 0) + $2.amount)::text::jsonb
);
RETURN r;
END;
$$ LANGUAGE plpgsql IMMUTABLE STRICT;

Expand All @@ -329,7 +360,24 @@ CREATE OPERATOR + (

CREATE FUNCTION currency_basket_add(currency_basket, currency_basket)
RETURNS currency_basket AS $$
BEGIN RETURN ($1.EUR + $2.EUR, $1.USD + $2.USD); END;
DECLARE
amounts1 jsonb;
amounts2 jsonb;
currency text;
BEGIN
amounts1 := (coalesce_currency_basket($1)).amounts;
amounts2 := (coalesce_currency_basket($2)).amounts;
FOR currency IN SELECT * FROM jsonb_object_keys(amounts2) LOOP
amounts1 := jsonb_set(
amounts1,
string_to_array(currency, ' '),
( coalesce((amounts1->>currency)::numeric, 0) +
coalesce((amounts2->>currency)::numeric, 0)
)::text::jsonb
);
END LOOP;
RETURN _wrap_amounts(amounts1);
END;
$$ LANGUAGE plpgsql IMMUTABLE STRICT;

CREATE OPERATOR + (
Expand All @@ -341,15 +389,7 @@ CREATE OPERATOR + (

CREATE FUNCTION currency_basket_sub(currency_basket, currency_amount)
RETURNS currency_basket AS $$
BEGIN
IF ($2.currency = 'EUR') THEN
RETURN ($1.EUR - $2.amount, $1.USD);
ELSIF ($2.currency = 'USD') THEN
RETURN ($1.EUR, $1.USD - $2.amount);
ELSE
RAISE 'unknown currency %', $2.currency;
END IF;
END;
BEGIN RETURN currency_basket_add($1, -$2); END;
$$ LANGUAGE plpgsql IMMUTABLE STRICT;

CREATE OPERATOR - (
Expand All @@ -360,7 +400,24 @@ CREATE OPERATOR - (

CREATE FUNCTION currency_basket_sub(currency_basket, currency_basket)
RETURNS currency_basket AS $$
BEGIN RETURN ($1.EUR - $2.EUR, $1.USD - $2.USD); END;
DECLARE
amounts1 jsonb;
amounts2 jsonb;
currency text;
BEGIN
amounts1 := (coalesce_currency_basket($1)).amounts;
amounts2 := (coalesce_currency_basket($2)).amounts;
FOR currency IN SELECT * FROM jsonb_object_keys(amounts2) LOOP
amounts1 := jsonb_set(
amounts1,
string_to_array(currency, ' '),
( coalesce((amounts1->>currency)::numeric, 0) -
coalesce((amounts2->>currency)::numeric, 0)
)::text::jsonb
);
END LOOP;
RETURN _wrap_amounts(amounts1);
END;
$$ LANGUAGE plpgsql IMMUTABLE STRICT;

CREATE OPERATOR - (
Expand All @@ -371,15 +428,7 @@ CREATE OPERATOR - (

CREATE FUNCTION currency_basket_contains(currency_basket, currency_amount)
RETURNS boolean AS $$
BEGIN
IF ($2.currency = 'EUR') THEN
RETURN ($1.EUR >= $2.amount);
ELSIF ($2.currency = 'USD') THEN
RETURN ($1.USD >= $2.amount);
ELSE
RAISE 'unknown currency %', $2.currency;
END IF;
END;
BEGIN RETURN coalesce(coalesce_currency_basket($1)->$2.currency::text, 0) >= $2.amount; END;
$$ LANGUAGE plpgsql IMMUTABLE STRICT;

CREATE OPERATOR >= (
Expand All @@ -391,13 +440,35 @@ CREATE OPERATOR >= (
CREATE AGGREGATE basket_sum(currency_amount) (
sfunc = currency_basket_add,
stype = currency_basket,
initcond = '(0.00,0.00)'
initcond = '(,,{})'
);

CREATE AGGREGATE sum(currency_basket) (
sfunc = currency_basket_add,
stype = currency_basket,
initcond = '(0.00,0.00)'
initcond = '(,,{})'
);

CREATE FUNCTION get_amount_from_currency_basket(currency_basket, currency)
RETURNS numeric AS $$
BEGIN RETURN (coalesce_currency_basket($1)).amounts->>$2::text; END;
$$ LANGUAGE plpgsql IMMUTABLE STRICT;

CREATE FUNCTION get_amount_from_currency_basket(currency_basket, text)
RETURNS numeric AS $$
BEGIN RETURN (coalesce_currency_basket($1)).amounts->>$2; END;
$$ LANGUAGE plpgsql IMMUTABLE STRICT;

CREATE OPERATOR -> (
leftarg = currency_basket,
rightarg = currency,
procedure = get_amount_from_currency_basket
);

CREATE OPERATOR -> (
leftarg = currency_basket,
rightarg = text,
procedure = get_amount_from_currency_basket
);


Expand Down

0 comments on commit 80cfe17

Please sign in to comment.