Date: prev next · Thread: first prev next last
2014 Archives by date, by thread · List index


At 16:57 08/02/2014 +0200, Hylton Conacher wrote:
What I seek is to be able to have a sheet of Lottery results downloaded from the Internet and pasted into a Calc sheet. On another Calc sheet I will have a listing of the 6 numbers held for each specific draw date. Each populated cell of my ticket sheet will indicate if the number in that cell is the same as a number in a range of cells from the results sheet, on a particular date. As an example:

Assume the draw results below dated drew the following numbers:
04/02/2014 16, 03, 19, 21, 23, 06
11/02/2014 17, 05, 02, 20, 22, 04
18/02/2014 09, 40, 05, 09, 42, 03

Also assume that draw numbers I chose for a draw on a date were:
11/02/2014  02, 05, 18, 20, 22, 04

If any number on my ticket matches a corresponding date value, I want the cell to change background colour.

Suppose the results are on a Results sheet in columns A to G, starting in row 1. Suppose also that the draw numbers are on a Tickets sheet in the same columns, again starting in row 1.

o Create a cell style with a suitable background colour.
o Select cell Tickets.B1.
o Go to Format | Conditional Formatting... .
o Tick Condition 1.
o Select "Formula is".
o For Cell Style, select your cell style with the coloured background.
o In the formula box, enter NOT(ISNA(MATCH(B1;OFFSET(Results.$B$1:$G$1;MATCH($A1;Results.$A$1:$A$99;0)-1;0);0))) . o With Tickets.B1 still selected, click the Format Paintbrush button in the Standard toolbar. o Drag the paintbrush icon from Tickets.B1 across to G1 and down as many rows as necessary.

How does it work? The inner MATCH() function searches the date column of the Results sheet and returns the row number of the matching date. The OFFSET() function then creates a reference to the range of results (Bn:Gn) for that date. The outer MATCH() function then searches that range of results for the individual ticket number, returning a column number (which we don't use) if it is found or the error value #N/A if it is not. The ISNA() function tests for #N/A, so returns TRUE if the ticket number was not found, and the NOT() function inverts this, thus returning TRUE for ticket numbers that are matched.

Note that you may need to force recalculation of cells before you see new colouring if you modify the data.

I trust this helps.

Brian Barker


--
To unsubscribe e-mail to: users+unsubscribe@global.libreoffice.org
Problems? http://www.libreoffice.org/get-help/mailing-lists/how-to-unsubscribe/
Posting guidelines + more: http://wiki.documentfoundation.org/Netiquette
List archive: http://listarchives.libreoffice.org/global/users/
All messages sent to this list will be publicly archived and cannot be deleted

Context


Privacy Policy | Impressum (Legal Info) | Copyright information: Unless otherwise specified, all text and images on this website are licensed under the Creative Commons Attribution-Share Alike 3.0 License. This does not include the source code of LibreOffice, which is licensed under the Mozilla Public License (MPLv2). "LibreOffice" and "The Document Foundation" are registered trademarks of their corresponding registered owners or are in actual use as trademarks in one or more countries. Their respective logos and icons are also subject to international copyright laws. Use thereof is explained in our trademark policy.