Add PL/pgSQL functions to add and edit products
I am going to add similar functions for invoices, as i will need to add the taxes for their products and their own taxes, thus the Go code will begin to be “too much work” and i feel better if that is in PL/pgSQL. If i have these functions for invoices, there is no point on having to do almost the same work, albeit less, for products.
This commit is contained in:
parent
989c1717e5
commit
13fa1d6b89
|
@ -0,0 +1,39 @@
|
||||||
|
-- Deploy numerus:add_product to pg
|
||||||
|
-- requires: schema_numerus
|
||||||
|
-- requires: product
|
||||||
|
-- requires: product_tax
|
||||||
|
-- requires: parse_price
|
||||||
|
-- requires: company
|
||||||
|
-- requires: currency
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
set search_path to numerus, public;
|
||||||
|
|
||||||
|
create or replace function add_product(company_id integer, name text, description text, price text, taxes integer[]) returns uuid
|
||||||
|
as $$
|
||||||
|
declare
|
||||||
|
pid integer;
|
||||||
|
pslug uuid;
|
||||||
|
begin
|
||||||
|
insert into product (company_id, name, description, price)
|
||||||
|
select add_product.company_id, add_product.name, add_product.description, parse_price(add_product.price, decimal_digits)
|
||||||
|
from company
|
||||||
|
join currency using (currency_code)
|
||||||
|
where company.company_id = add_product.company_id
|
||||||
|
returning product_id, slug
|
||||||
|
into pid, pslug;
|
||||||
|
|
||||||
|
insert into product_tax (product_id, tax_id)
|
||||||
|
select pid, tax_id
|
||||||
|
from unnest(taxes) as tax(tax_id);
|
||||||
|
|
||||||
|
return pslug;
|
||||||
|
end;
|
||||||
|
$$ language plpgsql;
|
||||||
|
|
||||||
|
revoke execute on function add_product(integer, text, text, text, integer[]) from public;
|
||||||
|
grant execute on function add_product(integer, text, text, text, integer[]) to invoicer;
|
||||||
|
grant execute on function add_product(integer, text, text, text, integer[]) to admin;
|
||||||
|
|
||||||
|
commit;
|
|
@ -0,0 +1,47 @@
|
||||||
|
-- Deploy numerus:edit_product to pg
|
||||||
|
-- requires: schema_numerus
|
||||||
|
-- requires: product
|
||||||
|
-- requires: product_tax
|
||||||
|
-- requires: parse_price
|
||||||
|
-- requires: company
|
||||||
|
-- requires: currency
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
set search_path to numerus, public;
|
||||||
|
|
||||||
|
create or replace function edit_product(slug uuid, name text, description text, price text, taxes integer[]) returns boolean
|
||||||
|
as $$
|
||||||
|
declare
|
||||||
|
pid integer;
|
||||||
|
begin
|
||||||
|
update product
|
||||||
|
set name = edit_product.name
|
||||||
|
, description = edit_product.description
|
||||||
|
, price = parse_price(edit_product.price, decimal_digits)
|
||||||
|
from company
|
||||||
|
join currency using (currency_code)
|
||||||
|
where product.company_id = company.company_id
|
||||||
|
and product.slug = edit_product.slug
|
||||||
|
returning product_id
|
||||||
|
into pid;
|
||||||
|
|
||||||
|
if pid is null then
|
||||||
|
return false;
|
||||||
|
end if;
|
||||||
|
|
||||||
|
delete from product_tax where product_id = pid;
|
||||||
|
|
||||||
|
insert into product_tax(product_id, tax_id)
|
||||||
|
select pid, tax_id
|
||||||
|
from unnest(taxes) as tax(tax_id);
|
||||||
|
|
||||||
|
return true;
|
||||||
|
end;
|
||||||
|
$$ language plpgsql;
|
||||||
|
|
||||||
|
revoke execute on function edit_product(uuid, text, text, text, integer[]) from public;
|
||||||
|
grant execute on function edit_product(uuid, text, text, text, integer[]) to invoicer;
|
||||||
|
grant execute on function edit_product(uuid, text, text, text, integer[]) to admin;
|
||||||
|
|
||||||
|
commit;
|
|
@ -90,6 +90,14 @@ func (c *Conn) MustGetText(ctx context.Context, def string, sql string, args ...
|
||||||
return result
|
return result
|
||||||
}
|
}
|
||||||
|
|
||||||
|
func (c *Conn) MustGetBool(ctx context.Context, sql string, args ...interface{}) bool {
|
||||||
|
var result bool
|
||||||
|
if err := c.Conn.QueryRow(ctx, sql, args...).Scan(&result); err != nil {
|
||||||
|
panic(err)
|
||||||
|
}
|
||||||
|
return result
|
||||||
|
}
|
||||||
|
|
||||||
func (c *Conn) MustExec(ctx context.Context, sql string, args ...interface{}) {
|
func (c *Conn) MustExec(ctx context.Context, sql string, args ...interface{}) {
|
||||||
if _, err := c.Conn.Exec(ctx, sql, args...); err != nil {
|
if _, err := c.Conn.Exec(ctx, sql, args...); err != nil {
|
||||||
panic(err)
|
panic(err)
|
||||||
|
|
|
@ -8,6 +8,7 @@ import (
|
||||||
"html/template"
|
"html/template"
|
||||||
"math"
|
"math"
|
||||||
"net/http"
|
"net/http"
|
||||||
|
"strconv"
|
||||||
)
|
)
|
||||||
|
|
||||||
type ProductEntry struct {
|
type ProductEntry struct {
|
||||||
|
@ -89,27 +90,31 @@ func HandleAddProduct(w http.ResponseWriter, r *http.Request, _ httprouter.Param
|
||||||
mustRenderNewProductForm(w, r, form)
|
mustRenderNewProductForm(w, r, form)
|
||||||
return
|
return
|
||||||
}
|
}
|
||||||
tx := conn.MustBegin(r.Context())
|
taxes := mustSliceAtoi(form.Tax.Selected)
|
||||||
productId := tx.MustGetInteger(r.Context(), "insert into product (company_id, name, description, price) select company_id, $2, $3, parse_price($4, decimal_digits) from company join currency using (currency_code) where company_id = $1 returning product_id", company.Id, form.Name, form.Description, form.Price)
|
conn.MustExec(r.Context(), "select add_product($1, $2, $3, $4, $5)", company.Id, form.Name, form.Description, form.Price, taxes)
|
||||||
if len(form.Tax.Selected) > 0 {
|
|
||||||
batch := &pgx.Batch{}
|
|
||||||
for _, tax := range form.Tax.Selected {
|
|
||||||
batch.Queue("insert into product_tax(product_id, tax_id) values ($1, $2)", productId, tax)
|
|
||||||
}
|
|
||||||
br := tx.SendBatch(r.Context(), batch)
|
|
||||||
for range form.Tax.Selected {
|
|
||||||
if _, err := br.Exec(); err != nil {
|
|
||||||
panic(err)
|
|
||||||
}
|
|
||||||
}
|
|
||||||
if err := br.Close(); err != nil {
|
|
||||||
panic(err)
|
|
||||||
}
|
|
||||||
}
|
|
||||||
tx.MustCommit(r.Context())
|
|
||||||
http.Redirect(w, r, companyURI(company, "/products"), http.StatusSeeOther)
|
http.Redirect(w, r, companyURI(company, "/products"), http.StatusSeeOther)
|
||||||
}
|
}
|
||||||
|
|
||||||
|
func sliceAtoi(s []string) ([]int, error) {
|
||||||
|
i := []int{}
|
||||||
|
for _, vs := range s {
|
||||||
|
vi, err := strconv.Atoi(vs)
|
||||||
|
if err != nil {
|
||||||
|
return i, err
|
||||||
|
}
|
||||||
|
i = append(i, vi)
|
||||||
|
}
|
||||||
|
return i, nil
|
||||||
|
}
|
||||||
|
|
||||||
|
func mustSliceAtoi(s []string) []int {
|
||||||
|
i, err := sliceAtoi(s)
|
||||||
|
if err != nil {
|
||||||
|
panic(err)
|
||||||
|
}
|
||||||
|
return i
|
||||||
|
}
|
||||||
|
|
||||||
func HandleUpdateProduct(w http.ResponseWriter, r *http.Request, params httprouter.Params) {
|
func HandleUpdateProduct(w http.ResponseWriter, r *http.Request, params httprouter.Params) {
|
||||||
conn := getConn(r)
|
conn := getConn(r)
|
||||||
locale := getLocale(r)
|
locale := getLocale(r)
|
||||||
|
@ -128,28 +133,11 @@ func HandleUpdateProduct(w http.ResponseWriter, r *http.Request, params httprout
|
||||||
mustRenderEditProductForm(w, r, form)
|
mustRenderEditProductForm(w, r, form)
|
||||||
return
|
return
|
||||||
}
|
}
|
||||||
tx := conn.MustBegin(r.Context())
|
|
||||||
slug := params[0].Value
|
slug := params[0].Value
|
||||||
productId := tx.MustGetIntegerOrDefault(r.Context(), 0, "update product set name = $1, description = $2, price = parse_price($3, decimal_digits) from company join currency using (currency_code) where product.company_id = company.company_id and product.slug = $4 returning product_id", form.Name, form.Description, form.Price, slug)
|
taxes := mustSliceAtoi(form.Tax.Selected)
|
||||||
if productId == 0 {
|
if ok := conn.MustGetBool(r.Context(), "select edit_product($1, $2, $3, $4, $5)", slug, form.Name, form.Description, form.Price, taxes); !ok {
|
||||||
tx.MustRollback(r.Context())
|
|
||||||
http.NotFound(w, r)
|
http.NotFound(w, r)
|
||||||
}
|
}
|
||||||
batch := &pgx.Batch{}
|
|
||||||
batch.Queue("delete from product_tax where product_id = $1", productId)
|
|
||||||
for _, tax := range form.Tax.Selected {
|
|
||||||
batch.Queue("insert into product_tax(product_id, tax_id) values ($1, $2)", productId, tax)
|
|
||||||
}
|
|
||||||
br := tx.SendBatch(r.Context(), batch)
|
|
||||||
for i := 0; i < batch.Len(); i++ {
|
|
||||||
if _, err := br.Exec(); err != nil {
|
|
||||||
panic(err)
|
|
||||||
}
|
|
||||||
}
|
|
||||||
if err := br.Close(); err != nil {
|
|
||||||
panic(err)
|
|
||||||
}
|
|
||||||
tx.MustCommit(r.Context())
|
|
||||||
http.Redirect(w, r, companyURI(company, "/products/"+slug), http.StatusSeeOther)
|
http.Redirect(w, r, companyURI(company, "/products/"+slug), http.StatusSeeOther)
|
||||||
}
|
}
|
||||||
|
|
||||||
|
|
|
@ -0,0 +1,7 @@
|
||||||
|
-- Revert numerus:add_product from pg
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
drop function if exists numerus.add_product(integer, text, text, text, integer[]);
|
||||||
|
|
||||||
|
commit;
|
|
@ -0,0 +1,7 @@
|
||||||
|
-- Revert numerus:edit_product from pg
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
drop function if exists numerus.edit_product(uuid, text, text, text, integer[]);
|
||||||
|
|
||||||
|
commit;
|
|
@ -49,3 +49,5 @@ product_tax [schema_numerus product tax] 2023-02-08T11:36:49Z jordi fita mas <jo
|
||||||
invoice [schema_numerus company contact invoice_status currency] 2023-02-09T09:52:21Z jordi fita mas <jordi@tandem.blog> # Add relation for invoice
|
invoice [schema_numerus company contact invoice_status currency] 2023-02-09T09:52:21Z jordi fita mas <jordi@tandem.blog> # Add relation for invoice
|
||||||
discount_rate [schema_numerus] 2023-02-10T17:22:40Z jordi fita mas <jordi@tandem.blog> # Add domain for discount rates
|
discount_rate [schema_numerus] 2023-02-10T17:22:40Z jordi fita mas <jordi@tandem.blog> # Add domain for discount rates
|
||||||
invoice_product [schema_numerus invoice discount_rate] 2023-02-10T17:07:08Z jordi fita mas <jordi@tandem.blog> # Add relation for invoice product
|
invoice_product [schema_numerus invoice discount_rate] 2023-02-10T17:07:08Z jordi fita mas <jordi@tandem.blog> # Add relation for invoice product
|
||||||
|
add_product [schema_numerus product product_tax parse_price company currency] 2023-02-14T10:32:18Z jordi fita mas <jordi@tandem.blog> # Add function to add new products
|
||||||
|
edit_product [schema_numerus product product_tax parse_price company currency] 2023-02-14T11:06:03Z jordi fita mas <jordi@tandem.blog> # Add function to edit products
|
||||||
|
|
|
@ -0,0 +1,80 @@
|
||||||
|
-- Test add_product
|
||||||
|
set client_min_messages to warning;
|
||||||
|
create extension if not exists pgtap;
|
||||||
|
reset client_min_messages;
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
select plan(14);
|
||||||
|
|
||||||
|
set search_path to auth, numerus, public;
|
||||||
|
|
||||||
|
select has_function('numerus', 'add_product', array ['integer', 'text', 'text', 'text', 'integer[]']);
|
||||||
|
select function_lang_is('numerus', 'add_product', array ['integer', 'text', 'text', 'text', 'integer[]'], 'plpgsql');
|
||||||
|
select function_returns('numerus', 'add_product', array ['integer', 'text', 'text', 'text', 'integer[]'], 'uuid');
|
||||||
|
select isnt_definer('numerus', 'add_product', array ['integer', 'text', 'text', 'text', 'integer[]']);
|
||||||
|
select volatility_is('numerus', 'add_product', array ['integer', 'text', 'text', 'text', 'integer[]'], 'volatile');
|
||||||
|
select function_privs_are('numerus', 'add_product', array ['integer', 'text', 'text', 'text', 'integer[]'], 'guest', array []::text[]);
|
||||||
|
select function_privs_are('numerus', 'add_product', array ['integer', 'text', 'text', 'text', 'integer[]'], 'invoicer', array ['EXECUTE']);
|
||||||
|
select function_privs_are('numerus', 'add_product', array ['integer', 'text', 'text', 'text', 'integer[]'], 'admin', array ['EXECUTE']);
|
||||||
|
select function_privs_are('numerus', 'add_product', array ['integer', 'text', 'text', 'text', 'integer[]'], 'authenticator', array []::text[]);
|
||||||
|
|
||||||
|
|
||||||
|
set client_min_messages to warning;
|
||||||
|
truncate product_tax cascade;
|
||||||
|
truncate product cascade;
|
||||||
|
truncate tax cascade;
|
||||||
|
truncate company cascade;
|
||||||
|
reset client_min_messages;
|
||||||
|
|
||||||
|
|
||||||
|
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code)
|
||||||
|
values (1, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR')
|
||||||
|
, (2, 'Company 4', 'XX234', '', '666-666-666', 'b@b', '', '', '', '', '', 'FR', 'USD')
|
||||||
|
;
|
||||||
|
|
||||||
|
insert into tax (tax_id, company_id, name, rate)
|
||||||
|
values (3, 1, 'IRPF -15 %', -0.15)
|
||||||
|
, (4, 1, 'IVA 21 %', 0.21)
|
||||||
|
, (5, 2, 'IRPF -7 %', -0.07)
|
||||||
|
, (6, 2, 'IVA 10 %', 0.10)
|
||||||
|
;
|
||||||
|
|
||||||
|
|
||||||
|
select lives_ok(
|
||||||
|
$$ select add_product(1, 'Product 1', 'Description 1', '12.12', array[3, 4]) $$,
|
||||||
|
'Should be able to add product to first company'
|
||||||
|
);
|
||||||
|
|
||||||
|
select lives_ok(
|
||||||
|
$$ select add_product(2, 'Product 2', 'Description 2', '24.24', array[6]) $$,
|
||||||
|
'Should be able to add product to second company'
|
||||||
|
);
|
||||||
|
|
||||||
|
select lives_ok(
|
||||||
|
$$ select add_product(2, 'Product 3', 'Description 3', '36.36', array[]::integer[]) $$,
|
||||||
|
'Should be able to add product without taxes'
|
||||||
|
);
|
||||||
|
|
||||||
|
select bag_eq(
|
||||||
|
$$ select company_id, name, description, price, created_at from product $$,
|
||||||
|
$$ values (1, 'Product 1', 'Description 1', 1212, current_timestamp)
|
||||||
|
, (2, 'Product 2', 'Description 2', 2424, current_timestamp)
|
||||||
|
, (2, 'Product 3', 'Description 3', 3636, current_timestamp)
|
||||||
|
$$,
|
||||||
|
'Should have added all three products'
|
||||||
|
);
|
||||||
|
|
||||||
|
select bag_eq(
|
||||||
|
$$ select tax_id, name from product_tax join product using (product_id) $$,
|
||||||
|
$$ values (3, 'Product 1')
|
||||||
|
, (4, 'Product 1')
|
||||||
|
, (6, 'Product 2')
|
||||||
|
$$,
|
||||||
|
'Should have added the taxes for the products we told to'
|
||||||
|
);
|
||||||
|
|
||||||
|
select *
|
||||||
|
from finish();
|
||||||
|
|
||||||
|
rollback;
|
|
@ -0,0 +1,101 @@
|
||||||
|
-- Test edit_product
|
||||||
|
set client_min_messages to warning;
|
||||||
|
create extension if not exists pgtap;
|
||||||
|
reset client_min_messages;
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
select plan(15);
|
||||||
|
|
||||||
|
set search_path to auth, numerus, public;
|
||||||
|
|
||||||
|
select has_function('numerus', 'edit_product', array ['uuid', 'text', 'text', 'text', 'integer[]']);
|
||||||
|
select function_lang_is('numerus', 'edit_product', array ['uuid', 'text', 'text', 'text', 'integer[]'], 'plpgsql');
|
||||||
|
select function_returns('numerus', 'edit_product', array ['uuid', 'text', 'text', 'text', 'integer[]'], 'boolean');
|
||||||
|
select isnt_definer('numerus', 'edit_product', array ['uuid', 'text', 'text', 'text', 'integer[]']);
|
||||||
|
select volatility_is('numerus', 'edit_product', array ['uuid', 'text', 'text', 'text', 'integer[]'], 'volatile');
|
||||||
|
select function_privs_are('numerus', 'edit_product', array ['uuid', 'text', 'text', 'text', 'integer[]'], 'guest', array []::text[]);
|
||||||
|
select function_privs_are('numerus', 'edit_product', array ['uuid', 'text', 'text', 'text', 'integer[]'], 'invoicer', array ['EXECUTE']);
|
||||||
|
select function_privs_are('numerus', 'edit_product', array ['uuid', 'text', 'text', 'text', 'integer[]'], 'admin', array ['EXECUTE']);
|
||||||
|
select function_privs_are('numerus', 'edit_product', array ['uuid', 'text', 'text', 'text', 'integer[]'], 'authenticator', array []::text[]);
|
||||||
|
|
||||||
|
|
||||||
|
set client_min_messages to warning;
|
||||||
|
truncate product_tax cascade;
|
||||||
|
truncate product cascade;
|
||||||
|
truncate tax cascade;
|
||||||
|
truncate company cascade;
|
||||||
|
reset client_min_messages;
|
||||||
|
|
||||||
|
|
||||||
|
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, country_code, currency_code)
|
||||||
|
values (1, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', 'ES', 'EUR')
|
||||||
|
, (2, 'Company 4', 'XX234', '', '666-666-666', 'b@b', '', '', '', '', '', 'FR', 'USD')
|
||||||
|
;
|
||||||
|
|
||||||
|
insert into tax (tax_id, company_id, name, rate)
|
||||||
|
values (3, 1, 'IRPF -15 %', -0.15)
|
||||||
|
, (4, 1, 'IVA 21 %', 0.21)
|
||||||
|
, (5, 2, 'IRPF -7 %', -0.07)
|
||||||
|
, (6, 2, 'IVA 10 %', 0.10)
|
||||||
|
;
|
||||||
|
|
||||||
|
insert into product (product_id, company_id, slug, name, description, price)
|
||||||
|
values (7, 1, 'd2300404-bd23-48b3-8e2b-2bbf86dc7bd6', 'Product 01', 'Description01', 1200)
|
||||||
|
, (8, 2, '2f085b8b-da90-41fe-b8cf-6ba8d94cfa38', 'Product 02', 'Description02', 2400)
|
||||||
|
, (9, 2, '84044d0b-af33-442a-95a6-21efc77260d5', 'Product 03', 'Description03', 3600)
|
||||||
|
;
|
||||||
|
|
||||||
|
insert into product_tax (product_id, tax_id)
|
||||||
|
values (7, 3)
|
||||||
|
, (8, 5)
|
||||||
|
, (9, 5)
|
||||||
|
, (9, 6)
|
||||||
|
;
|
||||||
|
|
||||||
|
select is(
|
||||||
|
edit_product('d2300404-bd23-48b3-8e2b-2bbf86dc7bd6', 'Product 1', 'Description 1', '12.12', array[3, 4]),
|
||||||
|
true,
|
||||||
|
'Should be able to edit product from first company'
|
||||||
|
);
|
||||||
|
|
||||||
|
select is(
|
||||||
|
edit_product('2f085b8b-da90-41fe-b8cf-6ba8d94cfa38', 'Product 2', 'Description 2', '24.24', array[6]),
|
||||||
|
true,
|
||||||
|
'Should be able to edit product from second company'
|
||||||
|
);
|
||||||
|
|
||||||
|
select is(
|
||||||
|
edit_product('84044d0b-af33-442a-95a6-21efc77260d5', 'Product 3', 'Description 3', '36.36', array[]::integer[]),
|
||||||
|
true,
|
||||||
|
'Should be able to edit a product a remove all taxes'
|
||||||
|
);
|
||||||
|
|
||||||
|
select is(
|
||||||
|
edit_product('87e158d1-a0f5-48a7-854b-b86d7b4bb21c', 'Product 4', 'Description 4', '48.48', array[]::integer[]),
|
||||||
|
false,
|
||||||
|
'Should return false when the product does not exist'
|
||||||
|
);
|
||||||
|
|
||||||
|
select bag_eq(
|
||||||
|
$$ select product_id, company_id, name, description, price from product $$,
|
||||||
|
$$ values (7, 1, 'Product 1', 'Description 1', 1212)
|
||||||
|
, (8, 2, 'Product 2', 'Description 2', 2424)
|
||||||
|
, (9, 2, 'Product 3', 'Description 3', 3636)
|
||||||
|
$$,
|
||||||
|
'Should have edited all three products'
|
||||||
|
);
|
||||||
|
|
||||||
|
select bag_eq(
|
||||||
|
$$ select product_id, tax_id from product_tax $$,
|
||||||
|
$$ values (7, 3)
|
||||||
|
, (7, 4)
|
||||||
|
, (8, 6)
|
||||||
|
$$,
|
||||||
|
'Should have updated the taxes for the products we told to'
|
||||||
|
);
|
||||||
|
|
||||||
|
select *
|
||||||
|
from finish();
|
||||||
|
|
||||||
|
rollback;
|
|
@ -33,8 +33,8 @@ select col_hasnt_default('product_tax', 'tax_id');
|
||||||
|
|
||||||
|
|
||||||
set client_min_messages to warning;
|
set client_min_messages to warning;
|
||||||
truncate product cascade;
|
|
||||||
truncate product_tax cascade;
|
truncate product_tax cascade;
|
||||||
|
truncate product cascade;
|
||||||
truncate tax cascade;
|
truncate tax cascade;
|
||||||
truncate company_user cascade;
|
truncate company_user cascade;
|
||||||
truncate company cascade;
|
truncate company cascade;
|
||||||
|
|
|
@ -0,0 +1,7 @@
|
||||||
|
-- Verify numerus:add_product on pg
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
select has_function_privilege('numerus.add_product(integer, text, text, text, integer[])', 'execute');
|
||||||
|
|
||||||
|
rollback;
|
|
@ -0,0 +1,7 @@
|
||||||
|
-- Verify numerus:edit_product on pg
|
||||||
|
|
||||||
|
begin;
|
||||||
|
|
||||||
|
select has_function_privilege('numerus.edit_product(uuid, text, text, text, integer[])', 'execute');
|
||||||
|
|
||||||
|
rollback;
|
Loading…
Reference in New Issue