Jump to content

Development: FieldtypeFloat - FieldtypeDecimal


kixe

Recommended Posts

Since some others and me have been run into problems with FieldtypeFloat. I want to start a discussion with the purpose to get a consistent FieldtypeFloat and/or to create a new Fieldtype maybe called FieldtypeDecimal to store exact values maybe for currencies.

First I will assume some known problems.

  1. precision
    Values of Type Float are stored in most of the Mysql Installations with a precision of 6 by default. PW FieldtypeFloat uses Type float() in the Mysql Database This could cause some problems.

    For easy understanding look at this table.
    +---------------+----------------+--------------------------------------------------+
    | input         | float()        | decimal(10,2)                                    |
    +---------------+----------------+--------------------------------------------------+
    | 1234.56       | 1234.56        | 1234.56                                          |
    +---------------+----------------+--------------------------------------------------+
    | 123456.78     | 123457         | 123456.78                                        |
    +---------------+----------------+--------------------------------------------------+
    | 12345678      | 12345600       | 12345678.00                                      |
    +---------------+----------------+--------------------------------------------------+
    | 1.23456789    | 1.23457        | 1.23                                             |
    +---------------+----------------+--------------------------------------------------+
    | 12345678912345| 12345600000000 | ERROR SQLSTATE[22003]: Numeric value out of range|
    +---------------+----------------+--------------------------------------------------+
    
    

    As an example in Apeisas Shoppingcart Module exists a field sc_price of type float().
    This field allows a maximum value of 9999.99 Euro Dollar or whatever. Don't use it to sell cars like Ferrari. :)

    Try to store the input values of the preceding table in a PW Field of Type Float in your surrounding and look what you get after saving.

    Threads treating the same problem
    https://processwire.com/talk/topic/3888-float-field-rounding-problem/
    https://processwire.com/talk/topic/86-float-field-rounding
     

  2. rounding
    Mysql will round anyway the float value to precision. So it is not necessary to round the value in php before storing.
    To store exact Values it is better to use Type decimal(M,D)
    where M is the lenght and D the number of digits.

    Thread treating the same problem
    https://processwire.com/talk/topic/86-float-field-rounding
     
  3. format
    We had already some discussion about local settings, storing and output of PHP-Values of Type (float). And Ryan did some Adjustments with number_format. But I don't trust completely, thats why I am using Textfields to store numbers. Would be nice to have a consistent Fieldtype working in different local-settings.

    Thread treating the same problem
    https://processwire.com/talk/topic/4123-decimal-point-changed-to-in-base-of-setlocale/
    https://processwire.com/talk/topic/86-float-field-rounding
     

What is a float (floating point value), what is decimal?
A float is an approximate value and exactly like this it is stored in Mysql.
For more understanding two examples.

1. example

CREATE TABLE `test` (
`test_float` float(10,2) NOT NULL,
`test_decimal` decimal(10,2) NOT NULL
);

INSERT INTO `test` (`test_float`, `test_decimal`) VALUES (5.43, 5.43);

SELECT (test_float * 1.0000000) AS f, (test_decimal * 1.0000000) AS d FROM test;

This will result the following:
f = 5.4299998 and d = 5.430000000

source: http://netzgewe.be/2012/03/mysql-und-waehrungsbetraege-float-vs-decimal/
(german)
 

2. example

mysql> create table numbers (a decimal(10,2), b float);
mysql> insert into numbers values (100, 100);
mysql> select @a := (a/3), @b := (b/3), @a * 3, @b * 3 from numbers \G
*************************** 1. row ***************************
  @a := (a/3): 33.333333333
  @b := (b/3): 33.333333333333
@a + @a + @a: 99.999999999000000000000000000000
@b + @b + @b: 100

source: http://stackoverflow.com/questions/5150274/difference-between-float-and-decimal-data-type

INFO & LEARNING
http://stackoverflow.com/questions/5150274/difference-between-float-and-decimal-data-type
http://stackoverflow.com/questions/4520620/float-precision-problem-in-mysql
http://dev.mysql.com/doc/refman/5.0/en/problems-with-float.html
http://dev.mysql.com/doc/refman/5.0/en/storage-requirements.html

INTENTION
The intention of this thread is to discuss good solutions for a consistent working FieldtypeFloat which makes clear to Everybody what it is via description.
Furthermore to build a new Fieldtype with setting options of total lenght and decimal places.

NOTES
Please use this thread rather for development than as a help forum.
BTW I am not an expert in Mysql PHP or whatever. Maybe there are some guys in the forum which could put the real good stuff here.

Thanks a lot and lets go. ???

  • Like 17
Link to comment
Share on other sites

I am glad you started a thread on this topic. I agree it would be great to see a FieldtypeDecimal module shipping with the core. This is something that's actually on a TODO-list for a big project of ours. It should definitely be a separate module (in other words, leave FieldtypeFloat alone) because floats have a different purpose.

The background of the problem is in how computers handle (or should you say, how they support handling) floating point values. It actually doesn't have anything to do with PHP or MySQL, even less with PW - although you can obviously feel the effect of it. Binary floating point values supported by the CPU/ALU/FPU, such as the commonly used IEEE 754 (C, Java, PHP and so on), are always approximations. They are used where speed matters the most and the tiny loss of precision is acceptable.

When precision is needed, you actually need something that implements arbitrary-precision arithmetic (bignum). The resulting loss of speed is irrelevant in many cases, such as handling currency.

The reason why I'm bringing this up is that even with a FieldtypeDecimal implementation, you would still need to make sure you are handling the values correctly in PHP. If you perform any arithmetic on the value using PHP's arithmetic operators, you are actually causing PHP to cast the value to a floating point representation. That would defeat our purpose here (because you could loose precision). Thus if you need to perform arithmetic on the value, you must use an arbitrary-precision arithmetic library.

For PHP you have at least two good options

Of course none of this matters unless you can first store the original value in the database without precision loss. This requires a DECIMAL field in MySQL - which indeed was the original topic of the thread :)

Here's a few links for general information. I recommend you to read at least the first one - it's a simple introduction.

  • Like 12
Link to comment
Share on other sites

I'm giving out an implementation which you can use while Ryan is considering this matter. It's based on Ryan's FieldtypeFloat and InputfieldFloat and it should cover all the basics.

cd <pw_modules_directory>
git clone https://github.com/sforsman/FieldtypeDecimal.git
git clone https://github.com/sforsman/InputfieldDecimal.git

To actually use them, you obviously need to tell PW to scan for new modules and then install them.

Couple of notes

  • Since the precision needs to be defined on the database-level, this module hooks ProcessField::fieldSaved and updates the database if you have changed the precision settings. You get a notification if it's been done. Be aware, if you decrease the precision you will obviously loose those decimals forever after the save - the database is immediteally and always modified. I don't consider this ugly because this is mandatory - one way or another. Due to the implementation of the DECIMAL type in MySQL, it's not possible to choose such default values that would be optimal for all of the different scenarios.
  • Along with a dot, I prefer to accept decimals with a comma as well. This is because many humans separate them with a comma.
  • As with InputfieldFloat, you can define the range of the values the InputfieldDecimal will accept. If you have a precision math library installed, the module will use it when doing the comparison. This will rarely make a difference but hey, what the heck.
  • To be consistent as to how the DECIMAL type is created in MySQL, the digits-parameter refers to the the total number of digits - including the decimal parts (5.55 has three digits and two decimals).
  • There's a few known "issues" (I prefer to call them "features", though)
    • The min/max configuration Inputfields are still using InputfieldFloat. This means you need to separate decimals in your min/max range with a dot.
    • The sanitizer currently uses is_numeric() to check the value, which means you can enter some weird stuff (like 0x539) and it's sent to the database. However MySQL obviously ignores such values and stores 0 for you. This should be improved later. 
    • The Fieldtype doesn't do much to the values and relies on MySQL to handle the necessary rounding etc. This is good in my opinion. However this also means that if you have set the precision to "2" and enter a value that doesn't have any decimals (e.g. "5"), MySQL will add the decimals (the DECIMAL type is afterall an exact fixed-point type) and that's what you will see after you have saved your value (e.g. "5.00") . Again, I consider this a good thing.
    • Like InputfieldFloat, the InputfieldDecimal doesn't do any validation on the data - invalid values are just blanked.
    • As I have intentionally hooked only ProcessField::fieldSaved, you need to manually either a) call $field->type->syncSchema() or b) hook Fields::save yourself if you are modifying the precision of a field through the API.

Oh and I'm open to any ideas - at least regarding these modules.

  • Like 10
Link to comment
Share on other sites

@sforsman

Thank you for your two posts!

What a great summary you made two posts up; loads of information and good points. Just want to pick up on a few of them...

 

The background of the problem is in how computers handle (or should you say, how they support handling) floating point values. It actually doesn't have anything to do with PHP or MySQL, even less with PW - although you can obviously feel the effect of it. Binary floating point values supported by the CPU/ALU/FPU, such as the commonly used IEEE 754 (C, Java, PHP and so on), are always approximations. They are used where speed matters the most and the tiny loss of precision is acceptable.

The hardware implementations are fast but that tiny loss of precision at high exponent values can represent huge absolute errors. Floats really work well when you don't mind about precision but you need to have a datatype that allows calculations over a huge range of values. 

Of course none of this matters unless you can first store the original value in the database without precision loss. This requires a DECIMAL field in MySQL - which indeed was the original topic of the thread

This seems to assume that a decimal is the only possible MySQL fieldtype that can solve the problem. Seeing as PHP uses strings to do BCMath stuff, isn't it possible to store an arbitrary precision variable in a straight MySQL varchar or text field? I've done that in the past and handled all the calculations in the PHP application using BCMaths functions and it's worked very well.

This approach would mean you don't have to go and alter your column if you need to start storing values outside of the initial storage range of the decimal column (as long as you made the varchar pretty big.) The approach wouldn't work well if you want to do some maths in queries or stored routines of course.

  • Like 2
Link to comment
Share on other sites

@netcarver

Thank you for the comments!

The hardware implementations are fast but that tiny loss of precision at high exponent values can represent huge absolute errors. Floats really work well when you don't mind about precision but you need to have a datatype that allows calculations over a huge range of values. 

Exactly.

This seems to assume that a decimal is the only possible MySQL fieldtype that can solve the problem. Seeing as PHP uses strings to do BCMath stuff, isn't it possible to store an arbitrary precision variable in a straight MySQL varchar or text field? I've done that in the past and handled all the calculations in the PHP application using BCMaths functions and it's worked very well.

 

This approach would mean you don't have to go and alter your column if you need to start storing values outside of the initial storage range of the decimal column (as long as you made the varchar pretty big.) The approach wouldn't work well if you want to do some maths in queries or stored routines of course.

You are correct. Actually I had this mentioned in an edit of mine, but I decided to remove it because generally I don't want to encourage using (VAR)CHAR, BLOB or TEXT (for storing decimals) - especially regarding ProcessWire-projects.

The reason behind this is that you don't get the benefits of a real DECIMAL field while performing database-operations on the field - you could actually get very unexpected results. Consider things like indexes, ORDER BY clauses, querying based on a range (field BETWEEN a AND b), aggregates (AVG, SUM) or other arithmetic done on the field (price*quantity*discount). Of course if you are writing SQL queries, you could ask MySQL to CAST the field (and it will actually do this for you in some cases), but this would be a lot slower (not to mention ugly).

Of course there are cases where you need none of this and then using a CHAR is perfectly fine! PHP is obiously a lot slower handling them, but if you're not processing large result sets then this doesn't matter either.

However I had even more reason to edit it away due the ProcessWire context. I'll give you two simple examples just to demonstrate my point. Consider the following selector

template=product, sort=-price, limit=5

If your price-field is a CHAR-field, your results would be all wrong. In your PageArray you'd have products with a price of $9 even if there was a product with $1000 price. MySQL sorts the text-based fields alphabetically, so anything that starts with the number 9 is bigger than something that starts with the number 1.

Then consider 

template=product, price>=10, price<=20

PW would actually return products that have a price of $100, which we clearly didn't ask for. This is because PW sends the values quoted (i.e. '10' and '20') which causes MySQL to compare the values as strings (because the database-field is a TEXT-field).

This approach would mean you don't have to go and alter your column if you need to start storing values outside of the initial storage range of the decimal column (as long as you made the varchar pretty big.) The approach wouldn't work well if you want to do some maths in queries or stored routines of course.

I don't really see a problem with altering the column - the module does it for you. PW requires ALTER permissions anyway. Besides, as I demonstrated, having a DECIMAL-field is the only proper way handling it in PW.

  • Like 4
Link to comment
Share on other sites

I'm giving out an implementation which you can use while Ryan is considering this matter. It's based on Ryan's FieldtypeFloat and InputfieldFloat and it should cover all the basics.

cd <pw_modules_directory>
git clone https://github.com/sforsman/FieldtypeDecimal.git
git clone https://github.com/sforsman/InputfieldDecimal.git

To actually use them, you obviously need to tell PW to scan for new modules and then install them.

@sforsman

thats exactly I wanted to unleash with the topic. Didn't expect to get a solution so quick. I tried it out. Great work, thats what we need.

I made few and tiny adjustments since I am still using PHP 5.3.

// We need to hook field save to check if our database field is up to date
$this->addHookAfter('ProcessField::fieldSaved', function ($event) {
$field = $event->arguments(0);
if($field->type instanceof FieldtypeDecimal)
{
// We could use $this inside here, if we could expect everybody to have PHP 5.4
$m = wire('modules')->get(__CLASS__);
$result = $m->syncSchema($field);
// We just add a message if the database was actually modified
if($result === true)
$field->message(__('Database schema was updated.'));
}
});
  • 'instanceof self' didn't work I switched it to the class name.
  • Message is a method of field object, no need to use $this.
  • And generally it is nice to make the messages translatable.

    So its already done ???

  • Like 3
Link to comment
Share on other sites

thats exactly I wanted to unleash with the topic. Didn't expect to get a solution so quick. I tried it out. Great work, thats what we need.

 

I'm glad I could help!

  • 'instanceof self' didn't work I switched it to the class name.
  • Message is a method of field object, no need to use $this.
  • And generally it is nice to make the messages translatable.

Thank you - excellent points. I'll make these changes and then post the module.

So its already done  ???

Well what can I say, you gave me exactly the little push I needed to go for it :)

  • Like 3
Link to comment
Share on other sites

  • 1 month later...

Really great!!!

Thank you very much for this module!

Just tested - only issue is with numbers with a . and more than two after that example:

40,55      = 40.55

40,559    = 40,56

40.55      = 40.55
40.559    = 40559.00

All other rounding works relly great with . or , no matter!

But this could be with a regex on the client to get no wrong entries.

(http://stackoverflow.com/questions/308122/simple-regular-expression-for-a-decimal-with-a-precision-of-2)

Thank you again!

Kind regards mr-fan

Link to comment
Share on other sites

Looks like a thousands separator. Check it with:

$locale_info = localeconv();
print_r($locale_info);

/* output maybe?
 *
 *
 * Array
 * (
 *  [thousands_sep] => .
 *
 * //other stuff
 * )
 */

You could change local settings with setlocale() to handle thousands and decimal separators or add the following line to the module

$value = str_replace(".",",",$value); // there is already something like this. Just uncomment and switch search and replacement string.

Would be nice to have an option in the module which sanitize the input depending on local settings. Or a config field in the module settings?

Link to comment
Share on other sites

Good morning!

Just clearing a few things first. Currently the module does not expect a thousand separator at all - neither does it understand anything about your locale. The module expects only a decimal separator, which is expected to be a dot or a comma. Currently there is no validation support either, so invalid values will be just sanitized - which is a bit brutal. However I am more than glad to implement these features now that I see there's interest for them :)

@kixe:

 Looks like a thousands separator

If I understood mr-fan correctly, he would like it to be interpreted as a thousands separator - which it currently is not doing, entering "40.559" would result in "40.56" in the database (if configured to use two-digit decimal precision).

 Would be nice to have an option in the module which sanitize the input depending on local settings. Or a config field in the module settings?

 

This is a good idea. I will provide this feature so that you can give the default option in the module-settings + the possibility to override it in the field-settings.

@mr-fan:

Thank you very much for this module!

Thanks a lot for your comments! 

 40.559    = 40559.00

Just to make sure, you would like the dot in this case to be understood as a thousands separator? So if "40.559" was entered, the module would store "40559.00" in the database (when used with two-digit decimal precision)? And if "40.559,559" was entered, you would like the module to store "40559.56"?

Either way I will provide an optional strict validation support, which will be based on the precision and sanitization options defined in the field-settings.

  • Like 1
Link to comment
Share on other sites

thank you for answering,

but what i meant was the 40,559 should be the same like 40.559 ?

So a User could use , or .

with two digit it works 40,55 = 40.55

but with more than 3 digits it don't round and set value to 40.559 without position after decimal point....

hope i can explain it clearly in en.... :undecided:

Link to comment
Share on other sites

@sforsman

If I understood mr-fan correctly, he would like it to be interpreted as a thousands separator - which it currently is not doing, entering "40.559" would result in "40.56" in the database (if configured to use two-digit decimal precision).

I think he doesn't want, but the module and/or system does it!

@mr-fan

but with more than 3 digits it don't round and set value to 40.559 without position after decimal point....

Did you try exactly 3 digits? or also more than 3?
 

Hey guys,
while playing around with it I get the following results:

40,558 => 40558 // comma thousands separator
40,5587 => 40.56 // comma as decimal separator
40.558 => 40.56 // dot as decimal separator

40,558.89 => 40558.89 // comma as thousand separator, dot as decimal separator
40.558,89 => 40558.89 // the other way round
 

Link to comment
Share on other sites

@kixe:

Thanks for the report. I will look into this with proper time. I did some tests and I couldn't yet repeat your results. The module itself does not change the value in a way that should ever result 40,558 getting converted to 40558. It's a very very odd result to be honest with you, because MySQL should only be aware of the locale in regard of dates and times. It seems very wrong that it would use the dot as a thousands separator, because we are talking about a DECIMAL-field. Which version of MySQL are you using? Are you also absolutely certain that you are using FieldtypeDecimal and InputfieldDecimal (and i.e. not FieldtypeFloat/InputfieldFloat)? And just for the sake of it, are you able to execute SHOW VARIABLES LIKE 'character_set%' and SHOW VARIABLES LIKE 'lc%'?

@mr-fan:

I'll get back to you after I've updated the module a little :)

Link to comment
Share on other sites

  • 5 months later...
  • 3 months later...

What I would love is a way to change a large number of float fields to use this decimal field without recreating them (they have data in in a lot of cases and as we're dealing with money things seem to go a bit wrong with a float field but seem to work perfect with this decimal field).

Is there a sensible query I can run to change the table structure? I can change the fieldtype used easily enough in the DB but am a bit wary about changing the table structure for fear of losing the data.

Link to comment
Share on other sites

Hey Pete! Altering the underlying column from a FLOAT to DECIMAL is safe - the other way around not so much, especially with high precision deicmals.

It would also be quite trivial to implement a conversion UI directly in the module (i.e. so that the module lists FieldtypeFloats and lets you select which fields to convert into FieldtypeDecimal). Let me know if this feature would help your case - I'm back in the game so, once again, I have time to contribute to this lovely community :)

  • Like 3
Link to comment
Share on other sites

Hey Pete! Altering the underlying column from a FLOAT to DECIMAL is safe - the other way around not so much, especially with high precision deicmals.

It would also be quite trivial to implement a conversion UI directly in the module (i.e. so that the module lists FieldtypeFloats and lets you select which fields to convert into FieldtypeDecimal). Let me know if this feature would help your case - I'm back in the game so, once again, I have time to contribute to this lovely community :)

It definitely would help - thanks. I could do with being able to do this tomorrow though so if there is an idiot's guide set of manual instructions on how to change the table data in the meantime that would be fantastic.

If that's a bit too tight a timeframe then no problem :)

The way you're proposing is interesting (to solve my "in bulk" requirement), however I'm not sure how many other people might need to do this in bulk. It might be easier (not sure) to do it the way other fieldtypes do on a per-field basis. Fr instance you can change an integer field to a float or text by editing the field, though I've never looked at the underlying code and how it handles any changes to the table in the DB. That might be the more "ProcessWire" way to go, but I'm not saying I would complain about a mass-field-converter either :D

Disclaimer: If changing the fields via SQL turns out to be so easy that I should have known better and done it by now, I'll chalk that up to a tiring week.

  • Like 1
Link to comment
Share on other sites

Haha here's the quickie then

ALTER TABLE `field_<the_name_of_the_float_field>` MODIFY data DECIMAL(12,2);
UPDATE fields SET type='FieldtypeDecimal' WHERE id=<the_id_of_the_float_field>;

If you need more than two decimals (or more than twelve digits in general), you can safely increase the precision through the module afterwards.

  • Like 3
Link to comment
Share on other sites

Indeed. It wasn't many pages it applied to (maybe 70) but there are about 10-15 float fields in the template that need changing so yep - best to double-check these things before destroying a client's data!

  • Like 1
Link to comment
Share on other sites

  • 8 months later...

Create an account or sign in to comment

You need to be a member in order to leave a comment

Create an account

Sign up for a new account in our community. It's easy!

Register a new account

Sign in

Already have an account? Sign in here.

Sign In Now
×
×
  • Create New...