In a new spreadsheet, execute these macros: Sub FormulaVsFormulaLocal ' Case 1. Comparing date values oCell = ThisComponent.Sheets(0).getCellByPosition(0, 0) oCell.Formula = "2021-12-27" oCell = ThisComponent.Sheets(0).getCellByPosition(0, 1) oCell.FormulaLocal = "2021-12-27" ' Case 2. Comparing boolean values oCell = ThisComponent.Sheets(0).getCellByPosition(1, 0) oCell.Formula = "TRUE" oCell = ThisComponent.Sheets(0).getCellByPosition(1, 1) oCell.FormulaLocal = "ИСТИНА" ' Note use of *localized* (ru) name for "TRUE" ' Case 3. Comparing string values oCell = ThisComponent.Sheets(0).getCellByPosition(2, 0) oCell.Formula = "'1" oCell = ThisComponent.Sheets(0).getCellByPosition(2, 1) oCell.FormulaLocal = "'1" End Sub Given that the initial format of all the cells is "Standard", I observe the following result in Version: 7.2.4.1 (x64) / LibreOffice Community Build ID: 27d75539669ac387bb498e35313b970b7fe9c4f9 CPU threads: 12; OS: Windows 10.0 Build 19044; UI render: Skia/Raster; VCL: win Locale: ru-RU (ru_RU); UI: en-US Calc: CL Case 1. Cell A1 is still formatted as Standard. It contains number 44557. Cell A2 is formatted as Date (YYYY-MM-DD). It contains date 2021-12-27. Case 2. Cell B1 is still formatted as Standard. It contains number 1. Cell B2 is formatted as BOOLEAN. It contains value "ИСТИНА". (Note that in other locales, the string in case 2 code should be modified accordingly.) Case 3. Cell C1 is formatted as Text (@). It contains string "1" (no apostrophe). Cell C2 is formatted as Standard. It contains string "'1" (apostrophe). I suppose all cases should behave consistently, and the only difference should be that Formula takes canonical representation, and FormulaLocal takes localized strings as user may enter... Especially confusing is that case 3 reverses which cell takes new number format.
FTR: cases 1 and 2 worked exactly the same in OOo 3.2.0; case 3 gave *both* C1 and C2 formatted as Standard, and containing strings "'1".
Case 4: oCell = ThisComponent.Sheets(0).getCellByPosition(3, 0) oCell.Formula = "'foo" oCell = ThisComponent.Sheets(0).getCellByPosition(3, 1) oCell.FormulaLocal = "'foo" In this case, cell D1 contains text "foo" (no apostrophe), and D2 contains text "'foo" (apostrophe); both cells are formatted as Standard.
It's complicated.. Formula = ... goes via ScCellObj::setFormula() (an implementation of css::table::XCell::setFormula()) ScDocFunc::SetCellText() the bEnglish=true case that for the result of ScStringUtil::parseInputString() distinguishes between ScInputStringType::Formula, ScInputStringType::Number and ScInputStringType::Text and does not apply any number format for the ScInputStringType::Number case, apparently on purpose, but does force-apply the Text format for ScInputStringType::Text via ScDocFunc::SetStringCell() ScDocument::SetString() ... ScColumn::ParseString() for content that could be numeric (the leading ' apostrophe was removed in ScStringUtil::parseInputString()). FormulaLocal = ... goes via ScCellObj::SetOnePropertyValue() SC_WID_UNO_FORMLOC ScCellObj::SetString_Impl() ScDocFunc::SetCellText() the bEnglish=false case ScDocFunc::SetNormalString() ScDocument::SetString() ... ScColumn::ParseString() that does apply a number format if aParam.mbDetectNumberFormat=true and the detected format is not compatible with the previous format or none was set. Questions remains, what would actually be expected for all cases.
(In reply to Eike Rathke from comment #3) > Questions remains, what would actually be expected for all cases. Personally I would be OK with any consistent behavior, with slight preference of "as if user entered that in Input line" behavior (i.e. applying format where it's needed to show recognized number in expected fashion). But I suppose we should also consider Excel VBA behavior in this case. Vladimir, could you please provide your insight how Excel behaves in this case? Thanks.
Hello colleagues! Excel behavior. Case 1. The cell value (Value2 property) is a number (corresponding to a date), the "General" NumberFormat is changed to "YYYY-MM-DD". Case 2. The cell value is of boolean type (not available in Calc). The NumberFormat does not change. Case 3, 4. The leading apostrophe is removed (always, even if the cell NumberFormat is "@"). The cell's Range.PrefixCharacter property is set to apostrophe. I hope I didn't confuse anything. :).
Dear Mike Kaganski, To make sure we're focusing on the bugs that affect our users today, LibreOffice QA is asking bug reporters and confirmers to retest open, confirmed bugs which have not been touched for over a year. There have been thousands of bug fixes and commits since anyone checked on this bug report. During that time, it's possible that the bug has been fixed, or the details of the problem have changed. We'd really appreciate your help in getting confirmation that the bug is still present. If you have time, please do the following: Test to see if the bug is still present with the latest version of LibreOffice from https://www.libreoffice.org/download/ If the bug is present, please leave a comment that includes the information from Help - About LibreOffice. If the bug is NOT present, please set the bug's Status field to RESOLVED-WORKSFORME and leave a comment that includes the information from Help - About LibreOffice. Please DO NOT Update the version field Reply via email (please reply directly on the bug tracker) Set the bug's Status field to RESOLVED - FIXED (this status has a particular meaning that is not appropriate in this case) If you want to do more to help you can test to see if your issue is a REGRESSION. To do so: 1. Download and install oldest version of LibreOffice (usually 3.3 unless your bug pertains to a feature added after 3.3) from https://downloadarchive.documentfoundation.org/libreoffice/old/ 2. Test your bug 3. Leave a comment with your results. 4a. If the bug was present with 3.3 - set version to 'inherited from OOo'; 4b. If the bug was not present in 3.3 - add 'regression' to keyword Feel free to come ask questions or to say hello in our QA chat: https://web.libera.chat/?settings=#libreoffice-qa Thank you for helping us make LibreOffice even better for everyone! Warm Regards, QA Team MassPing-UntouchedBug