numerus/deploy/contact_tax_details.sql

61 lines
1.5 KiB
MySQL
Raw Permalink Normal View History

Split contact relation into tax_details, phone, web, and email We need to have contacts with just a name: we need to assign freelancer’s quote as expense linked the government, but of course we do not have a phone or email for that “contact”, much less a VATIN or other tax details. It is also interesting for other expenses-only contacts to not have to input all tax details, as we may not need to invoice then, thus are useless for us, but sometimes it might be interesting to have them, “just in case”. Of course, i did not want to make nullable any of the tax details required to generate an invoice, otherwise we could allow illegal invoices. Therefore, that data had to go in a different relation, and invoice’s foreign key update to point to that relation, not just customer, or we would again be able to create invalid invoices. We replaced the contact’s trade name with just name, because we do not need _three_ names for a contact, but we _do_ need two: the one we use to refer to them and the business name for tax purposes. The new contact_phone, contact_web, and contact_email relations could be simply a nullable field, but i did not see the point, since there are not that many instances where i need any of this data. Now company.taxDetailsForm is no longer “the same as contactForm with some extra fields”, because i have to add a check whether the user needs to invoice the contact, to check that the required values are there. I have an additional problem with the contact form when not using JavaScript: i must set the required field to all tax details fields to avoid the “(optional)” suffix, and because they _are_ required when that checkbox is enabled, but i can not set them optional when the check is unchecked. My solution for now is to ignore the form validation, and later i will add some JavaScript that adds the validation again, so it will work in all cases.
2023-06-30 19:32:48 +00:00
-- Deploy numerus:contact_tax_details to pg
-- requires: roles
-- requires: schema_numerus
-- requires: contact
-- requires: extension_vat
-- requires: country_code
-- requires: country
begin;
set search_path to numerus, public;
create table contact_tax_details (
contact_id integer primary key references contact,
business_name text not null constraint business_name_not_empty check(length(trim(business_name)) > 1),
vatin vatin not null,
address text not null,
city text not null,
province text not null,
postal_code text not null,
country_code country_code not null references country
);
alter table contact_tax_details enable row level security;
create policy company_policy
on contact_tax_details
using (
exists(
select 1
from contact
where contact.contact_id = contact_tax_details.contact_id
)
);
grant select, insert, update, delete on table contact_tax_details to invoicer;
grant select, insert, update, delete on table contact_tax_details to admin;
insert into contact_tax_details
select contact_id, business_name, vatin, address, city, province, postal_code, country_code
from contact;
update contact set trade_name = business_name where trade_name = '';
alter table contact
rename column trade_name to name
;
alter table contact
drop column business_name
, drop column vatin
, drop column address
, drop column city
, drop column province
, drop column postal_code
, drop column country_code
, add constraint name_not_empty check(length(trim(name)) > 1)
;
commit;