numerus/revert/_merge_collection_into_paym...

121 lines
3.3 KiB
PL/PgSQL

-- Revert numerus:_merge_collection_into_payment from pg
begin;
set search_path to numerus, public;
create table collection (
collection_id integer generated by default as identity primary key,
company_id integer not null references company,
slug uuid not null unique default gen_random_uuid(),
description text not null,
collection_date date not null default current_date,
payment_account_id integer not null references payment_account,
amount integer not null constraint collection_amount_positive check (amount > 0),
currency_code text not null references currency,
tags tag_name[] not null default '{}',
payment_status text not null default 'complete' references payment_status,
created_at timestamptz not null default current_timestamp
);
grant select, insert, update, delete on table collection to invoicer;
grant select, insert, update, delete on table collection to admin;
alter table collection enable row level security;
create policy company_policy
on collection
using (
exists(
select 1
from company_user
join user_profile using (user_id)
where company_user.company_id = collection.company_id
)
);
insert into collection (company_id, slug, description, collection_date, payment_account_id, amount, currency_code, tags, payment_status, created_at)
select company_id, slug, description, payment_date, payment_account_id, amount, currency_code, tags, payment_status, created_at
from payment
where amount > 0
;
create table invoice_collection (
invoice_id integer not null references invoice,
collection_id integer not null references collection,
primary key (invoice_id, collection_id)
);
grant select, insert, update, delete on table invoice_collection to invoicer;
grant select, insert, update, delete on table invoice_collection to admin;
alter table invoice_collection enable row level security;
create policy company_policy
on invoice_collection
using (
exists(
select 1
from invoice
where invoice.invoice_id = invoice_collection.invoice_id
)
);
insert into invoice_collection (invoice_id, collection_id)
select invoice_id, collection_id
from invoice_payment
join payment using (payment_id)
join collection using (slug)
;
delete from invoice_payment;
create table collection_attachment (
collection_id integer primary key references collection,
original_filename text not null,
mime_type text not null,
content bytea not null
);
grant select, insert, update, delete on table collection_attachment to invoicer;
grant select, insert, update, delete on table collection_attachment to admin;
alter table collection_attachment enable row level security;
create policy company_policy
on collection_attachment
using (
exists(
select 1
from collection
where collection.collection_id = collection_attachment.collection_id
)
);
insert into collection_attachment (collection_id, original_filename, mime_type, content)
select collection_id, original_filename, mime_type, content
from payment_attachment
join payment using (payment_id)
join collection using (slug)
where payment.amount > 0
;
delete from payment_attachment
where payment_id in (
select payment_id from payment where amount > 0
);
delete from payment where amount > 0;
update payment
set amount = -amount
;
alter table payment
add constraint payment_amount_positive check (amount > 0)
, drop constraint if exists payment_amount_not_zero
;
commit;