Convert from cents to “price” and back
I do not want to use floats in the Go lang application, because it is not supposed to do anything with these values other than to print and retrieve them from the user; all computations will be performed by PostgreSQL in cents. That means i have to “convert” from the price format that users expect to see (e.g., 1.234,56) to cents (e.g., 123456) and back when passing data between Go and PostgreSQL, and that conversion depends on the currency’s decimal places. At first i did everything in Go, but saw that i would need to do it in a loop when retrieving the list of products, and immediately knew it was a mistake—i needed a PL/pgSQL function for that. I still need to convert from string to float, however, when printing the value to the user. Because the string representation is in C, but i need to format it according to the locale with golang/x/text. That package has the information of how to correctly format numbers, but it is in an internal package that i can not use, and numbers.Digit only accepts numeric types, not a string.
This commit is contained in:
parent
e9cc331ee0
commit
60f9792e58
|
@ -0,0 +1,47 @@
|
|||
-- Deploy numerus:parse_price to pg
|
||||
-- requires: schema_public
|
||||
|
||||
begin;
|
||||
|
||||
set search_path to numerus, public;
|
||||
|
||||
create or replace function parse_price(price text, decimal_digits integer) returns integer as
|
||||
$$
|
||||
declare
|
||||
parts text[];
|
||||
result int;
|
||||
frac_part text;
|
||||
begin
|
||||
parts := string_to_array(price, '.');
|
||||
if array_length(parts, 1) > 2 then
|
||||
raise invalid_parameter_value using message = price || ' is not a valid price representation.';
|
||||
end if;
|
||||
|
||||
result := parts[1]::integer;
|
||||
for d in 1..decimal_digits loop
|
||||
result := result * 10;
|
||||
end loop;
|
||||
|
||||
if array_length(parts, 1) = 2 then
|
||||
frac_part := rtrim(parts[2], '0');
|
||||
if length(frac_part) > decimal_digits then
|
||||
raise invalid_parameter_value using message = price || ' has too many digits in the fraction part.';
|
||||
end if;
|
||||
frac_part := rpad(frac_part, decimal_digits, '0');
|
||||
result := result + frac_part::integer;
|
||||
end if;
|
||||
|
||||
return result;
|
||||
end;
|
||||
$$
|
||||
language plpgsql
|
||||
immutable;
|
||||
|
||||
comment on function parse_price(text, integer) is
|
||||
'Converts the string representation of a price in decimal form to cents, according to the number of decimal digits passed.';
|
||||
|
||||
revoke execute on function parse_price(text, integer) from public;
|
||||
grant execute on function parse_price(text, integer) to invoicer;
|
||||
grant execute on function parse_price(text, integer) to admin;
|
||||
|
||||
commit;
|
|
@ -0,0 +1,28 @@
|
|||
-- Deploy numerus:to_price to pg
|
||||
-- requires: schema_numerus
|
||||
|
||||
begin;
|
||||
|
||||
set search_path to numerus, public;
|
||||
|
||||
create or replace function to_price(cents integer, decimal_digits integer) returns text as
|
||||
$$
|
||||
declare
|
||||
result text;
|
||||
scale integer := 10^decimal_digits;
|
||||
begin
|
||||
result = cents::text;
|
||||
return (cents / scale)::text || '.' || to_char(mod(cents, scale), rpad('FM', decimal_digits + 2, '0'));
|
||||
end;
|
||||
$$
|
||||
language plpgsql
|
||||
immutable;
|
||||
|
||||
comment on function to_price(integer, integer) is
|
||||
'Converts the cents to a price representation, without currency and any other separater than decimal.';
|
||||
|
||||
revoke execute on function to_price(integer, integer) from public;
|
||||
grant execute on function to_price(integer, integer) to invoicer;
|
||||
grant execute on function to_price(integer, integer) to admin;
|
||||
|
||||
commit;
|
|
@ -15,8 +15,10 @@ const (
|
|||
)
|
||||
|
||||
type Company struct {
|
||||
Id int
|
||||
Slug string
|
||||
Id int
|
||||
CurrencySymbol string
|
||||
DecimalDigits int
|
||||
Slug string
|
||||
}
|
||||
|
||||
func CompanyHandler(next http.Handler) httprouter.Handle {
|
||||
|
@ -25,7 +27,7 @@ func CompanyHandler(next http.Handler) httprouter.Handle {
|
|||
Slug: params[0].Value,
|
||||
}
|
||||
conn := getConn(r)
|
||||
err := conn.QueryRow(r.Context(), "select company_id from company where slug = $1", company.Slug).Scan(&company.Id)
|
||||
err := conn.QueryRow(r.Context(), "select company_id, currency_symbol, decimal_digits from company join currency using (currency_code) where slug = $1", company.Slug).Scan(&company.Id, &company.CurrencySymbol, &company.DecimalDigits)
|
||||
if err != nil {
|
||||
http.NotFound(w, r)
|
||||
return
|
||||
|
@ -41,6 +43,15 @@ func CompanyHandler(next http.Handler) httprouter.Handle {
|
|||
}
|
||||
}
|
||||
|
||||
func (c Company) MinCents() float64 {
|
||||
var r float64
|
||||
r = 1
|
||||
for i := 0; i < c.DecimalDigits; i++ {
|
||||
r /= 10.0
|
||||
}
|
||||
return r
|
||||
}
|
||||
|
||||
func getCompany(r *http.Request) *Company {
|
||||
company := r.Context().Value(ContextCompanyKey)
|
||||
if company == nil {
|
||||
|
|
|
@ -175,6 +175,11 @@ func (v *FormValidator) CheckValidInteger(field *InputField, min int, max int, m
|
|||
return v.checkInput(field, err == nil && value >= min && value <= max, message)
|
||||
}
|
||||
|
||||
func (v *FormValidator) CheckValidDecimal(field *InputField, min float64, max float64, message string) bool {
|
||||
value, err := strconv.ParseFloat(field.Val, 64)
|
||||
return v.checkInput(field, err == nil && value >= min && value <= max, message)
|
||||
}
|
||||
|
||||
func (v *FormValidator) checkInput(field *InputField, ok bool, message string) bool {
|
||||
if !ok {
|
||||
field.Errors = append(field.Errors, errors.New(message))
|
||||
|
|
|
@ -2,6 +2,7 @@ package pkg
|
|||
|
||||
import (
|
||||
"context"
|
||||
"fmt"
|
||||
"github.com/jackc/pgx/v4"
|
||||
"github.com/julienschmidt/httprouter"
|
||||
"html/template"
|
||||
|
@ -12,7 +13,7 @@ import (
|
|||
type ProductEntry struct {
|
||||
Slug string
|
||||
Name string
|
||||
Price int
|
||||
Price string
|
||||
}
|
||||
|
||||
type productsIndexPage struct {
|
||||
|
@ -39,7 +40,7 @@ func GetProductForm(w http.ResponseWriter, r *http.Request, params httprouter.Pa
|
|||
mustRenderNewProductForm(w, r, form)
|
||||
return
|
||||
}
|
||||
err := conn.QueryRow(r.Context(), "select name, description, price, tax_id from product where slug = $1", slug).Scan(form.Name, form.Description, form.Price, form.Tax)
|
||||
err := conn.QueryRow(r.Context(), "select product.name, product.description, to_price(price, decimal_digits), tax_id from product join company using (company_id) join currency using (currency_code) where product.slug = $1", slug).Scan(form.Name, form.Description, form.Price, form.Tax)
|
||||
if err != nil {
|
||||
if err == pgx.ErrNoRows {
|
||||
http.NotFound(w, r)
|
||||
|
@ -77,7 +78,7 @@ func HandleAddProduct(w http.ResponseWriter, r *http.Request, _ httprouter.Param
|
|||
mustRenderNewProductForm(w, r, form)
|
||||
return
|
||||
}
|
||||
conn.MustExec(r.Context(), "insert into product (company_id, name, description, price, tax_id) values ($1, $2, $3, $4, $5)", company.Id, form.Name, form.Description, form.Price, form.Tax)
|
||||
conn.MustExec(r.Context(), "insert into product (company_id, name, description, price, tax_id) select company_id, $2, $3, parse_price($4, decimal_digits), $5 from company join currency using (currency_code) where company_id = $1", company.Id, form.Name, form.Description, form.Price, form.Tax)
|
||||
http.Redirect(w, r, companyURI(company, "/products"), http.StatusSeeOther)
|
||||
}
|
||||
|
||||
|
@ -98,7 +99,7 @@ func HandleUpdateProduct(w http.ResponseWriter, r *http.Request, params httprout
|
|||
mustRenderEditProductForm(w, r, form)
|
||||
return
|
||||
}
|
||||
slug := conn.MustGetText(r.Context(), "", "update product set name = $1, description = $2, price = $3, tax_id = $4 where slug = $5 returning slug", form.Name, form.Description, form.Price, form.Tax, params[0].Value)
|
||||
slug := conn.MustGetText(r.Context(), "", "update product set name = $1, description = $2, price = parse_price($3, decimal_digits), tax_id = $4 from company join currency using (currency_code) where product.company_id = company.company_id and product.slug = $5 returning product.slug", form.Name, form.Description, form.Price, form.Tax, params[0].Value)
|
||||
if slug == "" {
|
||||
http.NotFound(w, r)
|
||||
}
|
||||
|
@ -106,7 +107,7 @@ func HandleUpdateProduct(w http.ResponseWriter, r *http.Request, params httprout
|
|||
}
|
||||
|
||||
func mustGetProductEntries(ctx context.Context, conn *Conn, company *Company) []*ProductEntry {
|
||||
rows, err := conn.Query(ctx, "select slug, name, price from product where company_id = $1 order by name", company.Id)
|
||||
rows, err := conn.Query(ctx, "select product.slug, product.name, to_price(price, decimal_digits) from product join company using (company_id) join currency using (currency_code) where company_id = $1 order by name", company.Id)
|
||||
if err != nil {
|
||||
panic(err)
|
||||
}
|
||||
|
@ -130,6 +131,7 @@ func mustGetProductEntries(ctx context.Context, conn *Conn, company *Company) []
|
|||
|
||||
type productForm struct {
|
||||
locale *Locale
|
||||
company *Company
|
||||
Name *InputField
|
||||
Description *InputField
|
||||
Price *InputField
|
||||
|
@ -138,7 +140,8 @@ type productForm struct {
|
|||
|
||||
func newProductForm(ctx context.Context, conn *Conn, locale *Locale, company *Company) *productForm {
|
||||
return &productForm{
|
||||
locale: locale,
|
||||
locale: locale,
|
||||
company: company,
|
||||
Name: &InputField{
|
||||
Name: "name",
|
||||
Label: pgettext("input", "Name", locale),
|
||||
|
@ -157,6 +160,7 @@ func newProductForm(ctx context.Context, conn *Conn, locale *Locale, company *Co
|
|||
Required: true,
|
||||
Attributes: []template.HTMLAttr{
|
||||
`min="0"`,
|
||||
template.HTMLAttr(fmt.Sprintf(`step="%v"`, company.MinCents())),
|
||||
},
|
||||
},
|
||||
Tax: &SelectField{
|
||||
|
@ -182,7 +186,7 @@ func (form *productForm) Validate() bool {
|
|||
validator := newFormValidator()
|
||||
validator.CheckRequiredInput(form.Name, gettext("Name can not be empty.", form.locale))
|
||||
if validator.CheckRequiredInput(form.Price, gettext("Price can not be empty.", form.locale)) {
|
||||
validator.CheckValidInteger(form.Price, 0, math.MaxInt, gettext("Price must be a number greater than zero.", form.locale))
|
||||
validator.CheckValidDecimal(form.Price, form.company.MinCents(), math.MaxFloat64, gettext("Price must be a number greater than zero.", form.locale))
|
||||
}
|
||||
validator.CheckValidSelectOption(form.Tax, gettext("Selected tax is not valid.", form.locale))
|
||||
return validator.AllOK()
|
||||
|
|
|
@ -2,9 +2,13 @@ package pkg
|
|||
|
||||
import (
|
||||
"fmt"
|
||||
"golang.org/x/text/message"
|
||||
"golang.org/x/text/number"
|
||||
"html/template"
|
||||
"io"
|
||||
"math"
|
||||
"net/http"
|
||||
"strconv"
|
||||
)
|
||||
|
||||
const overrideMethodName = "_method"
|
||||
|
@ -27,6 +31,14 @@ func mustRenderTemplate(wr io.Writer, r *http.Request, layout string, filename s
|
|||
"companyURI": func(uri string) string {
|
||||
return companyURI(company, uri)
|
||||
},
|
||||
"formatPrice": func(price string) string {
|
||||
p := message.NewPrinter(locale.Language)
|
||||
f, err := strconv.ParseFloat(price, 64)
|
||||
if err != nil {
|
||||
f = math.NaN()
|
||||
}
|
||||
return p.Sprintf("%.*f", company.DecimalDigits, number.Decimal(f))
|
||||
},
|
||||
"csrfToken": func() template.HTML {
|
||||
return template.HTML(fmt.Sprintf(`<input type="hidden" name="%s" value="%s">`, csrfTokenField, user.CsrfToken))
|
||||
},
|
||||
|
|
|
@ -0,0 +1,7 @@
|
|||
-- Revert numerus:parse_price from pg
|
||||
|
||||
begin;
|
||||
|
||||
drop function if exists numerus.parse_price(text, integer);
|
||||
|
||||
commit;
|
|
@ -0,0 +1,7 @@
|
|||
-- Revert numerus:to_price from pg
|
||||
|
||||
begin;
|
||||
|
||||
drop function if exists numerus.to_price(integer, integer);
|
||||
|
||||
commit;
|
|
@ -40,3 +40,5 @@ tax_rate [schema_numerus] 2023-01-28T11:33:39Z jordi fita mas <jordi@tandem.blog
|
|||
tax [schema_numerus company tax_rate] 2023-01-28T11:45:47Z jordi fita mas <jordi@tandem.blog> # Add relation for taxes
|
||||
contact [schema_numerus company extension_vat email extension_pg_libphonenumber extension_uri currency_code currency country_code country] 2023-01-29T12:59:18Z jordi fita mas <jordi@tandem.blog> # Add the relation for contacts
|
||||
product [schema_numerus company] 2023-02-04T09:17:24Z jordi fita mas <jordi@tandem.blog> # Add relation for products
|
||||
parse_price [schema_public] 2023-02-05T11:04:54Z jordi fita mas <jordi@tandem.blog> # Add function to convert from price to cents
|
||||
to_price [schema_numerus] 2023-02-05T11:46:31Z jordi fita mas <jordi@tandem.blog> # Add function to format cents to prices
|
||||
|
|
|
@ -0,0 +1,53 @@
|
|||
-- Test parse_price
|
||||
set client_min_messages to warning;
|
||||
create extension if not exists pgtap;
|
||||
reset client_min_messages;
|
||||
|
||||
begin;
|
||||
|
||||
select plan(36);
|
||||
|
||||
set search_path to auth, numerus, public;
|
||||
|
||||
select has_function('numerus', 'parse_price', array ['text', 'integer']);
|
||||
select function_lang_is('numerus', 'parse_price', array ['text', 'integer'], 'plpgsql');
|
||||
select function_returns('numerus', 'parse_price', array ['text', 'integer'], 'integer');
|
||||
select isnt_definer('numerus', 'parse_price', array ['text', 'integer']);
|
||||
select volatility_is('numerus', 'parse_price', array ['text', 'integer'], 'immutable');
|
||||
select function_privs_are('numerus', 'parse_price', array ['text', 'integer'], 'guest', array []::text[]);
|
||||
select function_privs_are('numerus', 'parse_price', array ['text', 'integer'], 'invoicer', array ['EXECUTE']);
|
||||
select function_privs_are('numerus', 'parse_price', array ['text', 'integer'], 'admin', array ['EXECUTE']);
|
||||
select function_privs_are('numerus', 'parse_price', array ['text', 'integer'], 'authenticator', array []::text[]);
|
||||
|
||||
select is( parse_price('1.1', 2), 110 );
|
||||
select is( parse_price('1.1', 3), 1100 );
|
||||
select is( parse_price('0', 2), 0 );
|
||||
select is( parse_price('0', 3), 0 );
|
||||
select is( parse_price('0.01', 2), 1 );
|
||||
select is( parse_price('0.001', 3), 1 );
|
||||
select is( parse_price('0.1', 2), 10 );
|
||||
select is( parse_price('0.01', 3), 10 );
|
||||
select is( parse_price('1', 2), 100 );
|
||||
select is( parse_price('0.1', 3), 100 );
|
||||
select is( parse_price('10', 2), 1000 );
|
||||
select is( parse_price('1', 3), 1000 );
|
||||
select is( parse_price('23.23', 2), 2323 );
|
||||
select is( parse_price('23.23', 3), 23230 );
|
||||
select throws_ok( $$ select parse_price('234.234', 2) $$ );
|
||||
select is( parse_price('234.234', 3), 234234 );
|
||||
select throws_ok( $$ select parse_price('2345.2345', 2) $$ );
|
||||
select throws_ok( $$ select parse_price('2345.2345', 3) $$ );
|
||||
select is( parse_price('00000000000000001.100000000000000000000', 2), 110 );
|
||||
select is( parse_price('00000000000000001.100000000000000000000', 3), 1100 );
|
||||
select is( parse_price('00000000000000000.100000000000000000000', 2), 10 );
|
||||
select is( parse_price('00000000000000000.100000000000000000000', 3), 100 );
|
||||
select is( parse_price('00000000000123456.780000000000000000000', 2), 12345678 );
|
||||
select is( parse_price('00000000000123456.789000000000000000000', 3), 123456789 );
|
||||
select throws_ok( $$ select parse_price('1,1', 2) $$ );
|
||||
select throws_ok( $$ select parse_price('1.1.1', 2) $$ );
|
||||
select throws_ok( $$ select parse_price('a.b', 2) $$ );
|
||||
|
||||
select *
|
||||
from finish();
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,40 @@
|
|||
-- Test to_price
|
||||
set client_min_messages to warning;
|
||||
create extension if not exists pgtap;
|
||||
reset client_min_messages;
|
||||
|
||||
begin;
|
||||
|
||||
select plan(23);
|
||||
|
||||
set search_path to numerus, public;
|
||||
|
||||
select has_function('numerus', 'to_price', array ['integer', 'integer']);
|
||||
select function_lang_is('numerus', 'to_price', array ['integer', 'integer'], 'plpgsql');
|
||||
select function_returns('numerus', 'to_price', array ['integer', 'integer'], 'text');
|
||||
select isnt_definer('numerus', 'to_price', array ['integer', 'integer']);
|
||||
select volatility_is('numerus', 'to_price', array ['integer', 'integer'], 'immutable');
|
||||
select function_privs_are('numerus', 'to_price', array ['integer', 'integer'], 'guest', array []::text[]);
|
||||
select function_privs_are('numerus', 'to_price', array ['integer', 'integer'], 'invoicer', array ['EXECUTE']);
|
||||
select function_privs_are('numerus', 'to_price', array ['integer', 'integer'], 'admin', array ['EXECUTE']);
|
||||
select function_privs_are('numerus', 'to_price', array ['integer', 'integer'], 'authenticator', array []::text[]);
|
||||
|
||||
select is( to_price(0, 2), '0.00' );
|
||||
select is( to_price(0, 3), '0.000' );
|
||||
select is( to_price(1, 2), '0.01' );
|
||||
select is( to_price(1, 3), '0.001' );
|
||||
select is( to_price(10, 2), '0.10' );
|
||||
select is( to_price(10, 3), '0.010' );
|
||||
select is( to_price(100, 2), '1.00' );
|
||||
select is( to_price(100, 3), '0.100' );
|
||||
select is( to_price(110, 2), '1.10' );
|
||||
select is( to_price(1100, 3), '1.100' );
|
||||
select is( to_price(12345678, 2), '123456.78' );
|
||||
select is( to_price(12345678, 3), '12345.678' );
|
||||
select is( to_price(12345678, 4), '1234.5678' );
|
||||
select is( to_price(12345678, 5), '123.45678' );
|
||||
|
||||
select *
|
||||
from finish();
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,7 @@
|
|||
-- Verify numerus:parse_price on pg
|
||||
|
||||
begin;
|
||||
|
||||
select has_function_privilege('numerus.parse_price(text, integer)', 'execute');
|
||||
|
||||
rollback;
|
|
@ -0,0 +1,7 @@
|
|||
-- Verify numerus:to_price on pg
|
||||
|
||||
begin;
|
||||
|
||||
select has_function_privilege('numerus.to_price(integer, integer)', 'execute');
|
||||
|
||||
rollback;
|
|
@ -29,7 +29,7 @@
|
|||
<tr>
|
||||
<td></td>
|
||||
<td><a href="{{ companyURI "/products/"}}{{ .Slug }}">{{ .Name }}</a></td>
|
||||
<td>{{ .Price }}</td>
|
||||
<td>{{ .Price | formatPrice }}</td>
|
||||
</tr>
|
||||
{{- end }}
|
||||
{{ else }}
|
||||
|
|
Loading…
Reference in New Issue