File: working_with_data_validation.rst

package info (click to toggle)
xlsxwriter 3.1.9-2
  • links: PTS, VCS
  • area: main
  • in suites: forky, sid, trixie
  • size: 56,308 kB
  • sloc: python: 51,511; javascript: 7,768; sh: 284; makefile: 195; perl: 75
file content (443 lines) | stat: -rw-r--r-- 17,004 bytes parent folder | download
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
.. SPDX-License-Identifier: BSD-2-Clause
   Copyright 2013-2023, John McNamara, jmcnamara@cpan.org

.. _working_with_data_validation:

Working with Data Validation
============================

Data validation is a feature of Excel which allows you to restrict the data
that a user enters in a cell and to display associated help and warning
messages. It also allows you to restrict input to values in a dropdown list.

A typical use case might be to restrict data in a cell to integer values in a
certain range, to provide a help message to indicate the required value and to
issue a warning if the input data doesn't meet the stated criteria. In
XlsxWriter we could do that as follows::

    worksheet.data_validation('B25', {'validate': 'integer',
                                      'criteria': 'between',
                                      'minimum': 1,
                                      'maximum': 100,
                                      'input_title': 'Enter an integer:',
                                      'input_message': 'between 1 and 100'})

.. image:: _images/data_validate1.png

If the user inputs a value that doesn't match the specified criteria an error
message is displayed:

.. image:: _images/data_validate4.png


For more information on data validation see the Microsoft support article
"Description and examples of data validation in Excel":
https://support.microsoft.com/en-us/office/apply-data-validation-to-cells-29fecbcc-d1b9-42c1-9d76-eff3ce5f7249.

The following sections describe how to use the ``data_validation()`` method and
its various options.


data_validation()
-----------------

The :func:`data_validation()` method is used to construct an Excel data
validation.

The data validation can be applied to a single cell or a range of cells. As
usual you can use A1 or Row/Column notation, see :ref:`cell_notation`.

With Row/Column notation you must specify all four cells in the range:
``(first_row, first_col, last_row, last_col)``. If you need to refer to a
single cell set the `last_` values equal to the `first_` values. With A1
notation you can refer to a single cell or a range of cells::

    worksheet.data_validation(0, 0, 4, 1, {...})
    worksheet.data_validation('B1',       {...})
    worksheet.data_validation('C1:E5',    {...})

The options parameter in ``data_validation()`` must be a dictionary containing
the parameters that describe the type and style of the data validation. The
main parameters are:

+-------------------+-------------+------------+
| ``validate``      |             |            |
+-------------------+-------------+------------+
| ``criteria``      |             |            |
+-------------------+-------------+------------+
| ``value``         | ``minimum`` | ``source`` |
+-------------------+-------------+------------+
| ``maximum``       |             |            |
+-------------------+-------------+------------+
| ``ignore_blank``  |             |            |
+-------------------+-------------+------------+
| ``dropdown``      |             |            |
+-------------------+-------------+------------+
| ``input_title``   |             |            |
+-------------------+-------------+------------+
| ``input_message`` |             |            |
+-------------------+-------------+------------+
| ``show_input``    |             |            |
+-------------------+-------------+------------+
| ``error_title``   |             |            |
+-------------------+-------------+------------+
| ``error_message`` |             |            |
+-------------------+-------------+------------+
| ``error_type``    |             |            |
+-------------------+-------------+------------+
| ``show_error``    |             |            |
+-------------------+-------------+------------+
| ``multi_range``   |             |            |
+-------------------+-------------+------------+

These parameters are explained in the following sections. Most of the
parameters are optional, however, you will generally require the three main
options ``validate``, ``criteria`` and ``value``::

    worksheet.data_validation('A1', {'validate': 'integer',
                                     'criteria': '>',
                                     'value': 100})


validate
********

The ``validate`` parameter is used to set the type of data that you wish to
validate::

    worksheet.data_validation('A1', {'validate': 'integer',
                                     'criteria': '>',
                                     'value': 100})

It is always required and it has no default value. Allowable values are::

    integer
    decimal
    list
    date
    time
    length
    custom
    any

* **integer**: restricts the cell to integer values. Excel refers to this as
  'whole number'.
* **decimal**: restricts the cell to decimal values.
* **list**: restricts the cell to a set of user specified values. These can
  be passed in a Python list or as an Excel cell range.
* **date**: restricts the cell to date values specified as a datetime object
  as shown in :ref:`working_with_dates_and_time` or a date formula.
* **time**: restricts the cell to time values specified as a datetime object
  as shown in :ref:`working_with_dates_and_time` or a time formula.
* **length**: restricts the cell data based on an integer string length.
  Excel refers to this as 'Text length'.
* **custom**: restricts the cell based on an external Excel formula that
  returns a ``TRUE/FALSE`` value.
* **any**: is used to specify that the type of data is unrestricted. It is
  mainly used for specifying cell input messages without a data validation.


criteria
********

The ``criteria`` parameter is used to set the criteria by which the data in the
cell is validated. It is almost always required except for the ``list``,
``custom`` and ``any`` validate options. It has no default value::

    worksheet.data_validation('A1', {'validate': 'integer',
                                     'criteria': '>',
                                     'value': 100})


Allowable values are:

+------------------------------+--------+
| ``between``                  |        |
+------------------------------+--------+
| ``not between``              |        |
+------------------------------+--------+
| ``equal to``                 | ``==`` |
+------------------------------+--------+
| ``not equal to``             | ``!=`` |
+------------------------------+--------+
| ``greater than``             | ``>``  |
+------------------------------+--------+
| ``less than``                | ``<``  |
+------------------------------+--------+
| ``greater than or equal to`` | ``>=`` |
+------------------------------+--------+
| ``less than or equal to``    | ``<=`` |
+------------------------------+--------+

You can either use Excel's textual description strings, in the first column
above, or the more common symbolic alternatives. The following are equivalent::

    worksheet.data_validation('A1', {'validate': 'integer',
                                     'criteria': '>',
                                     'value': 100})

    worksheet.data_validation('A1', {'validate': 'integer',
                                     'criteria': 'greater than',
                                     'value': 100})

The ``list``, ``custom`` and ``any`` validate options don't require a
``criteria``. If you specify one it will be ignored::

    worksheet.data_validation('B13', {'validate': 'list',
                                      'source': ['open', 'high', 'close']})

    worksheet.data_validation('B23', {'validate': 'custom',
                                      'value': '=AND(F5=50,G5=60)'})

value, minimum, source
**********************

The ``value`` parameter is used to set the limiting value to which the
``criteria`` is applied. It is always required and it has no default value.
You can also use the synonyms ``minimum`` or ``source`` to make the validation
a little clearer and closer to Excel's description of the parameter::

    # Using 'value'.
    worksheet.data_validation('A1', {'validate': 'integer',
                                     'criteria': 'greater than',
                                     'value': 100})

    # Using 'minimum'.
    worksheet.data_validation('B11', {'validate': 'decimal',
                                      'criteria': 'between',
                                      'minimum': 0.1,
                                      'maximum': 0.5})

    # Using 'source'.
    worksheet.data_validation('B10', {'validate': 'list',
                                      'source': '=$E$4:$G$4'})

    # Using 'source' with a string list.
    worksheet.data_validation('B13', {'validate': 'list',
                                      'source': ['open', 'high', 'close']})


Note, when using the ``list`` validation with a list of strings, like in the
last example above, Excel stores the strings internally as a Comma Separated
Variable string. The total length for this string, including commas, cannot
exceed the Excel limit of 255 characters. For longer sets of data you should
use a range reference like the prior example above. Also any double quotes in
strings like ``'"Hello"'`` must be double quoted like this ``'""Hello""'``.


maximum
*******

The ``maximum`` parameter is used to set the upper limiting value when the
``criteria`` is either ``'between'`` or ``'not between'``::

    worksheet.data_validation('B11', {'validate': 'decimal',
                                      'criteria': 'between',
                                      'minimum': 0.1,
                                      'maximum': 0.5})


ignore_blank
************

The ``ignore_blank`` parameter is used to toggle on and off the 'Ignore blank'
option in the Excel data validation dialog. When the option is on the data
validation is not applied to blank data in the cell. It is on by default::

        worksheet.data_validation('B5', {'validate': 'integer',
                                         'criteria': 'between',
                                         'minimum': 1,
                                         'maximum': 10,
                                         'ignore_blank': False,
                                         })


dropdown
********

The ``dropdown`` parameter is used to toggle on and off the 'In-cell dropdown'
option in the Excel data validation dialog. When the option is on a dropdown
list will be shown for ``list`` validations. It is on by default.


input_title
***********

The ``input_title`` parameter is used to set the title of the input message
that is displayed when a cell is entered. It has no default value and is only
displayed if the input message is displayed. See the ``input_message``
parameter below.

The maximum title length is 32 characters.


input_message
*************

The ``input_message`` parameter is used to set the input message that is
displayed when a cell is entered. It has no default value::

    worksheet.data_validation('B25', {'validate': 'integer',
                                      'criteria': 'between',
                                      'minimum': 1,
                                      'maximum': 100,
                                      'input_title': 'Enter an integer:',
                                      'input_message': 'between 1 and 100'})

The input message generated from the above example is:

.. image:: _images/data_validate3.png

The message can be split over several lines using newlines. The maximum message
length is 255 characters.


show_input
**********

The ``show_input`` parameter is used to toggle on and off the 'Show input
message when cell is selected' option in the Excel data validation dialog.
When the option is off an input message is not displayed even if it has been
set using ``input_message``. It is on by default.


error_title
***********

The ``error_title`` parameter is used to set the title of the error message
that is displayed when the data validation criteria is not met. The default
error title is 'Microsoft Excel'. The maximum title length is 32 characters.


error_message
*************

The ``error_message`` parameter is used to set the error message that is
displayed when a cell is entered. The default error message is "The value you
entered is not valid. A user has restricted values that can be entered into
the cell.". A non-default error message can be displayed as follows::

    worksheet.data_validation('B27', {'validate': 'integer',
                                      'criteria': 'between',
                                      'minimum': 1,
                                      'maximum': 100,
                                      'input_title': 'Enter an integer:',
                                      'input_message': 'between 1 and 100',
                                      'error_title': 'Input value not valid!',
                                      'error_message': 'It should be an integer between 1 and 100'})

Which give the following message:

.. image:: _images/data_validate2.png

The message can be split over several lines using newlines. The maximum message
length is 255 characters.


error_type
**********

The ``error_type`` parameter is used to specify the type of error dialog that
is displayed. There are 3 options::

    'stop'
    'warning'
    'information'

The default is ``'stop'``.


show_error
**********

The ``show_error`` parameter is used to toggle on and off the 'Show error alert
after invalid data is entered' option in the Excel data validation dialog.
When the option is off an error message is not displayed even if it has been
set using ``error_message``. It is on by default.


multi_range
***********

The ``multi_range`` option is used to extend a data validation over
non-contiguous ranges.

It is possible to apply the data validation to different cell ranges in a
worksheet using multiple calls to ``data_validation()``. However, as a
minor optimization it is also possible in Excel to apply the same data
validation to different non-contiguous cell ranges.

This is replicated in ``data_validation()`` using the ``multi_range``
option. The range must contain the primary range for the data validation
and any others separated by spaces.

For example to apply one data validation to two ranges, ``'B3:K6'`` and
``'B9:K12'``::

    worksheet.data_validation('B3:K6', {'validate': 'integer',
                                        'criteria': 'between',
                                        'minimum': 1,
                                        'maximum': 100,
                                        'multi_range': 'B3:K6 B9:K12'})


Data Validation Examples
------------------------

Example 1. Limiting input to an integer greater than a fixed value::

    worksheet.data_validation('A1', {'validate': 'integer',
                                     'criteria': '>',
                                     'value': 0,
                                     })

Example 2. Limiting input to an integer greater than a fixed value where the
value is referenced from a cell::

    worksheet.data_validation('A2', {'validate': 'integer',
                                     'criteria': '>',
                                     'value': '=E3',
                                     })

Example 3. Limiting input to a decimal in a fixed range::

    worksheet.data_validation('A3', {'validate': 'decimal',
                                     'criteria': 'between',
                                     'minimum': 0.1,
                                     'maximum': 0.5,
                                     })

Example 4. Limiting input to a value in a dropdown list::

    worksheet.data_validation('A4', {'validate': 'list',
                                     'source': ['open', 'high', 'close'],
                                     })

Example 5. Limiting input to a value in a dropdown list where the list is
specified as a cell range::

    worksheet.data_validation('A5', {'validate': 'list',
                                     'source': '=$E$4:$G$4',
                                     })

Example 6. Limiting input to a date in a fixed range::

    from datetime import date

    worksheet.data_validation('A6', {'validate': 'date',
                                     'criteria': 'between',
                                     'minimum': date(2013, 1, 1),
                                     'maximum': date(2013, 12, 12),
                                     })

Example 7. Displaying a message when the cell is selected::

    worksheet.data_validation('A7', {'validate': 'integer',
                                     'criteria': 'between',
                                     'minimum': 1,
                                     'maximum': 100,
                                     'input_title': 'Enter an integer:',
                                     'input_message': 'between 1 and 100',
                                     })

See also :ref:`ex_data_valid`.