Add function to create new quotes

I had to add the quote_number_format to company, similar to how we do
with invoices.
This commit is contained in:
jordi fita mas 2023-06-07 14:14:48 +02:00
parent aeca90256c
commit a066726c2e
20 changed files with 648 additions and 1 deletions

89
deploy/add_quote.sql Normal file
View File

@ -0,0 +1,89 @@
-- Deploy numerus:add_quote to pg
-- requires: roles
-- requires: schema_numerus
-- requires: quote
-- requires: company
-- requires: currency
-- requires: parse_price
-- requires: new_quote_product
-- requires: tax
-- requires: quote_product
-- requires: quote_payment_method
-- requires: quote_contact
-- requires: quote_product_product
-- requires: quote_product_tax
-- requires: next_quote_number
-- requires: tag_name
begin;
set search_path to numerus, public;
create or replace function add_quote(company integer, quote_date date, contact_id integer, terms_and_conditions text, notes text, payment_method_id integer, tags tag_name[], products new_quote_product[]) returns uuid as
$$
declare
qid integer;
qslug uuid;
product new_quote_product;
ccode text;
qpid integer;
begin
insert into quote (company_id, quote_number, quote_date, terms_and_conditions, notes, tags, currency_code)
select company_id
, next_quote_number(add_quote.company, quote_date)
, quote_date
, terms_and_conditions
, notes
, tags
, currency_code
from company
where company.company_id = add_quote.company
returning quote_id, slug, currency_code
into qid, qslug, ccode;
if contact_id is not null then
insert into quote_contact (quote_id, contact_id)
values (qid, contact_id);
end if;
if payment_method_id is not null then
insert into quote_payment_method (quote_id, payment_method_id)
values (qid, payment_method_id);
end if;
foreach product in array products
loop
insert into quote_product (quote_id, name, description, price, quantity, discount_rate)
select qid
, product.name
, coalesce(product.description, '')
, parse_price(product.price, currency.decimal_digits)
, product.quantity
, product.discount_rate
from currency
where currency_code = ccode
returning quote_product_id
into qpid;
if product.product_id is not null then
insert into quote_product_product (quote_product_id, product_id)
values (qpid, product.product_id);
end if;
insert into quote_product_tax (quote_product_id, tax_id, tax_rate)
select qpid, tax_id, tax.rate
from tax
join unnest(product.tax) as ptax(tax_id) using (tax_id);
end loop;
return qslug;
end;
$$
language plpgsql
;
revoke execute on function add_quote(integer, date, integer, text, text, integer, tag_name[], new_quote_product[]) from public;
grant execute on function add_quote(integer, date, integer, text, text, integer, tag_name[], new_quote_product[]) to invoicer;
grant execute on function add_quote(integer, date, integer, text, text, integer, tag_name[], new_quote_product[]) to admin;
commit;

View File

@ -27,6 +27,7 @@ create table company (
country_code country_code not null references country,
currency_code currency_code not null references currency,
invoice_number_format text not null default '"FRA"YYYY0000',
quote_number_format text not null default '"PRE"YYYY0000',
legal_disclaimer text not null default '',
created_at timestamptz not null default current_timestamp
);

View File

@ -0,0 +1,19 @@
-- Deploy numerus:new_quote_product to pg
-- requires: schema_numerus
-- requires: discount_rate
begin;
set search_path to numerus, public;
create type new_quote_product as (
product_id integer,
name text,
description text,
price text,
quantity integer,
discount_rate discount_rate,
tax integer[]
);
commit;

View File

@ -0,0 +1,40 @@
-- Deploy numerus:next_quote_number to pg
-- requires: roles
-- requires: schema_numerus
-- requires: quote_number_counter
begin;
set search_path to numerus, public;
create or replace function next_quote_number(company integer, quote_date date) returns text
as
$$
declare
num integer;
quote_number text;
begin
insert into quote_number_counter (company_id, year, currval)
values (next_quote_number.company, date_part('year', quote_date), 1)
on conflict (company_id, year) do
update
set currval = quote_number_counter.currval + 1
returning currval
into num;
select to_char(quote_date, to_char(num, 'FM' || replace(quote_number_format, '"', '\""')))
into quote_number
from company
where company_id = next_quote_number.company;
return quote_number;
end;
$$
language plpgsql
;
revoke execute on function next_quote_number(integer, date) from public;
grant execute on function next_quote_number(integer, date) to invoicer;
grant execute on function next_quote_number(integer, date) to admin;
commit;

View File

@ -0,0 +1,33 @@
-- Deploy numerus:quote_number_counter to pg
-- requires: roles
-- requires: schema_numerus
-- requires: company
begin;
set search_path to numerus, public;
create table quote_number_counter (
company_id integer not null references company,
year integer not null constraint year_always_positive check(year > 0),
currval integer not null constraint counter_zero_or_positive check(currval >= 0),
primary key (company_id, year)
);
grant select, insert, update on table quote_number_counter to invoicer;
grant select, insert, update on table quote_number_counter to admin;
alter table quote_number_counter enable row level security;
create policy company_policy
on quote_number_counter
using (
exists(
select 1
from company_user
join user_profile using (user_id)
where company_user.company_id = quote_number_counter.company_id
)
);
commit;

7
revert/add_quote.sql Normal file
View File

@ -0,0 +1,7 @@
-- Revert numerus:add_quote from pg
begin;
drop function if exists numerus.add_quote(integer, date, integer, text, text, integer, numerus.tag_name[], numerus.new_quote_product[]);
commit;

View File

@ -0,0 +1,7 @@
-- Revert numerus:new_quote_product from pg
begin;
drop type if exists numerus.new_quote_product;
commit;

View File

@ -0,0 +1,7 @@
-- Revert numerus:next_quote_number from pg
begin;
drop function if exists numerus.next_quote_number(integer, date);
commit;

View File

@ -0,0 +1,7 @@
-- Revert numerus:quote_number_counter from pg
begin;
drop table if exists numerus.quote_number_counter;
commit;

View File

@ -86,3 +86,7 @@ quote_product [roles schema_numerus quote discount_rate] 2023-06-06T18:25:05Z jo
quote_product_product [roles schema_numerus quote_product product] 2023-06-06T18:38:26Z jordi fita mas <jordi@tandem.blog> # Add relation of quote products and registered products
quote_product_tax [roles schema_numerus quote_product tax tax_rate] 2023-06-06T18:46:33Z jordi fita mas <jordi@tandem.blog> # Add relation of quotation product tax
quote_payment_method [roles schema_numerus quote payment_method] 2023-06-06T18:59:12Z jordi fita mas <jordi@tandem.blog> # Add relation for the payment method of quotes
quote_number_counter [roles schema_numerus company] 2023-06-07T11:05:51Z jordi fita mas <jordi@tandem.blog> # Add relatin to keep a counter of quote numbers
next_quote_number [roles schema_numerus quote_number_counter] 2023-06-07T11:20:54Z jordi fita mas <jordi@tandem.blog> # Add function to retrieve the next quote number
new_quote_product [schema_numerus discount_rate] 2023-06-07T11:36:37Z jordi fita mas <jordi@tandem.blog> # Add type for passing products to new quotes
add_quote [roles schema_numerus quote company currency parse_price new_quote_product tax quote_product quote_payment_method quote_contact quote_product_product quote_product_tax next_quote_number tag_name] 2023-06-07T11:39:45Z jordi fita mas <jordi@tandem.blog> # Add function to create new quotes

161
test/add_quote.sql Normal file
View File

@ -0,0 +1,161 @@
-- Test add_quote
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(18);
set search_path to auth, numerus, public;
select has_function('numerus', 'add_quote', array ['integer', 'date', 'integer', 'text', 'text', 'integer', 'tag_name[]', 'new_quote_product[]']);
select function_lang_is('numerus', 'add_quote', array ['integer', 'date', 'integer', 'text', 'text', 'integer', 'tag_name[]', 'new_quote_product[]'], 'plpgsql');
select function_returns('numerus', 'add_quote', array ['integer', 'date', 'integer', 'text', 'text', 'integer', 'tag_name[]', 'new_quote_product[]'], 'uuid');
select isnt_definer('numerus', 'add_quote', array ['integer', 'date', 'integer', 'text', 'text', 'integer', 'tag_name[]', 'new_quote_product[]']);
select volatility_is('numerus', 'add_quote', array ['integer', 'date', 'integer', 'text', 'text', 'integer', 'tag_name[]', 'new_quote_product[]'], 'volatile');
select function_privs_are('numerus', 'add_quote', array ['integer', 'date', 'integer', 'text', 'text', 'integer', 'tag_name[]', 'new_quote_product[]'], 'guest', array []::text[]);
select function_privs_are('numerus', 'add_quote', array ['integer', 'date', 'integer', 'text', 'text', 'integer', 'tag_name[]', 'new_quote_product[]'], 'invoicer', array ['EXECUTE']);
select function_privs_are('numerus', 'add_quote', array ['integer', 'date', 'integer', 'text', 'text', 'integer', 'tag_name[]', 'new_quote_product[]'], 'admin', array ['EXECUTE']);
select function_privs_are('numerus', 'add_quote', array ['integer', 'date', 'integer', 'text', 'text', 'integer', 'tag_name[]', 'new_quote_product[]'], 'authenticator', array []::text[]);
set client_min_messages to warning;
truncate quote_number_counter cascade;
truncate quote_product_tax cascade;
truncate quote_product cascade;
truncate quote_contact cascade;
truncate quote_payment_method cascade;
truncate quote cascade;
truncate contact cascade;
truncate product cascade;
truncate tax cascade;
truncate tax_class cascade;
truncate payment_method cascade;
truncate company cascade;
reset client_min_messages;
set constraints "company_default_payment_method_id_fkey" deferred;
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code, quote_number_format, default_payment_method_id)
values (1, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', '"Q"YYYY0000', 111)
, (2, 'Company 4', 'XX234', '', '666-666-666', 'b@b', '', '', '', '', '', 'FR', 'USD', '"QUO"000-YY', 222)
;
insert into payment_method (payment_method_id, company_id, name, instructions)
values (111, 1, 'cash', 'cash')
, (222, 2, 'cash', 'cash')
;
set constraints "company_default_payment_method_id_fkey" immediate;
insert into quote_number_counter (company_id, year, currval)
values (1, 2023, '5')
, (2, 2023, '55')
;
insert into tax_class (tax_class_id, company_id, name)
values (11, 1, 'tax')
, (22, 2, 'tax')
;
insert into tax (tax_id, company_id, tax_class_id, name, rate)
values (3, 1, 11, 'IRPF -15 %', -0.15)
, (4, 1, 11, 'IVA 21 %', 0.21)
, (5, 2, 22, 'IRPF -7 %', -0.07)
, (6, 2, 22, 'IVA 10 %', 0.10)
;
insert into product (product_id, company_id, name, price)
values ( 7, 1, 'Product 2.1', 1212)
, ( 8, 1, 'Product 2.2', 2424)
, ( 9, 2, 'Product 4.1', 4848)
, (10, 2, 'Product 4.2', 9696)
, (11, 2, 'Product 4.3', 1010)
;
insert into contact (contact_id, company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code)
values (12, 1, 'Contact 2.1', 'XX555', '', '777-777-777', 'c@c', '', '', '', '', '', 'ES')
, (13, 1, 'Contact 2.2', 'XX666', '', '888-888-888', 'd@d', '', '', '', '', '', 'ES')
, (14, 2, 'Contact 4.1', 'XX777', '', '999-999-999', 'e@e', '', '', '', '', '', 'ES')
, (15, 2, 'Contact 4.2', 'XX888', '', '000-000-000', 'f@f', '', '', '', '', '', 'ES')
;
select lives_ok(
$$ select add_quote(1, '2023-02-15', 12, 'No need for advance payment', 'Notes 1', null, '{tag1,tag2}','{"(7,Product 1,Description 1,12.24,2,0.0,{4})"}') $$,
'Should be able to insert an quote for the first company with a product'
);
select lives_ok(
$$ select add_quote(1, '2023-02-16', null, 'Pay 10% in advance', 'Notes 2', 111, '{}', '{"(7,Product 1 bis,Description 1 bis,33.33,1,0.50,\"{4,3}\")","(8,Product 2,Description 2,24.00,3,0.75,{})"}') $$,
'Should be able to insert a second quote for the first company with two product'
);
select lives_ok(
$$ select add_quote(2, '2023-02-14', 15, 'Pay half in advance', 'Notes 3', 222, '{tag3}','{"(11,Product 4.3,,11.11,1,0.0,{6})","(,Product 4.4,Description 4.4,22.22,3,0.05,{})"}') $$,
'Should be able to insert an quote for the second company with a product'
);
select bag_eq(
$$ select company_id, quote_number, quote_date, quote_status, terms_and_conditions, notes, currency_code, tags, created_at from quote $$,
$$ values (1, 'Q20230006', '2023-02-15'::date, 'created', 'No need for advance payment', 'Notes 1', 'EUR', '{tag1,tag2}'::tag_name[], current_timestamp)
, (1, 'Q20230007', '2023-02-16'::date, 'created', 'Pay 10% in advance', 'Notes 2', 'EUR', '{}'::tag_name[], current_timestamp)
, (2, 'QUO056-23', '2023-02-14'::date, 'created', 'Pay half in advance', 'Notes 3', 'USD', '{tag3}'::tag_name[], current_timestamp)
$$,
'Should have created all quotes'
);
select bag_eq(
$$ select quote_number, payment_method_id from quote_payment_method join quote using (quote_id) $$,
$$ values ('Q20230007', 111)
, ('QUO056-23', 222)
$$,
'Should have created all payment methods'
);
select bag_eq(
$$ select quote_number, contact_id from quote_contact join quote using (quote_id) $$,
$$ values ('Q20230006', 12)
, ('QUO056-23', 15)
$$,
'Should have created all contacts'
);
select bag_eq(
$$ select quote_number, name, description, price, quantity, discount_rate from quote_product join quote using (quote_id) $$,
$$ values ('Q20230006', 'Product 1', 'Description 1', 1224, 2, 0.00)
, ('Q20230007', 'Product 1 bis', 'Description 1 bis', 3333, 1, 0.50)
, ('Q20230007', 'Product 2', 'Description 2', 2400, 3, 0.75)
, ('QUO056-23', 'Product 4.3', '', 1111, 1, 0.0)
, ('QUO056-23', 'Product 4.4', 'Description 4.4', 2222, 3, 0.05)
$$,
'Should have created all quote products'
);
select bag_eq(
$$ select quote_number, product_id, name from quote_product left join quote_product_product using (quote_product_id) join quote using (quote_id) $$,
$$ values ('Q20230006', 7, 'Product 1')
, ('Q20230007', 7, 'Product 1 bis')
, ('Q20230007', 8, 'Product 2')
, ('QUO056-23', 11, 'Product 4.3')
, ('QUO056-23', NULL, 'Product 4.4')
$$,
'Should have linked all quote products'
);
select bag_eq(
$$ select quote_number, name, tax_id, tax_rate from quote_product_tax join quote_product using (quote_product_id) join quote using (quote_id) $$,
$$ values ('Q20230006', 'Product 1', 4, 0.21)
, ('Q20230007', 'Product 1 bis', 4, 0.21)
, ('Q20230007', 'Product 1 bis', 3, -0.15)
, ('QUO056-23', 'Product 4.3', 6, 0.10)
$$,
'Should have created all quote product taxes'
);
select *
from finish();
rollback;

View File

@ -5,7 +5,7 @@ reset client_min_messages;
begin;
select plan(96);
select plan(101);
set search_path to numerus, auth, public;
@ -100,6 +100,12 @@ select col_not_null('company', 'invoice_number_format');
select col_has_default('company', 'invoice_number_format');
select col_default_is('company', 'invoice_number_format', '"FRA"YYYY0000');
select has_column('company', 'quote_number_format');
select col_type_is('company', 'quote_number_format', 'text');
select col_not_null('company', 'quote_number_format');
select col_has_default('company', 'quote_number_format');
select col_default_is('company', 'quote_number_format', '"PRE"YYYY0000');
select has_column('company', 'legal_disclaimer');
select col_type_is('company', 'legal_disclaimer', 'text');
select col_not_null('company', 'legal_disclaimer');

View File

@ -0,0 +1,25 @@
-- Test new_quote_product
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(9);
set search_path to numerus, public;
select has_composite('numerus', 'new_quote_product', 'Composite type numerus.new_quote_product should exist');
select columns_are('numerus', 'new_quote_product', array['product_id', 'name', 'description', 'price', 'quantity', 'discount_rate', 'tax']);
select col_type_is('numerus'::name, 'new_quote_product'::name, 'product_id'::name, 'integer');
select col_type_is('numerus'::name, 'new_quote_product'::name, 'name'::name, 'text');
select col_type_is('numerus'::name, 'new_quote_product'::name, 'description'::name, 'text');
select col_type_is('numerus'::name, 'new_quote_product'::name, 'price'::name, 'text');
select col_type_is('numerus'::name, 'new_quote_product'::name, 'quantity'::name, 'integer');
select col_type_is('numerus'::name, 'new_quote_product'::name, 'discount_rate'::name, 'discount_rate');
select col_type_is('numerus'::name, 'new_quote_product'::name, 'tax'::name, 'integer[]');
select *
from finish();
rollback;

View File

@ -0,0 +1,60 @@
-- Test next_quote_number
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(17);
set search_path to numerus, public;
select has_function('numerus', 'next_quote_number', array ['integer', 'date']);
select function_lang_is('numerus', 'next_quote_number', array ['integer', 'date'], 'plpgsql');
select function_returns('numerus', 'next_quote_number', array ['integer', 'date'], 'text');
select isnt_definer('numerus', 'next_quote_number', array ['integer', 'date']);
select volatility_is('numerus', 'next_quote_number', array ['integer', 'date'], 'volatile');
select function_privs_are('numerus', 'next_quote_number', array ['integer', 'date'], 'guest', array []::text[]);
select function_privs_are('numerus', 'next_quote_number', array ['integer', 'date'], 'invoicer', array ['EXECUTE']);
select function_privs_are('numerus', 'next_quote_number', array ['integer', 'date'], 'admin', array ['EXECUTE']);
select function_privs_are('numerus', 'next_quote_number', array ['integer', 'date'], 'authenticator', array []::text[]);
set client_min_messages to warning;
truncate quote_number_counter cascade;
truncate payment_method cascade;
truncate company cascade;
reset client_min_messages;
set constraints "company_default_payment_method_id_fkey" deferred;
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code, quote_number_format, default_payment_method_id)
values (1, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', '"Q"YYYY0000', 111)
, (2, 'Company 4', 'XX234', '', '666-666-666', 'b@b', '', '', '', '', '', 'FR', 'USD', '"QUO"000-YY', 222)
;
insert into payment_method (payment_method_id, company_id, name, instructions)
values (111, 1, 'cash', 'cash')
, (222, 2, 'cash', 'cash')
;
set constraints "company_default_payment_method_id_fkey" immediate;
insert into quote_number_counter (company_id, year, currval)
values (1, 2010, 5)
, (2, 2010, 6)
;
select is( next_quote_number(1, '2010-12-25'), 'Q20100006' );
select is( next_quote_number(2, '2010-12-25'), 'QUO007-10' );
select is( next_quote_number(1, '2010-10-17'), 'Q20100007' );
select is( next_quote_number(2, '2010-10-17'), 'QUO008-10' );
select is( next_quote_number(1, '2011-12-25'), 'Q20110001' );
select is( next_quote_number(2, '2012-12-25'), 'QUO001-12' );
select is( next_quote_number(1, '2011-12-25'), 'Q20110002' );
select is( next_quote_number(2, '2012-12-25'), 'QUO002-12' );
select *
from finish();
rollback;

View File

@ -0,0 +1,145 @@
-- Test quote_number_counter
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(28);
set search_path to numerus, auth, public;
select has_table('quote_number_counter');
select has_pk('quote_number_counter' );
select col_is_pk('quote_number_counter', array['company_id', 'year']);
select table_privs_are('quote_number_counter', 'guest', array []::text[]);
select table_privs_are('quote_number_counter', 'invoicer', array ['SELECT', 'INSERT', 'UPDATE']);
select table_privs_are('quote_number_counter', 'admin', array ['SELECT', 'INSERT', 'UPDATE']);
select table_privs_are('quote_number_counter', 'authenticator', array []::text[]);
select has_column('quote_number_counter', 'company_id');
select col_is_fk('quote_number_counter', 'company_id');
select fk_ok('quote_number_counter', 'company_id', 'company', 'company_id');
select col_type_is('quote_number_counter', 'company_id', 'integer');
select col_not_null('quote_number_counter', 'company_id');
select col_hasnt_default('quote_number_counter', 'company_id');
select has_column('quote_number_counter', 'year');
select col_type_is('quote_number_counter', 'year', 'integer');
select col_not_null('quote_number_counter', 'year');
select col_hasnt_default('quote_number_counter', 'year');
select has_column('quote_number_counter', 'currval');
select col_type_is('quote_number_counter', 'currval', 'integer');
select col_not_null('quote_number_counter', 'currval');
select col_hasnt_default('quote_number_counter', 'currval');
set client_min_messages to warning;
truncate quote_number_counter cascade;
truncate company_user cascade;
truncate payment_method cascade;
truncate company cascade;
truncate auth."user" cascade;
reset client_min_messages;
insert into auth."user" (user_id, email, name, password, role, cookie, cookie_expires_at)
values (1, 'demo@tandem.blog', 'Demo', 'test', 'invoicer', '44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e', current_timestamp + interval '1 month')
, (5, 'admin@tandem.blog', 'Demo', 'test', 'admin', '12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524', current_timestamp + interval '1 month')
;
set constraints "company_default_payment_method_id_fkey" deferred;
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code, default_payment_method_id)
values (2, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR', 222)
, (4, 'Company 4', 'XX234', '', '666-666-666', 'b@b', '', '', '', '', '', 'FR', 'USD', 444)
;
insert into payment_method (payment_method_id, company_id, name, instructions)
values (444, 4, 'cash', 'cash')
, (222, 2, 'cash', 'cash')
;
set constraints "company_default_payment_method_id_fkey" immediate;
insert into company_user (company_id, user_id)
values (2, 1)
, (4, 5)
;
insert into quote_number_counter (company_id, year, currval)
values (2, 2010, 6)
, (2, 2011, 8)
, (4, 2010, 8)
, (4, 2012, 10)
;
prepare counter_data as
select company_id, year, currval
from quote_number_counter
;
set role invoicer;
select is_empty('counter_data', 'Should show no data when cookie is not set yet');
reset role;
select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/demo@tandem.blog');
select bag_eq(
'counter_data',
$$ values (2, 2010, 6)
, (2, 2011, 8)
$$,
'Should only list quote numbers of the companies where demo@tandem.blog is user of'
);
reset role;
select set_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/admin@tandem.blog');
select bag_eq(
'counter_data',
$$ values (4, 2010, 8)
, (4, 2012, 10)
$$,
'Should only list quote numbers of the companies where admin@tandem.blog is user of'
);
reset role;
select set_cookie('not-a-cookie');
select throws_ok(
'counter_data',
'42501', 'permission denied for table quote_number_counter',
'Should not allow select to guest users'
);
reset role;
select lives_ok( $$
insert into quote_number_counter (company_id, year, currval)
values (2, 2008, 0)
$$,
'Should allow starting a counter from zero'
);
select throws_ok( $$
insert into quote_number_counter (company_id, year, currval)
values (2, 2009, -1)
$$,
'23514', 'new row for relation "quote_number_counter" violates check constraint "counter_zero_or_positive"',
'Should not allow starting a counter from a negative value'
);
select throws_ok( $$
insert into quote_number_counter (company_id, year, currval)
values (2, -2008, 1)
$$,
'23514', 'new row for relation "quote_number_counter" violates check constraint "year_always_positive"',
'Should not allow counters for quotes issued before Jesus Christ was born'
);
select *
from finish();
rollback;

7
verify/add_quote.sql Normal file
View File

@ -0,0 +1,7 @@
-- Verify numerus:add_quote on pg
begin;
select has_function_privilege('numerus.add_quote(integer, date, integer, text, text, integer, numerus.tag_name[], numerus.new_quote_product[])', 'execute');
rollback;

View File

@ -17,6 +17,7 @@ select company_id
, country_code
, currency_code
, invoice_number_format
, quote_number_format
, legal_disclaimer
, created_at
from numerus.company

View File

@ -0,0 +1,7 @@
-- Verify numerus:new_quote_product on pg
begin;
select pg_catalog.has_type_privilege('numerus.new_quote_product', 'usage');
rollback;

View File

@ -0,0 +1,7 @@
-- Verify numerus:next_quote_number on pg
begin;
select has_function_privilege('numerus.next_quote_number(integer, date)', 'execute');
rollback;

View File

@ -0,0 +1,14 @@
-- Verify numerus:quote_number_counter on pg
begin;
select company_id
, year
, currval
from numerus.quote_number_counter
where false;
select 1 / count(*) from pg_class where oid = 'numerus.quote_number_counter'::regclass and relrowsecurity;
select 1 / count(*) from pg_policy where polname = 'company_policy' and polrelid = 'numerus.quote_number_counter'::regclass;
rollback;