1Excel::Writer::XLSX(3)User Contributed Perl DocumentationExcel::Writer::XLSX(3)
2
3
4
6 Excel::Writer::XLSX - Create a new file in the Excel 2007+ XLSX format.
7
9 To write a string, a formatted string, a number and a formula to the
10 first worksheet in an Excel workbook called perl.xlsx:
11
12 use Excel::Writer::XLSX;
13
14 # Create a new Excel workbook
15 my $workbook = Excel::Writer::XLSX->new( 'perl.xlsx' );
16
17 # Add a worksheet
18 $worksheet = $workbook->add_worksheet();
19
20 # Add and define a format
21 $format = $workbook->add_format();
22 $format->set_bold();
23 $format->set_color( 'red' );
24 $format->set_align( 'center' );
25
26 # Write a formatted and unformatted string, row and column notation.
27 $col = $row = 0;
28 $worksheet->write( $row, $col, 'Hi Excel!', $format );
29 $worksheet->write( 1, $col, 'Hi Excel!' );
30
31 # Write a number and a formula using A1 notation
32 $worksheet->write( 'A3', 1.2345 );
33 $worksheet->write( 'A4', '=SIN(PI()/4)' );
34
35 $workbook->close();
36
38 The "Excel::Writer::XLSX" module can be used to create an Excel file in
39 the 2007+ XLSX format.
40
41 Multiple worksheets can be added to a workbook and formatting can be
42 applied to cells. Text, numbers, and formulas can be written to the
43 cells.
44
46 "Excel::Writer::XLSX" uses the same interface as the
47 Spreadsheet::WriteExcel module which produces an Excel file in binary
48 XLS format.
49
51 Excel::Writer::XLSX tries to provide an interface to as many of Excel's
52 features as possible. As a result there is a lot of documentation to
53 accompany the interface and it can be difficult at first glance to see
54 what it important and what is not. So for those of you who prefer to
55 assemble Ikea furniture first and then read the instructions, here are
56 four easy steps:
57
58 1. Create a new Excel workbook (i.e. file) using new().
59
60 2. Add a worksheet to the new workbook using add_worksheet().
61
62 3. Write to the worksheet using write().
63
64 4. close() the file.
65
66 Like this:
67
68 use Excel::Writer::XLSX; # Step 0
69
70 my $workbook = Excel::Writer::XLSX->new( 'perl.xlsx' ); # Step 1
71 $worksheet = $workbook->add_worksheet(); # Step 2
72 $worksheet->write( 'A1', 'Hi Excel!' ); # Step 3
73
74 $workbook->close(); # Step 4
75
76 This will create an Excel file called "perl.xlsx" with a single
77 worksheet and the text 'Hi Excel!' in the relevant cell. And that's it.
78 Okay, so there is actually a zeroth step as well, but "use module" goes
79 without saying. There are many examples that come with the distribution
80 and which you can use to get you started. See "EXAMPLES".
81
82 Those of you who read the instructions first and assemble the furniture
83 afterwards will know how to proceed. ;-)
84
86 The Excel::Writer::XLSX module provides an object oriented interface to
87 a new Excel workbook. The following methods are available through a new
88 workbook.
89
90 new()
91 add_worksheet()
92 add_format()
93 add_chart()
94 add_shape()
95 add_vba_project()
96 set_vba_name()
97 close()
98 set_properties()
99 set_custom_property()
100 define_name()
101 set_tempdir()
102 set_custom_color()
103 sheets()
104 get_worksheet_by_name()
105 set_1904()
106 set_optimization()
107 set_calc_mode()
108 get_default_url_format()
109 read_only_recommended()
110
111 If you are unfamiliar with object oriented interfaces or the way that
112 they are implemented in Perl have a look at "perlobj" and "perltoot" in
113 the main Perl documentation.
114
115 new()
116 A new Excel workbook is created using the new() constructor which
117 accepts either a filename or a filehandle as a parameter. The following
118 example creates a new Excel file based on a filename:
119
120 my $workbook = Excel::Writer::XLSX->new( 'filename.xlsx' );
121 my $worksheet = $workbook->add_worksheet();
122 $worksheet->write( 0, 0, 'Hi Excel!' );
123 $workbook->close();
124
125 Here are some other examples of using new() with filenames:
126
127 my $workbook1 = Excel::Writer::XLSX->new( $filename );
128 my $workbook2 = Excel::Writer::XLSX->new( '/tmp/filename.xlsx' );
129 my $workbook3 = Excel::Writer::XLSX->new( "c:\\tmp\\filename.xlsx" );
130 my $workbook4 = Excel::Writer::XLSX->new( 'c:\tmp\filename.xlsx' );
131
132 The last two examples demonstrates how to create a file on DOS or
133 Windows where it is necessary to either escape the directory separator
134 "\" or to use single quotes to ensure that it isn't interpolated. For
135 more information see "perlfaq5: Why can't I use "C:\temp\foo" in DOS
136 paths?".
137
138 It is recommended that the filename uses the extension ".xlsx" rather
139 than ".xls" since the latter causes an Excel warning when used with the
140 XLSX format.
141
142 The new() constructor returns a Excel::Writer::XLSX object that you can
143 use to add worksheets and store data. It should be noted that although
144 "my" is not specifically required it defines the scope of the new
145 workbook variable and, in the majority of cases, ensures that the
146 workbook is closed properly without explicitly calling the close()
147 method.
148
149 If the file cannot be created, due to file permissions or some other
150 reason, "new" will return "undef". Therefore, it is good practice to
151 check the return value of "new" before proceeding. As usual the Perl
152 variable $! will be set if there is a file creation error. You will
153 also see one of the warning messages detailed in "DIAGNOSTICS":
154
155 my $workbook = Excel::Writer::XLSX->new( 'protected.xlsx' );
156 die "Problems creating new Excel file: $!" unless defined $workbook;
157
158 You can also pass a valid filehandle to the new() constructor. For
159 example in a CGI program you could do something like this:
160
161 binmode( STDOUT );
162 my $workbook = Excel::Writer::XLSX->new( \*STDOUT );
163
164 The requirement for binmode() is explained below.
165
166 See also, the "cgi.pl" program in the "examples" directory of the
167 distro.
168
169 In "mod_perl" programs where you will have to do something like the
170 following:
171
172 # mod_perl 1
173 ...
174 tie *XLSX, 'Apache';
175 binmode( XLSX );
176 my $workbook = Excel::Writer::XLSX->new( \*XLSX );
177 ...
178
179 # mod_perl 2
180 ...
181 tie *XLSX => $r; # Tie to the Apache::RequestRec object
182 binmode( *XLSX );
183 my $workbook = Excel::Writer::XLSX->new( \*XLSX );
184 ...
185
186 See also, the "mod_perl1.pl" and "mod_perl2.pl" programs in the
187 "examples" directory of the distro.
188
189 Filehandles can also be useful if you want to stream an Excel file over
190 a socket or if you want to store an Excel file in a scalar.
191
192 For example here is a way to write an Excel file to a scalar:
193
194 #!/usr/bin/perl -w
195
196 use strict;
197 use Excel::Writer::XLSX;
198
199 open my $fh, '>', \my $str or die "Failed to open filehandle: $!";
200
201 my $workbook = Excel::Writer::XLSX->new( $fh );
202 my $worksheet = $workbook->add_worksheet();
203
204 $worksheet->write( 0, 0, 'Hi Excel!' );
205
206 $workbook->close();
207
208 # The Excel file in now in $str. Remember to binmode() the output
209 # filehandle before printing it.
210 binmode STDOUT;
211 print $str;
212
213 See also the "write_to_scalar.pl" and "filehandle.pl" programs in the
214 "examples" directory of the distro.
215
216 Note about the requirement for binmode(). An Excel file is comprised of
217 binary data. Therefore, if you are using a filehandle you should ensure
218 that you binmode() it prior to passing it to new().You should do this
219 regardless of whether you are on a Windows platform or not.
220
221 You don't have to worry about binmode() if you are using filenames
222 instead of filehandles. Excel::Writer::XLSX performs the binmode()
223 internally when it converts the filename to a filehandle. For more
224 information about binmode() see "perlfunc" and "perlopentut" in the
225 main Perl documentation.
226
227 add_worksheet( $sheetname )
228 At least one worksheet should be added to a new workbook. A worksheet
229 is used to write data into cells:
230
231 $worksheet1 = $workbook->add_worksheet(); # Sheet1
232 $worksheet2 = $workbook->add_worksheet( 'Foglio2' ); # Foglio2
233 $worksheet3 = $workbook->add_worksheet( 'Data' ); # Data
234 $worksheet4 = $workbook->add_worksheet(); # Sheet4
235
236 If $sheetname is not specified the default Excel convention will be
237 followed, i.e. Sheet1, Sheet2, etc.
238
239 The worksheet name must be a valid Excel worksheet name, i.e:
240
241 • It must be less than 32 characters.
242
243 • It cannot contain any of the following characters: "[ ] : * ? / \"
244
245 • It cannot start or end with an apostrophe.
246
247 • It cannot be the same as an existing worksheet name (or a case
248 insensitive variant).
249
250 Note, the sheetname should not be "History" (case insensitive) which is
251 reserved in English language versions of Excel. Non-English versions
252 may have restrictions on the equivalent word.
253
254 See the Excel worksheet naming rules at
255 <https://support.office.com/en-ie/article/rename-a-worksheet-3f1f7148-ee83-404d-8ef0-9ff99fbad1f9>.
256
257 add_format( %properties )
258 The add_format() method can be used to create new Format objects which
259 are used to apply formatting to a cell. You can either define the
260 properties at creation time via a hash of property values or later via
261 method calls.
262
263 $format1 = $workbook->add_format( %props ); # Set properties at creation
264 $format2 = $workbook->add_format(); # Set properties later
265
266 See the "CELL FORMATTING" section for more details about Format
267 properties and how to set them.
268
269 add_chart( %properties )
270 This method is use to create a new chart either as a standalone
271 worksheet (the default) or as an embeddable object that can be inserted
272 into a worksheet via the insert_chart() Worksheet method.
273
274 my $chart = $workbook->add_chart( type => 'column' );
275
276 The properties that can be set are:
277
278 type (required)
279 subtype (optional)
280 name (optional)
281 embedded (optional)
282
283 • "type"
284
285 This is a required parameter. It defines the type of chart that
286 will be created.
287
288 my $chart = $workbook->add_chart( type => 'line' );
289
290 The available types are:
291
292 area
293 bar
294 column
295 line
296 pie
297 doughnut
298 scatter
299 stock
300
301 • "subtype"
302
303 Used to define a chart subtype where available.
304
305 my $chart = $workbook->add_chart( type => 'bar', subtype => 'stacked' );
306
307 See the Excel::Writer::XLSX::Chart documentation for a list of
308 available chart subtypes.
309
310 • "name"
311
312 Set the name for the chart sheet. The name property is optional and
313 if it isn't supplied will default to "Chart1 .. n". The name must
314 be a valid Excel worksheet name. See add_worksheet() for more
315 details on valid sheet names. The "name" property can be omitted
316 for embedded charts.
317
318 my $chart = $workbook->add_chart( type => 'line', name => 'Results Chart' );
319
320 • "embedded"
321
322 Specifies that the Chart object will be inserted in a worksheet via
323 the insert_chart() Worksheet method. It is an error to try insert a
324 Chart that doesn't have this flag set.
325
326 my $chart = $workbook->add_chart( type => 'line', embedded => 1 );
327
328 # Configure the chart.
329 ...
330
331 # Insert the chart into the a worksheet.
332 $worksheet->insert_chart( 'E2', $chart );
333
334 See Excel::Writer::XLSX::Chart for details on how to configure the
335 chart object once it is created. See also the "chart_*.pl" programs in
336 the examples directory of the distro.
337
338 add_shape( %properties )
339 The add_shape() method can be used to create new shapes that may be
340 inserted into a worksheet.
341
342 You can either define the properties at creation time via a hash of
343 property values or later via method calls.
344
345 # Set properties at creation.
346 $plus = $workbook->add_shape(
347 type => 'plus',
348 id => 3,
349 width => $pw,
350 height => $ph
351 );
352
353
354 # Default rectangle shape. Set properties later.
355 $rect = $workbook->add_shape();
356
357 See Excel::Writer::XLSX::Shape for details on how to configure the
358 shape object once it is created.
359
360 See also the "shape*.pl" programs in the examples directory of the
361 distro.
362
363 add_vba_project( 'vbaProject.bin' )
364 The add_vba_project() method can be used to add macros or functions to
365 an Excel::Writer::XLSX file using a binary VBA project file that has
366 been extracted from an existing Excel "xlsm" file.
367
368 my $workbook = Excel::Writer::XLSX->new( 'file.xlsm' );
369
370 $workbook->add_vba_project( './vbaProject.bin' );
371
372 The supplied "extract_vba" utility can be used to extract the required
373 "vbaProject.bin" file from an existing Excel file:
374
375 $ extract_vba file.xlsm
376 Extracted 'vbaProject.bin' successfully
377
378 Macros can be tied to buttons using the worksheet insert_button()
379 method (see the "WORKSHEET METHODS" section for details):
380
381 $worksheet->insert_button( 'C2', { macro => 'my_macro' } );
382
383 Note, Excel uses the file extension "xlsm" instead of "xlsx" for files
384 that contain macros. It is advisable to follow the same convention.
385
386 See also the "macros.pl" example file and the "WORKING WITH VBA
387 MACROS".
388
389 set_vba_name()
390 The set_vba_name() method can be used to set the VBA codename for the
391 workbook. This is sometimes required when a "vbaProject macro" included
392 via add_vba_project() refers to the workbook. The default Excel VBA
393 name of "ThisWorkbook" is used if a user defined name isn't specified.
394 See also "WORKING WITH VBA MACROS".
395
396 close()
397 In general your Excel file will be closed automatically when your
398 program ends or when the Workbook object goes out of scope. However it
399 is recommended to explicitly call the close() method close the Excel
400 file and avoid the potential issues outlined below. The close() method
401 is called like this:
402
403 $workbook->close();
404
405 The return value of close() is the same as that returned by perl when
406 it closes the file created by new(). This allows you to handle error
407 conditions in the usual way:
408
409 $workbook->close() or die "Error closing file: $!";
410
411 An explicit close() is required if the file must be closed prior to
412 performing some external action on it such as copying it, reading its
413 size or attaching it to an email.
414
415 In addition, close() may be required to prevent perl's garbage
416 collector from disposing of the Workbook, Worksheet and Format objects
417 in the wrong order. Situations where this can occur are:
418
419 • If my() was not used to declare the scope of a workbook variable
420 created using new().
421
422 • If the new(), add_worksheet() or add_format() methods are called in
423 subroutines.
424
425 The reason for this is that Excel::Writer::XLSX relies on Perl's
426 "DESTROY" mechanism to trigger destructor methods in a specific
427 sequence. This may not happen in cases where the Workbook, Worksheet
428 and Format variables are not lexically scoped or where they have
429 different lexical scopes.
430
431 To avoid these issues it is recommended that you always close the
432 Excel::Writer::XLSX filehandle using close().
433
434 set_size( $width, $height )
435 The set_size() method can be used to set the size of a workbook window.
436
437 $workbook->set_size(1200, 800);
438
439 The Excel window size was used in Excel 2007 to define the width and
440 height of a workbook window within the Multiple Document Interface
441 (MDI). In later versions of Excel for Windows this interface was
442 dropped. This method is currently only useful when setting the window
443 size in Excel for Mac 2011. The units are pixels and the default size
444 is 1073 x 644.
445
446 Note, this doesn't equate exactly to the Excel for Mac pixel size since
447 it is based on the original Excel 2007 for Windows sizing.
448
449 set_tab_ratio( $tab_ratio )
450 The set_tab_ratio() method can be used to set the ratio between
451 worksheet tabs and the horizontal slider at the bottom of a workbook.
452 This can be increased to give more room to the tabs or reduced to
453 increase the size of the horizontal slider:
454
455 $workbook->set_tab_ratio(75);
456
457 The default value in Excel is 60.
458
459 set_properties()
460 The "set_properties" method can be used to set the document properties
461 of the Excel file created by "Excel::Writer::XLSX". These properties
462 are visible when you use the "Office Button -> Prepare -> Properties"
463 option in Excel and are also available to external applications that
464 read or index Windows files.
465
466 The properties should be passed in hash format as follows:
467
468 $workbook->set_properties(
469 title => 'This is an example spreadsheet',
470 author => 'John McNamara',
471 comments => 'Created with Perl and Excel::Writer::XLSX',
472 );
473
474 The properties that can be set are:
475
476 title
477 subject
478 author
479 manager
480 company
481 category
482 keywords
483 comments
484 status
485 hyperlink_base
486 created - File create date. Such be an aref of gmtime() values.
487
488 See also the "properties.pl" program in the examples directory of the
489 distro.
490
491 set_custom_property( $name, $value, $type)
492 The "set_custom_property" method can be used to set one of more custom
493 document properties not covered by the set_properties() method above.
494 These properties are visible when you use the "Office Button -> Prepare
495 -> Properties -> Advanced Properties -> Custom" option in Excel and are
496 also available to external applications that read or index Windows
497 files.
498
499 The "set_custom_property" method takes 3 parameters:
500
501 $workbook-> set_custom_property( $name, $value, $type);
502
503 Where the available types are:
504
505 text
506 date
507 number
508 bool
509
510 For example:
511
512 $workbook->set_custom_property( 'Checked by', 'Eve', 'text' );
513 $workbook->set_custom_property( 'Date completed', '2016-12-12T23:00:00Z', 'date' );
514 $workbook->set_custom_property( 'Document number', '12345' , 'number' );
515 $workbook->set_custom_property( 'Reference', '1.2345', 'number' );
516 $workbook->set_custom_property( 'Has review', 1, 'bool' );
517 $workbook->set_custom_property( 'Signed off', 0, 'bool' );
518 $workbook->set_custom_property( 'Department', $some_string, 'text' );
519 $workbook->set_custom_property( 'Scale', '1.2345678901234', 'number' );
520
521 Dates should by in ISO8601 "yyyy-mm-ddThh:mm:ss.sssZ" date format in
522 Zulu time, as shown above.
523
524 The "text" and "number" types are optional since they can usually be
525 inferred from the data:
526
527 $workbook->set_custom_property( 'Checked by', 'Eve' );
528 $workbook->set_custom_property( 'Reference', '1.2345' );
529
530 The $name and $value parameters are limited to 255 characters by Excel.
531
532 define_name()
533 This method is used to defined a name that can be used to represent a
534 value, a single cell or a range of cells in a workbook.
535
536 For example to set a global/workbook name:
537
538 # Global/workbook names.
539 $workbook->define_name( 'Exchange_rate', '=0.96' );
540 $workbook->define_name( 'Sales', '=Sheet1!$G$1:$H$10' );
541
542 It is also possible to define a local/worksheet name by prefixing the
543 name with the sheet name using the syntax "sheetname!definedname":
544
545 # Local/worksheet name.
546 $workbook->define_name( 'Sheet2!Sales', '=Sheet2!$G$1:$G$10' );
547
548 If the sheet name contains spaces or special characters you must
549 enclose it in single quotes like in Excel:
550
551 $workbook->define_name( "'New Data'!Sales", '=Sheet2!$G$1:$G$10' );
552
553 See the defined_name.pl program in the examples dir of the distro.
554
555 Refer to the following to see Excel's syntax rules for defined names:
556 <http://office.microsoft.com/en-001/excel-help/define-and-use-names-in-formulas-HA010147120.aspx#BMsyntax_rules_for_names>
557
558 set_tempdir()
559 "Excel::Writer::XLSX" stores worksheet data in temporary files prior to
560 assembling the final workbook.
561
562 The "File::Temp" module is used to create these temporary files.
563 File::Temp uses "File::Spec" to determine an appropriate location for
564 these files such as "/tmp" or "c:\windows\temp". You can find out which
565 directory is used on your system as follows:
566
567 perl -MFile::Spec -le "print File::Spec->tmpdir()"
568
569 If the default temporary file directory isn't accessible to your
570 application, or doesn't contain enough space, you can specify an
571 alternative location using the set_tempdir() method:
572
573 $workbook->set_tempdir( '/tmp/writeexcel' );
574 $workbook->set_tempdir( 'c:\windows\temp\writeexcel' );
575
576 The directory for the temporary file must exist, set_tempdir() will not
577 create a new directory.
578
579 set_custom_color( $index, $red, $green, $blue )
580 The method is maintained for backward compatibility with
581 Spreadsheet::WriteExcel. Excel::Writer::XLSX programs don't require
582 this method and colours can be specified using a Html style "#RRGGBB"
583 value, see "WORKING WITH COLOURS".
584
585 sheets( 0, 1, ... )
586 The sheets() method returns a list, or a sliced list, of the worksheets
587 in a workbook.
588
589 If no arguments are passed the method returns a list of all the
590 worksheets in the workbook. This is useful if you want to repeat an
591 operation on each worksheet:
592
593 for $worksheet ( $workbook->sheets() ) {
594 print $worksheet->get_name();
595 }
596
597 You can also specify a slice list to return one or more worksheet
598 objects:
599
600 $worksheet = $workbook->sheets( 0 );
601 $worksheet->write( 'A1', 'Hello' );
602
603 Or since the return value from sheets() is a reference to a worksheet
604 object you can write the above example as:
605
606 $workbook->sheets( 0 )->write( 'A1', 'Hello' );
607
608 The following example returns the first and last worksheet in a
609 workbook:
610
611 for $worksheet ( $workbook->sheets( 0, -1 ) ) {
612 # Do something
613 }
614
615 Array slices are explained in the "perldata" manpage.
616
617 get_worksheet_by_name()
618 The get_worksheet_by_name() function return a worksheet or chartsheet
619 object in the workbook using the sheetname:
620
621 $worksheet = $workbook->get_worksheet_by_name('Sheet1');
622
623 set_1904()
624 Excel stores dates as real numbers where the integer part stores the
625 number of days since the epoch and the fractional part stores the
626 percentage of the day. The epoch can be either 1900 or 1904. Excel for
627 Windows uses 1900 and Excel for Macintosh uses 1904. However, Excel on
628 either platform will convert automatically between one system and the
629 other.
630
631 Excel::Writer::XLSX stores dates in the 1900 format by default. If you
632 wish to change this you can call the set_1904() workbook method. You
633 can query the current value by calling the get_1904() workbook method.
634 This returns 0 for 1900 and 1 for 1904.
635
636 See also "DATES AND TIME IN EXCEL" for more information about working
637 with Excel's date system.
638
639 In general you probably won't need to use set_1904().
640
641 set_optimization()
642 The set_optimization() method is used to turn on optimizations in the
643 Excel::Writer::XLSX module. Currently there is only one optimization
644 available and that is to reduce memory usage.
645
646 $workbook->set_optimization();
647
648 See "SPEED AND MEMORY USAGE" for more background information.
649
650 Note, that with this optimization turned on a row of data is written
651 and then discarded when a cell in a new row is added via one of the
652 Worksheet "write_*()" methods. As such data should be written in
653 sequential row order once the optimization is turned on.
654
655 This method must be called before any calls to add_worksheet().
656
657 set_calc_mode( $mode )
658 Set the calculation mode for formulas in the workbook. This is mainly
659 of use for workbooks with slow formulas where you want to allow the
660 user to calculate them manually.
661
662 The mode parameter can be one of the following strings:
663
664 "auto"
665 The default. Excel will re-calculate formulas when a formula or a
666 value affecting the formula changes.
667
668 "manual"
669 Only re-calculate formulas when the user requires it. Generally by
670 pressing F9.
671
672 "auto_except_tables"
673 Excel will automatically re-calculate formulas except for tables.
674
675 get_default_url_format()
676 The get_default_url_format() method gets a copy of the default url
677 format used when a user defined format isn't specified with the
678 worksheet write_url() method. The format is the hyperlink style defined
679 by Excel for the default theme:
680
681 my $url_format = $workbook->get_default_url_format();
682
683 read_only_recommended()
684 The read_only_recommended() method can be used to set the Excel "Read-
685 only Recommended" option that is available when saving a file. This
686 presents the user of the file with an option to open it in "read-only"
687 mode. This means that any changes to the file can't be saved back to
688 the same file and must be saved to a new file. It can be set as
689 follows:
690
691 $workbook->read_only_recommended();
692
694 A new worksheet is created by calling the add_worksheet() method from a
695 workbook object:
696
697 $worksheet1 = $workbook->add_worksheet();
698 $worksheet2 = $workbook->add_worksheet();
699
700 The following methods are available through a new worksheet:
701
702 write()
703 write_number()
704 write_string()
705 write_rich_string()
706 keep_leading_zeros()
707 write_blank()
708 write_row()
709 write_col()
710 write_date_time()
711 write_url()
712 write_url_range()
713 write_formula()
714 write_boolean()
715 write_comment()
716 show_comments()
717 set_comments_author()
718 add_write_handler()
719 insert_image()
720 insert_chart()
721 insert_shape()
722 insert_button()
723 data_validation()
724 conditional_formatting()
725 add_sparkline()
726 add_table()
727 get_name()
728 activate()
729 select()
730 hide()
731 set_first_sheet()
732 protect()
733 unprotect_range()
734 set_selection()
735 set_row()
736 set_row_pixels()
737 set_default_row()
738 set_column()
739 set_column_pixels()
740 outline_settings()
741 freeze_panes()
742 split_panes()
743 merge_range()
744 merge_range_type()
745 set_zoom()
746 right_to_left()
747 hide_zero()
748 set_background()
749 set_tab_color()
750 autofilter()
751 filter_column()
752 filter_column_list()
753 set_vba_name()
754 ignore_errors()
755
756 Cell notation
757 Excel::Writer::XLSX supports two forms of notation to designate the
758 position of cells: Row-column notation and A1 notation.
759
760 Row-column notation uses a zero based index for both row and column
761 while A1 notation uses the standard Excel alphanumeric sequence of
762 column letter and 1-based row. For example:
763
764 (0, 0) # The top left cell in row-column notation.
765 ('A1') # The top left cell in A1 notation.
766
767 (1999, 29) # Row-column notation.
768 ('AD2000') # The same cell in A1 notation.
769
770 Row-column notation is useful if you are referring to cells
771 programmatically:
772
773 for my $i ( 0 .. 9 ) {
774 $worksheet->write( $i, 0, 'Hello' ); # Cells A1 to A10
775 }
776
777 A1 notation is useful for setting up a worksheet manually and for
778 working with formulas:
779
780 $worksheet->write( 'H1', 200 );
781 $worksheet->write( 'H2', '=H1+1' );
782
783 In formulas and applicable methods you can also use the "A:A" column
784 notation:
785
786 $worksheet->write( 'A1', '=SUM(B:B)' );
787
788 The "Excel::Writer::XLSX::Utility" module that is included in the
789 distro contains helper functions for dealing with A1 notation, for
790 example:
791
792 use Excel::Writer::XLSX::Utility;
793
794 ( $row, $col ) = xl_cell_to_rowcol( 'C2' ); # (1, 2)
795 $str = xl_rowcol_to_cell( 1, 2 ); # C2
796
797 For simplicity, the parameter lists for the worksheet method calls in
798 the following sections are given in terms of row-column notation. In
799 all cases it is also possible to use A1 notation.
800
801 Note: in Excel it is also possible to use a R1C1 notation. This is not
802 supported by Excel::Writer::XLSX.
803
804 write( $row, $column, $token, $format )
805 Excel makes a distinction between data types such as strings, numbers,
806 blanks, formulas and hyperlinks. To simplify the process of writing
807 data the write() method acts as a general alias for several more
808 specific methods:
809
810 write_string()
811 write_number()
812 write_blank()
813 write_formula()
814 write_url()
815 write_row()
816 write_col()
817
818 The general rule is that if the data looks like a something then a
819 something is written. Here are some examples in both row-column and A1
820 notation:
821
822 # Same as:
823 $worksheet->write( 0, 0, 'Hello' ); # write_string()
824 $worksheet->write( 1, 0, 'One' ); # write_string()
825 $worksheet->write( 2, 0, 2 ); # write_number()
826 $worksheet->write( 3, 0, 3.00001 ); # write_number()
827 $worksheet->write( 4, 0, "" ); # write_blank()
828 $worksheet->write( 5, 0, '' ); # write_blank()
829 $worksheet->write( 6, 0, undef ); # write_blank()
830 $worksheet->write( 7, 0 ); # write_blank()
831 $worksheet->write( 8, 0, 'http://www.perl.com/' ); # write_url()
832 $worksheet->write( 'A9', 'ftp://ftp.cpan.org/' ); # write_url()
833 $worksheet->write( 'A10', 'internal:Sheet1!A1' ); # write_url()
834 $worksheet->write( 'A11', 'external:c:\foo.xlsx' ); # write_url()
835 $worksheet->write( 'A12', '=A3 + 3*A4' ); # write_formula()
836 $worksheet->write( 'A13', '=SIN(PI()/4)' ); # write_formula()
837 $worksheet->write( 'A14', \@array ); # write_row()
838 $worksheet->write( 'A15', [\@array] ); # write_col()
839
840 # And if the keep_leading_zeros property is set:
841 $worksheet->write( 'A16', '2' ); # write_number()
842 $worksheet->write( 'A17', '02' ); # write_string()
843 $worksheet->write( 'A18', '00002' ); # write_string()
844
845 # Write an array formula. Not available in Spreadsheet::WriteExcel.
846 $worksheet->write( 'A19', '{=SUM(A1:B1*A2:B2)}' ); # write_formula()
847
848 The "looks like" rule is defined by regular expressions:
849
850 write_number() if $token is a number based on the following regex:
851 "$token =~ /^([+-]?)(?=\d|\.\d)\d*(\.\d*)?([Ee]([+-]?\d+))?$/".
852
853 write_string() if keep_leading_zeros() is set and $token is an integer
854 with leading zeros based on the following regex: "$token =~ /^0\d+$/".
855
856 write_blank() if $token is undef or a blank string: "undef", "" or ''.
857
858 write_url() if $token is a http, https, ftp or mailto URL based on the
859 following regexes: "$token =~ m|^[fh]tt?ps?://|" or "$token =~
860 m|^mailto:|".
861
862 write_url() if $token is an internal or external sheet reference based
863 on the following regex: "$token =~ m[^(in|ex)ternal:]".
864
865 write_formula() if the first character of $token is "=".
866
867 write_array_formula() if the $token matches "/^{=.*}$/".
868
869 write_row() if $token is an array ref.
870
871 write_col() if $token is an array ref of array refs.
872
873 write_string() if none of the previous conditions apply.
874
875 The $format parameter is optional. It should be a valid Format object,
876 see "CELL FORMATTING":
877
878 my $format = $workbook->add_format();
879 $format->set_bold();
880 $format->set_color( 'red' );
881 $format->set_align( 'center' );
882
883 $worksheet->write( 4, 0, 'Hello', $format ); # Formatted string
884
885 The write() method will ignore empty strings or "undef" tokens unless a
886 format is also supplied. As such you needn't worry about special
887 handling for empty or "undef" values in your data. See also the
888 write_blank() method.
889
890 One problem with the write() method is that occasionally data looks
891 like a number but you don't want it treated as a number. For example,
892 zip codes or ID numbers often start with a leading zero. If you write
893 this data as a number then the leading zero(s) will be stripped. You
894 can change this default behaviour by using the keep_leading_zeros()
895 method. While this property is in place any integers with leading zeros
896 will be treated as strings and the zeros will be preserved. See the
897 keep_leading_zeros() section for a full discussion of this issue.
898
899 You can also add your own data handlers to the write() method using
900 add_write_handler().
901
902 The write() method will also handle Unicode strings in "UTF-8" format.
903
904 The "write" methods return:
905
906 0 for success.
907 -1 for insufficient number of arguments.
908 -2 for row or column out of bounds.
909 -3 for string too long.
910
911 write_number( $row, $column, $number, $format )
912 Write an integer or a float to the cell specified by $row and $column:
913
914 $worksheet->write_number( 0, 0, 123456 );
915 $worksheet->write_number( 'A2', 2.3451 );
916
917 See the note about "Cell notation". The $format parameter is optional.
918
919 In general it is sufficient to use the write() method.
920
921 Note: some versions of Excel 2007 do not display the calculated values
922 of formulas written by Excel::Writer::XLSX. Applying all available
923 Service Packs to Excel should fix this.
924
925 write_string( $row, $column, $string, $format )
926 Write a string to the cell specified by $row and $column:
927
928 $worksheet->write_string( 0, 0, 'Your text here' );
929 $worksheet->write_string( 'A2', 'or here' );
930
931 The maximum string size is 32767 characters. However the maximum string
932 segment that Excel can display in a cell is 1000. All 32767 characters
933 can be displayed in the formula bar.
934
935 The $format parameter is optional.
936
937 The write() method will also handle strings in "UTF-8" format. See also
938 the "unicode_*.pl" programs in the examples directory of the distro.
939
940 In general it is sufficient to use the write() method. However, you may
941 sometimes wish to use the write_string() method to write data that
942 looks like a number but that you don't want treated as a number. For
943 example, zip codes or phone numbers:
944
945 # Write as a plain string
946 $worksheet->write_string( 'A1', '01209' );
947
948 However, if the user edits this string Excel may convert it back to a
949 number. To get around this you can use the Excel text format "@":
950
951 # Format as a string. Doesn't change to a number when edited
952 my $format1 = $workbook->add_format( num_format => '@' );
953 $worksheet->write_string( 'A2', '01209', $format1 );
954
955 See also the note about "Cell notation".
956
957 write_rich_string( $row, $column, $format, $string, ..., $cell_format )
958 The write_rich_string() method is used to write strings with multiple
959 formats. For example to write the string "This is bold and this is
960 italic" you would use the following:
961
962 my $bold = $workbook->add_format( bold => 1 );
963 my $italic = $workbook->add_format( italic => 1 );
964
965 $worksheet->write_rich_string( 'A1',
966 'This is ', $bold, 'bold', ' and this is ', $italic, 'italic' );
967
968 The basic rule is to break the string into fragments and put a $format
969 object before the fragment that you want to format. For example:
970
971 # Unformatted string.
972 'This is an example string'
973
974 # Break it into fragments.
975 'This is an ', 'example', ' string'
976
977 # Add formatting before the fragments you want formatted.
978 'This is an ', $format, 'example', ' string'
979
980 # In Excel::Writer::XLSX.
981 $worksheet->write_rich_string( 'A1',
982 'This is an ', $format, 'example', ' string' );
983
984 String fragments that don't have a format are given a default format.
985 So for example when writing the string "Some bold text" you would use
986 the first example below but it would be equivalent to the second:
987
988 # With default formatting:
989 my $bold = $workbook->add_format( bold => 1 );
990
991 $worksheet->write_rich_string( 'A1',
992 'Some ', $bold, 'bold', ' text' );
993
994 # Or more explicitly:
995 my $bold = $workbook->add_format( bold => 1 );
996 my $default = $workbook->add_format();
997
998 $worksheet->write_rich_string( 'A1',
999 $default, 'Some ', $bold, 'bold', $default, ' text' );
1000
1001 As with Excel, only the font properties of the format such as font
1002 name, style, size, underline, color and effects are applied to the
1003 string fragments. Other features such as border, background, text wrap
1004 and alignment must be applied to the cell.
1005
1006 The write_rich_string() method allows you to do this by using the last
1007 argument as a cell format (if it is a format object). The following
1008 example centers a rich string in the cell:
1009
1010 my $bold = $workbook->add_format( bold => 1 );
1011 my $center = $workbook->add_format( align => 'center' );
1012
1013 $worksheet->write_rich_string( 'A5',
1014 'Some ', $bold, 'bold text', ' centered', $center );
1015
1016 See the "rich_strings.pl" example in the distro for more examples.
1017
1018 my $bold = $workbook->add_format( bold => 1 );
1019 my $italic = $workbook->add_format( italic => 1 );
1020 my $red = $workbook->add_format( color => 'red' );
1021 my $blue = $workbook->add_format( color => 'blue' );
1022 my $center = $workbook->add_format( align => 'center' );
1023 my $super = $workbook->add_format( font_script => 1 );
1024
1025
1026 # Write some strings with multiple formats.
1027 $worksheet->write_rich_string( 'A1',
1028 'This is ', $bold, 'bold', ' and this is ', $italic, 'italic' );
1029
1030 $worksheet->write_rich_string( 'A3',
1031 'This is ', $red, 'red', ' and this is ', $blue, 'blue' );
1032
1033 $worksheet->write_rich_string( 'A5',
1034 'Some ', $bold, 'bold text', ' centered', $center );
1035
1036 $worksheet->write_rich_string( 'A7',
1037 $italic, 'j = k', $super, '(n-1)', $center );
1038
1039 As with write_sting() the maximum string size is 32767 characters. See
1040 also the note about "Cell notation".
1041
1042 keep_leading_zeros()
1043 This method changes the default handling of integers with leading zeros
1044 when using the write() method.
1045
1046 The write() method uses regular expressions to determine what type of
1047 data to write to an Excel worksheet. If the data looks like a number it
1048 writes a number using write_number(). One problem with this approach is
1049 that occasionally data looks like a number but you don't want it
1050 treated as a number.
1051
1052 Zip codes and ID numbers, for example, often start with a leading zero.
1053 If you write this data as a number then the leading zero(s) will be
1054 stripped. This is the also the default behaviour when you enter data
1055 manually in Excel.
1056
1057 To get around this you can use one of three options. Write a formatted
1058 number, write the number as a string or use the keep_leading_zeros()
1059 method to change the default behaviour of write():
1060
1061 # Implicitly write a number, the leading zero is removed: 1209
1062 $worksheet->write( 'A1', '01209' );
1063
1064 # Write a zero padded number using a format: 01209
1065 my $format1 = $workbook->add_format( num_format => '00000' );
1066 $worksheet->write( 'A2', '01209', $format1 );
1067
1068 # Write explicitly as a string: 01209
1069 $worksheet->write_string( 'A3', '01209' );
1070
1071 # Write implicitly as a string: 01209
1072 $worksheet->keep_leading_zeros();
1073 $worksheet->write( 'A4', '01209' );
1074
1075 The above code would generate a worksheet that looked like the
1076 following:
1077
1078 -----------------------------------------------------------
1079 | | A | B | C | D | ...
1080 -----------------------------------------------------------
1081 | 1 | 1209 | | | | ...
1082 | 2 | 01209 | | | | ...
1083 | 3 | 01209 | | | | ...
1084 | 4 | 01209 | | | | ...
1085
1086 The examples are on different sides of the cells due to the fact that
1087 Excel displays strings with a left justification and numbers with a
1088 right justification by default. You can change this by using a format
1089 to justify the data, see "CELL FORMATTING".
1090
1091 It should be noted that if the user edits the data in examples "A3" and
1092 "A4" the strings will revert back to numbers. Again this is Excel's
1093 default behaviour. To avoid this you can use the text format "@":
1094
1095 # Format as a string (01209)
1096 my $format2 = $workbook->add_format( num_format => '@' );
1097 $worksheet->write_string( 'A5', '01209', $format2 );
1098
1099 The keep_leading_zeros() property is off by default. The
1100 keep_leading_zeros() method takes 0 or 1 as an argument. It defaults to
1101 1 if an argument isn't specified:
1102
1103 $worksheet->keep_leading_zeros(); # Set on
1104 $worksheet->keep_leading_zeros( 1 ); # Set on
1105 $worksheet->keep_leading_zeros( 0 ); # Set off
1106
1107 See also the add_write_handler() method.
1108
1109 write_blank( $row, $column, $format )
1110 Write a blank cell specified by $row and $column:
1111
1112 $worksheet->write_blank( 0, 0, $format );
1113
1114 This method is used to add formatting to a cell which doesn't contain a
1115 string or number value.
1116
1117 Excel differentiates between an "Empty" cell and a "Blank" cell. An
1118 "Empty" cell is a cell which doesn't contain data whilst a "Blank" cell
1119 is a cell which doesn't contain data but does contain formatting. Excel
1120 stores "Blank" cells but ignores "Empty" cells.
1121
1122 As such, if you write an empty cell without formatting it is ignored:
1123
1124 $worksheet->write( 'A1', undef, $format ); # write_blank()
1125 $worksheet->write( 'A2', undef ); # Ignored
1126
1127 This seemingly uninteresting fact means that you can write arrays of
1128 data without special treatment for "undef" or empty string values.
1129
1130 See the note about "Cell notation".
1131
1132 write_row( $row, $column, $array_ref, $format )
1133 The write_row() method can be used to write a 1D or 2D array of data in
1134 one go. This is useful for converting the results of a database query
1135 into an Excel worksheet. You must pass a reference to the array of data
1136 rather than the array itself. The write() method is then called for
1137 each element of the data. For example:
1138
1139 @array = ( 'awk', 'gawk', 'mawk' );
1140 $array_ref = \@array;
1141
1142 $worksheet->write_row( 0, 0, $array_ref );
1143
1144 # The above example is equivalent to:
1145 $worksheet->write( 0, 0, $array[0] );
1146 $worksheet->write( 0, 1, $array[1] );
1147 $worksheet->write( 0, 2, $array[2] );
1148
1149 Note: For convenience the write() method behaves in the same way as
1150 write_row() if it is passed an array reference. Therefore the following
1151 two method calls are equivalent:
1152
1153 $worksheet->write_row( 'A1', $array_ref ); # Write a row of data
1154 $worksheet->write( 'A1', $array_ref ); # Same thing
1155
1156 As with all of the write methods the $format parameter is optional. If
1157 a format is specified it is applied to all the elements of the data
1158 array.
1159
1160 Array references within the data will be treated as columns. This
1161 allows you to write 2D arrays of data in one go. For example:
1162
1163 @eec = (
1164 ['maggie', 'milly', 'molly', 'may' ],
1165 [13, 14, 15, 16 ],
1166 ['shell', 'star', 'crab', 'stone']
1167 );
1168
1169 $worksheet->write_row( 'A1', \@eec );
1170
1171 Would produce a worksheet as follows:
1172
1173 -----------------------------------------------------------
1174 | | A | B | C | D | E | ...
1175 -----------------------------------------------------------
1176 | 1 | maggie | 13 | shell | ... | ... | ...
1177 | 2 | milly | 14 | star | ... | ... | ...
1178 | 3 | molly | 15 | crab | ... | ... | ...
1179 | 4 | may | 16 | stone | ... | ... | ...
1180 | 5 | ... | ... | ... | ... | ... | ...
1181 | 6 | ... | ... | ... | ... | ... | ...
1182
1183 To write the data in a row-column order refer to the write_col() method
1184 below.
1185
1186 Any "undef" values in the data will be ignored unless a format is
1187 applied to the data, in which case a formatted blank cell will be
1188 written. In either case the appropriate row or column value will still
1189 be incremented.
1190
1191 To find out more about array references refer to "perlref" and
1192 "perlreftut" in the main Perl documentation. To find out more about 2D
1193 arrays or "lists of lists" refer to "perllol".
1194
1195 The write_row() method returns the first error encountered when writing
1196 the elements of the data or zero if no errors were encountered. See the
1197 return values described for the write() method above.
1198
1199 See also the "write_arrays.pl" program in the "examples" directory of
1200 the distro.
1201
1202 The write_row() method allows the following idiomatic conversion of a
1203 text file to an Excel file:
1204
1205 #!/usr/bin/perl -w
1206
1207 use strict;
1208 use Excel::Writer::XLSX;
1209
1210 my $workbook = Excel::Writer::XLSX->new( 'file.xlsx' );
1211 my $worksheet = $workbook->add_worksheet();
1212
1213 open INPUT, 'file.txt' or die "Couldn't open file: $!";
1214
1215 $worksheet->write( $. -1, 0, [split] ) while <INPUT>;
1216
1217 $workbook->close();
1218
1219 write_col( $row, $column, $array_ref, $format )
1220 The write_col() method can be used to write a 1D or 2D array of data in
1221 one go. This is useful for converting the results of a database query
1222 into an Excel worksheet. You must pass a reference to the array of data
1223 rather than the array itself. The write() method is then called for
1224 each element of the data. For example:
1225
1226 @array = ( 'awk', 'gawk', 'mawk' );
1227 $array_ref = \@array;
1228
1229 $worksheet->write_col( 0, 0, $array_ref );
1230
1231 # The above example is equivalent to:
1232 $worksheet->write( 0, 0, $array[0] );
1233 $worksheet->write( 1, 0, $array[1] );
1234 $worksheet->write( 2, 0, $array[2] );
1235
1236 As with all of the write methods the $format parameter is optional. If
1237 a format is specified it is applied to all the elements of the data
1238 array.
1239
1240 Array references within the data will be treated as rows. This allows
1241 you to write 2D arrays of data in one go. For example:
1242
1243 @eec = (
1244 ['maggie', 'milly', 'molly', 'may' ],
1245 [13, 14, 15, 16 ],
1246 ['shell', 'star', 'crab', 'stone']
1247 );
1248
1249 $worksheet->write_col( 'A1', \@eec );
1250
1251 Would produce a worksheet as follows:
1252
1253 -----------------------------------------------------------
1254 | | A | B | C | D | E | ...
1255 -----------------------------------------------------------
1256 | 1 | maggie | milly | molly | may | ... | ...
1257 | 2 | 13 | 14 | 15 | 16 | ... | ...
1258 | 3 | shell | star | crab | stone | ... | ...
1259 | 4 | ... | ... | ... | ... | ... | ...
1260 | 5 | ... | ... | ... | ... | ... | ...
1261 | 6 | ... | ... | ... | ... | ... | ...
1262
1263 To write the data in a column-row order refer to the write_row() method
1264 above.
1265
1266 Any "undef" values in the data will be ignored unless a format is
1267 applied to the data, in which case a formatted blank cell will be
1268 written. In either case the appropriate row or column value will still
1269 be incremented.
1270
1271 As noted above the write() method can be used as a synonym for
1272 write_row() and write_row() handles nested array refs as columns.
1273 Therefore, the following two method calls are equivalent although the
1274 more explicit call to write_col() would be preferable for
1275 maintainability:
1276
1277 $worksheet->write_col( 'A1', $array_ref ); # Write a column of data
1278 $worksheet->write( 'A1', [ $array_ref ] ); # Same thing
1279
1280 To find out more about array references refer to "perlref" and
1281 "perlreftut" in the main Perl documentation. To find out more about 2D
1282 arrays or "lists of lists" refer to "perllol".
1283
1284 The write_col() method returns the first error encountered when writing
1285 the elements of the data or zero if no errors were encountered. See the
1286 return values described for the write() method above.
1287
1288 See also the "write_arrays.pl" program in the "examples" directory of
1289 the distro.
1290
1291 write_date_time( $row, $col, $date_string, $format )
1292 The write_date_time() method can be used to write a date or time to the
1293 cell specified by $row and $column:
1294
1295 $worksheet->write_date_time( 'A1', '2004-05-13T23:20', $date_format );
1296
1297 The $date_string should be in the following format:
1298
1299 yyyy-mm-ddThh:mm:ss.sss
1300
1301 This conforms to an ISO8601 date but it should be noted that the full
1302 range of ISO8601 formats are not supported.
1303
1304 The following variations on the $date_string parameter are permitted:
1305
1306 yyyy-mm-ddThh:mm:ss.sss # Standard format
1307 yyyy-mm-ddT # No time
1308 Thh:mm:ss.sss # No date
1309 yyyy-mm-ddThh:mm:ss.sssZ # Additional Z (but not time zones)
1310 yyyy-mm-ddThh:mm:ss # No fractional seconds
1311 yyyy-mm-ddThh:mm # No seconds
1312
1313 Note that the "T" is required in all cases.
1314
1315 A date should always have a $format, otherwise it will appear as a
1316 number, see "DATES AND TIME IN EXCEL" and "CELL FORMATTING". Here is a
1317 typical example:
1318
1319 my $date_format = $workbook->add_format( num_format => 'mm/dd/yy' );
1320 $worksheet->write_date_time( 'A1', '2004-05-13T23:20', $date_format );
1321
1322 Valid dates should be in the range 1900-01-01 to 9999-12-31, for the
1323 1900 epoch and 1904-01-01 to 9999-12-31, for the 1904 epoch. As with
1324 Excel, dates outside these ranges will be written as a string.
1325
1326 See also the date_time.pl program in the "examples" directory of the
1327 distro.
1328
1329 write_url( $row, $col, $url, $format, $label )
1330 Write a hyperlink to a URL in the cell specified by $row and $column.
1331 The hyperlink is comprised of two elements: the visible label and the
1332 invisible link. The visible label is the same as the link unless an
1333 alternative label is specified. The $label parameter is optional. The
1334 label is written using the write() method. Therefore it is possible to
1335 write strings, numbers or formulas as labels.
1336
1337 The $format parameter is also optional and the default Excel hyperlink
1338 style will be used if it isn't specified. If required you can access
1339 the default url format using the Workbook "get_default_url_format"
1340 method:
1341
1342 my $url_format = $workbook->get_default_url_format();
1343
1344 There are four web style URI's supported: "http://", "https://",
1345 "ftp://" and "mailto:":
1346
1347 $worksheet->write_url( 0, 0, 'ftp://www.perl.org/' );
1348 $worksheet->write_url( 'A3', 'http://www.perl.com/' );
1349 $worksheet->write_url( 'A4', 'mailto:jmcnamara@cpan.org' );
1350
1351 You can display an alternative string using the $label parameter:
1352
1353 $worksheet->write_url( 1, 0, 'http://www.perl.com/', undef, 'Perl' );
1354
1355 If you wish to have some other cell data such as a number or a formula
1356 you can overwrite the cell using another call to "write_*()":
1357
1358 $worksheet->write_url( 'A1', 'http://www.perl.com/' );
1359
1360 # Overwrite the URL string with a formula. The cell is still a link.
1361 # Note the use of the default url format for consistency with other links.
1362 my $url_format = $workbook->get_default_url_format();
1363 $worksheet->write_formula( 'A1', '=1+1', $url_format );
1364
1365 There are two local URIs supported: "internal:" and "external:". These
1366 are used for hyperlinks to internal worksheet references or external
1367 workbook and worksheet references:
1368
1369 $worksheet->write_url( 'A6', 'internal:Sheet2!A1' );
1370 $worksheet->write_url( 'A7', 'internal:Sheet2!A1' );
1371 $worksheet->write_url( 'A8', 'internal:Sheet2!A1:B2' );
1372 $worksheet->write_url( 'A9', q{internal:'Sales Data'!A1} );
1373 $worksheet->write_url( 'A10', 'external:c:\temp\foo.xlsx' );
1374 $worksheet->write_url( 'A11', 'external:c:\foo.xlsx#Sheet2!A1' );
1375 $worksheet->write_url( 'A12', 'external:..\foo.xlsx' );
1376 $worksheet->write_url( 'A13', 'external:..\foo.xlsx#Sheet2!A1' );
1377 $worksheet->write_url( 'A13', 'external:\\\\NET\share\foo.xlsx' );
1378
1379 All of the these URI types are recognised by the write() method, see
1380 above.
1381
1382 Worksheet references are typically of the form "Sheet1!A1". You can
1383 also refer to a worksheet range using the standard Excel notation:
1384 "Sheet1!A1:B2".
1385
1386 In external links the workbook and worksheet name must be separated by
1387 the "#" character: "external:Workbook.xlsx#Sheet1!A1'".
1388
1389 You can also link to a named range in the target worksheet. For example
1390 say you have a named range called "my_name" in the workbook
1391 "c:\temp\foo.xlsx" you could link to it as follows:
1392
1393 $worksheet->write_url( 'A14', 'external:c:\temp\foo.xlsx#my_name' );
1394
1395 Excel requires that worksheet names containing spaces or non
1396 alphanumeric characters are single quoted as follows "'Sales Data'!A1".
1397 If you need to do this in a single quoted string then you can either
1398 escape the single quotes "\'" or use the quote operator "q{}" as
1399 described in "perlop" in the main Perl documentation.
1400
1401 Links to network files are also supported. MS/Novell Network files
1402 normally begin with two back slashes as follows "\\NETWORK\etc". In
1403 order to generate this in a single or double quoted string you will
1404 have to escape the backslashes, '\\\\NETWORK\etc'.
1405
1406 If you are using double quote strings then you should be careful to
1407 escape anything that looks like a metacharacter. For more information
1408 see "perlfaq5: Why can't I use "C:\temp\foo" in DOS paths?".
1409
1410 Finally, you can avoid most of these quoting problems by using forward
1411 slashes. These are translated internally to backslashes:
1412
1413 $worksheet->write_url( 'A14', "external:c:/temp/foo.xlsx" );
1414 $worksheet->write_url( 'A15', 'external://NETWORK/share/foo.xlsx' );
1415
1416 Note: Excel::Writer::XLSX will escape the following characters in URLs
1417 as required by Excel: "\s " < > \ [ ] ` ^ { }" unless the URL already
1418 contains %xx style escapes. In which case it is assumed that the URL
1419 was escaped correctly by the user and will by passed directly to Excel.
1420
1421 Versions of Excel prior to Excel 2015 limited hyperlink links and
1422 anchor/locations to 255 characters each. Versions after that support
1423 urls up to 2079 characters. Excel::Writer::XLSX versions >= 1.0.2
1424 support the new longer limit by default.
1425
1426 See also, the note about "Cell notation".
1427
1428 write_formula( $row, $column, $formula, $format, $value )
1429 Write a formula or function to the cell specified by $row and $column:
1430
1431 $worksheet->write_formula( 0, 0, '=$B$3 + B4' );
1432 $worksheet->write_formula( 1, 0, '=SIN(PI()/4)' );
1433 $worksheet->write_formula( 2, 0, '=SUM(B1:B5)' );
1434 $worksheet->write_formula( 'A4', '=IF(A3>1,"Yes", "No")' );
1435 $worksheet->write_formula( 'A5', '=AVERAGE(1, 2, 3, 4)' );
1436 $worksheet->write_formula( 'A6', '=DATEVALUE("1-Jan-2001")' );
1437
1438 Array formulas are also supported:
1439
1440 $worksheet->write_formula( 'A7', '{=SUM(A1:B1*A2:B2)}' );
1441
1442 See also the write_array_formula() method below.
1443
1444 See the note about "Cell notation". For more information about writing
1445 Excel formulas see "FORMULAS AND FUNCTIONS IN EXCEL"
1446
1447 If required, it is also possible to specify the calculated value of the
1448 formula. This is occasionally necessary when working with non-Excel
1449 applications that don't calculate the value of the formula. The
1450 calculated $value is added at the end of the argument list:
1451
1452 $worksheet->write( 'A1', '=2+2', $format, 4 );
1453
1454 However, this probably isn't something that you will ever need to do.
1455 If you do use this feature then do so with care.
1456
1457 write_array_formula($first_row, $first_col, $last_row, $last_col, $formula,
1458 $format, $value)
1459 Write an array formula to a cell range. In Excel an array formula is a
1460 formula that performs a calculation on a set of values. It can return a
1461 single value or a range of values.
1462
1463 An array formula is indicated by a pair of braces around the formula:
1464 "{=SUM(A1:B1*A2:B2)}". If the array formula returns a single value
1465 then the $first_ and $last_ parameters should be the same:
1466
1467 $worksheet->write_array_formula('A1:A1', '{=SUM(B1:C1*B2:C2)}');
1468
1469 It this case however it is easier to just use the write_formula() or
1470 write() methods:
1471
1472 # Same as above but more concise.
1473 $worksheet->write( 'A1', '{=SUM(B1:C1*B2:C2)}' );
1474 $worksheet->write_formula( 'A1', '{=SUM(B1:C1*B2:C2)}' );
1475
1476 For array formulas that return a range of values you must specify the
1477 range that the return values will be written to:
1478
1479 $worksheet->write_array_formula( 'A1:A3', '{=TREND(C1:C3,B1:B3)}' );
1480 $worksheet->write_array_formula( 0, 0, 2, 0, '{=TREND(C1:C3,B1:B3)}' );
1481
1482 If required, it is also possible to specify the calculated value of the
1483 formula. This is occasionally necessary when working with non-Excel
1484 applications that don't calculate the value of the formula. However,
1485 using this parameter only writes a single value to the upper left cell
1486 in the result array. For a multi-cell array formula where the results
1487 are required, the other result values can be specified by using
1488 write_number() to write to the appropriate cell:
1489
1490 # Specify the result for a single cell range.
1491 $worksheet->write_array_formula( 'A1:A3', '{=SUM(B1:C1*B2:C2)}, $format, 2005 );
1492
1493 # Specify the results for a multi cell range.
1494 $worksheet->write_array_formula( 'A1:A3', '{=TREND(C1:C3,B1:B3)}', $format, 105 );
1495 $worksheet->write_number( 'A2', 12, format );
1496 $worksheet->write_number( 'A3', 14, format );
1497
1498 In addition, some early versions of Excel 2007 don't calculate the
1499 values of array formulas when they aren't supplied. Installing the
1500 latest Office Service Pack should fix this issue.
1501
1502 See also the "array_formula.pl" program in the "examples" directory of
1503 the distro.
1504
1505 Note: Array formulas are not supported by Spreadsheet::WriteExcel.
1506
1507 write_boolean( $row, $column, $value, $format )
1508 Write an Excel boolean value to the cell specified by $row and $column:
1509
1510 $worksheet->write_boolean( 'A1', 1 ); # TRUE
1511 $worksheet->write_boolean( 'A2', 0 ); # FALSE
1512 $worksheet->write_boolean( 'A3', undef ); # FALSE
1513 $worksheet->write_boolean( 'A3', 0, $format ); # FALSE, with format.
1514
1515 A $value that is true or false using Perl's rules will be written as an
1516 Excel boolean "TRUE" or "FALSE" value.
1517
1518 See the note about "Cell notation".
1519
1520 store_formula( $formula )
1521 Deprecated. This is a Spreadsheet::WriteExcel method that is no longer
1522 required by Excel::Writer::XLSX. See below.
1523
1524 repeat_formula( $row, $col, $formula, $format )
1525 Deprecated. This is a Spreadsheet::WriteExcel method that is no longer
1526 required by Excel::Writer::XLSX.
1527
1528 In Spreadsheet::WriteExcel it was computationally expensive to write
1529 formulas since they were parsed by a recursive descent parser. The
1530 store_formula() and repeat_formula() methods were used as a way of
1531 avoiding the overhead of repeated formulas by reusing a pre-parsed
1532 formula.
1533
1534 In Excel::Writer::XLSX this is no longer necessary since it is just as
1535 quick to write a formula as it is to write a string or a number.
1536
1537 The methods remain for backward compatibility but new
1538 Excel::Writer::XLSX programs shouldn't use them.
1539
1540 write_comment( $row, $column, $string, ... )
1541 The write_comment() method is used to add a comment to a cell. A cell
1542 comment is indicated in Excel by a small red triangle in the upper
1543 right-hand corner of the cell. Moving the cursor over the red triangle
1544 will reveal the comment.
1545
1546 The following example shows how to add a comment to a cell:
1547
1548 $worksheet->write ( 2, 2, 'Hello' );
1549 $worksheet->write_comment( 2, 2, 'This is a comment.' );
1550
1551 As usual you can replace the $row and $column parameters with an "A1"
1552 cell reference. See the note about "Cell notation".
1553
1554 $worksheet->write ( 'C3', 'Hello');
1555 $worksheet->write_comment( 'C3', 'This is a comment.' );
1556
1557 The write_comment() method will also handle strings in "UTF-8" format.
1558
1559 $worksheet->write_comment( 'C3', "\x{263a}" ); # Smiley
1560 $worksheet->write_comment( 'C4', 'Comment ca va?' );
1561
1562 In addition to the basic 3 argument form of write_comment() you can
1563 pass in several optional key/value pairs to control the format of the
1564 comment. For example:
1565
1566 $worksheet->write_comment( 'C3', 'Hello', visible => 1, author => 'Perl' );
1567
1568 Most of these options are quite specific and in general the default
1569 comment behaves will be all that you need. However, should you need
1570 greater control over the format of the cell comment the following
1571 options are available:
1572
1573 author
1574 visible
1575 x_scale
1576 width
1577 y_scale
1578 height
1579 color
1580 start_cell
1581 start_row
1582 start_col
1583 x_offset
1584 y_offset
1585 font
1586 font_size
1587
1588 Option: author
1589 This option is used to indicate who is the author of the cell
1590 comment. Excel displays the author of the comment in the status bar
1591 at the bottom of the worksheet. This is usually of interest in
1592 corporate environments where several people might review and
1593 provide comments to a workbook.
1594
1595 $worksheet->write_comment( 'C3', 'Atonement', author => 'Ian McEwan' );
1596
1597 The default author for all cell comments can be set using the
1598 set_comments_author() method (see below).
1599
1600 $worksheet->set_comments_author( 'Perl' );
1601
1602 Option: visible
1603 This option is used to make a cell comment visible when the
1604 worksheet is opened. The default behaviour in Excel is that
1605 comments are initially hidden. However, it is also possible in
1606 Excel to make individual or all comments visible. In
1607 Excel::Writer::XLSX individual comments can be made visible as
1608 follows:
1609
1610 $worksheet->write_comment( 'C3', 'Hello', visible => 1 );
1611
1612 It is possible to make all comments in a worksheet visible using
1613 the show_comments() worksheet method (see below). Alternatively, if
1614 all of the cell comments have been made visible you can hide
1615 individual comments:
1616
1617 $worksheet->write_comment( 'C3', 'Hello', visible => 0 );
1618
1619 Option: x_scale
1620 This option is used to set the width of the cell comment box as a
1621 factor of the default width.
1622
1623 $worksheet->write_comment( 'C3', 'Hello', x_scale => 2 );
1624 $worksheet->write_comment( 'C4', 'Hello', x_scale => 4.2 );
1625
1626 Option: width
1627 This option is used to set the width of the cell comment box
1628 explicitly in pixels.
1629
1630 $worksheet->write_comment( 'C3', 'Hello', width => 200 );
1631
1632 Option: y_scale
1633 This option is used to set the height of the cell comment box as a
1634 factor of the default height.
1635
1636 $worksheet->write_comment( 'C3', 'Hello', y_scale => 2 );
1637 $worksheet->write_comment( 'C4', 'Hello', y_scale => 4.2 );
1638
1639 Option: height
1640 This option is used to set the height of the cell comment box
1641 explicitly in pixels.
1642
1643 $worksheet->write_comment( 'C3', 'Hello', height => 200 );
1644
1645 Option: color
1646 This option is used to set the background colour of cell comment
1647 box. You can use one of the named colours recognised by
1648 Excel::Writer::XLSX or a Html style "#RRGGBB" colour. See "WORKING
1649 WITH COLOURS".
1650
1651 $worksheet->write_comment( 'C3', 'Hello', color => 'green' );
1652 $worksheet->write_comment( 'C4', 'Hello', color => '#FF6600' ); # Orange
1653
1654 Option: start_cell
1655 This option is used to set the cell in which the comment will
1656 appear. By default Excel displays comments one cell to the right
1657 and one cell above the cell to which the comment relates. However,
1658 you can change this behaviour if you wish. In the following example
1659 the comment which would appear by default in cell "D2" is moved to
1660 "E2".
1661
1662 $worksheet->write_comment( 'C3', 'Hello', start_cell => 'E2' );
1663
1664 Option: start_row
1665 This option is used to set the row in which the comment will
1666 appear. See the "start_cell" option above. The row is zero indexed.
1667
1668 $worksheet->write_comment( 'C3', 'Hello', start_row => 0 );
1669
1670 Option: start_col
1671 This option is used to set the column in which the comment will
1672 appear. See the "start_cell" option above. The column is zero
1673 indexed.
1674
1675 $worksheet->write_comment( 'C3', 'Hello', start_col => 4 );
1676
1677 Option: x_offset
1678 This option is used to change the x offset, in pixels, of a comment
1679 within a cell:
1680
1681 $worksheet->write_comment( 'C3', $comment, x_offset => 30 );
1682
1683 Option: y_offset
1684 This option is used to change the y offset, in pixels, of a comment
1685 within a cell:
1686
1687 $worksheet->write_comment('C3', $comment, x_offset => 30);
1688
1689 Option: font
1690 This option is used to change the font used in the comment from
1691 'Tahoma' which is the default.
1692
1693 $worksheet->write_comment('C3', $comment, font => 'Calibri');
1694
1695 Option: font_size
1696 This option is used to change the font size used in the comment
1697 from 8 which is the default.
1698
1699 $worksheet->write_comment('C3', $comment, font_size => 20);
1700
1701 You can apply as many of these options as you require.
1702
1703 Note about using options that adjust the position of the cell comment
1704 such as start_cell, start_row, start_col, x_offset and y_offset: Excel
1705 only displays offset cell comments when they are displayed as
1706 "visible". Excel does not display hidden cells as moved when you mouse
1707 over them.
1708
1709 Note about row height and comments. If you specify the height of a row
1710 that contains a comment then Excel::Writer::XLSX will adjust the height
1711 of the comment to maintain the default or user specified dimensions.
1712 However, the height of a row can also be adjusted automatically by
1713 Excel if the text wrap property is set or large fonts are used in the
1714 cell. This means that the height of the row is unknown to the module at
1715 run time and thus the comment box is stretched with the row. Use the
1716 set_row() method to specify the row height explicitly and avoid this
1717 problem.
1718
1719 show_comments()
1720 This method is used to make all cell comments visible when a worksheet
1721 is opened.
1722
1723 $worksheet->show_comments();
1724
1725 Individual comments can be made visible using the "visible" parameter
1726 of the "write_comment" method (see above):
1727
1728 $worksheet->write_comment( 'C3', 'Hello', visible => 1 );
1729
1730 If all of the cell comments have been made visible you can hide
1731 individual comments as follows:
1732
1733 $worksheet->show_comments();
1734 $worksheet->write_comment( 'C3', 'Hello', visible => 0 );
1735
1736 set_comments_author()
1737 This method is used to set the default author of all cell comments.
1738
1739 $worksheet->set_comments_author( 'Perl' );
1740
1741 Individual comment authors can be set using the "author" parameter of
1742 the "write_comment" method (see above).
1743
1744 The default comment author is an empty string, '', if no author is
1745 specified.
1746
1747 add_write_handler( $re, $code_ref )
1748 This method is used to extend the Excel::Writer::XLSX write() method to
1749 handle user defined data.
1750
1751 If you refer to the section on write() above you will see that it acts
1752 as an alias for several more specific "write_*" methods. However, it
1753 doesn't always act in exactly the way that you would like it to.
1754
1755 One solution is to filter the input data yourself and call the
1756 appropriate "write_*" method. Another approach is to use the
1757 add_write_handler() method to add your own automated behaviour to
1758 write().
1759
1760 The add_write_handler() method take two arguments, $re, a regular
1761 expression to match incoming data and $code_ref a callback function to
1762 handle the matched data:
1763
1764 $worksheet->add_write_handler( qr/^\d\d\d\d$/, \&my_write );
1765
1766 (In the these examples the "qr" operator is used to quote the regular
1767 expression strings, see perlop for more details).
1768
1769 The method is used as follows. say you wished to write 7 digit ID
1770 numbers as a string so that any leading zeros were preserved*, you
1771 could do something like the following:
1772
1773 $worksheet->add_write_handler( qr/^\d{7}$/, \&write_my_id );
1774
1775
1776 sub write_my_id {
1777 my $worksheet = shift;
1778 return $worksheet->write_string( @_ );
1779 }
1780
1781 * You could also use the keep_leading_zeros() method for this.
1782
1783 Then if you call write() with an appropriate string it will be handled
1784 automatically:
1785
1786 # Writes 0000000. It would normally be written as a number; 0.
1787 $worksheet->write( 'A1', '0000000' );
1788
1789 The callback function will receive a reference to the calling worksheet
1790 and all of the other arguments that were passed to write(). The
1791 callback will see an @_ argument list that looks like the following:
1792
1793 $_[0] A ref to the calling worksheet. *
1794 $_[1] Zero based row number.
1795 $_[2] Zero based column number.
1796 $_[3] A number or string or token.
1797 $_[4] A format ref if any.
1798 $_[5] Any other arguments.
1799 ...
1800
1801 * It is good style to shift this off the list so the @_ is the same
1802 as the argument list seen by write().
1803
1804 Your callback should return() the return value of the "write_*" method
1805 that was called or "undef" to indicate that you rejected the match and
1806 want write() to continue as normal.
1807
1808 So for example if you wished to apply the previous filter only to ID
1809 values that occur in the first column you could modify your callback
1810 function as follows:
1811
1812 sub write_my_id {
1813 my $worksheet = shift;
1814 my $col = $_[1];
1815
1816 if ( $col == 0 ) {
1817 return $worksheet->write_string( @_ );
1818 }
1819 else {
1820 # Reject the match and return control to write()
1821 return undef;
1822 }
1823 }
1824
1825 Now, you will get different behaviour for the first column and other
1826 columns:
1827
1828 $worksheet->write( 'A1', '0000000' ); # Writes 0000000
1829 $worksheet->write( 'B1', '0000000' ); # Writes 0
1830
1831 You may add more than one handler in which case they will be called in
1832 the order that they were added.
1833
1834 Note, the add_write_handler() method is particularly suited for
1835 handling dates.
1836
1837 See the "write_handler 1-4" programs in the "examples" directory for
1838 further examples.
1839
1840 insert_image( $row, $col, $filename, { %options } )
1841 This method can be used to insert a image into a worksheet. The image
1842 can be in PNG, JPEG, GIF or BMP format.
1843
1844 $worksheet1->insert_image( 'A1', 'perl.bmp' );
1845 $worksheet2->insert_image( 'A1', '../images/perl.bmp' );
1846 $worksheet3->insert_image( 'A1', '.c:\images\perl.bmp' );
1847
1848 The optional "options" hash/hashref parameter can be used to set
1849 various options for the image. The defaults are:
1850
1851 %options = (
1852 x_offset => 0,
1853 y_offset => 0,
1854 x_scale => 1,
1855 y_scale => 1,
1856 object_position => 2,
1857 url => undef,
1858 tip => undef,
1859 description => $filename,
1860 decorative => 0,
1861 );
1862
1863 The parameters "x_offset" and "y_offset" can be used to specify an
1864 offset from the top left hand corner of the cell specified by $row and
1865 $col. The offset values are in pixels.
1866
1867 $worksheet1->insert_image('A1', 'perl.bmp', { x_offset =>32, y_offset => 10 });
1868
1869 The offsets can be greater than the width or height of the underlying
1870 cell. This can be occasionally useful if you wish to align two or more
1871 images relative to the same cell.
1872
1873 The parameters "x_scale" and "y_scale" can be used to scale the
1874 inserted image horizontally and vertically:
1875
1876 # Scale the inserted image: width x 2.0, height x 0.8
1877 $worksheet->insert_image( 'A1', 'perl.bmp', { y_scale => 2, y_scale => 0.8 } );
1878
1879 The positioning of the image when cells are resized can be set with the
1880 "object_position" parameter:
1881
1882 $worksheet->insert_image( 'A1', 'perl.bmp', { object_position => 1 } );
1883
1884 The "object_position" parameter can have one of the following allowable
1885 values:
1886
1887 1. Move and size with cells.
1888 2. Move but don't size with cells.
1889 3. Don't move or size with cells.
1890 4. Same as Option 1, see below.
1891
1892 Option 4 appears in Excel as Option 1. However, the worksheet object is
1893 sized to take hidden rows or columns into account. This allows the user
1894 to hide an image in a cell, possibly as part of an autofilter.
1895
1896 The "url" option can be use to used to add a hyperlink to an image:
1897
1898 $worksheet->insert_image( 'A1', 'logo.png',
1899 { url => 'https://github.com/jmcnamara' } );
1900
1901 The supported url formats are the same as those supported by the
1902 write_url() method and the same rules/limits apply.
1903
1904 The "tip" option can be use to used to add a mouseover tip to the
1905 hyperlink:
1906
1907 $worksheet->insert_image( 'A1', 'logo.png',
1908 {
1909 url => 'https://github.com/jmcnamara',
1910 tip => 'GitHub'
1911 }
1912 );
1913
1914 The "description" parameter can be used to specify a description or
1915 "alt text" string for the image. In general this would be used to
1916 provide a text description of the image to help accessibility. It is an
1917 optional parameter and defaults to the filename of the image. It can be
1918 used as follows:
1919
1920 $worksheet->insert_image( 'E9', 'logo.png',
1921 {description => "This is some alternative text"} );
1922
1923 The optional "decorative" parameter is also used to help accessibility.
1924 It is used to mark the image as decorative, and thus uninformative, for
1925 automated screen readers. As in Excel, if this parameter is in use the
1926 "description" field isn't written. It is used as follows:
1927
1928 $worksheet->insert_image( 'E9', 'logo.png', {decorative => 1} );
1929
1930 Note: you must call set_row() or set_column() before insert_image() if
1931 you wish to change the default dimensions of any of the rows or columns
1932 that the image occupies. The height of a row can also change if you use
1933 a font that is larger than the default. This in turn will affect the
1934 scaling of your image. To avoid this you should explicitly set the
1935 height of the row using set_row() if it contains a font size that will
1936 change the row height.
1937
1938 BMP images must be 24 bit, true colour, bitmaps. In general it is best
1939 to avoid BMP images since they aren't compressed.
1940
1941 insert_chart( $row, $col, $chart, { %options } )
1942 This method can be used to insert a Chart object into a worksheet. The
1943 Chart must be created by the add_chart() Workbook method and it must
1944 have the "embedded" option set.
1945
1946 my $chart = $workbook->add_chart( type => 'line', embedded => 1 );
1947
1948 # Configure the chart.
1949 ...
1950
1951 # Insert the chart into the a worksheet.
1952 $worksheet->insert_chart( 'E2', $chart );
1953
1954 See add_chart() for details on how to create the Chart object and
1955 Excel::Writer::XLSX::Chart for details on how to configure it. See also
1956 the "chart_*.pl" programs in the examples directory of the distro.
1957
1958 The optional "options" hash/hashref parameter can be used to set
1959 various options for the chart. The defaults are:
1960
1961 %options = (
1962 x_offset => 0,
1963 y_offset => 0,
1964 x_scale => 1,
1965 y_scale => 1,
1966 object_position => 1,
1967 );
1968
1969 The parameters "x_offset" and "y_offset" can be used to specify an
1970 offset from the top left hand corner of the cell specified by $row and
1971 $col. The offset values are in pixels.
1972
1973 $worksheet1->insert_chart( 'E2', $chart, { x_offset =>10, y_offset => 20 });
1974
1975 The parameters "x_scale" and "y_scale" can be used to scale the
1976 inserted chart horizontally and vertically:
1977
1978 # Scale the width by 120% and the height by 150%
1979 $worksheet->insert_chart( 'E2', $chart, { y_scale => 1.2, y_scale => 1.5 } );
1980
1981 The positioning of the chart when cells are resized can be set with the
1982 "object_position" parameter:
1983
1984 $worksheet->insert_chart( 'E2', $chart, { object_position => 2 } );
1985
1986 The "object_position" parameter can have one of the following allowable
1987 values:
1988
1989 1. Move and size with cells.
1990 2. Move but don't size with cells.
1991 3. Don't move or size with cells.
1992 4. Same as Option 1, see below.
1993
1994 Option 4 appears in Excel as Option 1. However, the worksheet object is
1995 sized to take hidden rows or columns into account. This is generally
1996 only useful for images and not for charts.
1997
1998 insert_shape( $row, $col, $shape, $x, $y, $x_scale, $y_scale )
1999 This method can be used to insert a Shape object into a worksheet. The
2000 Shape must be created by the add_shape() Workbook method.
2001
2002 my $shape = $workbook->add_shape( name => 'My Shape', type => 'plus' );
2003
2004 # Configure the shape.
2005 $shape->set_text('foo');
2006 ...
2007
2008 # Insert the shape into the a worksheet.
2009 $worksheet->insert_shape( 'E2', $shape );
2010
2011 See add_shape() for details on how to create the Shape object and
2012 Excel::Writer::XLSX::Shape for details on how to configure it.
2013
2014 The $x, $y, $x_scale and $y_scale parameters are optional.
2015
2016 The parameters $x and $y can be used to specify an offset from the top
2017 left hand corner of the cell specified by $row and $col. The offset
2018 values are in pixels.
2019
2020 $worksheet1->insert_shape( 'E2', $chart, 3, 3 );
2021
2022 The parameters $x_scale and $y_scale can be used to scale the inserted
2023 shape horizontally and vertically:
2024
2025 # Scale the width by 120% and the height by 150%
2026 $worksheet->insert_shape( 'E2', $shape, 0, 0, 1.2, 1.5 );
2027
2028 See also the "shape*.pl" programs in the examples directory of the
2029 distro.
2030
2031 insert_button( $row, $col, { %options })
2032 The insert_button() method can be used to insert an Excel form button
2033 into a worksheet.
2034
2035 This method is generally only useful when used in conjunction with the
2036 Workbook add_vba_project() method to tie the button to a macro from an
2037 embedded VBA project:
2038
2039 my $workbook = Excel::Writer::XLSX->new( 'file.xlsm' );
2040 ...
2041 $workbook->add_vba_project( './vbaProject.bin' );
2042
2043 $worksheet->insert_button( 'C2', { macro => 'my_macro' } );
2044
2045 The properties of the button that can be set are:
2046
2047 macro
2048 caption
2049 width
2050 height
2051 x_scale
2052 y_scale
2053 x_offset
2054 y_offset
2055
2056 Option: macro
2057 This option is used to set the macro that the button will invoke
2058 when the user clicks on it. The macro should be included using the
2059 Workbook add_vba_project() method shown above.
2060
2061 $worksheet->insert_button( 'C2', { macro => 'my_macro' } );
2062
2063 The default macro is "ButtonX_Click" where X is the button number.
2064
2065 Option: caption
2066 This option is used to set the caption on the button. The default
2067 is "Button X" where X is the button number.
2068
2069 $worksheet->insert_button( 'C2', { macro => 'my_macro', caption => 'Hello' } );
2070
2071 Option: width
2072 This option is used to set the width of the button in pixels.
2073
2074 $worksheet->insert_button( 'C2', { macro => 'my_macro', width => 128 } );
2075
2076 The default button width is 64 pixels which is the width of a
2077 default cell.
2078
2079 Option: height
2080 This option is used to set the height of the button in pixels.
2081
2082 $worksheet->insert_button( 'C2', { macro => 'my_macro', height => 40 } );
2083
2084 The default button height is 20 pixels which is the height of a
2085 default cell.
2086
2087 Option: x_scale
2088 This option is used to set the width of the button as a factor of
2089 the default width.
2090
2091 $worksheet->insert_button( 'C2', { macro => 'my_macro', x_scale => 2.0 );
2092
2093 Option: y_scale
2094 This option is used to set the height of the button as a factor of
2095 the default height.
2096
2097 $worksheet->insert_button( 'C2', { macro => 'my_macro', y_scale => 2.0 );
2098
2099 Option: x_offset
2100 This option is used to change the x offset, in pixels, of a button
2101 within a cell:
2102
2103 $worksheet->insert_button( 'C2', { macro => 'my_macro', x_offset => 2 );
2104
2105 Option: y_offset
2106 This option is used to change the y offset, in pixels, of a comment
2107 within a cell.
2108
2109 Note: Button is the only Excel form element that is available in
2110 Excel::Writer::XLSX. Form elements represent a lot of work to implement
2111 and the underlying VML syntax isn't very much fun.
2112
2113 data_validation()
2114 The data_validation() method is used to construct an Excel data
2115 validation or to limit the user input to a dropdown list of values.
2116
2117 $worksheet->data_validation('B3',
2118 {
2119 validate => 'integer',
2120 criteria => '>',
2121 value => 100,
2122 });
2123
2124 $worksheet->data_validation('B5:B9',
2125 {
2126 validate => 'list',
2127 value => ['open', 'high', 'close'],
2128 });
2129
2130 This method contains a lot of parameters and is described in detail in
2131 a separate section "DATA VALIDATION IN EXCEL".
2132
2133 See also the "data_validate.pl" program in the examples directory of
2134 the distro
2135
2136 conditional_formatting()
2137 The conditional_formatting() method is used to add formatting to a cell
2138 or range of cells based on user defined criteria.
2139
2140 $worksheet->conditional_formatting( 'A1:J10',
2141 {
2142 type => 'cell',
2143 criteria => '>=',
2144 value => 50,
2145 format => $format1,
2146 }
2147 );
2148
2149 This method contains a lot of parameters and is described in detail in
2150 a separate section "CONDITIONAL FORMATTING IN EXCEL".
2151
2152 See also the "conditional_format.pl" program in the examples directory
2153 of the distro
2154
2155 add_sparkline()
2156 The add_sparkline() worksheet method is used to add sparklines to a
2157 cell or a range of cells.
2158
2159 $worksheet->add_sparkline(
2160 {
2161 location => 'F2',
2162 range => 'Sheet1!A2:E2',
2163 type => 'column',
2164 style => 12,
2165 }
2166 );
2167
2168 This method contains a lot of parameters and is described in detail in
2169 a separate section "SPARKLINES IN EXCEL".
2170
2171 See also the "sparklines1.pl" and "sparklines2.pl" example programs in
2172 the "examples" directory of the distro.
2173
2174 Note: Sparklines are a feature of Excel 2010+ only. You can write them
2175 to an XLSX file that can be read by Excel 2007 but they won't be
2176 displayed.
2177
2178 add_table()
2179 The add_table() method is used to group a range of cells into an Excel
2180 Table.
2181
2182 $worksheet->add_table( 'B3:F7', { ... } );
2183
2184 This method contains a lot of parameters and is described in detail in
2185 a separate section "TABLES IN EXCEL".
2186
2187 See also the "tables.pl" program in the examples directory of the
2188 distro
2189
2190 get_name()
2191 The get_name() method is used to retrieve the name of a worksheet. For
2192 example:
2193
2194 for my $sheet ( $workbook->sheets() ) {
2195 print $sheet->get_name();
2196 }
2197
2198 For reasons related to the design of Excel::Writer::XLSX and to the
2199 internals of Excel there is no set_name() method. The only way to set
2200 the worksheet name is via the add_worksheet() method.
2201
2202 activate()
2203 The activate() method is used to specify which worksheet is initially
2204 visible in a multi-sheet workbook:
2205
2206 $worksheet1 = $workbook->add_worksheet( 'To' );
2207 $worksheet2 = $workbook->add_worksheet( 'the' );
2208 $worksheet3 = $workbook->add_worksheet( 'wind' );
2209
2210 $worksheet3->activate();
2211
2212 This is similar to the Excel VBA activate method. More than one
2213 worksheet can be selected via the select() method, see below, however
2214 only one worksheet can be active.
2215
2216 The default active worksheet is the first worksheet.
2217
2218 select()
2219 The select() method is used to indicate that a worksheet is selected in
2220 a multi-sheet workbook:
2221
2222 $worksheet1->activate();
2223 $worksheet2->select();
2224 $worksheet3->select();
2225
2226 A selected worksheet has its tab highlighted. Selecting worksheets is a
2227 way of grouping them together so that, for example, several worksheets
2228 could be printed in one go. A worksheet that has been activated via the
2229 activate() method will also appear as selected.
2230
2231 hide()
2232 The hide() method is used to hide a worksheet:
2233
2234 $worksheet2->hide();
2235
2236 You may wish to hide a worksheet in order to avoid confusing a user
2237 with intermediate data or calculations.
2238
2239 A hidden worksheet can not be activated or selected so this method is
2240 mutually exclusive with the activate() and select() methods. In
2241 addition, since the first worksheet will default to being the active
2242 worksheet, you cannot hide the first worksheet without activating
2243 another sheet:
2244
2245 $worksheet2->activate();
2246 $worksheet1->hide();
2247
2248 set_first_sheet()
2249 The activate() method determines which worksheet is initially selected.
2250 However, if there are a large number of worksheets the selected
2251 worksheet may not appear on the screen. To avoid this you can select
2252 which is the leftmost visible worksheet using set_first_sheet():
2253
2254 for ( 1 .. 20 ) {
2255 $workbook->add_worksheet;
2256 }
2257
2258 $worksheet21 = $workbook->add_worksheet();
2259 $worksheet22 = $workbook->add_worksheet();
2260
2261 $worksheet21->set_first_sheet();
2262 $worksheet22->activate();
2263
2264 This method is not required very often. The default value is the first
2265 worksheet.
2266
2267 protect( $password, \%options )
2268 The protect() method is used to protect a worksheet from modification:
2269
2270 $worksheet->protect();
2271
2272 The protect() method also has the effect of enabling a cell's "locked"
2273 and "hidden" properties if they have been set. A locked cell cannot be
2274 edited and this property is on by default for all cells. A hidden cell
2275 will display the results of a formula but not the formula itself.
2276
2277 See the "protection.pl" program in the examples directory of the distro
2278 for an illustrative example and the "set_locked" and "set_hidden"
2279 format methods in "CELL FORMATTING".
2280
2281 You can optionally add a password to the worksheet protection:
2282
2283 $worksheet->protect( 'drowssap' );
2284
2285 Passing the empty string '' is the same as turning on protection
2286 without a password.
2287
2288 Note, the worksheet level password in Excel provides very weak
2289 protection. It does not encrypt your data and is very easy to
2290 deactivate. Full workbook encryption is not supported by
2291 "Excel::Writer::XLSX" since it requires a completely different file
2292 format and would take several man months to implement.
2293
2294 You can specify which worksheet elements you wish to protect by passing
2295 a hash_ref with any or all of the following keys:
2296
2297 # Default shown.
2298 %options = (
2299 objects => 0,
2300 scenarios => 0,
2301 format_cells => 0,
2302 format_columns => 0,
2303 format_rows => 0,
2304 insert_columns => 0,
2305 insert_rows => 0,
2306 insert_hyperlinks => 0,
2307 delete_columns => 0,
2308 delete_rows => 0,
2309 select_locked_cells => 1,
2310 sort => 0,
2311 autofilter => 0,
2312 pivot_tables => 0,
2313 select_unlocked_cells => 1,
2314 );
2315
2316 The default boolean values are shown above. Individual elements can be
2317 protected as follows:
2318
2319 $worksheet->protect( 'drowssap', { insert_rows => 1 } );
2320
2321 For chartsheets the allowable options and default values are:
2322
2323 %options = (
2324 objects => 1,
2325 content => 1,
2326 );
2327
2328 unprotect_range( $cell_range, $range_name )
2329 The unprotect_range() method is used to unprotect ranges in a protected
2330 worksheet. It can be used to set a single range or multiple ranges:
2331
2332 $worksheet->unprotect_range( 'A1' );
2333 $worksheet->unprotect_range( 'C1' );
2334 $worksheet->unprotect_range( 'E1:E3' );
2335 $worksheet->unprotect_range( 'G1:K100' );
2336
2337 As in Excel the ranges are given sequential names like "Range1" and
2338 "Range2" but a user defined name can also be specified:
2339
2340 $worksheet->unprotect_range( 'G4:I6', 'MyRange' );
2341
2342 set_selection( $first_row, $first_col, $last_row, $last_col )
2343 This method can be used to specify which cell or cells are selected in
2344 a worksheet. The most common requirement is to select a single cell, in
2345 which case $last_row and $last_col can be omitted. The active cell
2346 within a selected range is determined by the order in which $first and
2347 $last are specified. It is also possible to specify a cell or a range
2348 using A1 notation. See the note about "Cell notation".
2349
2350 Examples:
2351
2352 $worksheet1->set_selection( 3, 3 ); # 1. Cell D4.
2353 $worksheet2->set_selection( 3, 3, 6, 6 ); # 2. Cells D4 to G7.
2354 $worksheet3->set_selection( 6, 6, 3, 3 ); # 3. Cells G7 to D4.
2355 $worksheet4->set_selection( 'D4' ); # Same as 1.
2356 $worksheet5->set_selection( 'D4:G7' ); # Same as 2.
2357 $worksheet6->set_selection( 'G7:D4' ); # Same as 3.
2358
2359 The default cell selections is (0, 0), 'A1'.
2360
2361 set_row( $row, $height, $format, $hidden, $level, $collapsed )
2362 This method can be used to change the default properties of a row. All
2363 parameters apart from $row are optional.
2364
2365 The most common use for this method is to change the height of a row.
2366
2367 $worksheet->set_row( 0, 20 ); # Row 1 height set to 20
2368
2369 Note: the row height is in Excel character units. To set the height in
2370 pixels use the set_row_pixels() method, see below.
2371
2372 If you wish to set the format without changing the height you can pass
2373 "undef" as the height parameter:
2374
2375 $worksheet->set_row( 0, undef, $format );
2376
2377 The $format parameter will be applied to any cells in the row that
2378 don't have a format. For example
2379
2380 $worksheet->set_row( 0, undef, $format1 ); # Set the format for row 1
2381 $worksheet->write( 'A1', 'Hello' ); # Defaults to $format1
2382 $worksheet->write( 'B1', 'Hello', $format2 ); # Keeps $format2
2383
2384 If you wish to define a row format in this way you should call the
2385 method before any calls to write(). Calling it afterwards will
2386 overwrite any format that was previously specified.
2387
2388 The $hidden parameter should be set to 1 if you wish to hide a row.
2389 This can be used, for example, to hide intermediary steps in a
2390 complicated calculation:
2391
2392 $worksheet->set_row( 0, 20, $format, 1 );
2393 $worksheet->set_row( 1, undef, undef, 1 );
2394
2395 The $level parameter is used to set the outline level of the row.
2396 Outlines are described in "OUTLINES AND GROUPING IN EXCEL". Adjacent
2397 rows with the same outline level are grouped together into a single
2398 outline.
2399
2400 The following example sets an outline level of 1 for rows 2 and 3
2401 (zero-indexed):
2402
2403 $worksheet->set_row( 1, undef, undef, 0, 1 );
2404 $worksheet->set_row( 2, undef, undef, 0, 1 );
2405
2406 The $hidden parameter can also be used to hide collapsed outlined rows
2407 when used in conjunction with the $level parameter.
2408
2409 $worksheet->set_row( 1, undef, undef, 1, 1 );
2410 $worksheet->set_row( 2, undef, undef, 1, 1 );
2411
2412 For collapsed outlines you should also indicate which row has the
2413 collapsed "+" symbol using the optional $collapsed parameter.
2414
2415 $worksheet->set_row( 3, undef, undef, 0, 0, 1 );
2416
2417 For a more complete example see the "outline.pl" and
2418 "outline_collapsed.pl" programs in the examples directory of the
2419 distro.
2420
2421 Excel allows up to 7 outline levels. Therefore the $level parameter
2422 should be in the range "0 <= $level <= 7".
2423
2424 set_row_pixels( $row, $height, $format, $hidden, $level, $collapsed )
2425 This method is the same as set_row() except that $height is in pixels.
2426
2427 $worksheet->set_row ( 0, 24 ); # Set row height in character units
2428 $worksheet->set_row_pixels( 1, 18 ); # Set row to same height in pixels
2429
2430 set_column( $first_col, $last_col, $width, $format, $hidden, $level,
2431 $collapsed )
2432 This method can be used to change the default properties of a single
2433 column or a range of columns. All parameters apart from $first_col and
2434 $last_col are optional.
2435
2436 If set_column() is applied to a single column the value of $first_col
2437 and $last_col should be the same. In the case where $last_col is zero
2438 it is set to the same value as $first_col.
2439
2440 It is also possible, and generally clearer, to specify a column range
2441 using the form of A1 notation used for columns. See the note about
2442 "Cell notation".
2443
2444 Examples:
2445
2446 $worksheet->set_column( 0, 0, 20 ); # Column A width set to 20
2447 $worksheet->set_column( 1, 3, 30 ); # Columns B-D width set to 30
2448 $worksheet->set_column( 'E:E', 20 ); # Column E width set to 20
2449 $worksheet->set_column( 'F:H', 30 ); # Columns F-H width set to 30
2450
2451 The width corresponds to the column width value that is specified in
2452 Excel. It is approximately equal to the length of a string in the
2453 default font of Calibri 11. To set the width in pixels use the
2454 set_column_pixels() method, see below.
2455
2456 Unfortunately, there is no way to specify "AutoFit" for a column in the
2457 Excel file format. This feature is only available at runtime from
2458 within Excel.
2459
2460 As usual the $format parameter is optional, for additional information,
2461 see "CELL FORMATTING". If you wish to set the format without changing
2462 the width you can pass "undef" as the width parameter:
2463
2464 $worksheet->set_column( 0, 0, undef, $format );
2465
2466 The $format parameter will be applied to any cells in the column that
2467 don't have a format. For example
2468
2469 $worksheet->set_column( 'A:A', undef, $format1 ); # Set format for col 1
2470 $worksheet->write( 'A1', 'Hello' ); # Defaults to $format1
2471 $worksheet->write( 'A2', 'Hello', $format2 ); # Keeps $format2
2472
2473 If you wish to define a column format in this way you should call the
2474 method before any calls to write(). If you call it afterwards it won't
2475 have any effect.
2476
2477 A default row format takes precedence over a default column format
2478
2479 $worksheet->set_row( 0, undef, $format1 ); # Set format for row 1
2480 $worksheet->set_column( 'A:A', undef, $format2 ); # Set format for col 1
2481 $worksheet->write( 'A1', 'Hello' ); # Defaults to $format1
2482 $worksheet->write( 'A2', 'Hello' ); # Defaults to $format2
2483
2484 The $hidden parameter should be set to 1 if you wish to hide a column.
2485 This can be used, for example, to hide intermediary steps in a
2486 complicated calculation:
2487
2488 $worksheet->set_column( 'D:D', 20, $format, 1 );
2489 $worksheet->set_column( 'E:E', undef, undef, 1 );
2490
2491 The $level parameter is used to set the outline level of the column.
2492 Outlines are described in "OUTLINES AND GROUPING IN EXCEL". Adjacent
2493 columns with the same outline level are grouped together into a single
2494 outline.
2495
2496 The following example sets an outline level of 1 for columns B to G:
2497
2498 $worksheet->set_column( 'B:G', undef, undef, 0, 1 );
2499
2500 The $hidden parameter can also be used to hide collapsed outlined
2501 columns when used in conjunction with the $level parameter.
2502
2503 $worksheet->set_column( 'B:G', undef, undef, 1, 1 );
2504
2505 For collapsed outlines you should also indicate which row has the
2506 collapsed "+" symbol using the optional $collapsed parameter.
2507
2508 $worksheet->set_column( 'H:H', undef, undef, 0, 0, 1 );
2509
2510 For a more complete example see the "outline.pl" and
2511 "outline_collapsed.pl" programs in the examples directory of the
2512 distro.
2513
2514 Excel allows up to 7 outline levels. Therefore the $level parameter
2515 should be in the range "0 <= $level <= 7".
2516
2517 set_column_pixels( $first_col, $last_col, $width, $format, $hidden, $level,
2518 $collapsed )
2519 This method is the same as set_column() except that $width is in
2520 pixels.
2521
2522 $worksheet->set_column( 0, 0, 10 ); # Column A width set to 20 in character units
2523 $worksheet->set_column( 1, 1, 75 ); # Column B set to the same width in pixels
2524
2525 set_default_row( $height, $hide_unused_rows )
2526 The set_default_row() method is used to set the limited number of
2527 default row properties allowed by Excel. These are the default height
2528 and the option to hide unused rows.
2529
2530 $worksheet->set_default_row( 24 ); # Set the default row height to 24.
2531
2532 The option to hide unused rows is used by Excel as an optimisation so
2533 that the user can hide a large number of rows without generating a very
2534 large file with an entry for each hidden row.
2535
2536 $worksheet->set_default_row( undef, 1 );
2537
2538 See the "hide_row_col.pl" example program.
2539
2540 outline_settings( $visible, $symbols_below, $symbols_right, $auto_style )
2541 The outline_settings() method is used to control the appearance of
2542 outlines in Excel. Outlines are described in "OUTLINES AND GROUPING IN
2543 EXCEL".
2544
2545 The $visible parameter is used to control whether or not outlines are
2546 visible. Setting this parameter to 0 will cause all outlines on the
2547 worksheet to be hidden. They can be unhidden in Excel by means of the
2548 "Show Outline Symbols" command button. The default setting is 1 for
2549 visible outlines.
2550
2551 $worksheet->outline_settings( 0 );
2552
2553 The $symbols_below parameter is used to control whether the row outline
2554 symbol will appear above or below the outline level bar. The default
2555 setting is 1 for symbols to appear below the outline level bar.
2556
2557 The $symbols_right parameter is used to control whether the column
2558 outline symbol will appear to the left or the right of the outline
2559 level bar. The default setting is 1 for symbols to appear to the right
2560 of the outline level bar.
2561
2562 The $auto_style parameter is used to control whether the automatic
2563 outline generator in Excel uses automatic styles when creating an
2564 outline. This has no effect on a file generated by
2565 "Excel::Writer::XLSX" but it does have an effect on how the worksheet
2566 behaves after it is created. The default setting is 0 for "Automatic
2567 Styles" to be turned off.
2568
2569 The default settings for all of these parameters correspond to Excel's
2570 default parameters.
2571
2572 The worksheet parameters controlled by outline_settings() are rarely
2573 used.
2574
2575 freeze_panes( $row, $col, $top_row, $left_col )
2576 This method can be used to divide a worksheet into horizontal or
2577 vertical regions known as panes and to also "freeze" these panes so
2578 that the splitter bars are not visible. This is the same as the
2579 "Window->Freeze Panes" menu command in Excel
2580
2581 The parameters $row and $col are used to specify the location of the
2582 split. It should be noted that the split is specified at the top or
2583 left of a cell and that the method uses zero based indexing. Therefore
2584 to freeze the first row of a worksheet it is necessary to specify the
2585 split at row 2 (which is 1 as the zero-based index). This might lead
2586 you to think that you are using a 1 based index but this is not the
2587 case.
2588
2589 You can set one of the $row and $col parameters as zero if you do not
2590 want either a vertical or horizontal split.
2591
2592 Examples:
2593
2594 $worksheet->freeze_panes( 1, 0 ); # Freeze the first row
2595 $worksheet->freeze_panes( 'A2' ); # Same using A1 notation
2596 $worksheet->freeze_panes( 0, 1 ); # Freeze the first column
2597 $worksheet->freeze_panes( 'B1' ); # Same using A1 notation
2598 $worksheet->freeze_panes( 1, 2 ); # Freeze first row and first 2 columns
2599 $worksheet->freeze_panes( 'C2' ); # Same using A1 notation
2600
2601 The parameters $top_row and $left_col are optional. They are used to
2602 specify the top-most or left-most visible row or column in the
2603 scrolling region of the panes. For example to freeze the first row and
2604 to have the scrolling region begin at row twenty:
2605
2606 $worksheet->freeze_panes( 1, 0, 20, 0 );
2607
2608 You cannot use A1 notation for the $top_row and $left_col parameters.
2609
2610 See also the "panes.pl" program in the "examples" directory of the
2611 distribution.
2612
2613 split_panes( $y, $x, $top_row, $left_col )
2614 This method can be used to divide a worksheet into horizontal or
2615 vertical regions known as panes. This method is different from the
2616 freeze_panes() method in that the splits between the panes will be
2617 visible to the user and each pane will have its own scroll bars.
2618
2619 The parameters $y and $x are used to specify the vertical and
2620 horizontal position of the split. The units for $y and $x are the same
2621 as those used by Excel to specify row height and column width. However,
2622 the vertical and horizontal units are different from each other.
2623 Therefore you must specify the $y and $x parameters in terms of the row
2624 heights and column widths that you have set or the default values which
2625 are 15 for a row and 8.43 for a column.
2626
2627 You can set one of the $y and $x parameters as zero if you do not want
2628 either a vertical or horizontal split. The parameters $top_row and
2629 $left_col are optional. They are used to specify the top-most or left-
2630 most visible row or column in the bottom-right pane.
2631
2632 Example:
2633
2634 $worksheet->split_panes( 15, 0, ); # First row
2635 $worksheet->split_panes( 0, 8.43 ); # First column
2636 $worksheet->split_panes( 15, 8.43 ); # First row and column
2637
2638 You cannot use A1 notation with this method.
2639
2640 See also the freeze_panes() method and the "panes.pl" program in the
2641 "examples" directory of the distribution.
2642
2643 merge_range( $first_row, $first_col, $last_row, $last_col, $token, $format
2644 )
2645 The merge_range() method allows you to merge cells that contain other
2646 types of alignment in addition to the merging:
2647
2648 my $format = $workbook->add_format(
2649 border => 6,
2650 valign => 'vcenter',
2651 align => 'center',
2652 );
2653
2654 $worksheet->merge_range( 'B3:D4', 'Vertical and horizontal', $format );
2655
2656 merge_range() writes its $token argument using the worksheet write()
2657 method. Therefore it will handle numbers, strings, formulas or urls as
2658 required. If you need to specify the required "write_*()" method use
2659 the merge_range_type() method, see below.
2660
2661 The full possibilities of this method are shown in the "merge3.pl" to
2662 "merge6.pl" programs in the "examples" directory of the distribution.
2663
2664 merge_range_type( $type, $first_row, $first_col, $last_row, $last_col, ...
2665 )
2666 The merge_range() method, see above, uses write() to insert the
2667 required data into to a merged range. However, there may be times where
2668 this isn't what you require so as an alternative the "merge_range_type
2669 ()" method allows you to specify the type of data you wish to write.
2670 For example:
2671
2672 $worksheet->merge_range_type( 'number', 'B2:C2', 123, $format1 );
2673 $worksheet->merge_range_type( 'string', 'B4:C4', 'foo', $format2 );
2674 $worksheet->merge_range_type( 'formula', 'B6:C6', '=1+2', $format3 );
2675
2676 The $type must be one of the following, which corresponds to a
2677 "write_*()" method:
2678
2679 'number'
2680 'string'
2681 'formula'
2682 'array_formula'
2683 'blank'
2684 'rich_string'
2685 'date_time'
2686 'url'
2687
2688 Any arguments after the range should be whatever the appropriate method
2689 accepts:
2690
2691 $worksheet->merge_range_type( 'rich_string', 'B8:C8',
2692 'This is ', $bold, 'bold', $format4 );
2693
2694 Note, you must always pass a $format object as an argument, even if it
2695 is a default format.
2696
2697 set_zoom( $scale )
2698 Set the worksheet zoom factor in the range "10 <= $scale <= 400":
2699
2700 $worksheet1->set_zoom( 50 );
2701 $worksheet2->set_zoom( 75 );
2702 $worksheet3->set_zoom( 300 );
2703 $worksheet4->set_zoom( 400 );
2704
2705 The default zoom factor is 100. You cannot zoom to "Selection" because
2706 it is calculated by Excel at run-time.
2707
2708 Note, set_zoom() does not affect the scale of the printed page. For
2709 that you should use set_print_scale().
2710
2711 right_to_left()
2712 The right_to_left() method is used to change the default direction of
2713 the worksheet from left-to-right, with the A1 cell in the top left, to
2714 right-to-left, with the A1 cell in the top right.
2715
2716 $worksheet->right_to_left();
2717
2718 This is useful when creating Arabic, Hebrew or other near or far
2719 eastern worksheets that use right-to-left as the default direction.
2720
2721 hide_zero()
2722 The hide_zero() method is used to hide any zero values that appear in
2723 cells.
2724
2725 $worksheet->hide_zero();
2726
2727 In Excel this option is found under Tools->Options->View.
2728
2729 set_background( $filename )
2730 The set_background() method can be used to set the background image for
2731 the worksheet:
2732
2733 $worksheet->set_background( 'logo.png' )
2734
2735 The set_background() method supports all the image formats supported by
2736 insert_image().
2737
2738 Some people use this method to add a watermark background to their
2739 document. However, Microsoft recommends using a header image to set a
2740 watermark <https://support.microsoft.com/en-us/office/add-a-watermark-
2741 in-excel-a372182a-d733-484e-825c-18ddf3edf009>. The choice of method
2742 depends on whether you want the watermark to be visible in normal
2743 viewing mode or just when the file is printed. In Excel::Writer::XLSX
2744 you can get the header watermark effect using set_header():
2745
2746 $worksheet->set_header( '&C&G', undef, { image_center => 'watermark.png' } )
2747
2748 set_tab_color()
2749 The set_tab_color() method is used to change the colour of the
2750 worksheet tab. You can use one of the standard colour names provided by
2751 the Format object or a Html style "#RRGGBB" colour. See "WORKING WITH
2752 COLOURS".
2753
2754 $worksheet1->set_tab_color( 'red' );
2755 $worksheet2->set_tab_color( '#FF6600' );
2756
2757 See the "tab_colors.pl" program in the examples directory of the
2758 distro.
2759
2760 autofilter( $first_row, $first_col, $last_row, $last_col )
2761 This method allows an autofilter to be added to a worksheet. An
2762 autofilter is a way of adding drop down lists to the headers of a 2D
2763 range of worksheet data. This allows users to filter the data based on
2764 simple criteria so that some data is shown and some is hidden.
2765
2766 To add an autofilter to a worksheet:
2767
2768 $worksheet->autofilter( 0, 0, 10, 3 );
2769 $worksheet->autofilter( 'A1:D11' ); # Same as above in A1 notation.
2770
2771 Filter conditions can be applied using the filter_column() or
2772 filter_column_list() method.
2773
2774 See the "autofilter.pl" program in the examples directory of the distro
2775 for a more detailed example.
2776
2777 filter_column( $column, $expression )
2778 The "filter_column" method can be used to filter columns in a
2779 autofilter range based on simple conditions.
2780
2781 NOTE: It isn't sufficient to just specify the filter condition. You
2782 must also hide any rows that don't match the filter condition. Rows are
2783 hidden using the set_row() "visible" parameter. "Excel::Writer::XLSX"
2784 cannot do this automatically since it isn't part of the file format.
2785 See the "autofilter.pl" program in the examples directory of the distro
2786 for an example.
2787
2788 The conditions for the filter are specified using simple expressions:
2789
2790 $worksheet->filter_column( 'A', 'x > 2000' );
2791 $worksheet->filter_column( 'B', 'x > 2000 and x < 5000' );
2792
2793 The $column parameter can either be a zero indexed column number or a
2794 string column name.
2795
2796 The following operators are available:
2797
2798 Operator Synonyms
2799 == = eq =~
2800 != <> ne !=
2801 >
2802 <
2803 >=
2804 <=
2805
2806 and &&
2807 or ||
2808
2809 The operator synonyms are just syntactic sugar to make you more
2810 comfortable using the expressions. It is important to remember that the
2811 expressions will be interpreted by Excel and not by perl.
2812
2813 An expression can comprise a single statement or two statements
2814 separated by the "and" and "or" operators. For example:
2815
2816 'x < 2000'
2817 'x > 2000'
2818 'x == 2000'
2819 'x > 2000 and x < 5000'
2820 'x == 2000 or x == 5000'
2821
2822 Filtering of blank or non-blank data can be achieved by using a value
2823 of "Blanks" or "NonBlanks" in the expression:
2824
2825 'x == Blanks'
2826 'x == NonBlanks'
2827
2828 Excel also allows some simple string matching operations:
2829
2830 'x =~ b*' # begins with b
2831 'x !~ b*' # doesn't begin with b
2832 'x =~ *b' # ends with b
2833 'x !~ *b' # doesn't end with b
2834 'x =~ *b*' # contains b
2835 'x !~ *b*' # doesn't contains b
2836
2837 You can also use "*" to match any character or number and "?" to match
2838 any single character or number. No other regular expression quantifier
2839 is supported by Excel's filters. Excel's regular expression characters
2840 can be escaped using "~".
2841
2842 The placeholder variable "x" in the above examples can be replaced by
2843 any simple string. The actual placeholder name is ignored internally so
2844 the following are all equivalent:
2845
2846 'x < 2000'
2847 'col < 2000'
2848 'Price < 2000'
2849
2850 Also, note that a filter condition can only be applied to a column in a
2851 range specified by the autofilter() Worksheet method.
2852
2853 See the "autofilter.pl" program in the examples directory of the distro
2854 for a more detailed example.
2855
2856 Note Spreadsheet::WriteExcel supports Top 10 style filters. These
2857 aren't currently supported by Excel::Writer::XLSX but may be added
2858 later.
2859
2860 filter_column_list( $column, @matches )
2861 Prior to Excel 2007 it was only possible to have either 1 or 2 filter
2862 conditions such as the ones shown above in the "filter_column" method.
2863
2864 Excel 2007 introduced a new list style filter where it is possible to
2865 specify 1 or more 'or' style criteria. For example if your column
2866 contained data for the first six months the initial data would be
2867 displayed as all selected as shown on the left. Then if you selected
2868 'March', 'April' and 'May' they would be displayed as shown on the
2869 right.
2870
2871 No criteria selected Some criteria selected.
2872
2873 [/] (Select all) [X] (Select all)
2874 [/] January [ ] January
2875 [/] February [ ] February
2876 [/] March [/] March
2877 [/] April [/] April
2878 [/] May [/] May
2879 [/] June [ ] June
2880
2881 The filter_column_list() method can be used to represent these types of
2882 filters:
2883
2884 $worksheet->filter_column_list( 'A', 'March', 'April', 'May' );
2885
2886 The $column parameter can either be a zero indexed column number or a
2887 string column name.
2888
2889 One or more criteria can be selected:
2890
2891 $worksheet->filter_column_list( 0, 'March' );
2892 $worksheet->filter_column_list( 1, 100, 110, 120, 130 );
2893
2894 NOTE: It isn't sufficient to just specify the filter condition. You
2895 must also hide any rows that don't match the filter condition. Rows are
2896 hidden using the set_row() "visible" parameter. "Excel::Writer::XLSX"
2897 cannot do this automatically since it isn't part of the file format.
2898 See the "autofilter.pl" program in the examples directory of the distro
2899 for an example.
2900
2901 convert_date_time( $date_string )
2902 The convert_date_time() method is used internally by the
2903 write_date_time() method to convert date strings to a number that
2904 represents an Excel date and time.
2905
2906 It is exposed as a public method for utility purposes.
2907
2908 The $date_string format is detailed in the write_date_time() method.
2909
2910 set_vba_name()
2911 The Worksheet set_vba_name() method can be used to set the VBA codename
2912 for the worksheet (there is a similar method for the workbook VBA
2913 name). This is sometimes required when a "vbaProject" macro included
2914 via add_vba_project() refers to the worksheet. The default Excel VBA
2915 name of "Sheet1", etc., is used if a user defined name isn't specified.
2916
2917 See also "WORKING WITH VBA MACROS".
2918
2919 ignore_errors()
2920 The ignore_errors() method can be used to ignore various worksheet cell
2921 errors/warnings. For example the following code writes a string that
2922 looks like a number:
2923
2924 $worksheet->write_string('D2', '123');
2925
2926 This causes Excel to display a small green triangle in the top left
2927 hand corner of the cell to indicate an error/warning.
2928
2929 Sometimes these warnings are useful indicators that there is an issue
2930 in the spreadsheet but sometimes it is preferable to turn them off.
2931 Warnings can be turned off at the Excel level for all workbooks and
2932 worksheets by using the using "Excel options -> Formulas -> Error
2933 checking rules". Alternatively you can turn them off for individual
2934 cells in a worksheet, or ranges of cells, using the ignore_errors()
2935 method with a hashref of options and ranges like this:
2936
2937 $worksheet->ignore_errors({number_stored_as_text => 'A1:H50'});
2938
2939 # Or for more than one option:
2940 $worksheet->ignore_errors({number_stored_as_text => 'A1:H50',
2941 eval_error => 'A1:H50'});
2942
2943 The range can be a single cell, a range of cells, or multiple cells and
2944 ranges separated by spaces:
2945
2946 # Single cell.
2947 $worksheet->ignore_errors({eval_error => 'C6'});
2948
2949 # Or a single range:
2950 $worksheet->ignore_errors({eval_error => 'C6:G8'});
2951
2952 # Or multiple cells and ranges:
2953 $worksheet->ignore_errors({eval_error => 'C6 E6 G1:G20 J2:J6'});
2954
2955 Note: calling "ignore_errors" multiple times will overwrite the
2956 previous settings.
2957
2958 You can turn off warnings for an entire column by specifying the range
2959 from the first cell in the column to the last cell in the column:
2960
2961 $worksheet->ignore_errors({number_stored_as_text => 'A1:A1048576'});
2962
2963 Or for the entire worksheet by specifying the range from the first cell
2964 in the worksheet to the last cell in the worksheet:
2965
2966 $worksheet->ignore_errors({number_stored_as_text => 'A1:XFD1048576'});
2967
2968 The worksheet errors/warnings that can be ignored are:
2969
2970 • "number_stored_as_text": Turn off errors/warnings for numbers
2971 stores as text.
2972
2973 • "eval_error": Turn off errors/warnings for formula errors (such as
2974 divide by zero).
2975
2976 • "formula_differs": Turn off errors/warnings for formulas that
2977 differ from surrounding formulas.
2978
2979 • "formula_range": Turn off errors/warnings for formulas that omit
2980 cells in a range.
2981
2982 • "formula_unlocked": Turn off errors/warnings for unlocked cells
2983 that contain formulas.
2984
2985 • "empty_cell_reference": Turn off errors/warnings for formulas that
2986 refer to empty cells.
2987
2988 • "list_data_validation": Turn off errors/warnings for cells in a
2989 table that do not comply with applicable data validation rules.
2990
2991 • "calculated_column": Turn off errors/warnings for cell formulas
2992 that differ from the column formula.
2993
2994 • "two_digit_text_year": Turn off errors/warnings for formulas that
2995 contain a two digit text representation of a year.
2996
2998 Page set-up methods affect the way that a worksheet looks when it is
2999 printed. They control features such as page headers and footers and
3000 margins. These methods are really just standard worksheet methods. They
3001 are documented here in a separate section for the sake of clarity.
3002
3003 The following methods are available for page set-up:
3004
3005 set_landscape()
3006 set_portrait()
3007 set_page_view()
3008 set_paper()
3009 center_horizontally()
3010 center_vertically()
3011 set_margins()
3012 set_header()
3013 set_footer()
3014 repeat_rows()
3015 repeat_columns()
3016 hide_gridlines()
3017 print_row_col_headers()
3018 print_area()
3019 print_across()
3020 fit_to_pages()
3021 set_start_page()
3022 set_print_scale()
3023 print_black_and_white()
3024 set_h_pagebreaks()
3025 set_v_pagebreaks()
3026
3027 A common requirement when working with Excel::Writer::XLSX is to apply
3028 the same page set-up features to all of the worksheets in a workbook.
3029 To do this you can use the sheets() method of the "workbook" class to
3030 access the array of worksheets in a workbook:
3031
3032 for $worksheet ( $workbook->sheets() ) {
3033 $worksheet->set_landscape();
3034 }
3035
3036 set_landscape()
3037 This method is used to set the orientation of a worksheet's printed
3038 page to landscape:
3039
3040 $worksheet->set_landscape(); # Landscape mode
3041
3042 set_portrait()
3043 This method is used to set the orientation of a worksheet's printed
3044 page to portrait. The default worksheet orientation is portrait, so you
3045 won't generally need to call this method.
3046
3047 $worksheet->set_portrait(); # Portrait mode
3048
3049 set_page_view()
3050 This method is used to display the worksheet in "Page View/Layout"
3051 mode.
3052
3053 $worksheet->set_page_view();
3054
3055 set_paper( $index )
3056 This method is used to set the paper format for the printed output of a
3057 worksheet. The following paper styles are available:
3058
3059 Index Paper format Paper size
3060 ===== ============ ==========
3061 0 Printer default -
3062 1 Letter 8 1/2 x 11 in
3063 2 Letter Small 8 1/2 x 11 in
3064 3 Tabloid 11 x 17 in
3065 4 Ledger 17 x 11 in
3066 5 Legal 8 1/2 x 14 in
3067 6 Statement 5 1/2 x 8 1/2 in
3068 7 Executive 7 1/4 x 10 1/2 in
3069 8 A3 297 x 420 mm
3070 9 A4 210 x 297 mm
3071 10 A4 Small 210 x 297 mm
3072 11 A5 148 x 210 mm
3073 12 B4 250 x 354 mm
3074 13 B5 182 x 257 mm
3075 14 Folio 8 1/2 x 13 in
3076 15 Quarto 215 x 275 mm
3077 16 - 10x14 in
3078 17 - 11x17 in
3079 18 Note 8 1/2 x 11 in
3080 19 Envelope 9 3 7/8 x 8 7/8
3081 20 Envelope 10 4 1/8 x 9 1/2
3082 21 Envelope 11 4 1/2 x 10 3/8
3083 22 Envelope 12 4 3/4 x 11
3084 23 Envelope 14 5 x 11 1/2
3085 24 C size sheet -
3086 25 D size sheet -
3087 26 E size sheet -
3088 27 Envelope DL 110 x 220 mm
3089 28 Envelope C3 324 x 458 mm
3090 29 Envelope C4 229 x 324 mm
3091 30 Envelope C5 162 x 229 mm
3092 31 Envelope C6 114 x 162 mm
3093 32 Envelope C65 114 x 229 mm
3094 33 Envelope B4 250 x 353 mm
3095 34 Envelope B5 176 x 250 mm
3096 35 Envelope B6 176 x 125 mm
3097 36 Envelope 110 x 230 mm
3098 37 Monarch 3.875 x 7.5 in
3099 38 Envelope 3 5/8 x 6 1/2 in
3100 39 Fanfold 14 7/8 x 11 in
3101 40 German Std Fanfold 8 1/2 x 12 in
3102 41 German Legal Fanfold 8 1/2 x 13 in
3103
3104 Note, it is likely that not all of these paper types will be available
3105 to the end user since it will depend on the paper formats that the
3106 user's printer supports. Therefore, it is best to stick to standard
3107 paper types.
3108
3109 $worksheet->set_paper( 1 ); # US Letter
3110 $worksheet->set_paper( 9 ); # A4
3111
3112 If you do not specify a paper type the worksheet will print using the
3113 printer's default paper.
3114
3115 center_horizontally()
3116 Center the worksheet data horizontally between the margins on the
3117 printed page:
3118
3119 $worksheet->center_horizontally();
3120
3121 center_vertically()
3122 Center the worksheet data vertically between the margins on the printed
3123 page:
3124
3125 $worksheet->center_vertically();
3126
3127 set_margins( $inches )
3128 There are several methods available for setting the worksheet margins
3129 on the printed page:
3130
3131 set_margins() # Set all margins to the same value
3132 set_margins_LR() # Set left and right margins to the same value
3133 set_margins_TB() # Set top and bottom margins to the same value
3134 set_margin_left(); # Set left margin
3135 set_margin_right(); # Set right margin
3136 set_margin_top(); # Set top margin
3137 set_margin_bottom(); # Set bottom margin
3138
3139 All of these methods take a distance in inches as a parameter. Note: 1
3140 inch = 25.4mm. ";-)" The default left and right margin is 0.7 inch. The
3141 default top and bottom margin is 0.75 inch. Note, these defaults are
3142 different from the defaults used in the binary file format by
3143 Spreadsheet::WriteExcel.
3144
3145 set_header( $string, $margin )
3146 Headers and footers are generated using a $string which is a
3147 combination of plain text and control characters. The $margin parameter
3148 is optional.
3149
3150 The available control character are:
3151
3152 Control Category Description
3153 ======= ======== ===========
3154 &L Justification Left
3155 &C Center
3156 &R Right
3157
3158 &P Information Page number
3159 &N Total number of pages
3160 &D Date
3161 &T Time
3162 &F File name
3163 &A Worksheet name
3164 &Z Workbook path
3165
3166 &fontsize Font Font size
3167 &"font,style" Font name and style
3168 &U Single underline
3169 &E Double underline
3170 &S Strikethrough
3171 &X Superscript
3172 &Y Subscript
3173
3174 &[Picture] Images Image placeholder
3175 &G Same as &[Picture]
3176
3177 && Miscellaneous Literal ampersand &
3178
3179 Text in headers and footers can be justified (aligned) to the left,
3180 center and right by prefixing the text with the control characters &L,
3181 &C and &R.
3182
3183 For example (with ASCII art representation of the results):
3184
3185 $worksheet->set_header('&LHello');
3186
3187 ---------------------------------------------------------------
3188 | |
3189 | Hello |
3190 | |
3191
3192
3193 $worksheet->set_header('&CHello');
3194
3195 ---------------------------------------------------------------
3196 | |
3197 | Hello |
3198 | |
3199
3200
3201 $worksheet->set_header('&RHello');
3202
3203 ---------------------------------------------------------------
3204 | |
3205 | Hello |
3206 | |
3207
3208 For simple text, if you do not specify any justification the text will
3209 be centred. However, you must prefix the text with &C if you specify a
3210 font name or any other formatting:
3211
3212 $worksheet->set_header('Hello');
3213
3214 ---------------------------------------------------------------
3215 | |
3216 | Hello |
3217 | |
3218
3219 You can have text in each of the justification regions:
3220
3221 $worksheet->set_header('&LCiao&CBello&RCielo');
3222
3223 ---------------------------------------------------------------
3224 | |
3225 | Ciao Bello Cielo |
3226 | |
3227
3228 The information control characters act as variables that Excel will
3229 update as the workbook or worksheet changes. Times and dates are in the
3230 users default format:
3231
3232 $worksheet->set_header('&CPage &P of &N');
3233
3234 ---------------------------------------------------------------
3235 | |
3236 | Page 1 of 6 |
3237 | |
3238
3239
3240 $worksheet->set_header('&CUpdated at &T');
3241
3242 ---------------------------------------------------------------
3243 | |
3244 | Updated at 12:30 PM |
3245 | |
3246
3247 Images can be inserted using the options shown below. Each image must
3248 have a placeholder in header string using the "&[Picture]" or &G
3249 control characters:
3250
3251 $worksheet->set_header( '&L&G', 0.3, { image_left => 'logo.jpg' });
3252
3253 You can specify the font size of a section of the text by prefixing it
3254 with the control character &n where "n" is the font size:
3255
3256 $worksheet1->set_header( '&C&30Hello Big' );
3257 $worksheet2->set_header( '&C&10Hello Small' );
3258
3259 You can specify the font of a section of the text by prefixing it with
3260 the control sequence "&"font,style"" where "fontname" is a font name
3261 such as "Courier New" or "Times New Roman" and "style" is one of the
3262 standard Windows font descriptions: "Regular", "Italic", "Bold" or
3263 "Bold Italic":
3264
3265 $worksheet1->set_header( '&C&"Courier New,Italic"Hello' );
3266 $worksheet2->set_header( '&C&"Courier New,Bold Italic"Hello' );
3267 $worksheet3->set_header( '&C&"Times New Roman,Regular"Hello' );
3268
3269 It is possible to combine all of these features together to create
3270 sophisticated headers and footers. As an aid to setting up complicated
3271 headers and footers you can record a page set-up as a macro in Excel
3272 and look at the format strings that VBA produces. Remember however that
3273 VBA uses two double quotes "" to indicate a single double quote. For
3274 the last example above the equivalent VBA code looks like this:
3275
3276 .LeftHeader = ""
3277 .CenterHeader = "&""Times New Roman,Regular""Hello"
3278 .RightHeader = ""
3279
3280 To include a single literal ampersand "&" in a header or footer you
3281 should use a double ampersand "&&":
3282
3283 $worksheet1->set_header('&CCuriouser && Curiouser - Attorneys at Law');
3284
3285 As stated above the margin parameter is optional. As with the other
3286 margins the value should be in inches. The default header and footer
3287 margin is 0.3 inch. Note, the default margin is different from the
3288 default used in the binary file format by Spreadsheet::WriteExcel. The
3289 header and footer margin size can be set as follows:
3290
3291 $worksheet->set_header( '&CHello', 0.75 );
3292
3293 The header and footer margins are independent of the top and bottom
3294 margins.
3295
3296 The available options are:
3297
3298 • "image_left" The path to the image. Requires a &G or "&[Picture]"
3299 placeholder.
3300
3301 • "image_center" Same as above.
3302
3303 • "image_right" Same as above.
3304
3305 • "scale_with_doc" Scale header with document. Defaults to true.
3306
3307 • "align_with_margins" Align header to margins. Defaults to true.
3308
3309 The image options must have an accompanying "&[Picture]" or &G control
3310 character in the header string:
3311
3312 $worksheet->set_header(
3313 '&L&[Picture]&C&[Picture]&R&[Picture]',
3314 undef, # If you don't want to change the margin.
3315 {
3316 image_left => 'red.jpg',
3317 image_center => 'blue.jpg',
3318 image_right => 'yellow.jpg'
3319 }
3320 );
3321
3322 Note, the header or footer string must be less than 255 characters.
3323 Strings longer than this will not be written and a warning will be
3324 generated.
3325
3326 The set_header() method can also handle Unicode strings in "UTF-8"
3327 format.
3328
3329 $worksheet->set_header( "&C\x{263a}" )
3330
3331 See, also the "headers.pl" program in the "examples" directory of the
3332 distribution.
3333
3334 set_footer( $string, $margin )
3335 The syntax of the set_footer() method is the same as set_header(), see
3336 above.
3337
3338 repeat_rows( $first_row, $last_row )
3339 Set the number of rows to repeat at the top of each printed page.
3340
3341 For large Excel documents it is often desirable to have the first row
3342 or rows of the worksheet print out at the top of each page. This can be
3343 achieved by using the repeat_rows() method. The parameters $first_row
3344 and $last_row are zero based. The $last_row parameter is optional if
3345 you only wish to specify one row:
3346
3347 $worksheet1->repeat_rows( 0 ); # Repeat the first row
3348 $worksheet2->repeat_rows( 0, 1 ); # Repeat the first two rows
3349
3350 repeat_columns( $first_col, $last_col )
3351 Set the columns to repeat at the left hand side of each printed page.
3352
3353 For large Excel documents it is often desirable to have the first
3354 column or columns of the worksheet print out at the left hand side of
3355 each page. This can be achieved by using the repeat_columns() method.
3356 The parameters $first_column and $last_column are zero based. The
3357 $last_column parameter is optional if you only wish to specify one
3358 column. You can also specify the columns using A1 column notation, see
3359 the note about "Cell notation".
3360
3361 $worksheet1->repeat_columns( 0 ); # Repeat the first column
3362 $worksheet2->repeat_columns( 0, 1 ); # Repeat the first two columns
3363 $worksheet3->repeat_columns( 'A:A' ); # Repeat the first column
3364 $worksheet4->repeat_columns( 'A:B' ); # Repeat the first two columns
3365
3366 hide_gridlines( $option )
3367 This method is used to hide the gridlines on the screen and printed
3368 page. Gridlines are the lines that divide the cells on a worksheet.
3369 Screen and printed gridlines are turned on by default in an Excel
3370 worksheet. If you have defined your own cell borders you may wish to
3371 hide the default gridlines.
3372
3373 $worksheet->hide_gridlines();
3374
3375 The following values of $option are valid:
3376
3377 0 : Don't hide gridlines
3378 1 : Hide printed gridlines only
3379 2 : Hide screen and printed gridlines
3380
3381 If you don't supply an argument or use "undef" the default option is 1,
3382 i.e. only the printed gridlines are hidden.
3383
3384 print_row_col_headers()
3385 Set the option to print the row and column headers on the printed page.
3386
3387 An Excel worksheet looks something like the following;
3388
3389 ------------------------------------------
3390 | | A | B | C | D | ...
3391 ------------------------------------------
3392 | 1 | | | | | ...
3393 | 2 | | | | | ...
3394 | 3 | | | | | ...
3395 | 4 | | | | | ...
3396 |...| ... | ... | ... | ... | ...
3397
3398 The headers are the letters and numbers at the top and the left of the
3399 worksheet. Since these headers serve mainly as a indication of position
3400 on the worksheet they generally do not appear on the printed page. If
3401 you wish to have them printed you can use the print_row_col_headers()
3402 method:
3403
3404 $worksheet->print_row_col_headers();
3405
3406 Do not confuse these headers with page headers as described in the
3407 set_header() section above.
3408
3409 hide_row_col_headers()
3410 Similar to print_row_col_headers() above but set the option to hide the
3411 row and column headers within Excel so that they aren't visible to the
3412 user:
3413
3414 $worksheet->hide_row_col_headers();
3415
3416 print_area( $first_row, $first_col, $last_row, $last_col )
3417 This method is used to specify the area of the worksheet that will be
3418 printed. All four parameters must be specified. You can also use A1
3419 notation, see the note about "Cell notation".
3420
3421 $worksheet1->print_area( 'A1:H20' ); # Cells A1 to H20
3422 $worksheet2->print_area( 0, 0, 19, 7 ); # The same
3423 $worksheet2->print_area( 'A:H' ); # Columns A to H if rows have data
3424
3425 print_across()
3426 The "print_across" method is used to change the default print
3427 direction. This is referred to by Excel as the sheet "page order".
3428
3429 $worksheet->print_across();
3430
3431 The default page order is shown below for a worksheet that extends over
3432 4 pages. The order is called "down then across":
3433
3434 [1] [3]
3435 [2] [4]
3436
3437 However, by using the "print_across" method the print order will be
3438 changed to "across then down":
3439
3440 [1] [2]
3441 [3] [4]
3442
3443 fit_to_pages( $width, $height )
3444 The fit_to_pages() method is used to fit the printed area to a specific
3445 number of pages both vertically and horizontally. If the printed area
3446 exceeds the specified number of pages it will be scaled down to fit.
3447 This guarantees that the printed area will always appear on the
3448 specified number of pages even if the page size or margins change.
3449
3450 $worksheet1->fit_to_pages( 1, 1 ); # Fit to 1x1 pages
3451 $worksheet2->fit_to_pages( 2, 1 ); # Fit to 2x1 pages
3452 $worksheet3->fit_to_pages( 1, 2 ); # Fit to 1x2 pages
3453
3454 The print area can be defined using the print_area() method as
3455 described above.
3456
3457 A common requirement is to fit the printed output to n pages wide but
3458 have the height be as long as necessary. To achieve this set the
3459 $height to zero:
3460
3461 $worksheet1->fit_to_pages( 1, 0 ); # 1 page wide and as long as necessary
3462
3463 Note that although it is valid to use both fit_to_pages() and
3464 set_print_scale() on the same worksheet only one of these options can
3465 be active at a time. The last method call made will set the active
3466 option.
3467
3468 Note that fit_to_pages() will override any manual page breaks that are
3469 defined in the worksheet.
3470
3471 Note: When using fit_to_pages() it may also be required to set the
3472 printer paper size using set_paper() or else Excel will default to "US
3473 Letter".
3474
3475 set_start_page( $start_page )
3476 The set_start_page() method is used to set the number of the starting
3477 page when the worksheet is printed out. The default value is 1.
3478
3479 $worksheet->set_start_page( 2 );
3480
3481 set_print_scale( $scale )
3482 Set the scale factor of the printed page. Scale factors in the range
3483 "10 <= $scale <= 400" are valid:
3484
3485 $worksheet1->set_print_scale( 50 );
3486 $worksheet2->set_print_scale( 75 );
3487 $worksheet3->set_print_scale( 300 );
3488 $worksheet4->set_print_scale( 400 );
3489
3490 The default scale factor is 100. Note, set_print_scale() does not
3491 affect the scale of the visible page in Excel. For that you should use
3492 set_zoom().
3493
3494 Note also that although it is valid to use both fit_to_pages() and
3495 set_print_scale() on the same worksheet only one of these options can
3496 be active at a time. The last method call made will set the active
3497 option.
3498
3499 print_black_and_white()
3500 Set the option to print the worksheet in black and white:
3501
3502 $worksheet->print_black_and_white();
3503
3504 set_h_pagebreaks( @breaks )
3505 Add horizontal page breaks to a worksheet. A page break causes all the
3506 data that follows it to be printed on the next page. Horizontal page
3507 breaks act between rows. To create a page break between rows 20 and 21
3508 you must specify the break at row 21. However in zero index notation
3509 this is actually row 20. So you can pretend for a small while that you
3510 are using 1 index notation:
3511
3512 $worksheet1->set_h_pagebreaks( 20 ); # Break between row 20 and 21
3513
3514 The set_h_pagebreaks() method will accept a list of page breaks and you
3515 can call it more than once:
3516
3517 $worksheet2->set_h_pagebreaks( 20, 40, 60, 80, 100 ); # Add breaks
3518 $worksheet2->set_h_pagebreaks( 120, 140, 160, 180, 200 ); # Add some more
3519
3520 Note: If you specify the "fit to page" option via the fit_to_pages()
3521 method it will override all manual page breaks.
3522
3523 There is a silent limitation of about 1000 horizontal page breaks per
3524 worksheet in line with an Excel internal limitation.
3525
3526 set_v_pagebreaks( @breaks )
3527 Add vertical page breaks to a worksheet. A page break causes all the
3528 data that follows it to be printed on the next page. Vertical page
3529 breaks act between columns. To create a page break between columns 20
3530 and 21 you must specify the break at column 21. However in zero index
3531 notation this is actually column 20. So you can pretend for a small
3532 while that you are using 1 index notation:
3533
3534 $worksheet1->set_v_pagebreaks(20); # Break between column 20 and 21
3535
3536 The set_v_pagebreaks() method will accept a list of page breaks and you
3537 can call it more than once:
3538
3539 $worksheet2->set_v_pagebreaks( 20, 40, 60, 80, 100 ); # Add breaks
3540 $worksheet2->set_v_pagebreaks( 120, 140, 160, 180, 200 ); # Add some more
3541
3542 Note: If you specify the "fit to page" option via the fit_to_pages()
3543 method it will override all manual page breaks.
3544
3546 This section describes the methods and properties that are available
3547 for formatting cells in Excel. The properties of a cell that can be
3548 formatted include: fonts, colours, patterns, borders, alignment and
3549 number formatting.
3550
3551 Creating and using a Format object
3552 Cell formatting is defined through a Format object. Format objects are
3553 created by calling the workbook add_format() method as follows:
3554
3555 my $format1 = $workbook->add_format(); # Set properties later
3556 my $format2 = $workbook->add_format( %props ); # Set at creation
3557
3558 The format object holds all the formatting properties that can be
3559 applied to a cell, a row or a column. The process of setting these
3560 properties is discussed in the next section.
3561
3562 Once a Format object has been constructed and its properties have been
3563 set it can be passed as an argument to the worksheet "write" methods as
3564 follows:
3565
3566 $worksheet->write( 0, 0, 'One', $format );
3567 $worksheet->write_string( 1, 0, 'Two', $format );
3568 $worksheet->write_number( 2, 0, 3, $format );
3569 $worksheet->write_blank( 3, 0, $format );
3570
3571 Formats can also be passed to the worksheet set_row() and set_column()
3572 methods to define the default property for a row or column.
3573
3574 $worksheet->set_row( 0, 15, $format );
3575 $worksheet->set_column( 0, 0, 15, $format );
3576
3577 Format methods and Format properties
3578 The following table shows the Excel format categories, the formatting
3579 properties that can be applied and the equivalent object method:
3580
3581 Category Description Property Method Name
3582 -------- ----------- -------- -----------
3583 Font Font type font set_font()
3584 Font size size set_size()
3585 Font color color set_color()
3586 Bold bold set_bold()
3587 Italic italic set_italic()
3588 Underline underline set_underline()
3589 Strikeout font_strikeout set_font_strikeout()
3590 Super/Subscript font_script set_font_script()
3591 Outline font_outline set_font_outline()
3592 Shadow font_shadow set_font_shadow()
3593
3594 Number Numeric format num_format set_num_format()
3595
3596 Protection Lock cells locked set_locked()
3597 Hide formulas hidden set_hidden()
3598
3599 Alignment Horizontal align align set_align()
3600 Vertical align valign set_align()
3601 Rotation rotation set_rotation()
3602 Text wrap text_wrap set_text_wrap()
3603 Justify last text_justlast set_text_justlast()
3604 Center across center_across set_center_across()
3605 Indentation indent set_indent()
3606 Shrink to fit shrink set_shrink()
3607
3608 Pattern Cell pattern pattern set_pattern()
3609 Background color bg_color set_bg_color()
3610 Foreground color fg_color set_fg_color()
3611
3612 Border Cell border border set_border()
3613 Bottom border bottom set_bottom()
3614 Top border top set_top()
3615 Left border left set_left()
3616 Right border right set_right()
3617 Border color border_color set_border_color()
3618 Bottom color bottom_color set_bottom_color()
3619 Top color top_color set_top_color()
3620 Left color left_color set_left_color()
3621 Right color right_color set_right_color()
3622 Diagonal type diag_type set_diag_type()
3623 Diagonal border diag_border set_diag_border()
3624 Diagonal color diag_color set_diag_color()
3625
3626 There are two ways of setting Format properties: by using the object
3627 method interface or by setting the property directly. For example, a
3628 typical use of the method interface would be as follows:
3629
3630 my $format = $workbook->add_format();
3631 $format->set_bold();
3632 $format->set_color( 'red' );
3633
3634 By comparison the properties can be set directly by passing a hash of
3635 properties to the Format constructor:
3636
3637 my $format = $workbook->add_format( bold => 1, color => 'red' );
3638
3639 or after the Format has been constructed by means of the
3640 set_format_properties() method as follows:
3641
3642 my $format = $workbook->add_format();
3643 $format->set_format_properties( bold => 1, color => 'red' );
3644
3645 You can also store the properties in one or more named hashes and pass
3646 them to the required method:
3647
3648 my %font = (
3649 font => 'Calibri',
3650 size => 12,
3651 color => 'blue',
3652 bold => 1,
3653 );
3654
3655 my %shading = (
3656 bg_color => 'green',
3657 pattern => 1,
3658 );
3659
3660
3661 my $format1 = $workbook->add_format( %font ); # Font only
3662 my $format2 = $workbook->add_format( %font, %shading ); # Font and shading
3663
3664 The provision of two ways of setting properties might lead you to
3665 wonder which is the best way. The method mechanism may be better if you
3666 prefer setting properties via method calls (which the author did when
3667 the code was first written) otherwise passing properties to the
3668 constructor has proved to be a little more flexible and self
3669 documenting in practice. An additional advantage of working with
3670 property hashes is that it allows you to share formatting between
3671 workbook objects as shown in the example above.
3672
3673 The Perl/Tk style of adding properties is also supported:
3674
3675 my %font = (
3676 -font => 'Calibri',
3677 -size => 12,
3678 -color => 'blue',
3679 -bold => 1,
3680 );
3681
3682 Working with formats
3683 The default format is Calibri 11 with all other properties off.
3684
3685 Each unique format in Excel::Writer::XLSX must have a corresponding
3686 Format object. It isn't possible to use a Format with a write() method
3687 and then redefine the Format for use at a later stage. This is because
3688 a Format is applied to a cell not in its current state but in its final
3689 state. Consider the following example:
3690
3691 my $format = $workbook->add_format();
3692 $format->set_bold();
3693 $format->set_color( 'red' );
3694 $worksheet->write( 'A1', 'Cell A1', $format );
3695 $format->set_color( 'green' );
3696 $worksheet->write( 'B1', 'Cell B1', $format );
3697
3698 Cell A1 is assigned the Format $format which is initially set to the
3699 colour red. However, the colour is subsequently set to green. When
3700 Excel displays Cell A1 it will display the final state of the Format
3701 which in this case will be the colour green.
3702
3703 In general a method call without an argument will turn a property on,
3704 for example:
3705
3706 my $format1 = $workbook->add_format();
3707 $format1->set_bold(); # Turns bold on
3708 $format1->set_bold( 1 ); # Also turns bold on
3709 $format1->set_bold( 0 ); # Turns bold off
3710
3712 The Format object methods are described in more detail in the following
3713 sections. In addition, there is a Perl program called "formats.pl" in
3714 the "examples" directory of the WriteExcel distribution. This program
3715 creates an Excel workbook called "formats.xlsx" which contains examples
3716 of almost all the format types.
3717
3718 The following Format methods are available:
3719
3720 set_font()
3721 set_size()
3722 set_color()
3723 set_bold()
3724 set_italic()
3725 set_underline()
3726 set_font_strikeout()
3727 set_font_script()
3728 set_font_outline()
3729 set_font_shadow()
3730 set_num_format()
3731 set_locked()
3732 set_hidden()
3733 set_align()
3734 set_rotation()
3735 set_text_wrap()
3736 set_text_justlast()
3737 set_center_across()
3738 set_indent()
3739 set_shrink()
3740 set_pattern()
3741 set_bg_color()
3742 set_fg_color()
3743 set_border()
3744 set_bottom()
3745 set_top()
3746 set_left()
3747 set_right()
3748 set_border_color()
3749 set_bottom_color()
3750 set_top_color()
3751 set_left_color()
3752 set_right_color()
3753 set_diag_type()
3754 set_diag_border()
3755 set_diag_color()
3756
3757 The above methods can also be applied directly as properties. For
3758 example "$format->set_bold()" is equivalent to
3759 "$workbook->add_format(bold => 1)".
3760
3761 set_format_properties( %properties )
3762 The properties of an existing Format object can be also be set by means
3763 of set_format_properties():
3764
3765 my $format = $workbook->add_format();
3766 $format->set_format_properties( bold => 1, color => 'red' );
3767
3768 However, this method is here mainly for legacy reasons. It is
3769 preferable to set the properties in the format constructor:
3770
3771 my $format = $workbook->add_format( bold => 1, color => 'red' );
3772
3773 set_font( $fontname )
3774 Default state: Font is Calibri
3775 Default action: None
3776 Valid args: Any valid font name
3777
3778 Specify the font used:
3779
3780 $format->set_font('Times New Roman');
3781
3782 Excel can only display fonts that are installed on the system that it
3783 is running on. Therefore it is best to use the fonts that come as
3784 standard such as 'Calibri', 'Times New Roman' and 'Courier New'. See
3785 also the Fonts worksheet created by formats.pl
3786
3787 set_size()
3788 Default state: Font size is 10
3789 Default action: Set font size to 1
3790 Valid args: Integer values from 1 to as big as your screen.
3791
3792 Set the font size. Excel adjusts the height of a row to accommodate the
3793 largest font size in the row. You can also explicitly specify the
3794 height of a row using the set_row() worksheet method.
3795
3796 my $format = $workbook->add_format();
3797 $format->set_size( 30 );
3798
3799 set_color()
3800 Default state: Excels default color, usually black
3801 Default action: Set the default color
3802 Valid args: Integers from 8..63 or the following strings:
3803 'black'
3804 'blue'
3805 'brown'
3806 'cyan'
3807 'gray'
3808 'green'
3809 'lime'
3810 'magenta'
3811 'navy'
3812 'orange'
3813 'pink'
3814 'purple'
3815 'red'
3816 'silver'
3817 'white'
3818 'yellow'
3819
3820 Set the font colour. The set_color() method is used as follows:
3821
3822 my $format = $workbook->add_format();
3823 $format->set_color( 'red' );
3824 $worksheet->write( 0, 0, 'wheelbarrow', $format );
3825
3826 Note: The set_color() method is used to set the colour of the font in a
3827 cell. To set the colour of a cell use the set_bg_color() and
3828 set_pattern() methods.
3829
3830 For additional examples see the 'Named colors' and 'Standard colors'
3831 worksheets created by formats.pl in the examples directory.
3832
3833 See also "WORKING WITH COLOURS".
3834
3835 set_bold()
3836 Default state: bold is off
3837 Default action: Turn bold on
3838 Valid args: 0, 1
3839
3840 Set the bold property of the font:
3841
3842 $format->set_bold(); # Turn bold on
3843
3844 set_italic()
3845 Default state: Italic is off
3846 Default action: Turn italic on
3847 Valid args: 0, 1
3848
3849 Set the italic property of the font:
3850
3851 $format->set_italic(); # Turn italic on
3852
3853 set_underline()
3854 Default state: Underline is off
3855 Default action: Turn on single underline
3856 Valid args: 0 = No underline
3857 1 = Single underline
3858 2 = Double underline
3859 33 = Single accounting underline
3860 34 = Double accounting underline
3861
3862 Set the underline property of the font.
3863
3864 $format->set_underline(); # Single underline
3865
3866 set_font_strikeout()
3867 Default state: Strikeout is off
3868 Default action: Turn strikeout on
3869 Valid args: 0, 1
3870
3871 Set the strikeout property of the font.
3872
3873 set_font_script()
3874 Default state: Super/Subscript is off
3875 Default action: Turn Superscript on
3876 Valid args: 0 = Normal
3877 1 = Superscript
3878 2 = Subscript
3879
3880 Set the superscript/subscript property of the font.
3881
3882 set_font_outline()
3883 Default state: Outline is off
3884 Default action: Turn outline on
3885 Valid args: 0, 1
3886
3887 Macintosh only.
3888
3889 set_font_shadow()
3890 Default state: Shadow is off
3891 Default action: Turn shadow on
3892 Valid args: 0, 1
3893
3894 Macintosh only.
3895
3896 set_num_format()
3897 Default state: General format
3898 Default action: Format index 1
3899 Valid args: See the following table
3900
3901 This method is used to define the numerical format of a number in
3902 Excel. It controls whether a number is displayed as an integer, a
3903 floating point number, a date, a currency value or some other user
3904 defined format.
3905
3906 The numerical format of a cell can be specified by using a format
3907 string or an index to one of Excel's built-in formats:
3908
3909 my $format1 = $workbook->add_format();
3910 my $format2 = $workbook->add_format();
3911 $format1->set_num_format( 'd mmm yyyy' ); # Format string
3912 $format2->set_num_format( 0x0f ); # Format index
3913
3914 $worksheet->write( 0, 0, 36892.521, $format1 ); # 1 Jan 2001
3915 $worksheet->write( 0, 0, 36892.521, $format2 ); # 1-Jan-01
3916
3917 Using format strings you can define very sophisticated formatting of
3918 numbers.
3919
3920 $format01->set_num_format( '0.000' );
3921 $worksheet->write( 0, 0, 3.1415926, $format01 ); # 3.142
3922
3923 $format02->set_num_format( '#,##0' );
3924 $worksheet->write( 1, 0, 1234.56, $format02 ); # 1,235
3925
3926 $format03->set_num_format( '#,##0.00' );
3927 $worksheet->write( 2, 0, 1234.56, $format03 ); # 1,234.56
3928
3929 $format04->set_num_format( '$0.00' );
3930 $worksheet->write( 3, 0, 49.99, $format04 ); # $49.99
3931
3932 # Note you can use other currency symbols such as the pound or yen as well.
3933 # Other currencies may require the use of Unicode.
3934
3935 $format07->set_num_format( 'mm/dd/yy' );
3936 $worksheet->write( 6, 0, 36892.521, $format07 ); # 01/01/01
3937
3938 $format08->set_num_format( 'mmm d yyyy' );
3939 $worksheet->write( 7, 0, 36892.521, $format08 ); # Jan 1 2001
3940
3941 $format09->set_num_format( 'd mmmm yyyy' );
3942 $worksheet->write( 8, 0, 36892.521, $format09 ); # 1 January 2001
3943
3944 $format10->set_num_format( 'dd/mm/yyyy hh:mm AM/PM' );
3945 $worksheet->write( 9, 0, 36892.521, $format10 ); # 01/01/2001 12:30 AM
3946
3947 $format11->set_num_format( '0 "dollar and" .00 "cents"' );
3948 $worksheet->write( 10, 0, 1.87, $format11 ); # 1 dollar and .87 cents
3949
3950 # Conditional numerical formatting.
3951 $format12->set_num_format( '[Green]General;[Red]-General;General' );
3952 $worksheet->write( 11, 0, 123, $format12 ); # > 0 Green
3953 $worksheet->write( 12, 0, -45, $format12 ); # < 0 Red
3954 $worksheet->write( 13, 0, 0, $format12 ); # = 0 Default colour
3955
3956 # Zip code
3957 $format13->set_num_format( '00000' );
3958 $worksheet->write( 14, 0, '01209', $format13 );
3959
3960 The number system used for dates is described in "DATES AND TIME IN
3961 EXCEL".
3962
3963 The colour format should have one of the following values:
3964
3965 [Black] [Blue] [Cyan] [Green] [Magenta] [Red] [White] [Yellow]
3966
3967 Alternatively you can specify the colour based on a colour index as
3968 follows: "[Color n]", where n is a standard Excel colour index - 7. See
3969 the 'Standard colors' worksheet created by formats.pl.
3970
3971 For more information refer to the documentation on formatting in the
3972 "docs" directory of the Excel::Writer::XLSX distro, the Excel on-line
3973 help or
3974 <http://office.microsoft.com/en-gb/assistance/HP051995001033.aspx>.
3975
3976 You should ensure that the format string is valid in Excel prior to
3977 using it in WriteExcel.
3978
3979 Excel's built-in formats are shown in the following table:
3980
3981 Index Index Format String
3982 0 0x00 General
3983 1 0x01 0
3984 2 0x02 0.00
3985 3 0x03 #,##0
3986 4 0x04 #,##0.00
3987 5 0x05 ($#,##0_);($#,##0)
3988 6 0x06 ($#,##0_);[Red]($#,##0)
3989 7 0x07 ($#,##0.00_);($#,##0.00)
3990 8 0x08 ($#,##0.00_);[Red]($#,##0.00)
3991 9 0x09 0%
3992 10 0x0a 0.00%
3993 11 0x0b 0.00E+00
3994 12 0x0c # ?/?
3995 13 0x0d # ??/??
3996 14 0x0e m/d/yy
3997 15 0x0f d-mmm-yy
3998 16 0x10 d-mmm
3999 17 0x11 mmm-yy
4000 18 0x12 h:mm AM/PM
4001 19 0x13 h:mm:ss AM/PM
4002 20 0x14 h:mm
4003 21 0x15 h:mm:ss
4004 22 0x16 m/d/yy h:mm
4005 .. .... ...........
4006 37 0x25 (#,##0_);(#,##0)
4007 38 0x26 (#,##0_);[Red](#,##0)
4008 39 0x27 (#,##0.00_);(#,##0.00)
4009 40 0x28 (#,##0.00_);[Red](#,##0.00)
4010 41 0x29 _(* #,##0_);_(* (#,##0);_(* "-"_);_(@_)
4011 42 0x2a _($* #,##0_);_($* (#,##0);_($* "-"_);_(@_)
4012 43 0x2b _(* #,##0.00_);_(* (#,##0.00);_(* "-"??_);_(@_)
4013 44 0x2c _($* #,##0.00_);_($* (#,##0.00);_($* "-"??_);_(@_)
4014 45 0x2d mm:ss
4015 46 0x2e [h]:mm:ss
4016 47 0x2f mm:ss.0
4017 48 0x30 ##0.0E+0
4018 49 0x31 @
4019
4020 For examples of these formatting codes see the 'Numerical formats'
4021 worksheet created by formats.pl. See also the number_formats1.html and
4022 the number_formats2.html documents in the "docs" directory of the
4023 distro.
4024
4025 Note 1. Numeric formats 23 to 36 are not documented by Microsoft and
4026 may differ in international versions.
4027
4028 Note 2. The built-in formats are localised according to the locale
4029 settings (regional settings on Windows) of the user when opening the
4030 file in Excel:
4031
4032 • The dot appears as the defined local decimal separator.
4033
4034 • The comma appears as the defined local digit groups separator.
4035
4036 • The dollar sign appears as the defined local currency symbol.
4037
4038 • The date, time and duration formats appear as the local equivalent
4039 date or time format.
4040
4041 set_locked()
4042 Default state: Cell locking is on
4043 Default action: Turn locking on
4044 Valid args: 0, 1
4045
4046 This property can be used to prevent modification of a cells contents.
4047 Following Excel's convention, cell locking is turned on by default.
4048 However, it only has an effect if the worksheet has been protected, see
4049 the worksheet protect() method.
4050
4051 my $locked = $workbook->add_format();
4052 $locked->set_locked( 1 ); # A non-op
4053
4054 my $unlocked = $workbook->add_format();
4055 $locked->set_locked( 0 );
4056
4057 # Enable worksheet protection
4058 $worksheet->protect();
4059
4060 # This cell cannot be edited.
4061 $worksheet->write( 'A1', '=1+2', $locked );
4062
4063 # This cell can be edited.
4064 $worksheet->write( 'A2', '=1+2', $unlocked );
4065
4066 Note: This offers weak protection even with a password, see the note in
4067 relation to the protect() method.
4068
4069 set_hidden()
4070 Default state: Formula hiding is off
4071 Default action: Turn hiding on
4072 Valid args: 0, 1
4073
4074 This property is used to hide a formula while still displaying its
4075 result. This is generally used to hide complex calculations from end
4076 users who are only interested in the result. It only has an effect if
4077 the worksheet has been protected, see the worksheet protect() method.
4078
4079 my $hidden = $workbook->add_format();
4080 $hidden->set_hidden();
4081
4082 # Enable worksheet protection
4083 $worksheet->protect();
4084
4085 # The formula in this cell isn't visible
4086 $worksheet->write( 'A1', '=1+2', $hidden );
4087
4088 Note: This offers weak protection even with a password, see the note in
4089 relation to the protect() method.
4090
4091 set_align()
4092 Default state: Alignment is off
4093 Default action: Left alignment
4094 Valid args: 'left' Horizontal
4095 'center'
4096 'right'
4097 'fill'
4098 'justify'
4099 'center_across'
4100
4101 'top' Vertical
4102 'vcenter'
4103 'bottom'
4104 'vjustify'
4105
4106 This method is used to set the horizontal and vertical text alignment
4107 within a cell. Vertical and horizontal alignments can be combined. The
4108 method is used as follows:
4109
4110 my $format = $workbook->add_format();
4111 $format->set_align( 'center' );
4112 $format->set_align( 'vcenter' );
4113 $worksheet->set_row( 0, 30 );
4114 $worksheet->write( 0, 0, 'X', $format );
4115
4116 Text can be aligned across two or more adjacent cells using the
4117 "center_across" property. However, for genuine merged cells it is
4118 better to use the merge_range() worksheet method.
4119
4120 The "vjustify" (vertical justify) option can be used to provide
4121 automatic text wrapping in a cell. The height of the cell will be
4122 adjusted to accommodate the wrapped text. To specify where the text
4123 wraps use the set_text_wrap() method.
4124
4125 For further examples see the 'Alignment' worksheet created by
4126 formats.pl.
4127
4128 set_center_across()
4129 Default state: Center across selection is off
4130 Default action: Turn center across on
4131 Valid args: 1
4132
4133 Text can be aligned across two or more adjacent cells using the
4134 set_center_across() method. This is an alias for the
4135 set_align('center_across') method call.
4136
4137 Only one cell should contain the text, the other cells should be blank:
4138
4139 my $format = $workbook->add_format();
4140 $format->set_center_across();
4141
4142 $worksheet->write( 1, 1, 'Center across selection', $format );
4143 $worksheet->write_blank( 1, 2, $format );
4144
4145 See also the "merge1.pl" to "merge6.pl" programs in the "examples"
4146 directory and the merge_range() method.
4147
4148 set_text_wrap()
4149 Default state: Text wrap is off
4150 Default action: Turn text wrap on
4151 Valid args: 0, 1
4152
4153 Here is an example using the text wrap property, the escape character
4154 "\n" is used to indicate the end of line:
4155
4156 my $format = $workbook->add_format();
4157 $format->set_text_wrap();
4158 $worksheet->write( 0, 0, "It's\na bum\nwrap", $format );
4159
4160 Excel will adjust the height of the row to accommodate the wrapped
4161 text. A similar effect can be obtained without newlines using the
4162 set_align('vjustify') method. See the "textwrap.pl" program in the
4163 "examples" directory.
4164
4165 set_rotation()
4166 Default state: Text rotation is off
4167 Default action: None
4168 Valid args: Integers in the range -90 to 90 and 270
4169
4170 Set the rotation of the text in a cell. The rotation can be any angle
4171 in the range -90 to 90 degrees.
4172
4173 my $format = $workbook->add_format();
4174 $format->set_rotation( 30 );
4175 $worksheet->write( 0, 0, 'This text is rotated', $format );
4176
4177 The angle 270 is also supported. This indicates text where the letters
4178 run from top to bottom.
4179
4180 set_indent()
4181 Default state: Text indentation is off
4182 Default action: Indent text 1 level
4183 Valid args: Positive integers
4184
4185 This method can be used to indent text. The argument, which should be
4186 an integer, is taken as the level of indentation:
4187
4188 my $format = $workbook->add_format();
4189 $format->set_indent( 2 );
4190 $worksheet->write( 0, 0, 'This text is indented', $format );
4191
4192 Indentation is a horizontal alignment property. It will override any
4193 other horizontal properties but it can be used in conjunction with
4194 vertical properties.
4195
4196 set_shrink()
4197 Default state: Text shrinking is off
4198 Default action: Turn "shrink to fit" on
4199 Valid args: 1
4200
4201 This method can be used to shrink text so that it fits in a cell.
4202
4203 my $format = $workbook->add_format();
4204 $format->set_shrink();
4205 $worksheet->write( 0, 0, 'Honey, I shrunk the text!', $format );
4206
4207 set_text_justlast()
4208 Default state: Justify last is off
4209 Default action: Turn justify last on
4210 Valid args: 0, 1
4211
4212 Only applies to Far Eastern versions of Excel.
4213
4214 set_pattern()
4215 Default state: Pattern is off
4216 Default action: Solid fill is on
4217 Valid args: 0 .. 18
4218
4219 Set the background pattern of a cell.
4220
4221 Examples of the available patterns are shown in the 'Patterns'
4222 worksheet created by formats.pl. However, it is unlikely that you will
4223 ever need anything other than Pattern 1 which is a solid fill of the
4224 background color.
4225
4226 set_bg_color()
4227 Default state: Color is off
4228 Default action: Solid fill.
4229 Valid args: See set_color()
4230
4231 The set_bg_color() method can be used to set the background colour of a
4232 pattern. Patterns are defined via the set_pattern() method. If a
4233 pattern hasn't been defined then a solid fill pattern is used as the
4234 default.
4235
4236 Here is an example of how to set up a solid fill in a cell:
4237
4238 my $format = $workbook->add_format();
4239
4240 $format->set_pattern(); # This is optional when using a solid fill
4241
4242 $format->set_bg_color( 'green' );
4243 $worksheet->write( 'A1', 'Ray', $format );
4244
4245 For further examples see the 'Patterns' worksheet created by
4246 formats.pl.
4247
4248 set_fg_color()
4249 Default state: Color is off
4250 Default action: Solid fill.
4251 Valid args: See set_color()
4252
4253 The set_fg_color() method can be used to set the foreground colour of a
4254 pattern.
4255
4256 For further examples see the 'Patterns' worksheet created by
4257 formats.pl.
4258
4259 set_border()
4260 Also applies to: set_bottom()
4261 set_top()
4262 set_left()
4263 set_right()
4264
4265 Default state: Border is off
4266 Default action: Set border type 1
4267 Valid args: 0-13, See below.
4268
4269 A cell border is comprised of a border on the bottom, top, left and
4270 right. These can be set to the same value using set_border() or
4271 individually using the relevant method calls shown above.
4272
4273 The following shows the border styles sorted by Excel::Writer::XLSX
4274 index number:
4275
4276 Index Name Weight Style
4277 ===== ============= ====== ===========
4278 0 None 0
4279 1 Continuous 1 -----------
4280 2 Continuous 2 -----------
4281 3 Dash 1 - - - - - -
4282 4 Dot 1 . . . . . .
4283 5 Continuous 3 -----------
4284 6 Double 3 ===========
4285 7 Continuous 0 -----------
4286 8 Dash 2 - - - - - -
4287 9 Dash Dot 1 - . - . - .
4288 10 Dash Dot 2 - . - . - .
4289 11 Dash Dot Dot 1 - . . - . .
4290 12 Dash Dot Dot 2 - . . - . .
4291 13 SlantDash Dot 2 / - . / - .
4292
4293 The following shows the borders sorted by style:
4294
4295 Name Weight Style Index
4296 ============= ====== =========== =====
4297 Continuous 0 ----------- 7
4298 Continuous 1 ----------- 1
4299 Continuous 2 ----------- 2
4300 Continuous 3 ----------- 5
4301 Dash 1 - - - - - - 3
4302 Dash 2 - - - - - - 8
4303 Dash Dot 1 - . - . - . 9
4304 Dash Dot 2 - . - . - . 10
4305 Dash Dot Dot 1 - . . - . . 11
4306 Dash Dot Dot 2 - . . - . . 12
4307 Dot 1 . . . . . . 4
4308 Double 3 =========== 6
4309 None 0 0
4310 SlantDash Dot 2 / - . / - . 13
4311
4312 The following shows the borders in the order shown in the Excel Dialog.
4313
4314 Index Style Index Style
4315 ===== ===== ===== =====
4316 0 None 12 - . . - . .
4317 7 ----------- 13 / - . / - .
4318 4 . . . . . . 10 - . - . - .
4319 11 - . . - . . 8 - - - - - -
4320 9 - . - . - . 2 -----------
4321 3 - - - - - - 5 -----------
4322 1 ----------- 6 ===========
4323
4324 Examples of the available border styles are shown in the 'Borders'
4325 worksheet created by formats.pl.
4326
4327 set_border_color()
4328 Also applies to: set_bottom_color()
4329 set_top_color()
4330 set_left_color()
4331 set_right_color()
4332
4333 Default state: Color is off
4334 Default action: Undefined
4335 Valid args: See set_color()
4336
4337 Set the colour of the cell borders. A cell border is comprised of a
4338 border on the bottom, top, left and right. These can be set to the same
4339 colour using set_border_color() or individually using the relevant
4340 method calls shown above. Examples of the border styles and colours are
4341 shown in the 'Borders' worksheet created by formats.pl.
4342
4343 set_diag_type()
4344 Default state: Diagonal border is off.
4345 Default action: None.
4346 Valid args: 1-3, See below.
4347
4348 Set the diagonal border type for the cell. Three types of diagonal
4349 borders are available in Excel:
4350
4351 1: From bottom left to top right.
4352 2: From top left to bottom right.
4353 3: Same as 1 and 2 combined.
4354
4355 For example:
4356
4357 $format->set_diag_type( 3 );
4358
4359 set_diag_border()
4360 Default state: Border is off
4361 Default action: Set border type 1
4362 Valid args: 0-13, See below.
4363
4364 Set the diagonal border style. Same as the parameter to set_border()
4365 above.
4366
4367 set_diag_color()
4368 Default state: Color is off
4369 Default action: Undefined
4370 Valid args: See set_color()
4371
4372 Set the colour of the diagonal cell border:
4373
4374 $format->set_diag_type( 3 );
4375 $format->set_diag_border( 7 );
4376 $format->set_diag_color( 'red' );
4377
4378 copy( $format )
4379 This method is used to copy all of the properties from one Format
4380 object to another:
4381
4382 my $lorry1 = $workbook->add_format();
4383 $lorry1->set_bold();
4384 $lorry1->set_italic();
4385 $lorry1->set_color( 'red' ); # lorry1 is bold, italic and red
4386
4387 my $lorry2 = $workbook->add_format();
4388 $lorry2->copy( $lorry1 );
4389 $lorry2->set_color( 'yellow' ); # lorry2 is bold, italic and yellow
4390
4391 The copy() method is only useful if you are using the method interface
4392 to Format properties. It generally isn't required if you are setting
4393 Format properties directly using hashes.
4394
4395 Note: this is not a copy constructor, both objects must exist prior to
4396 copying.
4397
4399 The following is a brief introduction to handling Unicode in
4400 "Excel::Writer::XLSX".
4401
4402 For a more general introduction to Unicode handling in Perl see
4403 perlunitut and perluniintro.
4404
4405 Excel::Writer::XLSX writer differs from Spreadsheet::WriteExcel in that
4406 it only handles Unicode data in "UTF-8" format and doesn't try to
4407 handle legacy UTF-16 Excel formats.
4408
4409 If the data is in "UTF-8" format then Excel::Writer::XLSX will handle
4410 it automatically.
4411
4412 If you are dealing with non-ASCII characters that aren't in "UTF-8"
4413 then perl provides useful tools in the guise of the "Encode" module to
4414 help you to convert to the required format. For example:
4415
4416 use Encode 'decode';
4417
4418 my $string = 'some string with koi8-r characters';
4419 $string = decode('koi8-r', $string); # koi8-r to utf8
4420
4421 Alternatively you can read data from an encoded file and convert it to
4422 "UTF-8" as you read it in:
4423
4424 my $file = 'unicode_koi8r.txt';
4425 open FH, '<:encoding(koi8-r)', $file or die "Couldn't open $file: $!\n";
4426
4427 my $row = 0;
4428 while ( <FH> ) {
4429 # Data read in is now in utf8 format.
4430 chomp;
4431 $worksheet->write( $row++, 0, $_ );
4432 }
4433
4434 These methodologies are explained in more detail in perlunitut,
4435 perluniintro and perlunicode.
4436
4437 If the program contains UTF-8 text then you will also need to add "use
4438 utf8" to the includes:
4439
4440 use utf8;
4441
4442 ...
4443
4444 $worksheet->write( 'A1', 'Some UTF-8 string' );
4445
4446 See also the "unicode_*.pl" programs in the examples directory of the
4447 distro.
4448
4450 Throughout Excel::Writer::XLSX colours can be specified using a Html
4451 style "#RRGGBB" value. For example with a Format object:
4452
4453 $format->set_color( '#FF0000' );
4454
4455 For backward compatibility a limited number of color names are
4456 supported:
4457
4458 $format->set_color( 'red' );
4459
4460 The color names supported are:
4461
4462 black
4463 blue
4464 brown
4465 cyan
4466 gray
4467 green
4468 lime
4469 magenta
4470 navy
4471 orange
4472 pink
4473 purple
4474 red
4475 silver
4476 white
4477 yellow
4478
4479 See also "colors.pl" in the "examples" directory.
4480
4482 There are two important things to understand about dates and times in
4483 Excel:
4484
4485 1 A date/time in Excel is a real number plus an Excel number format.
4486 2 Excel::Writer::XLSX doesn't automatically convert date/time strings
4487 in write() to an Excel date/time.
4488
4489 These two points are explained in more detail below along with some
4490 suggestions on how to convert times and dates to the required format.
4491
4492 An Excel date/time is a number plus a format
4493 If you write a date string with write() then all you will get is a
4494 string:
4495
4496 $worksheet->write( 'A1', '02/03/04' ); # !! Writes a string not a date. !!
4497
4498 Dates and times in Excel are represented by real numbers, for example
4499 "Jan 1 2001 12:30 AM" is represented by the number 36892.521.
4500
4501 The integer part of the number stores the number of days since the
4502 epoch and the fractional part stores the percentage of the day.
4503
4504 A date or time in Excel is just like any other number. To have the
4505 number display as a date you must apply an Excel number format to it.
4506 Here are some examples.
4507
4508 #!/usr/bin/perl -w
4509
4510 use strict;
4511 use Excel::Writer::XLSX;
4512
4513 my $workbook = Excel::Writer::XLSX->new( 'date_examples.xlsx' );
4514 my $worksheet = $workbook->add_worksheet();
4515
4516 $worksheet->set_column( 'A:A', 30 ); # For extra visibility.
4517
4518 my $number = 39506.5;
4519
4520 $worksheet->write( 'A1', $number ); # 39506.5
4521
4522 my $format2 = $workbook->add_format( num_format => 'dd/mm/yy' );
4523 $worksheet->write( 'A2', $number, $format2 ); # 28/02/08
4524
4525 my $format3 = $workbook->add_format( num_format => 'mm/dd/yy' );
4526 $worksheet->write( 'A3', $number, $format3 ); # 02/28/08
4527
4528 my $format4 = $workbook->add_format( num_format => 'd-m-yyyy' );
4529 $worksheet->write( 'A4', $number, $format4 ); # 28-2-2008
4530
4531 my $format5 = $workbook->add_format( num_format => 'dd/mm/yy hh:mm' );
4532 $worksheet->write( 'A5', $number, $format5 ); # 28/02/08 12:00
4533
4534 my $format6 = $workbook->add_format( num_format => 'd mmm yyyy' );
4535 $worksheet->write( 'A6', $number, $format6 ); # 28 Feb 2008
4536
4537 my $format7 = $workbook->add_format( num_format => 'mmm d yyyy hh:mm AM/PM' );
4538 $worksheet->write('A7', $number , $format7); # Feb 28 2008 12:00 PM
4539
4540 $workbook->close();
4541
4542 Excel::Writer::XLSX doesn't automatically convert date/time strings
4543 Excel::Writer::XLSX doesn't automatically convert input date strings
4544 into Excel's formatted date numbers due to the large number of possible
4545 date formats and also due to the possibility of misinterpretation.
4546
4547 For example, does "02/03/04" mean March 2 2004, February 3 2004 or even
4548 March 4 2002.
4549
4550 Therefore, in order to handle dates you will have to convert them to
4551 numbers and apply an Excel format. Some methods for converting dates
4552 are listed in the next section.
4553
4554 The most direct way is to convert your dates to the ISO8601
4555 "yyyy-mm-ddThh:mm:ss.sss" date format and use the write_date_time()
4556 worksheet method:
4557
4558 $worksheet->write_date_time( 'A2', '2001-01-01T12:20', $format );
4559
4560 See the write_date_time() section of the documentation for more
4561 details.
4562
4563 A general methodology for handling date strings with write_date_time()
4564 is:
4565
4566 1. Identify incoming date/time strings with a regex.
4567 2. Extract the component parts of the date/time using the same regex.
4568 3. Convert the date/time to the ISO8601 format.
4569 4. Write the date/time using write_date_time() and a number format.
4570
4571 Here is an example:
4572
4573 #!/usr/bin/perl -w
4574
4575 use strict;
4576 use Excel::Writer::XLSX;
4577
4578 my $workbook = Excel::Writer::XLSX->new( 'example.xlsx' );
4579 my $worksheet = $workbook->add_worksheet();
4580
4581 # Set the default format for dates.
4582 my $date_format = $workbook->add_format( num_format => 'mmm d yyyy' );
4583
4584 # Increase column width to improve visibility of data.
4585 $worksheet->set_column( 'A:C', 20 );
4586
4587 # Simulate reading from a data source.
4588 my $row = 0;
4589
4590 while ( <DATA> ) {
4591 chomp;
4592
4593 my $col = 0;
4594 my @data = split ' ';
4595
4596 for my $item ( @data ) {
4597
4598 # Match dates in the following formats: d/m/yy, d/m/yyyy
4599 if ( $item =~ qr[^(\d{1,2})/(\d{1,2})/(\d{4})$] ) {
4600
4601 # Change to the date format required by write_date_time().
4602 my $date = sprintf "%4d-%02d-%02dT", $3, $2, $1;
4603
4604 $worksheet->write_date_time( $row, $col++, $date,
4605 $date_format );
4606 }
4607 else {
4608
4609 # Just plain data
4610 $worksheet->write( $row, $col++, $item );
4611 }
4612 }
4613 $row++;
4614 }
4615
4616 $workbook->close();
4617
4618 __DATA__
4619 Item Cost Date
4620 Book 10 1/9/2007
4621 Beer 4 12/9/2007
4622 Bed 500 5/10/2007
4623
4624 For a slightly more advanced solution you can modify the write() method
4625 to handle date formats of your choice via the add_write_handler()
4626 method. See the add_write_handler() section of the docs and the
4627 write_handler3.pl and write_handler4.pl programs in the examples
4628 directory of the distro.
4629
4630 Converting dates and times to an Excel date or time
4631 The write_date_time() method above is just one way of handling dates
4632 and times.
4633
4634 You can also use the convert_date_time() worksheet method to convert
4635 from an ISO8601 style date string to an Excel date and time number.
4636
4637 The Excel::Writer::XLSX::Utility module which is included in the distro
4638 has date/time handling functions:
4639
4640 use Excel::Writer::XLSX::Utility;
4641
4642 $date = xl_date_list(2002, 1, 1); # 37257
4643 $date = xl_parse_date("11 July 1997"); # 35622
4644 $time = xl_parse_time('3:21:36 PM'); # 0.64
4645 $date = xl_decode_date_EU("13 May 2002"); # 37389
4646
4647 Note: some of these functions require additional CPAN modules.
4648
4649 For date conversions using the CPAN "DateTime" framework see
4650 DateTime::Format::Excel
4651 <http://search.cpan.org/search?dist=DateTime-Format-Excel>.
4652
4654 Excel allows you to group rows or columns so that they can be hidden or
4655 displayed with a single mouse click. This feature is referred to as
4656 outlines.
4657
4658 Outlines can reduce complex data down to a few salient sub-totals or
4659 summaries.
4660
4661 This feature is best viewed in Excel but the following is an ASCII
4662 representation of what a worksheet with three outlines might look like.
4663 Rows 3-4 and rows 7-8 are grouped at level 2. Rows 2-9 are grouped at
4664 level 1. The lines at the left hand side are called outline level bars.
4665
4666 ------------------------------------------
4667 1 2 3 | | A | B | C | D | ...
4668 ------------------------------------------
4669 _ | 1 | A | | | | ...
4670 | _ | 2 | B | | | | ...
4671 | | | 3 | (C) | | | | ...
4672 | | | 4 | (D) | | | | ...
4673 | - | 5 | E | | | | ...
4674 | _ | 6 | F | | | | ...
4675 | | | 7 | (G) | | | | ...
4676 | | | 8 | (H) | | | | ...
4677 | - | 9 | I | | | | ...
4678 - | . | ... | ... | ... | ... | ...
4679
4680 Clicking the minus sign on each of the level 2 outlines will collapse
4681 and hide the data as shown in the next figure. The minus sign changes
4682 to a plus sign to indicate that the data in the outline is hidden.
4683
4684 ------------------------------------------
4685 1 2 3 | | A | B | C | D | ...
4686 ------------------------------------------
4687 _ | 1 | A | | | | ...
4688 | | 2 | B | | | | ...
4689 | + | 5 | E | | | | ...
4690 | | 6 | F | | | | ...
4691 | + | 9 | I | | | | ...
4692 - | . | ... | ... | ... | ... | ...
4693
4694 Clicking on the minus sign on the level 1 outline will collapse the
4695 remaining rows as follows:
4696
4697 ------------------------------------------
4698 1 2 3 | | A | B | C | D | ...
4699 ------------------------------------------
4700 | 1 | A | | | | ...
4701 + | . | ... | ... | ... | ... | ...
4702
4703 Grouping in "Excel::Writer::XLSX" is achieved by setting the outline
4704 level via the set_row() and set_column() worksheet methods:
4705
4706 set_row( $row, $height, $format, $hidden, $level, $collapsed )
4707 set_column( $first_col, $last_col, $width, $format, $hidden, $level, $collapsed )
4708
4709 The following example sets an outline level of 1 for rows 2 and 3
4710 (zero-indexed) and columns B to G. The parameters $height and $XF are
4711 assigned default values since they are undefined:
4712
4713 $worksheet->set_row( 1, undef, undef, 0, 1 );
4714 $worksheet->set_row( 2, undef, undef, 0, 1 );
4715 $worksheet->set_column( 'B:G', undef, undef, 0, 1 );
4716
4717 Excel allows up to 7 outline levels. Therefore the $level parameter
4718 should be in the range "0 <= $level <= 7".
4719
4720 Rows and columns can be collapsed by setting the $hidden flag for the
4721 hidden rows/columns and setting the $collapsed flag for the row/column
4722 that has the collapsed "+" symbol:
4723
4724 $worksheet->set_row( 1, undef, undef, 1, 1 );
4725 $worksheet->set_row( 2, undef, undef, 1, 1 );
4726 $worksheet->set_row( 3, undef, undef, 0, 0, 1 ); # Collapsed flag.
4727
4728 $worksheet->set_column( 'B:G', undef, undef, 1, 1 );
4729 $worksheet->set_column( 'H:H', undef, undef, 0, 0, 1 ); # Collapsed flag.
4730
4731 Note: Setting the $collapsed flag is particularly important for
4732 compatibility with OpenOffice.org and Gnumeric.
4733
4734 For a more complete example see the "outline.pl" and
4735 "outline_collapsed.pl" programs in the examples directory of the
4736 distro.
4737
4738 Some additional outline properties can be set via the
4739 outline_settings() worksheet method, see above.
4740
4742 Data validation is a feature of Excel which allows you to restrict the
4743 data that a users enters in a cell and to display help and warning
4744 messages. It also allows you to restrict input to values in a drop down
4745 list.
4746
4747 A typical use case might be to restrict data in a cell to integer
4748 values in a certain range, to provide a help message to indicate the
4749 required value and to issue a warning if the input data doesn't meet
4750 the stated criteria. In Excel::Writer::XLSX we could do that as
4751 follows:
4752
4753 $worksheet->data_validation('B3',
4754 {
4755 validate => 'integer',
4756 criteria => 'between',
4757 minimum => 1,
4758 maximum => 100,
4759 input_title => 'Input an integer:',
4760 input_message => 'Between 1 and 100',
4761 error_message => 'Sorry, try again.',
4762 });
4763
4764 For more information on data validation see the following Microsoft
4765 support article "Description and examples of data validation in Excel":
4766 <http://support.microsoft.com/kb/211485>.
4767
4768 The following sections describe how to use the data_validation() method
4769 and its various options.
4770
4771 data_validation( $row, $col, { parameter => 'value', ... } )
4772 The data_validation() method is used to construct an Excel data
4773 validation.
4774
4775 It can be applied to a single cell or a range of cells. You can pass 3
4776 parameters such as "($row, $col, {...})" or 5 parameters such as
4777 "($first_row, $first_col, $last_row, $last_col, {...})". You can also
4778 use "A1" style notation. For example:
4779
4780 $worksheet->data_validation( 0, 0, {...} );
4781 $worksheet->data_validation( 0, 0, 4, 1, {...} );
4782
4783 # Which are the same as:
4784
4785 $worksheet->data_validation( 'A1', {...} );
4786 $worksheet->data_validation( 'A1:B5', {...} );
4787
4788 See also the note about "Cell notation" for more information.
4789
4790 The last parameter in data_validation() must be a hash ref containing
4791 the parameters that describe the type and style of the data validation.
4792 The allowable parameters are:
4793
4794 validate
4795 criteria
4796 value | minimum | source
4797 maximum
4798 ignore_blank
4799 dropdown
4800
4801 input_title
4802 input_message
4803 show_input
4804
4805 error_title
4806 error_message
4807 error_type
4808 show_error
4809
4810 These parameters are explained in the following sections. Most of the
4811 parameters are optional, however, you will generally require the three
4812 main options "validate", "criteria" and "value".
4813
4814 $worksheet->data_validation('B3',
4815 {
4816 validate => 'integer',
4817 criteria => '>',
4818 value => 100,
4819 });
4820
4821 The "data_validation" method returns:
4822
4823 0 for success.
4824 -1 for insufficient number of arguments.
4825 -2 for row or column out of bounds.
4826 -3 for incorrect parameter or value.
4827
4828 validate
4829 This parameter is passed in a hash ref to data_validation().
4830
4831 The "validate" parameter is used to set the type of data that you wish
4832 to validate. It is always required and it has no default value.
4833 Allowable values are:
4834
4835 any
4836 integer
4837 decimal
4838 list
4839 date
4840 time
4841 length
4842 custom
4843
4844 • any is used to specify that the type of data is unrestricted. This
4845 is useful to display an input message without restricting the data
4846 that can be entered.
4847
4848 • integer restricts the cell to integer values. Excel refers to this
4849 as 'whole number'.
4850
4851 validate => 'integer',
4852 criteria => '>',
4853 value => 100,
4854
4855 • decimal restricts the cell to decimal values.
4856
4857 validate => 'decimal',
4858 criteria => '>',
4859 value => 38.6,
4860
4861 • list restricts the cell to a set of user specified values. These
4862 can be passed in an array ref or as a cell range (named ranges
4863 aren't currently supported):
4864
4865 validate => 'list',
4866 value => ['open', 'high', 'close'],
4867 # Or like this:
4868 value => 'B1:B3',
4869
4870 Excel requires that range references are only to cells on the same
4871 worksheet.
4872
4873 • date restricts the cell to date values. Dates in Excel are
4874 expressed as integer values but you can also pass an ISO8601 style
4875 string as used in write_date_time(). See also "DATES AND TIME IN
4876 EXCEL" for more information about working with Excel's dates.
4877
4878 validate => 'date',
4879 criteria => '>',
4880 value => 39653, # 24 July 2008
4881 # Or like this:
4882 value => '2008-07-24T',
4883
4884 • time restricts the cell to time values. Times in Excel are
4885 expressed as decimal values but you can also pass an ISO8601 style
4886 string as used in write_date_time(). See also "DATES AND TIME IN
4887 EXCEL" for more information about working with Excel's times.
4888
4889 validate => 'time',
4890 criteria => '>',
4891 value => 0.5, # Noon
4892 # Or like this:
4893 value => 'T12:00:00',
4894
4895 • length restricts the cell data based on an integer string length.
4896 Excel refers to this as 'Text length'.
4897
4898 validate => 'length',
4899 criteria => '>',
4900 value => 10,
4901
4902 • custom restricts the cell based on an external Excel formula that
4903 returns a "TRUE/FALSE" value.
4904
4905 validate => 'custom',
4906 value => '=IF(A10>B10,TRUE,FALSE)',
4907
4908 criteria
4909 This parameter is passed in a hash ref to data_validation().
4910
4911 The "criteria" parameter is used to set the criteria by which the data
4912 in the cell is validated. It is almost always required except for the
4913 "list" and "custom" validate options. It has no default value.
4914 Allowable values are:
4915
4916 'between'
4917 'not between'
4918 'equal to' | '==' | '='
4919 'not equal to' | '!=' | '<>'
4920 'greater than' | '>'
4921 'less than' | '<'
4922 'greater than or equal to' | '>='
4923 'less than or equal to' | '<='
4924
4925 You can either use Excel's textual description strings, in the first
4926 column above, or the more common symbolic alternatives. The following
4927 are equivalent:
4928
4929 validate => 'integer',
4930 criteria => 'greater than',
4931 value => 100,
4932
4933 validate => 'integer',
4934 criteria => '>',
4935 value => 100,
4936
4937 The "list" and "custom" validate options don't require a "criteria". If
4938 you specify one it will be ignored.
4939
4940 validate => 'list',
4941 value => ['open', 'high', 'close'],
4942
4943 validate => 'custom',
4944 value => '=IF(A10>B10,TRUE,FALSE)',
4945
4946 value | minimum | source
4947 This parameter is passed in a hash ref to data_validation().
4948
4949 The "value" parameter is used to set the limiting value to which the
4950 "criteria" is applied. It is always required and it has no default
4951 value. You can also use the synonyms "minimum" or "source" to make the
4952 validation a little clearer and closer to Excel's description of the
4953 parameter:
4954
4955 # Use 'value'
4956 validate => 'integer',
4957 criteria => '>',
4958 value => 100,
4959
4960 # Use 'minimum'
4961 validate => 'integer',
4962 criteria => 'between',
4963 minimum => 1,
4964 maximum => 100,
4965
4966 # Use 'source'
4967 validate => 'list',
4968 source => '$B$1:$B$3',
4969
4970 maximum
4971 This parameter is passed in a hash ref to data_validation().
4972
4973 The "maximum" parameter is used to set the upper limiting value when
4974 the "criteria" is either 'between' or 'not between':
4975
4976 validate => 'integer',
4977 criteria => 'between',
4978 minimum => 1,
4979 maximum => 100,
4980
4981 ignore_blank
4982 This parameter is passed in a hash ref to data_validation().
4983
4984 The "ignore_blank" parameter is used to toggle on and off the 'Ignore
4985 blank' option in the Excel data validation dialog. When the option is
4986 on the data validation is not applied to blank data in the cell. It is
4987 on by default.
4988
4989 ignore_blank => 0, # Turn the option off
4990
4991 dropdown
4992 This parameter is passed in a hash ref to data_validation().
4993
4994 The "dropdown" parameter is used to toggle on and off the 'In-cell
4995 dropdown' option in the Excel data validation dialog. When the option
4996 is on a dropdown list will be shown for "list" validations. It is on by
4997 default.
4998
4999 dropdown => 0, # Turn the option off
5000
5001 input_title
5002 This parameter is passed in a hash ref to data_validation().
5003
5004 The "input_title" parameter is used to set the title of the input
5005 message that is displayed when a cell is entered. It has no default
5006 value and is only displayed if the input message is displayed. See the
5007 "input_message" parameter below.
5008
5009 input_title => 'This is the input title',
5010
5011 The maximum title length is 32 characters.
5012
5013 input_message
5014 This parameter is passed in a hash ref to data_validation().
5015
5016 The "input_message" parameter is used to set the input message that is
5017 displayed when a cell is entered. It has no default value.
5018
5019 validate => 'integer',
5020 criteria => 'between',
5021 minimum => 1,
5022 maximum => 100,
5023 input_title => 'Enter the applied discount:',
5024 input_message => 'between 1 and 100',
5025
5026 The message can be split over several lines using newlines, "\n" in
5027 double quoted strings.
5028
5029 input_message => "This is\na test.",
5030
5031 The maximum message length is 255 characters.
5032
5033 show_input
5034 This parameter is passed in a hash ref to data_validation().
5035
5036 The "show_input" parameter is used to toggle on and off the 'Show input
5037 message when cell is selected' option in the Excel data validation
5038 dialog. When the option is off an input message is not displayed even
5039 if it has been set using "input_message". It is on by default.
5040
5041 show_input => 0, # Turn the option off
5042
5043 error_title
5044 This parameter is passed in a hash ref to data_validation().
5045
5046 The "error_title" parameter is used to set the title of the error
5047 message that is displayed when the data validation criteria is not met.
5048 The default error title is 'Microsoft Excel'.
5049
5050 error_title => 'Input value is not valid',
5051
5052 The maximum title length is 32 characters.
5053
5054 error_message
5055 This parameter is passed in a hash ref to data_validation().
5056
5057 The "error_message" parameter is used to set the error message that is
5058 displayed when a cell is entered. The default error message is "The
5059 value you entered is not valid.\nA user has restricted values that can
5060 be entered into the cell.".
5061
5062 validate => 'integer',
5063 criteria => 'between',
5064 minimum => 1,
5065 maximum => 100,
5066 error_title => 'Input value is not valid',
5067 error_message => 'It should be an integer between 1 and 100',
5068
5069 The message can be split over several lines using newlines, "\n" in
5070 double quoted strings.
5071
5072 input_message => "This is\na test.",
5073
5074 The maximum message length is 255 characters.
5075
5076 error_type
5077 This parameter is passed in a hash ref to data_validation().
5078
5079 The "error_type" parameter is used to specify the type of error dialog
5080 that is displayed. There are 3 options:
5081
5082 'stop'
5083 'warning'
5084 'information'
5085
5086 The default is 'stop'.
5087
5088 show_error
5089 This parameter is passed in a hash ref to data_validation().
5090
5091 The "show_error" parameter is used to toggle on and off the 'Show error
5092 alert after invalid data is entered' option in the Excel data
5093 validation dialog. When the option is off an error message is not
5094 displayed even if it has been set using "error_message". It is on by
5095 default.
5096
5097 show_error => 0, # Turn the option off
5098
5099 Data Validation Examples
5100 Example 1. Limiting input to an integer greater than a fixed value.
5101
5102 $worksheet->data_validation('A1',
5103 {
5104 validate => 'integer',
5105 criteria => '>',
5106 value => 0,
5107 });
5108
5109 Example 2. Limiting input to an integer greater than a fixed value
5110 where the value is referenced from a cell.
5111
5112 $worksheet->data_validation('A2',
5113 {
5114 validate => 'integer',
5115 criteria => '>',
5116 value => '=E3',
5117 });
5118
5119 Example 3. Limiting input to a decimal in a fixed range.
5120
5121 $worksheet->data_validation('A3',
5122 {
5123 validate => 'decimal',
5124 criteria => 'between',
5125 minimum => 0.1,
5126 maximum => 0.5,
5127 });
5128
5129 Example 4. Limiting input to a value in a dropdown list.
5130
5131 $worksheet->data_validation('A4',
5132 {
5133 validate => 'list',
5134 source => ['open', 'high', 'close'],
5135 });
5136
5137 Example 5. Limiting input to a value in a dropdown list where the list
5138 is specified as a cell range.
5139
5140 $worksheet->data_validation('A5',
5141 {
5142 validate => 'list',
5143 source => '=$E$4:$G$4',
5144 });
5145
5146 Example 6. Limiting input to a date in a fixed range.
5147
5148 $worksheet->data_validation('A6',
5149 {
5150 validate => 'date',
5151 criteria => 'between',
5152 minimum => '2008-01-01T',
5153 maximum => '2008-12-12T',
5154 });
5155
5156 Example 7. Displaying a message when the cell is selected.
5157
5158 $worksheet->data_validation('A7',
5159 {
5160 validate => 'integer',
5161 criteria => 'between',
5162 minimum => 1,
5163 maximum => 100,
5164 input_title => 'Enter an integer:',
5165 input_message => 'between 1 and 100',
5166 });
5167
5168 See also the "data_validate.pl" program in the examples directory of
5169 the distro.
5170
5172 Conditional formatting is a feature of Excel which allows you to apply
5173 a format to a cell or a range of cells based on a certain criteria.
5174
5175 For example the following criteria is used to highlight cells >= 50 in
5176 red in the "conditional_format.pl" example from the distro:
5177
5178 # Write a conditional format over a range.
5179 $worksheet->conditional_formatting( 'B3:K12',
5180 {
5181 type => 'cell',
5182 criteria => '>=',
5183 value => 50,
5184 format => $format1,
5185 }
5186 );
5187
5188 conditional_formatting( $row, $col, { parameter => 'value', ... } )
5189 The conditional_formatting() method is used to apply formatting based
5190 on user defined criteria to an Excel::Writer::XLSX file.
5191
5192 It can be applied to a single cell or a range of cells. You can pass 3
5193 parameters such as "($row, $col, {...})" or 5 parameters such as
5194 "($first_row, $first_col, $last_row, $last_col, {...})". You can also
5195 use "A1" style notation. For example:
5196
5197 $worksheet->conditional_formatting( 0, 0, {...} );
5198 $worksheet->conditional_formatting( 0, 0, 4, 1, {...} );
5199
5200 # Which are the same as:
5201
5202 $worksheet->conditional_formatting( 'A1', {...} );
5203 $worksheet->conditional_formatting( 'A1:B5', {...} );
5204
5205 See also the note about "Cell notation" for more information.
5206
5207 Using "A1" style notation is also possible to specify non-contiguous
5208 ranges, separated by a comma. For example:
5209
5210 $worksheet->conditional_formatting( 'A1:D5,A8:D12', {...} );
5211
5212 The last parameter in conditional_formatting() must be a hash ref
5213 containing the parameters that describe the type and style of the data
5214 validation. The main parameters are:
5215
5216 type
5217 format
5218 criteria
5219 value
5220 minimum
5221 maximum
5222
5223 Other, less commonly used parameters are:
5224
5225 min_type
5226 mid_type
5227 max_type
5228 min_value
5229 mid_value
5230 max_value
5231 min_color
5232 mid_color
5233 max_color
5234 bar_color
5235 bar_only
5236 bar_solid
5237 bar_negative_color
5238 bar_border_color
5239 bar_negative_border_color
5240 bar_negative_color_same
5241 bar_negative_border_color_same
5242 bar_no_border
5243 bar_direction
5244 bar_axis_position
5245 bar_axis_color
5246 data_bar_2010
5247 icon_style
5248 icons
5249 reverse_icons
5250 icons_only
5251 stop_if_true
5252 multi_range
5253
5254 Additional parameters which are used for specific conditional format
5255 types are shown in the relevant sections below.
5256
5257 type
5258 This parameter is passed in a hash ref to conditional_formatting().
5259
5260 The "type" parameter is used to set the type of conditional formatting
5261 that you wish to apply. It is always required and it has no default
5262 value. Allowable "type" values and their associated parameters are:
5263
5264 Type Parameters
5265 ==== ==========
5266 cell criteria
5267 value
5268 minimum
5269 maximum
5270 format
5271
5272 date criteria
5273 value
5274 minimum
5275 maximum
5276 format
5277
5278 time_period criteria
5279 format
5280
5281 text criteria
5282 value
5283 format
5284
5285 average criteria
5286 format
5287
5288 duplicate format
5289
5290 unique format
5291
5292 top criteria
5293 value
5294 format
5295
5296 bottom criteria
5297 value
5298 format
5299
5300 blanks format
5301
5302 no_blanks format
5303
5304 errors format
5305
5306 no_errors format
5307
5308 formula criteria
5309 format
5310
5311 2_color_scale min_type
5312 max_type
5313 min_value
5314 max_value
5315 min_color
5316 max_color
5317
5318 3_color_scale min_type
5319 mid_type
5320 max_type
5321 min_value
5322 mid_value
5323 max_value
5324 min_color
5325 mid_color
5326 max_color
5327
5328 data_bar min_type
5329 max_type
5330 min_value
5331 max_value
5332 bar_only
5333 bar_color
5334 bar_solid*
5335 bar_negative_color*
5336 bar_border_color*
5337 bar_negative_border_color*
5338 bar_negative_color_same*
5339 bar_negative_border_color_same*
5340 bar_no_border*
5341 bar_direction*
5342 bar_axis_position*
5343 bar_axis_color*
5344 data_bar_2010*
5345
5346 icon_set icon_style
5347 reverse_icons
5348 icons
5349 icons_only
5350
5351 Data bar parameters marked with (*) are only available in Excel 2010
5352 and later. Files that use these properties can still be opened in Excel
5353 2007 but the data bars will be displayed without them.
5354
5355 type => 'cell'
5356 This is the most common conditional formatting type. It is used when a
5357 format is applied to a cell based on a simple criterion. For example:
5358
5359 $worksheet->conditional_formatting( 'A1',
5360 {
5361 type => 'cell',
5362 criteria => 'greater than',
5363 value => 5,
5364 format => $red_format,
5365 }
5366 );
5367
5368 Or, using the "between" criteria:
5369
5370 $worksheet->conditional_formatting( 'C1:C4',
5371 {
5372 type => 'cell',
5373 criteria => 'between',
5374 minimum => 20,
5375 maximum => 30,
5376 format => $green_format,
5377 }
5378 );
5379
5380 criteria
5381 The "criteria" parameter is used to set the criteria by which the cell
5382 data will be evaluated. It has no default value. The most common
5383 criteria as applied to "{ type => 'cell' }" are:
5384
5385 'between'
5386 'not between'
5387 'equal to' | '==' | '='
5388 'not equal to' | '!=' | '<>'
5389 'greater than' | '>'
5390 'less than' | '<'
5391 'greater than or equal to' | '>='
5392 'less than or equal to' | '<='
5393
5394 You can either use Excel's textual description strings, in the first
5395 column above, or the more common symbolic alternatives.
5396
5397 Additional criteria which are specific to other conditional format
5398 types are shown in the relevant sections below.
5399
5400 value
5401 The "value" is generally used along with the "criteria" parameter to
5402 set the rule by which the cell data will be evaluated.
5403
5404 type => 'cell',
5405 criteria => '>',
5406 value => 5
5407 format => $format,
5408
5409 The "value" property can also be an cell reference.
5410
5411 type => 'cell',
5412 criteria => '>',
5413 value => '$C$1',
5414 format => $format,
5415
5416 format
5417 The "format" parameter is used to specify the format that will be
5418 applied to the cell when the conditional formatting criterion is met.
5419 The format is created using the add_format() method in the same way as
5420 cell formats:
5421
5422 $format = $workbook->add_format( bold => 1, italic => 1 );
5423
5424 $worksheet->conditional_formatting( 'A1',
5425 {
5426 type => 'cell',
5427 criteria => '>',
5428 value => 5
5429 format => $format,
5430 }
5431 );
5432
5433 The conditional format follows the same rules as in Excel: it is
5434 superimposed over the existing cell format and not all font and border
5435 properties can be modified. Font properties that can't be modified are
5436 font name, font size, superscript and subscript. The border property
5437 that cannot be modified is diagonal borders.
5438
5439 Excel specifies some default formats to be used with conditional
5440 formatting. You can replicate them using the following
5441 Excel::Writer::XLSX formats:
5442
5443 # Light red fill with dark red text.
5444
5445 my $format1 = $workbook->add_format(
5446 bg_color => '#FFC7CE',
5447 color => '#9C0006',
5448 );
5449
5450 # Light yellow fill with dark yellow text.
5451
5452 my $format2 = $workbook->add_format(
5453 bg_color => '#FFEB9C',
5454 color => '#9C6500',
5455 );
5456
5457 # Green fill with dark green text.
5458
5459 my $format3 = $workbook->add_format(
5460 bg_color => '#C6EFCE',
5461 color => '#006100',
5462 );
5463
5464 minimum
5465 The "minimum" parameter is used to set the lower limiting value when
5466 the "criteria" is either 'between' or 'not between':
5467
5468 validate => 'integer',
5469 criteria => 'between',
5470 minimum => 1,
5471 maximum => 100,
5472
5473 maximum
5474 The "maximum" parameter is used to set the upper limiting value when
5475 the "criteria" is either 'between' or 'not between'. See the previous
5476 example.
5477
5478 type => 'date'
5479 The "date" type is the same as the "cell" type and uses the same
5480 criteria and values. However it allows the "value", "minimum" and
5481 "maximum" properties to be specified in the ISO8601
5482 "yyyy-mm-ddThh:mm:ss.sss" date format which is detailed in the
5483 write_date_time() method.
5484
5485 $worksheet->conditional_formatting( 'A1:A4',
5486 {
5487 type => 'date',
5488 criteria => 'greater than',
5489 value => '2011-01-01T',
5490 format => $format,
5491 }
5492 );
5493
5494 type => 'time_period'
5495 The "time_period" type is used to specify Excel's "Dates Occurring"
5496 style conditional format.
5497
5498 $worksheet->conditional_formatting( 'A1:A4',
5499 {
5500 type => 'time_period',
5501 criteria => 'yesterday',
5502 format => $format,
5503 }
5504 );
5505
5506 The period is set in the "criteria" and can have one of the following
5507 values:
5508
5509 criteria => 'yesterday',
5510 criteria => 'today',
5511 criteria => 'last 7 days',
5512 criteria => 'last week',
5513 criteria => 'this week',
5514 criteria => 'next week',
5515 criteria => 'last month',
5516 criteria => 'this month',
5517 criteria => 'next month'
5518
5519 type => 'text'
5520 The "text" type is used to specify Excel's "Specific Text" style
5521 conditional format. It is used to do simple string matching using the
5522 "criteria" and "value" parameters:
5523
5524 $worksheet->conditional_formatting( 'A1:A4',
5525 {
5526 type => 'text',
5527 criteria => 'containing',
5528 value => 'foo',
5529 format => $format,
5530 }
5531 );
5532
5533 The "criteria" can have one of the following values:
5534
5535 criteria => 'containing',
5536 criteria => 'not containing',
5537 criteria => 'begins with',
5538 criteria => 'ends with',
5539
5540 The "value" parameter should be a string or single character.
5541
5542 type => 'average'
5543 The "average" type is used to specify Excel's "Average" style
5544 conditional format.
5545
5546 $worksheet->conditional_formatting( 'A1:A4',
5547 {
5548 type => 'average',
5549 criteria => 'above',
5550 format => $format,
5551 }
5552 );
5553
5554 The type of average for the conditional format range is specified by
5555 the "criteria":
5556
5557 criteria => 'above',
5558 criteria => 'below',
5559 criteria => 'equal or above',
5560 criteria => 'equal or below',
5561 criteria => '1 std dev above',
5562 criteria => '1 std dev below',
5563 criteria => '2 std dev above',
5564 criteria => '2 std dev below',
5565 criteria => '3 std dev above',
5566 criteria => '3 std dev below',
5567
5568 type => 'duplicate'
5569 The "duplicate" type is used to highlight duplicate cells in a range:
5570
5571 $worksheet->conditional_formatting( 'A1:A4',
5572 {
5573 type => 'duplicate',
5574 format => $format,
5575 }
5576 );
5577
5578 type => 'unique'
5579 The "unique" type is used to highlight unique cells in a range:
5580
5581 $worksheet->conditional_formatting( 'A1:A4',
5582 {
5583 type => 'unique',
5584 format => $format,
5585 }
5586 );
5587
5588 type => 'top'
5589 The "top" type is used to specify the top "n" values by number or
5590 percentage in a range:
5591
5592 $worksheet->conditional_formatting( 'A1:A4',
5593 {
5594 type => 'top',
5595 value => 10,
5596 format => $format,
5597 }
5598 );
5599
5600 The "criteria" can be used to indicate that a percentage condition is
5601 required:
5602
5603 $worksheet->conditional_formatting( 'A1:A4',
5604 {
5605 type => 'top',
5606 value => 10,
5607 criteria => '%',
5608 format => $format,
5609 }
5610 );
5611
5612 type => 'bottom'
5613 The "bottom" type is used to specify the bottom "n" values by number or
5614 percentage in a range.
5615
5616 It takes the same parameters as "top", see above.
5617
5618 type => 'blanks'
5619 The "blanks" type is used to highlight blank cells in a range:
5620
5621 $worksheet->conditional_formatting( 'A1:A4',
5622 {
5623 type => 'blanks',
5624 format => $format,
5625 }
5626 );
5627
5628 type => 'no_blanks'
5629 The "no_blanks" type is used to highlight non blank cells in a range:
5630
5631 $worksheet->conditional_formatting( 'A1:A4',
5632 {
5633 type => 'no_blanks',
5634 format => $format,
5635 }
5636 );
5637
5638 type => 'errors'
5639 The "errors" type is used to highlight error cells in a range:
5640
5641 $worksheet->conditional_formatting( 'A1:A4',
5642 {
5643 type => 'errors',
5644 format => $format,
5645 }
5646 );
5647
5648 type => 'no_errors'
5649 The "no_errors" type is used to highlight non error cells in a range:
5650
5651 $worksheet->conditional_formatting( 'A1:A4',
5652 {
5653 type => 'no_errors',
5654 format => $format,
5655 }
5656 );
5657
5658 type => 'formula'
5659 The "formula" type is used to specify a conditional format based on a
5660 user defined formula:
5661
5662 $worksheet->conditional_formatting( 'A1:A4',
5663 {
5664 type => 'formula',
5665 criteria => '=$A$1 > 5',
5666 format => $format,
5667 }
5668 );
5669
5670 The formula is specified in the "criteria".
5671
5672 type => '2_color_scale'
5673 The "2_color_scale" type is used to specify Excel's "2 Color Scale"
5674 style conditional format.
5675
5676 $worksheet->conditional_formatting( 'A1:A12',
5677 {
5678 type => '2_color_scale',
5679 }
5680 );
5681
5682 This conditional type can be modified with "min_type", "max_type",
5683 "min_value", "max_value", "min_color" and "max_color", see below.
5684
5685 type => '3_color_scale'
5686 The "3_color_scale" type is used to specify Excel's "3 Color Scale"
5687 style conditional format.
5688
5689 $worksheet->conditional_formatting( 'A1:A12',
5690 {
5691 type => '3_color_scale',
5692 }
5693 );
5694
5695 This conditional type can be modified with "min_type", "mid_type",
5696 "max_type", "min_value", "mid_value", "max_value", "min_color",
5697 "mid_color" and "max_color", see below.
5698
5699 type => 'data_bar'
5700 The "data_bar" type is used to specify Excel's "Data Bar" style
5701 conditional format.
5702
5703 $worksheet->conditional_formatting( 'A1:A12',
5704 {
5705 type => 'data_bar',
5706 }
5707 );
5708
5709 This data bar conditional type can be modified with the following
5710 parameters, which are explained in the sections below. These properties
5711 were available in the original xlsx file specification used in Excel
5712 2007::
5713
5714 min_type
5715 max_type
5716 min_value
5717 max_value
5718 bar_color
5719 bar_only
5720
5721 In Excel 2010 additional data bar properties were added such as solid
5722 (non-gradient) bars and control over how negative values are displayed.
5723 These properties can be set using the following parameters:
5724
5725 bar_solid
5726 bar_negative_color
5727 bar_border_color
5728 bar_negative_border_color
5729 bar_negative_color_same
5730 bar_negative_border_color_same
5731 bar_no_border
5732 bar_direction
5733 bar_axis_position
5734 bar_axis_color
5735 data_bar_2010
5736
5737 Files that use these Excel 2010 properties can still be opened in Excel
5738 2007 but the data bars will be displayed without them.
5739
5740 type => 'icon_set'
5741 The "icon_set" type is used to specify a conditional format with a set
5742 of icons such as traffic lights or arrows:
5743
5744 $worksheet->conditional_formatting( 'A1:C1',
5745 {
5746 type => 'icon_set',
5747 icon_style => '3_traffic_lights',
5748 }
5749 );
5750
5751 The icon set style is specified by the "icon_style" parameter. Valid
5752 options are:
5753
5754 3_arrows
5755 3_arrows_gray
5756 3_flags
5757 3_signs
5758 3_symbols
5759 3_symbols_circled
5760 3_traffic_lights
5761 3_traffic_lights_rimmed
5762
5763 4_arrows
5764 4_arrows_gray
5765 4_ratings
5766 4_red_to_black
5767 4_traffic_lights
5768
5769 5_arrows
5770 5_arrows_gray
5771 5_quarters
5772 5_ratings
5773
5774 The criteria, type and value of each icon can be specified using the
5775 "icon" array of hash refs with optional "criteria", "type" and "value"
5776 parameters:
5777
5778 $worksheet->conditional_formatting( 'A1:D1',
5779 {
5780 type => 'icon_set',
5781 icon_style => '4_red_to_black',
5782 icons => [ {criteria => '>', type => 'number', value => 90},
5783 {criteria => '>=', type => 'percentile', value => 50},
5784 {criteria => '>', type => 'percent', value => 25},
5785 ],
5786 }
5787 );
5788
5789 The "icons criteria" parameter should be either ">=" or ">". The
5790 default "criteria" is ">=".
5791
5792 The "icons type" parameter should be one of the following values:
5793
5794 number
5795 percentile
5796 percent
5797 formula
5798
5799 The default "type" is "percent".
5800
5801 The "icons value" parameter can be a value or formula:
5802
5803 $worksheet->conditional_formatting( 'A1:D1',
5804 {
5805 type => 'icon_set',
5806 icon_style => '4_red_to_black',
5807 icons => [ {value => 90},
5808 {value => 50},
5809 {value => 25},
5810 ],
5811 }
5812 );
5813
5814 Note: The "icons" parameters should start with the highest value and
5815 with each subsequent one being lower. The default "value" is "(n * 100)
5816 / number_of_icons". The lowest number icon in an icon set has
5817 properties defined by Excel. Therefore in a "n" icon set, there is no
5818 "n-1" hash of parameters.
5819
5820 The order of the icons can be reversed using the "reverse_icons"
5821 parameter:
5822
5823 $worksheet->conditional_formatting( 'A1:C1',
5824 {
5825 type => 'icon_set',
5826 icon_style => '3_arrows',
5827 reverse_icons => 1,
5828 }
5829 );
5830
5831 The icons can be displayed without the cell value using the
5832 "icons_only" parameter:
5833
5834 $worksheet->conditional_formatting( 'A1:C1',
5835 {
5836 type => 'icon_set',
5837 icon_style => '3_flags',
5838 icons_only => 1,
5839 }
5840 );
5841
5842 min_type, mid_type, max_type
5843 The "min_type" and "max_type" properties are available when the
5844 conditional formatting type is "2_color_scale", "3_color_scale" or
5845 "data_bar". The "mid_type" is available for "3_color_scale". The
5846 properties are used as follows:
5847
5848 $worksheet->conditional_formatting( 'A1:A12',
5849 {
5850 type => '2_color_scale',
5851 min_type => 'percent',
5852 max_type => 'percent',
5853 }
5854 );
5855
5856 The available min/mid/max types are:
5857
5858 min (for min_type only)
5859 num
5860 percent
5861 percentile
5862 formula
5863 max (for max_type only)
5864
5865 min_value, mid_value, max_value
5866 The "min_value" and "max_value" properties are available when the
5867 conditional formatting type is "2_color_scale", "3_color_scale" or
5868 "data_bar". The "mid_value" is available for "3_color_scale". The
5869 properties are used as follows:
5870
5871 $worksheet->conditional_formatting( 'A1:A12',
5872 {
5873 type => '2_color_scale',
5874 min_value => 10,
5875 max_value => 90,
5876 }
5877 );
5878
5879 min_color, mid_color, max_color, bar_color
5880 The "min_color" and "max_color" properties are available when the
5881 conditional formatting type is "2_color_scale", "3_color_scale" or
5882 "data_bar". The "mid_color" is available for "3_color_scale". The
5883 properties are used as follows:
5884
5885 $worksheet->conditional_formatting( 'A1:A12',
5886 {
5887 type => '2_color_scale',
5888 min_color => "#C5D9F1",
5889 max_color => "#538ED5",
5890 }
5891 );
5892
5893 The color can be specified as an Excel::Writer::XLSX color index or,
5894 more usefully, as a HTML style RGB hex number, as shown above.
5895
5896 bar_only
5897 The "bar_only" parameter property displays a bar data but not the data
5898 in the cells:
5899
5900 $worksheet->conditional_formatting( 'D3:D14',
5901 {
5902 type => 'data_bar',
5903 bar_only => 1
5904 }
5905 );
5906
5907 bar_solid
5908 The "bar_solid" parameter turns on a solid (non-gradient) fill for data
5909 bars:
5910
5911 $worksheet->conditional_formatting( 'H3:H14',
5912 {
5913 type => 'data_bar',
5914 bar_solid => 1
5915 }
5916 );
5917
5918 Note, this property is only visible in Excel 2010 and later.
5919
5920 bar_negative_color
5921 The "bar_negative_color" parameter is used to set the color fill for
5922 the negative portion of a data bar.
5923
5924 The color can be specified as an Excel::Writer::XLSX color index or as
5925 a HTML style RGB hex number, as shown in the other examples.
5926
5927 Note, this property is only visible in Excel 2010 and later.
5928
5929 bar_border_color
5930 The "bar_border_color" parameter is used to set the border color of a
5931 data bar.
5932
5933 The color can be specified as an Excel::Writer::XLSX color index or as
5934 a HTML style RGB hex number, as shown in the other examples.
5935
5936 Note, this property is only visible in Excel 2010 and later.
5937
5938 bar_negative_border_color
5939 The "bar_negative_border_color" parameter is used to set the border
5940 color of the negative portion of a data bar.
5941
5942 The color can be specified as an Excel::Writer::XLSX color index or as
5943 a HTML style RGB hex number, as shown in the other examples.
5944
5945 Note, this property is only visible in Excel 2010 and later.
5946
5947 bar_negative_color_same
5948 The "bar_negative_color_same" parameter sets the fill color for the
5949 negative portion of a data bar to be the same as the fill color for the
5950 positive portion of the data bar:
5951
5952 $worksheet->conditional_formatting( 'N3:N14',
5953 {
5954 type => 'data_bar',
5955 bar_negative_color_same => 1,
5956 bar_negative_border_color_same => 1
5957 }
5958 );
5959
5960 Note, this property is only visible in Excel 2010 and later.
5961
5962 bar_negative_border_color_same
5963 The "bar_negative_border_color_same" parameter sets the border color
5964 for the negative portion of a data bar to be the same as the border
5965 color for the positive portion of the data bar.
5966
5967 Note, this property is only visible in Excel 2010 and later.
5968
5969 bar_no_border
5970 The "bar_no_border" parameter turns off the border of a data bar.
5971
5972 Note, this property is only visible in Excel 2010 and later, however
5973 the default in Excel 2007 is not to have a border.
5974
5975 bar_direction
5976 The "bar_direction" parameter sets the direction for data bars. This
5977 property can be either "left" for left-to-right or "right" for right-
5978 to-left. If the property isn't set then Excel will adjust the position
5979 automatically based on the context:
5980
5981 $worksheet->conditional_formatting( 'J3:J14',
5982 {
5983 type => 'data_bar',
5984 bar_direction => 'right'
5985 }
5986 );
5987
5988 Note, this property is only visible in Excel 2010 and later.
5989
5990 bar_axis_position
5991 The "bar_axis_position" parameter sets the position within the cells
5992 for the axis that is shown in data bars when there are negative values
5993 to display. The property can be either "middle" or "none". If the
5994 property isn't set then Excel will position the axis based on the range
5995 of positive and negative values.
5996
5997 Note, this property is only visible in Excel 2010 and later.
5998
5999 bar_axis_color
6000 The "bar_axis_color" parameter sets the color for the axis that is
6001 shown in data bars when there are negative values to display.
6002
6003 The color can be specified as an Excel::Writer::XLSX color index or as
6004 a HTML style RGB hex number, as shown in the other examples.
6005
6006 Note, this property is only visible in Excel 2010 and later.
6007
6008 data_bar_2010
6009 The "data_bar_2010" parameter sets Excel 2010 style data bars even when
6010 Excel 2010 specific properties aren't used. This can be used to create
6011 consistency across all the data bar formatting in a worksheet:
6012
6013 $worksheet->conditional_formatting( 'L3:L14',
6014 {
6015 type => 'data_bar',
6016 data_bar_2010 => 1
6017 }
6018 );
6019
6020 Note, this property is only visible in Excel 2010 and later.
6021
6022 stop_if_true
6023 The "stop_if_true" parameter, if set to a true value, will enable the
6024 "stop if true" feature on the conditional formatting rule, so that
6025 subsequent rules are not examined for any cell on which the conditions
6026 for this rule are met.
6027
6028 Conditional Formatting Examples
6029 Example 1. Highlight cells greater than an integer value.
6030
6031 $worksheet->conditional_formatting( 'A1:F10',
6032 {
6033 type => 'cell',
6034 criteria => 'greater than',
6035 value => 5,
6036 format => $format,
6037 }
6038 );
6039
6040 Example 2. Highlight cells greater than a value in a reference cell.
6041
6042 $worksheet->conditional_formatting( 'A1:F10',
6043 {
6044 type => 'cell',
6045 criteria => 'greater than',
6046 value => '$H$1',
6047 format => $format,
6048 }
6049 );
6050
6051 Example 3. Highlight cells greater than a certain date:
6052
6053 $worksheet->conditional_formatting( 'A1:F10',
6054 {
6055 type => 'date',
6056 criteria => 'greater than',
6057 value => '2011-01-01T',
6058 format => $format,
6059 }
6060 );
6061
6062 Example 4. Highlight cells with a date in the last seven days:
6063
6064 $worksheet->conditional_formatting( 'A1:F10',
6065 {
6066 type => 'time_period',
6067 criteria => 'last 7 days',
6068 format => $format,
6069 }
6070 );
6071
6072 Example 5. Highlight cells with strings starting with the letter "b":
6073
6074 $worksheet->conditional_formatting( 'A1:F10',
6075 {
6076 type => 'text',
6077 criteria => 'begins with',
6078 value => 'b',
6079 format => $format,
6080 }
6081 );
6082
6083 Example 6. Highlight cells that are 1 std deviation above the average
6084 for the range:
6085
6086 $worksheet->conditional_formatting( 'A1:F10',
6087 {
6088 type => 'average',
6089 format => $format,
6090 }
6091 );
6092
6093 Example 7. Highlight duplicate cells in a range:
6094
6095 $worksheet->conditional_formatting( 'A1:F10',
6096 {
6097 type => 'duplicate',
6098 format => $format,
6099 }
6100 );
6101
6102 Example 8. Highlight unique cells in a range.
6103
6104 $worksheet->conditional_formatting( 'A1:F10',
6105 {
6106 type => 'unique',
6107 format => $format,
6108 }
6109 );
6110
6111 Example 9. Highlight the top 10 cells.
6112
6113 $worksheet->conditional_formatting( 'A1:F10',
6114 {
6115 type => 'top',
6116 value => 10,
6117 format => $format,
6118 }
6119 );
6120
6121 Example 10. Highlight blank cells.
6122
6123 $worksheet->conditional_formatting( 'A1:F10',
6124 {
6125 type => 'blanks',
6126 format => $format,
6127 }
6128 );
6129
6130 Example 11. Set traffic light icons in 3 cells:
6131
6132 $worksheet->conditional_formatting( 'A1:C1',
6133 {
6134 type => 'icon_set',
6135 icon_style => '3_traffic_lights',
6136 }
6137 );
6138
6139 See also the "conditional_format.pl" example program in "EXAMPLES".
6140
6142 Sparklines are a feature of Excel 2010+ which allows you to add small
6143 charts to worksheet cells. These are useful for showing visual trends
6144 in data in a compact format.
6145
6146 In Excel::Writer::XLSX Sparklines can be added to cells using the
6147 add_sparkline() worksheet method:
6148
6149 $worksheet->add_sparkline(
6150 {
6151 location => 'F2',
6152 range => 'Sheet1!A2:E2',
6153 type => 'column',
6154 style => 12,
6155 }
6156 );
6157
6158 Note: Sparklines are a feature of Excel 2010+ only. You can write them
6159 to an XLSX file that can be read by Excel 2007 but they won't be
6160 displayed.
6161
6162 add_sparkline( { parameter => 'value', ... } )
6163 The add_sparkline() worksheet method is used to add sparklines to a
6164 cell or a range of cells.
6165
6166 The parameters to add_sparkline() must be passed in a hash ref. The
6167 main sparkline parameters are:
6168
6169 location (required)
6170 range (required)
6171 type
6172 style
6173
6174 markers
6175 negative_points
6176 axis
6177 reverse
6178
6179 Other, less commonly used parameters are:
6180
6181 high_point
6182 low_point
6183 first_point
6184 last_point
6185 max
6186 min
6187 empty_cells
6188 show_hidden
6189 date_axis
6190 weight
6191
6192 series_color
6193 negative_color
6194 markers_color
6195 first_color
6196 last_color
6197 high_color
6198 low_color
6199
6200 These parameters are explained in the sections below:
6201
6202 location
6203 This is the cell where the sparkline will be displayed:
6204
6205 location => 'F1'
6206
6207 The "location" should be a single cell. (For multiple cells see
6208 "Grouped Sparklines" below).
6209
6210 To specify the location in row-column notation use the
6211 xl_rowcol_to_cell() function from the Excel::Writer::XLSX::Utility
6212 module.
6213
6214 use Excel::Writer::XLSX::Utility ':rowcol';
6215 ...
6216 location => xl_rowcol_to_cell( 0, 5 ), # F1
6217
6218 range
6219 This specifies the cell data range that the sparkline will plot:
6220
6221 $worksheet->add_sparkline(
6222 {
6223 location => 'F1',
6224 range => 'A1:E1',
6225 }
6226 );
6227
6228 The "range" should be a 2D array. (For 3D arrays of cells see "Grouped
6229 Sparklines" below).
6230
6231 If "range" is not on the same worksheet you can specify its location
6232 using the usual Excel notation:
6233
6234 range => 'Sheet1!A1:E1',
6235
6236 If the worksheet contains spaces or special characters you should quote
6237 the worksheet name in the same way that Excel does:
6238
6239 range => q('Monthly Data'!A1:E1),
6240
6241 To specify the location in row-column notation use the xl_range() or
6242 xl_range_formula() functions from the Excel::Writer::XLSX::Utility
6243 module.
6244
6245 use Excel::Writer::XLSX::Utility ':rowcol';
6246 ...
6247 range => xl_range( 1, 1, 0, 4 ), # 'A1:E1'
6248 range => xl_range_formula( 'Sheet1', 0, 0, 0, 4 ), # 'Sheet1!A2:E2'
6249
6250 type
6251 Specifies the type of sparkline. There are 3 available sparkline types:
6252
6253 line (default)
6254 column
6255 win_loss
6256
6257 For example:
6258
6259 {
6260 location => 'F1',
6261 range => 'A1:E1',
6262 type => 'column',
6263 }
6264
6265 style
6266 Excel provides 36 built-in Sparkline styles in 6 groups of 6. The
6267 "style" parameter can be used to replicate these and should be a
6268 corresponding number from 1 .. 36.
6269
6270 {
6271 location => 'A14',
6272 range => 'Sheet2!A2:J2',
6273 style => 3,
6274 }
6275
6276 The style number starts in the top left of the style grid and runs left
6277 to right. The default style is 1. It is possible to override colour
6278 elements of the sparklines using the *_color parameters below.
6279
6280 markers
6281 Turn on the markers for "line" style sparklines.
6282
6283 {
6284 location => 'A6',
6285 range => 'Sheet2!A1:J1',
6286 markers => 1,
6287 }
6288
6289 Markers aren't shown in Excel for "column" and "win_loss" sparklines.
6290
6291 negative_points
6292 Highlight negative values in a sparkline range. This is usually
6293 required with "win_loss" sparklines.
6294
6295 {
6296 location => 'A21',
6297 range => 'Sheet2!A3:J3',
6298 type => 'win_loss',
6299 negative_points => 1,
6300 }
6301
6302 axis
6303 Display a horizontal axis in the sparkline:
6304
6305 {
6306 location => 'A10',
6307 range => 'Sheet2!A1:J1',
6308 axis => 1,
6309 }
6310
6311 reverse
6312 Plot the data from right-to-left instead of the default left-to-right:
6313
6314 {
6315 location => 'A24',
6316 range => 'Sheet2!A4:J4',
6317 type => 'column',
6318 reverse => 1,
6319 }
6320
6321 weight
6322 Adjust the default line weight (thickness) for "line" style sparklines.
6323
6324 weight => 0.25,
6325
6326 The weight value should be one of the following values allowed by
6327 Excel:
6328
6329 0.25 0.5 0.75
6330 1 1.25
6331 2.25
6332 3
6333 4.25
6334 6
6335
6336 high_point, low_point, first_point, last_point
6337 Highlight points in a sparkline range.
6338
6339 high_point => 1,
6340 low_point => 1,
6341 first_point => 1,
6342 last_point => 1,
6343
6344 max, min
6345 Specify the maximum and minimum vertical axis values:
6346
6347 max => 0.5,
6348 min => -0.5,
6349
6350 As a special case you can set the maximum and minimum to be for a group
6351 of sparklines rather than one:
6352
6353 max => 'group',
6354
6355 See "Grouped Sparklines" below.
6356
6357 empty_cells
6358 Define how empty cells are handled in a sparkline.
6359
6360 empty_cells => 'zero',
6361
6362 The available options are:
6363
6364 gaps : show empty cells as gaps (the default).
6365 zero : plot empty cells as 0.
6366 connect: Connect points with a line ("line" type sparklines only).
6367
6368 show_hidden
6369 Plot data in hidden rows and columns:
6370
6371 show_hidden => 1,
6372
6373 Note, this option is off by default.
6374
6375 date_axis
6376 Specify an alternative date axis for the sparkline. This is useful if
6377 the data being plotted isn't at fixed width intervals:
6378
6379 {
6380 location => 'F3',
6381 range => 'A3:E3',
6382 date_axis => 'A4:E4',
6383 }
6384
6385 The number of cells in the date range should correspond to the number
6386 of cells in the data range.
6387
6388 series_color
6389 It is possible to override the colour of a sparkline style using the
6390 following parameters:
6391
6392 series_color
6393 negative_color
6394 markers_color
6395 first_color
6396 last_color
6397 high_color
6398 low_color
6399
6400 The color should be specified as a HTML style "#rrggbb" hex value:
6401
6402 {
6403 location => 'A18',
6404 range => 'Sheet2!A2:J2',
6405 type => 'column',
6406 series_color => '#E965E0',
6407 }
6408
6409 Grouped Sparklines
6410 The add_sparkline() worksheet method can be used multiple times to
6411 write as many sparklines as are required in a worksheet.
6412
6413 However, it is sometimes necessary to group contiguous sparklines so
6414 that changes that are applied to one are applied to all. In Excel this
6415 is achieved by selecting a 3D range of cells for the data "range" and a
6416 2D range of cells for the "location".
6417
6418 In Excel::Writer::XLSX, you can simulate this by passing an array refs
6419 of values to "location" and "range":
6420
6421 {
6422 location => [ 'A27', 'A28', 'A29' ],
6423 range => [ 'Sheet2!A5:J5', 'Sheet2!A6:J6', 'Sheet2!A7:J7' ],
6424 markers => 1,
6425 }
6426
6427 Sparkline examples
6428 See the "sparklines1.pl" and "sparklines2.pl" example programs in the
6429 "examples" directory of the distro.
6430
6432 Tables in Excel are a way of grouping a range of cells into a single
6433 entity that has common formatting or that can be referenced from
6434 formulas. Tables can have column headers, autofilters, total rows,
6435 column formulas and default formatting.
6436
6437 For more information see "An Overview of Excel Tables"
6438 <http://office.microsoft.com/en-us/excel-help/overview-of-excel-tables-HA010048546.aspx>.
6439
6440 Note, tables don't work in Excel::Writer::XLSX when set_optimization()
6441 mode in on.
6442
6443 add_table( $row1, $col1, $row2, $col2, { parameter => 'value', ... })
6444 Tables are added to a worksheet using the add_table() method:
6445
6446 $worksheet->add_table( 'B3:F7', { %parameters } );
6447
6448 The data range can be specified in 'A1' or 'row/col' notation (see also
6449 the note about "Cell notation" for more information):
6450
6451 $worksheet->add_table( 'B3:F7' );
6452 # Same as:
6453 $worksheet->add_table( 2, 1, 6, 5 );
6454
6455 The last parameter in add_table() should be a hash ref containing the
6456 parameters that describe the table options and data. The available
6457 parameters are:
6458
6459 data
6460 autofilter
6461 header_row
6462 banded_columns
6463 banded_rows
6464 first_column
6465 last_column
6466 style
6467 total_row
6468 columns
6469 name
6470
6471 The table parameters are detailed below. There are no required
6472 parameters and the hash ref isn't required if no options are specified.
6473
6474 data
6475 The "data" parameter can be used to specify the data in the cells of
6476 the table.
6477
6478 my $data = [
6479 [ 'Apples', 10000, 5000, 8000, 6000 ],
6480 [ 'Pears', 2000, 3000, 4000, 5000 ],
6481 [ 'Bananas', 6000, 6000, 6500, 6000 ],
6482 [ 'Oranges', 500, 300, 200, 700 ],
6483
6484 ];
6485
6486 $worksheet->add_table( 'B3:F7', { data => $data } );
6487
6488 Table data can also be written separately, as an array or individual
6489 cells.
6490
6491 # These two statements are the same as the single statement above.
6492 $worksheet->add_table( 'B3:F7' );
6493 $worksheet->write_col( 'B4', $data );
6494
6495 Writing the cell data separately is occasionally required when you need
6496 to control the "write_*()" method used to populate the cells or if you
6497 wish to tweak the cell formatting.
6498
6499 The "data" structure should be an array ref of array refs holding row
6500 data as shown above.
6501
6502 header_row
6503 The "header_row" parameter can be used to turn on or off the header row
6504 in the table. It is on by default.
6505
6506 $worksheet->add_table( 'B4:F7', { header_row => 0 } ); # Turn header off.
6507
6508 The header row will contain default captions such as "Column 1",
6509 "Column 2", etc. These captions can be overridden using the "columns"
6510 parameter below.
6511
6512 autofilter
6513 The "autofilter" parameter can be used to turn on or off the autofilter
6514 in the header row. It is on by default.
6515
6516 $worksheet->add_table( 'B3:F7', { autofilter => 0 } ); # Turn autofilter off.
6517
6518 The "autofilter" is only shown if the "header_row" is on. Filters
6519 within the table are not supported.
6520
6521 banded_rows
6522 The "banded_rows" parameter can be used to used to create rows of
6523 alternating colour in the table. It is on by default.
6524
6525 $worksheet->add_table( 'B3:F7', { banded_rows => 0 } );
6526
6527 banded_columns
6528 The "banded_columns" parameter can be used to used to create columns of
6529 alternating colour in the table. It is off by default.
6530
6531 $worksheet->add_table( 'B3:F7', { banded_columns => 1 } );
6532
6533 first_column
6534 The "first_column" parameter can be used to highlight the first column
6535 of the table. The type of highlighting will depend on the "style" of
6536 the table. It may be bold text or a different colour. It is off by
6537 default.
6538
6539 $worksheet->add_table( 'B3:F7', { first_column => 1 } );
6540
6541 last_column
6542 The "last_column" parameter can be used to highlight the last column of
6543 the table. The type of highlighting will depend on the "style" of the
6544 table. It may be bold text or a different colour. It is off by default.
6545
6546 $worksheet->add_table( 'B3:F7', { last_column => 1 } );
6547
6548 style
6549 The "style" parameter can be used to set the style of the table.
6550 Standard Excel table format names should be used (with matching
6551 capitalisation):
6552
6553 $worksheet11->add_table(
6554 'B3:F7',
6555 {
6556 data => $data,
6557 style => 'Table Style Light 11',
6558 }
6559 );
6560
6561 The default table style is 'Table Style Medium 9'.
6562
6563 You can also turn the table style off by setting it to 'None':
6564
6565 $worksheet11->add_table( 'B3:F7', { style => 'None' } );
6566
6567 name
6568 By default tables are named "Table1", "Table2", etc. The "name"
6569 parameter can be used to set the name of the table:
6570
6571 $worksheet->add_table( 'B3:F7', { name => 'SalesData' } );
6572
6573 If you override the table name you must ensure that it doesn't clash
6574 with an existing table name and that it follows Excel's requirements
6575 for table names
6576 <http://office.microsoft.com/en-001/excel-help/define-and-use-names-in-formulas-HA010147120.aspx#BMsyntax_rules_for_names>.
6577
6578 If you need to know the name of the table, for example to use it in a
6579 formula, you can get it as follows:
6580
6581 my $table = $worksheet2->add_table( 'B3:F7' );
6582 my $table_name = $table->{_name};
6583
6584 total_row
6585 The "total_row" parameter can be used to turn on the total row in the
6586 last row of a table. It is distinguished from the other rows by a
6587 different formatting and also with dropdown "SUBTOTAL" functions.
6588
6589 $worksheet->add_table( 'B3:F7', { total_row => 1 } );
6590
6591 The default total row doesn't have any captions or functions. These
6592 must by specified via the "columns" parameter below.
6593
6594 columns
6595 The "columns" parameter can be used to set properties for columns
6596 within the table.
6597
6598 The sub-properties that can be set are:
6599
6600 header
6601 formula
6602 total_string
6603 total_function
6604 total_value
6605 format
6606 header_format
6607
6608 The column data must be specified as an array ref of hash refs. For
6609 example to override the default 'Column n' style table headers:
6610
6611 $worksheet->add_table(
6612 'B3:F7',
6613 {
6614 data => $data,
6615 columns => [
6616 { header => 'Product' },
6617 { header => 'Quarter 1' },
6618 { header => 'Quarter 2' },
6619 { header => 'Quarter 3' },
6620 { header => 'Quarter 4' },
6621 ]
6622 }
6623 );
6624
6625 If you don't wish to specify properties for a specific column you pass
6626 an empty hash ref and the defaults will be applied:
6627
6628 ...
6629 columns => [
6630 { header => 'Product' },
6631 { header => 'Quarter 1' },
6632 { }, # Defaults to 'Column 3'.
6633 { header => 'Quarter 3' },
6634 { header => 'Quarter 4' },
6635 ]
6636 ...
6637
6638 Column formulas can by applied using the "formula" column property:
6639
6640 $worksheet8->add_table(
6641 'B3:G7',
6642 {
6643 data => $data,
6644 columns => [
6645 { header => 'Product' },
6646 { header => 'Quarter 1' },
6647 { header => 'Quarter 2' },
6648 { header => 'Quarter 3' },
6649 { header => 'Quarter 4' },
6650 {
6651 header => 'Year',
6652 formula => '=SUM(Table8[@[Quarter 1]:[Quarter 4]])'
6653 },
6654 ]
6655 }
6656 );
6657
6658 The Excel 2007 "[#This Row]" and Excel 2010 "@" structural references
6659 are supported within the formula.
6660
6661 As stated above the "total_row" table parameter turns on the "Total"
6662 row in the table but it doesn't populate it with any defaults. Total
6663 captions and functions must be specified via the "columns" property and
6664 the "total_string", "total_function" and "total_value" sub properties:
6665
6666 $worksheet10->add_table(
6667 'B3:F8',
6668 {
6669 data => $data,
6670 total_row => 1,
6671 columns => [
6672 { header => 'Product', total_string => 'Totals' },
6673 { header => 'Quarter 1', total_function => 'sum' },
6674 { header => 'Quarter 2', total_function => 'sum' },
6675 { header => 'Quarter 3', total_function => 'sum' },
6676 { header => 'Quarter 4', total_function => 'sum' },
6677 ]
6678 }
6679 );
6680
6681 The supported totals row "SUBTOTAL" functions are:
6682
6683 average
6684 count_nums
6685 count
6686 max
6687 min
6688 std_dev
6689 sum
6690 var
6691
6692 User defined functions or formulas aren't supported.
6693
6694 It is also possible to set a calculated value for the "total_function"
6695 using the "total_value" sub property. This is only necessary when
6696 creating workbooks for applications that cannot calculate the value of
6697 formulas automatically. This is similar to setting the "value" optional
6698 property in write_formula():
6699
6700 $worksheet10->add_table(
6701 'B3:F8',
6702 {
6703 data => $data,
6704 total_row => 1,
6705 columns => [
6706 { total_string => 'Totals' },
6707 { total_function => 'sum', total_value => 100 },
6708 { total_function => 'sum', total_value => 200 },
6709 { total_function => 'sum', total_value => 100 },
6710 { total_function => 'sum', total_value => 400 },
6711 ]
6712 }
6713 );
6714
6715 Formatting can also be applied to columns, to the column data using
6716 "format" and to the header using "header_format":
6717
6718 my $currency_format = $workbook->add_format( num_format => '$#,##0' );
6719
6720 $worksheet->add_table(
6721 'B3:D8',
6722 {
6723 data => $data,
6724 total_row => 1,
6725 columns => [
6726 { header => 'Product', total_string => 'Totals' },
6727 {
6728 header => 'Quarter 1',
6729 total_function => 'sum',
6730 format => $currency_format,
6731 },
6732 {
6733 header => 'Quarter 2',
6734 header_format => $bold,
6735 total_function => 'sum',
6736 format => $currency_format,
6737 },
6738 ]
6739 }
6740 );
6741
6742 Standard Excel::Writer::XLSX format objects can be used. However, they
6743 should be limited to numerical formats for the columns and simple
6744 formatting like text wrap for the headers. Overriding other table
6745 formatting may produce inconsistent results.
6746
6748 Introduction
6749 The following is a brief introduction to formulas and functions in
6750 Excel and Excel::Writer::XLSX.
6751
6752 A formula is a string that begins with an equals sign:
6753
6754 '=A1+B1'
6755 '=AVERAGE(1, 2, 3)'
6756
6757 The formula can contain numbers, strings, boolean values, cell
6758 references, cell ranges and functions. Named ranges are not supported.
6759 Formulas should be written as they appear in Excel, that is cells and
6760 functions must be in uppercase.
6761
6762 Cells in Excel are referenced using the A1 notation system where the
6763 column is designated by a letter and the row by a number. Columns range
6764 from A to XFD i.e. 0 to 16384, rows range from 1 to 1048576. The
6765 "Excel::Writer::XLSX::Utility" module that is included in the distro
6766 contains helper functions for dealing with A1 notation, for example:
6767
6768 use Excel::Writer::XLSX::Utility;
6769
6770 ( $row, $col ) = xl_cell_to_rowcol( 'C2' ); # (1, 2)
6771 $str = xl_rowcol_to_cell( 1, 2 ); # C2
6772
6773 The Excel "$" notation in cell references is also supported. This
6774 allows you to specify whether a row or column is relative or absolute.
6775 This only has an effect if the cell is copied. The following examples
6776 show relative and absolute values.
6777
6778 '=A1' # Column and row are relative
6779 '=$A1' # Column is absolute and row is relative
6780 '=A$1' # Column is relative and row is absolute
6781 '=$A$1' # Column and row are absolute
6782
6783 Formulas can also refer to cells in other worksheets of the current
6784 workbook. For example:
6785
6786 '=Sheet2!A1'
6787 '=Sheet2!A1:A5'
6788 '=Sheet2:Sheet3!A1'
6789 '=Sheet2:Sheet3!A1:A5'
6790 q{='Test Data'!A1}
6791 q{='Test Data1:Test Data2'!A1}
6792
6793 The sheet reference and the cell reference are separated by "!" the
6794 exclamation mark symbol. If worksheet names contain spaces, commas or
6795 parentheses then Excel requires that the name is enclosed in single
6796 quotes as shown in the last two examples above. In order to avoid using
6797 a lot of escape characters you can use the quote operator "q{}" to
6798 protect the quotes. See "perlop" in the main Perl documentation. Only
6799 valid sheet names that have been added using the add_worksheet() method
6800 can be used in formulas. You cannot reference external workbooks.
6801
6802 The following table lists the operators that are available in Excel's
6803 formulas. The majority of the operators are the same as Perl's,
6804 differences are indicated:
6805
6806 Arithmetic operators:
6807 =====================
6808 Operator Meaning Example
6809 + Addition 1+2
6810 - Subtraction 2-1
6811 * Multiplication 2*3
6812 / Division 1/4
6813 ^ Exponentiation 2^3 # Equivalent to **
6814 - Unary minus -(1+2)
6815 % Percent (Not modulus) 13%
6816
6817
6818 Comparison operators:
6819 =====================
6820 Operator Meaning Example
6821 = Equal to A1 = B1 # Equivalent to ==
6822 <> Not equal to A1 <> B1 # Equivalent to !=
6823 > Greater than A1 > B1
6824 < Less than A1 < B1
6825 >= Greater than or equal to A1 >= B1
6826 <= Less than or equal to A1 <= B1
6827
6828
6829 String operator:
6830 ================
6831 Operator Meaning Example
6832 & Concatenation "Hello " & "World!" # [1]
6833
6834
6835 Reference operators:
6836 ====================
6837 Operator Meaning Example
6838 : Range operator A1:A4 # [2]
6839 , Union operator SUM(1, 2+2, B3) # [3]
6840
6841
6842 Notes:
6843 [1]: Equivalent to "Hello " . "World!" in Perl.
6844 [2]: This range is equivalent to cells A1, A2, A3 and A4.
6845 [3]: The comma behaves like the list separator in Perl.
6846
6847 The range and comma operators can have different symbols in non-English
6848 versions of Excel, see below.
6849
6850 For a general introduction to Excel's formulas and an explanation of
6851 the syntax of the function refer to the Excel help files or the
6852 following:
6853 <http://office.microsoft.com/en-us/assistance/CH062528031033.aspx>.
6854
6855 In most cases a formula in Excel can be used directly in the
6856 "write_formula" method. However, there are a few potential issues and
6857 differences that the user should be aware of. These are explained in
6858 the following sections.
6859
6860 Non US Excel functions and syntax
6861 Excel stores formulas in the format of the US English version,
6862 regardless of the language or locale of the end-user's version of
6863 Excel. Therefore all formula function names written using
6864 Excel::Writer::XLSX must be in English:
6865
6866 worksheet->write_formula('A1', '=SUM(1, 2, 3)'); # OK
6867 worksheet->write_formula('A2', '=SOMME(1, 2, 3)'); # French. Error on load.
6868
6869 Also, formulas must be written with the US style separator/range
6870 operator which is a comma (not semi-colon). Therefore a formula with
6871 multiple values should be written as follows:
6872
6873 worksheet->write_formula('A1', '=SUM(1, 2, 3)'); # OK
6874 worksheet->write_formula('A2', '=SUM(1; 2; 3)'); # Semi-colon. Error on load.
6875
6876 If you have a non-English version of Excel you can use the following
6877 multi-lingual Formula Translator
6878 (<http://en.excel-translator.de/language/>) to help you convert the
6879 formula. It can also replace semi-colons with commas.
6880
6881 Formulas added in Excel 2010 and later
6882 Excel 2010 and later added functions which weren't defined in the
6883 original file specification. These functions are referred to by
6884 Microsoft as future functions. Examples of these functions are "ACOT",
6885 "CHISQ.DIST.RT" , "CONFIDENCE.NORM", "STDEV.P", "STDEV.S" and
6886 "WORKDAY.INTL".
6887
6888 When written using write_formula() these functions need to be fully
6889 qualified with a "_xlfn." (or other) prefix as they are shown the list
6890 below. For example:
6891
6892 worksheet->write_formula('A1', '=_xlfn.STDEV.S(B1:B10)')
6893
6894 They will appear without the prefix in Excel.
6895
6896 The following list is taken from the MS XLSX extensions documentation
6897 on future functions:
6898 <http://msdn.microsoft.com/en-us/library/dd907480%28v=office.12%29.aspx>:
6899
6900 _xlfn.ACOT
6901 _xlfn.ACOTH
6902 _xlfn.AGGREGATE
6903 _xlfn.ARABIC
6904 _xlfn.BASE
6905 _xlfn.BETA.DIST
6906 _xlfn.BETA.INV
6907 _xlfn.BINOM.DIST
6908 _xlfn.BINOM.DIST.RANGE
6909 _xlfn.BINOM.INV
6910 _xlfn.BITAND
6911 _xlfn.BITLSHIFT
6912 _xlfn.BITOR
6913 _xlfn.BITRSHIFT
6914 _xlfn.BITXOR
6915 _xlfn.CEILING.MATH
6916 _xlfn.CEILING.PRECISE
6917 _xlfn.CHISQ.DIST
6918 _xlfn.CHISQ.DIST.RT
6919 _xlfn.CHISQ.INV
6920 _xlfn.CHISQ.INV.RT
6921 _xlfn.CHISQ.TEST
6922 _xlfn.COMBINA
6923 _xlfn.CONFIDENCE.NORM
6924 _xlfn.CONFIDENCE.T
6925 _xlfn.COT
6926 _xlfn.COTH
6927 _xlfn.COVARIANCE.P
6928 _xlfn.COVARIANCE.S
6929 _xlfn.CSC
6930 _xlfn.CSCH
6931 _xlfn.DAYS
6932 _xlfn.DECIMAL
6933 ECMA.CEILING
6934 _xlfn.ERF.PRECISE
6935 _xlfn.ERFC.PRECISE
6936 _xlfn.EXPON.DIST
6937 _xlfn.F.DIST
6938 _xlfn.F.DIST.RT
6939 _xlfn.F.INV
6940 _xlfn.F.INV.RT
6941 _xlfn.F.TEST
6942 _xlfn.FILTERXML
6943 _xlfn.FLOOR.MATH
6944 _xlfn.FLOOR.PRECISE
6945 _xlfn.FORECAST.ETS
6946 _xlfn.FORECAST.ETS.CONFINT
6947 _xlfn.FORECAST.ETS.SEASONALITY
6948 _xlfn.FORECAST.ETS.STAT
6949 _xlfn.FORECAST.LINEAR
6950 _xlfn.FORMULATEXT
6951 _xlfn.GAMMA
6952 _xlfn.GAMMA.DIST
6953 _xlfn.GAMMA.INV
6954 _xlfn.GAMMALN.PRECISE
6955 _xlfn.GAUSS
6956 _xlfn.HYPGEOM.DIST
6957 _xlfn.IFNA
6958 _xlfn.IMCOSH
6959 _xlfn.IMCOT
6960 _xlfn.IMCSC
6961 _xlfn.IMCSCH
6962 _xlfn.IMSEC
6963 _xlfn.IMSECH
6964 _xlfn.IMSINH
6965 _xlfn.IMTAN
6966 _xlfn.ISFORMULA
6967 ISO.CEILING
6968 _xlfn.ISOWEEKNUM
6969 _xlfn.LOGNORM.DIST
6970 _xlfn.LOGNORM.INV
6971 _xlfn.MODE.MULT
6972 _xlfn.MODE.SNGL
6973 _xlfn.MUNIT
6974 _xlfn.NEGBINOM.DIST
6975 NETWORKDAYS.INTL
6976 _xlfn.NORM.DIST
6977 _xlfn.NORM.INV
6978 _xlfn.NORM.S.DIST
6979 _xlfn.NORM.S.INV
6980 _xlfn.NUMBERVALUE
6981 _xlfn.PDURATION
6982 _xlfn.PERCENTILE.EXC
6983 _xlfn.PERCENTILE.INC
6984 _xlfn.PERCENTRANK.EXC
6985 _xlfn.PERCENTRANK.INC
6986 _xlfn.PERMUTATIONA
6987 _xlfn.PHI
6988 _xlfn.POISSON.DIST
6989 _xlfn.QUARTILE.EXC
6990 _xlfn.QUARTILE.INC
6991 _xlfn.QUERYSTRING
6992 _xlfn.RANK.AVG
6993 _xlfn.RANK.EQ
6994 _xlfn.RRI
6995 _xlfn.SEC
6996 _xlfn.SECH
6997 _xlfn.SHEET
6998 _xlfn.SHEETS
6999 _xlfn.SKEW.P
7000 _xlfn.STDEV.P
7001 _xlfn.STDEV.S
7002 _xlfn.T.DIST
7003 _xlfn.T.DIST.2T
7004 _xlfn.T.DIST.RT
7005 _xlfn.T.INV
7006 _xlfn.T.INV.2T
7007 _xlfn.T.TEST
7008 _xlfn.UNICHAR
7009 _xlfn.UNICODE
7010 _xlfn.VAR.P
7011 _xlfn.VAR.S
7012 _xlfn.WEBSERVICE
7013 _xlfn.WEIBULL.DIST
7014 WORKDAY.INTL
7015 _xlfn.XOR
7016 _xlfn.Z.TEST
7017
7018 Using Tables in Formulas
7019 Worksheet tables can be added with Excel::Writer::XLSX using the
7020 add_table() method:
7021
7022 worksheet->add_table('B3:F7', {options});
7023
7024 By default tables are named "Table1", "Table2", etc., in the order that
7025 they are added. However it can also be set by the user using the "name"
7026 parameter:
7027
7028 worksheet->add_table('B3:F7', {'name': 'SalesData'});
7029
7030 If you need to know the name of the table, for example to use it in a
7031 formula, you can get it as follows:
7032
7033 table = worksheet->add_table('B3:F7');
7034 table_name = table->{_name};
7035
7036 When used in a formula a table name such as "TableX" should be referred
7037 to as "TableX[]" (like a Perl array):
7038
7039 worksheet->write_formula('A5', '=VLOOKUP("Sales", Table1[], 2, FALSE');
7040
7041 Dealing with #NAME? errors
7042 If there is an error in the syntax of a formula it is usually displayed
7043 in Excel as "#NAME?". If you encounter an error like this you can debug
7044 it as follows:
7045
7046 1. Ensure the formula is valid in Excel by copying and pasting it into
7047 a cell. Note, this should be done in Excel and not other applications
7048 such as OpenOffice or LibreOffice since they may have slightly
7049 different syntax.
7050 2. Ensure the formula is using comma separators instead of semi-colons,
7051 see "Non US Excel functions and syntax" above.
7052 3. Ensure the formula is in English, see "Non US Excel functions and
7053 syntax" above.
7054 4. Ensure that the formula doesn't contain an Excel 2010+ future
7055 function as listed in "Formulas added in Excel 2010 and later" above.
7056 If it does then ensure that the correct prefix is used.
7057
7058 Finally if you have completed all the previous steps and still get a
7059 "#NAME?" error you can examine a valid Excel file to see what the
7060 correct syntax should be. To do this you should create a valid formula
7061 in Excel and save the file. You can then examine the XML in the
7062 unzipped file.
7063
7064 The following shows how to do that using Linux "unzip" and libxml's
7065 xmllint <http://xmlsoft.org/xmllint.html> to format the XML for
7066 clarity:
7067
7068 $ unzip myfile.xlsx -d myfile
7069 $ xmllint --format myfile/xl/worksheets/sheet1.xml | grep '<f>'
7070
7071 <f>SUM(1, 2, 3)</f>
7072
7073 Formula Results
7074 Excel::Writer::XLSX doesn't calculate the result of a formula and
7075 instead stores the value 0 as the formula result. It then sets a global
7076 flag in the XLSX file to say that all formulas and functions should be
7077 recalculated when the file is opened.
7078
7079 This is the method recommended in the Excel documentation and in
7080 general it works fine with spreadsheet applications. However,
7081 applications that don't have a facility to calculate formulas will only
7082 display the 0 results. Examples of such applications are Excel Viewer,
7083 PDF Converters, and some mobile device applications.
7084
7085 If required, it is also possible to specify the calculated result of
7086 the formula using the optional last "value" parameter in
7087 "write_formula":
7088
7089 worksheet->write_formula('A1', '=2+2', num_format, 4);
7090
7091 The "value" parameter can be a number, a string, a boolean sting
7092 ('TRUE' or 'FALSE') or one of the following Excel error codes:
7093
7094 #DIV/0!
7095 #N/A
7096 #NAME?
7097 #NULL!
7098 #NUM!
7099 #REF!
7100 #VALUE!
7101
7102 It is also possible to specify the calculated result of an array
7103 formula created with "write_array_formula":
7104
7105 # Specify the result for a single cell range.
7106 worksheet->write_array_formula('A1:A1', '{=SUM(B1:C1*B2:C2)}', format, 2005);
7107
7108 However, using this parameter only writes a single value to the upper
7109 left cell in the result array. For a multi-cell array formula where the
7110 results are required, the other result values can be specified by using
7111 write_number() to write to the appropriate cell:
7112
7113 # Specify the results for a multi cell range.
7114 worksheet->write_array_formula('A1:A3', '{=TREND(C1:C3,B1:B3)}', format, 15);
7115 worksheet->write_number('A2', 12, format);
7116 worksheet->write_number('A3', 14, format);
7117
7119 An Excel "xlsm" file is exactly the same as a "xlsx" file except that
7120 is includes an additional "vbaProject.bin" file which contains
7121 functions and/or macros. Excel uses a different extension to
7122 differentiate between the two file formats since files containing
7123 macros are usually subject to additional security checks.
7124
7125 The "vbaProject.bin" file is a binary OLE COM container. This was the
7126 format used in older "xls" versions of Excel prior to Excel 2007.
7127 Unlike all of the other components of an xlsx/xlsm file the data isn't
7128 stored in XML format. Instead the functions and macros as stored as
7129 pre-parsed binary format. As such it wouldn't be feasible to define
7130 macros and create a "vbaProject.bin" file from scratch (at least not in
7131 the remaining lifespan and interest levels of the author).
7132
7133 Instead a workaround is used to extract "vbaProject.bin" files from
7134 existing xlsm files and then add these to Excel::Writer::XLSX files.
7135
7136 The extract_vba utility
7137 The "extract_vba" utility is used to extract the "vbaProject.bin"
7138 binary from an Excel 2007+ xlsm file. The utility is included in the
7139 Excel::Writer::XLSX bin directory and is also installed as a standalone
7140 executable file:
7141
7142 $ extract_vba macro_file.xlsm
7143 Extracted: vbaProject.bin
7144
7145 Adding the VBA macros to a Excel::Writer::XLSX file
7146 Once the "vbaProject.bin" file has been extracted it can be added to
7147 the Excel::Writer::XLSX workbook using the add_vba_project() method:
7148
7149 $workbook->add_vba_project( './vbaProject.bin' );
7150
7151 If the VBA file contains functions you can then refer to them in
7152 calculations using "write_formula":
7153
7154 $worksheet->write_formula( 'A1', '=MyMortgageCalc(200000, 25)' );
7155
7156 Excel files that contain functions and macros should use an "xlsm"
7157 extension or else Excel will complain and possibly not open the file:
7158
7159 my $workbook = Excel::Writer::XLSX->new( 'file.xlsm' );
7160
7161 It is also possible to assign a macro to a button that is inserted into
7162 a worksheet using the insert_button() method:
7163
7164 my $workbook = Excel::Writer::XLSX->new( 'file.xlsm' );
7165 ...
7166 $workbook->add_vba_project( './vbaProject.bin' );
7167
7168 $worksheet->insert_button( 'C2', { macro => 'my_macro' } );
7169
7170 It may be necessary to specify a more explicit macro name prefixed by
7171 the workbook VBA name as follows:
7172
7173 $worksheet->insert_button( 'C2', { macro => 'ThisWorkbook.my_macro' } );
7174
7175 See the "macros.pl" from the examples directory for a working example.
7176
7177 Note: Button is the only VBA Control supported by Excel::Writer::XLSX.
7178 Due to the large effort in implementation (1+ man months) it is
7179 unlikely that any other form elements will be added in the future.
7180
7181 Setting the VBA codenames
7182 VBA macros generally refer to workbook and worksheet objects. If the
7183 VBA codenames aren't specified then Excel::Writer::XLSX will use the
7184 Excel defaults of "ThisWorkbook" and "Sheet1", "Sheet2" etc.
7185
7186 If the macro uses other codenames you can set them using the workbook
7187 and worksheet set_vba_name() methods as follows:
7188
7189 $workbook->set_vba_name( 'MyWorkbook' );
7190 $worksheet->set_vba_name( 'MySheet' );
7191
7192 You can find the names that are used in the VBA editor or by unzipping
7193 the "xlsm" file and grepping the files. The following shows how to do
7194 that using libxml's xmllint <http://xmlsoft.org/xmllint.html> to format
7195 the XML for clarity:
7196
7197 $ unzip myfile.xlsm -d myfile
7198 $ xmllint --format `find myfile -name "*.xml" | xargs` | grep "Pr.*codeName"
7199
7200 <workbookPr codeName="MyWorkbook" defaultThemeVersion="124226"/>
7201 <sheetPr codeName="MySheet"/>
7202
7203 Note: This step is particularly important for macros created with non-
7204 English versions of Excel.
7205
7206 What to do if it doesn't work
7207 This feature should be considered experimental and there is no
7208 guarantee that it will work in all cases. Some effort may be required
7209 and some knowledge of VBA will certainly help. If things don't work out
7210 here are some things to try:
7211
7212 • Start with a simple macro file, ensure that it works and then add
7213 complexity.
7214
7215 • Try to extract the macros from an Excel 2007 file. The method
7216 should work with macros from later versions (it was also tested
7217 with Excel 2010 macros). However there may be features in the macro
7218 files of more recent version of Excel that aren't backward
7219 compatible.
7220
7221 • Check the code names that macros use to refer to the workbook and
7222 worksheets (see the previous section above). In general VBA uses a
7223 code name of "ThisWorkbook" to refer to the current workbook and
7224 the sheet name (such as "Sheet1") to refer to the worksheets. These
7225 are the defaults used by Excel::Writer::XLSX. If the macro uses
7226 other names then you can specify these using the workbook and
7227 worksheet set_vba_name() methods:
7228
7229 $workbook>set_vba_name( 'MyWorkbook' );
7230 $worksheet->set_vba_name( 'MySheet' );
7231
7233 See Excel::Writer::XLSX::Examples for a full list of examples.
7234
7235 Example 1
7236 The following example shows some of the basic features of
7237 Excel::Writer::XLSX.
7238
7239 #!/usr/bin/perl -w
7240
7241 use strict;
7242 use Excel::Writer::XLSX;
7243
7244 # Create a new workbook called simple.xlsx and add a worksheet
7245 my $workbook = Excel::Writer::XLSX->new( 'simple.xlsx' );
7246 my $worksheet = $workbook->add_worksheet();
7247
7248 # The general syntax is write($row, $column, $token). Note that row and
7249 # column are zero indexed
7250
7251 # Write some text
7252 $worksheet->write( 0, 0, 'Hi Excel!' );
7253
7254
7255 # Write some numbers
7256 $worksheet->write( 2, 0, 3 );
7257 $worksheet->write( 3, 0, 3.00000 );
7258 $worksheet->write( 4, 0, 3.00001 );
7259 $worksheet->write( 5, 0, 3.14159 );
7260
7261
7262 # Write some formulas
7263 $worksheet->write( 7, 0, '=A3 + A6' );
7264 $worksheet->write( 8, 0, '=IF(A5>3,"Yes", "No")' );
7265
7266
7267 # Write a hyperlink
7268 my $hyperlink_format = $workbook->add_format(
7269 color => 'blue',
7270 underline => 1,
7271 );
7272
7273 $worksheet->write( 10, 0, 'http://www.perl.com/', $hyperlink_format );
7274
7275 $workbook->close();
7276
7277 Example 2
7278 The following is a general example which demonstrates some features of
7279 working with multiple worksheets.
7280
7281 #!/usr/bin/perl -w
7282
7283 use strict;
7284 use Excel::Writer::XLSX;
7285
7286 # Create a new Excel workbook
7287 my $workbook = Excel::Writer::XLSX->new( 'regions.xlsx' );
7288
7289 # Add some worksheets
7290 my $north = $workbook->add_worksheet( 'North' );
7291 my $south = $workbook->add_worksheet( 'South' );
7292 my $east = $workbook->add_worksheet( 'East' );
7293 my $west = $workbook->add_worksheet( 'West' );
7294
7295 # Add a Format
7296 my $format = $workbook->add_format();
7297 $format->set_bold();
7298 $format->set_color( 'blue' );
7299
7300 # Add a caption to each worksheet
7301 for my $worksheet ( $workbook->sheets() ) {
7302 $worksheet->write( 0, 0, 'Sales', $format );
7303 }
7304
7305 # Write some data
7306 $north->write( 0, 1, 200000 );
7307 $south->write( 0, 1, 100000 );
7308 $east->write( 0, 1, 150000 );
7309 $west->write( 0, 1, 100000 );
7310
7311 # Set the active worksheet
7312 $south->activate();
7313
7314 # Set the width of the first column
7315 $south->set_column( 0, 0, 20 );
7316
7317 # Set the active cell
7318 $south->set_selection( 0, 1 );
7319
7320 $workbook->close();
7321
7322 Example 3
7323 Example of how to add conditional formatting to an Excel::Writer::XLSX
7324 file. The example below highlights cells that have a value greater than
7325 or equal to 50 in red and cells below that value in green.
7326
7327 #!/usr/bin/perl
7328
7329 use strict;
7330 use warnings;
7331 use Excel::Writer::XLSX;
7332
7333 my $workbook = Excel::Writer::XLSX->new( 'conditional_format.xlsx' );
7334 my $worksheet = $workbook->add_worksheet();
7335
7336
7337 # This example below highlights cells that have a value greater than or
7338 # equal to 50 in red and cells below that value in green.
7339
7340 # Light red fill with dark red text.
7341 my $format1 = $workbook->add_format(
7342 bg_color => '#FFC7CE',
7343 color => '#9C0006',
7344
7345 );
7346
7347 # Green fill with dark green text.
7348 my $format2 = $workbook->add_format(
7349 bg_color => '#C6EFCE',
7350 color => '#006100',
7351
7352 );
7353
7354 # Some sample data to run the conditional formatting against.
7355 my $data = [
7356 [ 34, 72, 38, 30, 75, 48, 75, 66, 84, 86 ],
7357 [ 6, 24, 1, 84, 54, 62, 60, 3, 26, 59 ],
7358 [ 28, 79, 97, 13, 85, 93, 93, 22, 5, 14 ],
7359 [ 27, 71, 40, 17, 18, 79, 90, 93, 29, 47 ],
7360 [ 88, 25, 33, 23, 67, 1, 59, 79, 47, 36 ],
7361 [ 24, 100, 20, 88, 29, 33, 38, 54, 54, 88 ],
7362 [ 6, 57, 88, 28, 10, 26, 37, 7, 41, 48 ],
7363 [ 52, 78, 1, 96, 26, 45, 47, 33, 96, 36 ],
7364 [ 60, 54, 81, 66, 81, 90, 80, 93, 12, 55 ],
7365 [ 70, 5, 46, 14, 71, 19, 66, 36, 41, 21 ],
7366 ];
7367
7368 my $caption = 'Cells with values >= 50 are in light red. '
7369 . 'Values < 50 are in light green';
7370
7371 # Write the data.
7372 $worksheet->write( 'A1', $caption );
7373 $worksheet->write_col( 'B3', $data );
7374
7375 # Write a conditional format over a range.
7376 $worksheet->conditional_formatting( 'B3:K12',
7377 {
7378 type => 'cell',
7379 criteria => '>=',
7380 value => 50,
7381 format => $format1,
7382 }
7383 );
7384
7385 # Write another conditional format over the same range.
7386 $worksheet->conditional_formatting( 'B3:K12',
7387 {
7388 type => 'cell',
7389 criteria => '<',
7390 value => 50,
7391 format => $format2,
7392 }
7393 );
7394
7395 $workbook->close();
7396
7397 Example 4
7398 The following is a simple example of using functions.
7399
7400 #!/usr/bin/perl -w
7401
7402 use strict;
7403 use Excel::Writer::XLSX;
7404
7405 # Create a new workbook and add a worksheet
7406 my $workbook = Excel::Writer::XLSX->new( 'stats.xlsx' );
7407 my $worksheet = $workbook->add_worksheet( 'Test data' );
7408
7409 # Set the column width for columns 1
7410 $worksheet->set_column( 0, 0, 20 );
7411
7412
7413 # Create a format for the headings
7414 my $format = $workbook->add_format();
7415 $format->set_bold();
7416
7417
7418 # Write the sample data
7419 $worksheet->write( 0, 0, 'Sample', $format );
7420 $worksheet->write( 0, 1, 1 );
7421 $worksheet->write( 0, 2, 2 );
7422 $worksheet->write( 0, 3, 3 );
7423 $worksheet->write( 0, 4, 4 );
7424 $worksheet->write( 0, 5, 5 );
7425 $worksheet->write( 0, 6, 6 );
7426 $worksheet->write( 0, 7, 7 );
7427 $worksheet->write( 0, 8, 8 );
7428
7429 $worksheet->write( 1, 0, 'Length', $format );
7430 $worksheet->write( 1, 1, 25.4 );
7431 $worksheet->write( 1, 2, 25.4 );
7432 $worksheet->write( 1, 3, 24.8 );
7433 $worksheet->write( 1, 4, 25.0 );
7434 $worksheet->write( 1, 5, 25.3 );
7435 $worksheet->write( 1, 6, 24.9 );
7436 $worksheet->write( 1, 7, 25.2 );
7437 $worksheet->write( 1, 8, 24.8 );
7438
7439 # Write some statistical functions
7440 $worksheet->write( 4, 0, 'Count', $format );
7441 $worksheet->write( 4, 1, '=COUNT(B1:I1)' );
7442
7443 $worksheet->write( 5, 0, 'Sum', $format );
7444 $worksheet->write( 5, 1, '=SUM(B2:I2)' );
7445
7446 $worksheet->write( 6, 0, 'Average', $format );
7447 $worksheet->write( 6, 1, '=AVERAGE(B2:I2)' );
7448
7449 $worksheet->write( 7, 0, 'Min', $format );
7450 $worksheet->write( 7, 1, '=MIN(B2:I2)' );
7451
7452 $worksheet->write( 8, 0, 'Max', $format );
7453 $worksheet->write( 8, 1, '=MAX(B2:I2)' );
7454
7455 $worksheet->write( 9, 0, 'Standard Deviation', $format );
7456 $worksheet->write( 9, 1, '=STDEV(B2:I2)' );
7457
7458 $worksheet->write( 10, 0, 'Kurtosis', $format );
7459 $worksheet->write( 10, 1, '=KURT(B2:I2)' );
7460
7461 $workbook->close();
7462
7463 Example 5
7464 The following example converts a tab separated file called "tab.txt"
7465 into an Excel file called "tab.xlsx".
7466
7467 #!/usr/bin/perl -w
7468
7469 use strict;
7470 use Excel::Writer::XLSX;
7471
7472 open( TABFILE, 'tab.txt' ) or die "tab.txt: $!";
7473
7474 my $workbook = Excel::Writer::XLSX->new( 'tab.xlsx' );
7475 my $worksheet = $workbook->add_worksheet();
7476
7477 # Row and column are zero indexed
7478 my $row = 0;
7479
7480 while ( <TABFILE> ) {
7481 chomp;
7482
7483 # Split on single tab
7484 my @fields = split( '\t', $_ );
7485
7486 my $col = 0;
7487 for my $token ( @fields ) {
7488 $worksheet->write( $row, $col, $token );
7489 $col++;
7490 }
7491 $row++;
7492 }
7493
7494 $workbook->close();
7495
7496 NOTE: This is a simple conversion program for illustrative purposes
7497 only. For converting a CSV or Tab separated or any other type of
7498 delimited text file to Excel I recommend the more rigorous csv2xls
7499 program that is part of H.Merijn Brand's Text::CSV_XS module distro.
7500
7501 See the examples/csv2xls link here:
7502 <http://search.cpan.org/~hmbrand/Text-CSV_XS/MANIFEST>.
7503
7504 Additional Examples
7505 The following is a description of the example files that are provided
7506 in the standard Excel::Writer::XLSX distribution. They demonstrate the
7507 different features and options of the module. See
7508 Excel::Writer::XLSX::Examples for more details.
7509
7510 Getting started
7511 ===============
7512 a_simple.pl A simple demo of some of the features.
7513 bug_report.pl A template for submitting bug reports.
7514 demo.pl A demo of some of the available features.
7515 formats.pl All the available formatting on several worksheets.
7516 regions.pl A simple example of multiple worksheets.
7517 stats.pl Basic formulas and functions.
7518
7519
7520 Intermediate
7521 ============
7522 autofilter.pl Examples of worksheet autofilters.
7523 array_formula.pl Examples of how to write array formulas.
7524 cgi.pl A simple CGI program.
7525 chart_area.pl A demo of area style charts.
7526 chart_bar.pl A demo of bar (vertical histogram) style charts.
7527 chart_column.pl A demo of column (histogram) style charts.
7528 chart_line.pl A demo of line style charts.
7529 chart_pie.pl A demo of pie style charts.
7530 chart_doughnut.pl A demo of doughnut style charts.
7531 chart_radar.pl A demo of radar style charts.
7532 chart_scatter.pl A demo of scatter style charts.
7533 chart_secondary_axis.pl A demo of a line chart with a secondary axis.
7534 chart_combined.pl A demo of a combined column and line chart.
7535 chart_pareto.pl A demo of a combined Pareto chart.
7536 chart_stock.pl A demo of stock style charts.
7537 chart_data_table.pl A demo of a chart with a data table on the axis.
7538 chart_data_tools.pl A demo of charts with data highlighting options.
7539 chart_data_labels.pl A demo of standard and custom chart data labels.
7540 chart_clustered.pl A demo of a chart with a clustered axis.
7541 chart_styles.pl A demo of the available chart styles.
7542 chart_gauge.pl A demo of a gauge style chart.
7543 colors.pl A demo of the colour palette and named colours.
7544 comments1.pl Add comments to worksheet cells.
7545 comments2.pl Add comments with advanced options.
7546 conditional_format.pl Add conditional formats to a range of cells.
7547 data_validate.pl An example of data validation and dropdown lists.
7548 date_time.pl Write dates and times with write_date_time().
7549 defined_name.pl Example of how to create defined names.
7550 diag_border.pl A simple example of diagonal cell borders.
7551 filehandle.pl Examples of working with filehandles.
7552 headers.pl Examples of worksheet headers and footers.
7553 hide_row_col.pl Example of hiding rows and columns.
7554 hide_sheet.pl Simple example of hiding a worksheet.
7555 hyperlink1.pl Shows how to create web hyperlinks.
7556 hyperlink2.pl Examples of internal and external hyperlinks.
7557 indent.pl An example of cell indentation.
7558 ignore_errors.pl An example of turning off worksheet cells errors/warnings.
7559 macros.pl An example of adding macros from an existing file.
7560 merge1.pl A simple example of cell merging.
7561 merge2.pl A simple example of cell merging with formatting.
7562 merge3.pl Add hyperlinks to merged cells.
7563 merge4.pl An advanced example of merging with formatting.
7564 merge5.pl An advanced example of merging with formatting.
7565 merge6.pl An example of merging with Unicode strings.
7566 mod_perl1.pl A simple mod_perl 1 program.
7567 mod_perl2.pl A simple mod_perl 2 program.
7568 outline.pl An example of outlines and grouping.
7569 outline_collapsed.pl An example of collapsed outlines.
7570 panes.pl An example of how to create panes.
7571 properties.pl Add document properties to a workbook.
7572 protection.pl Example of cell locking and formula hiding.
7573 rich_strings.pl Example of strings with multiple formats.
7574 right_to_left.pl Change default sheet direction to right to left.
7575 sales.pl An example of a simple sales spreadsheet.
7576 shape1.pl Insert shapes in worksheet.
7577 shape2.pl Insert shapes in worksheet. With properties.
7578 shape3.pl Insert shapes in worksheet. Scaled.
7579 shape4.pl Insert shapes in worksheet. With modification.
7580 shape5.pl Insert shapes in worksheet. With connections.
7581 shape6.pl Insert shapes in worksheet. With connections.
7582 shape7.pl Insert shapes in worksheet. One to many connections.
7583 shape8.pl Insert shapes in worksheet. One to many connections.
7584 shape_all.pl Demo of all the available shape and connector types.
7585 sparklines1.pl Simple sparklines demo.
7586 sparklines2.pl Sparklines demo showing formatting options.
7587 stats_ext.pl Same as stats.pl with external references.
7588 stocks.pl Demonstrates conditional formatting.
7589 background.pl Example of how to set the background image for a worksheet.
7590 tab_colors.pl Example of how to set worksheet tab colours.
7591 tables.pl Add Excel tables to a worksheet.
7592 write_handler1.pl Example of extending the write() method. Step 1.
7593 write_handler2.pl Example of extending the write() method. Step 2.
7594 write_handler3.pl Example of extending the write() method. Step 3.
7595 write_handler4.pl Example of extending the write() method. Step 4.
7596 write_to_scalar.pl Example of writing an Excel file to a Perl scalar.
7597
7598
7599 Unicode
7600 =======
7601 unicode_2022_jp.pl Japanese: ISO-2022-JP.
7602 unicode_8859_11.pl Thai: ISO-8859_11.
7603 unicode_8859_7.pl Greek: ISO-8859_7.
7604 unicode_big5.pl Chinese: BIG5.
7605 unicode_cp1251.pl Russian: CP1251.
7606 unicode_cp1256.pl Arabic: CP1256.
7607 unicode_cyrillic.pl Russian: Cyrillic.
7608 unicode_koi8r.pl Russian: KOI8-R.
7609 unicode_polish_utf8.pl Polish : UTF8.
7610 unicode_shift_jis.pl Japanese: Shift JIS.
7611
7613 The following limits are imposed by Excel 2007+:
7614
7615 Description Limit
7616 -------------------------------------- ------
7617 Maximum number of chars in a string 32,767
7618 Maximum number of columns 16,384
7619 Maximum number of rows 1,048,576
7620 Maximum chars in a sheet name 31
7621 Maximum chars in a header/footer 254
7622
7623 Maximum characters in hyperlink url (1) 2079
7624 Maximum number of unique hyperlinks (2) 65,530
7625
7626 (1) Versions of Excel prior to Excel 2015 limited hyperlink links and
7627 anchor/locations to 255 characters each. Versions after that support
7628 urls up to 2079 characters. Excel::Writer::XLSX versions >= 1.0.2
7629 support the new longer limit by default.
7630
7631 (2) Per worksheet. Excel allows a greater number of non-unique
7632 hyperlinks if they are contiguous and can be grouped into a single
7633 range. This isn't supported by Excel::Writer::XLSX.
7634
7636 <http://search.cpan.org/search?dist=Archive-Zip/>.
7637
7638 Perl 5.8.2.
7639
7641 "Spreadsheet::WriteExcel" was written to optimise speed and reduce
7642 memory usage. However, these design goals meant that it wasn't easy to
7643 implement features that many users requested such as writing formatting
7644 and data separately.
7645
7646 As a result "Excel::Writer::XLSX" takes a different design approach and
7647 holds a lot more data in memory so that it is functionally more
7648 flexible.
7649
7650 The effect of this is that Excel::Writer::XLSX is about 30% slower than
7651 Spreadsheet::WriteExcel and uses 5 times more memory.
7652
7653 In addition the extended row and column ranges in Excel 2007+ mean that
7654 it is possible to run out of memory creating large files. This was
7655 almost never an issue with Spreadsheet::WriteExcel.
7656
7657 This memory usage can be reduced almost completely by using the
7658 Workbook set_optimization() method:
7659
7660 $workbook->set_optimization();
7661
7662 The trade-off is that you won't be able to take advantage of features
7663 that manipulate cell data after it is written. One such feature is
7664 Tables.
7665
7667 The latest version of this module is always available at:
7668 <http://search.cpan.org/search?dist=Excel-Writer-XLSX/>.
7669
7671 The module can be installed using the standard Perl procedure:
7672
7673 perl Makefile.PL
7674 make
7675 make test
7676 make install # You may need to be sudo/root
7677
7679 Filename required by Excel::Writer::XLSX->new()
7680 A filename must be given in the constructor.
7681
7682 Can't open filename. It may be in use or protected.
7683 The file cannot be opened for writing. The directory that you are
7684 writing to may be protected or the file may be in use by another
7685 program.
7686
7687 Can't call method "XXX" on an undefined value at someprogram.pl.
7688 On Windows this is usually caused by the file that you are trying
7689 to create clashing with a version that is already open and locked
7690 by Excel.
7691
7692 The file you are trying to open 'file.xls' is in a different format
7693 than specified by the file extension.
7694 This warning occurs when you create an XLSX file but give it an xls
7695 extension.
7696
7698 Depending on your requirements, background and general sensibilities
7699 you may prefer one of the following methods of getting data into Excel:
7700
7701 • Spreadsheet::WriteExcel
7702
7703 This module is the precursor to Excel::Writer::XLSX and uses the
7704 same interface. It produces files in the Excel Biff xls format that
7705 was used in Excel versions 97-2003. These files can still be read
7706 by Excel 2007 but have some limitations in relation to the number
7707 of rows and columns that the format supports.
7708
7709 Spreadsheet::WriteExcel.
7710
7711 • Win32::OLE module and office automation
7712
7713 This requires a Windows platform and an installed copy of Excel.
7714 This is the most powerful and complete method for interfacing with
7715 Excel.
7716
7717 Win32::OLE
7718
7719 • CSV, comma separated variables or text
7720
7721 Excel will open and automatically convert files with a "csv"
7722 extension.
7723
7724 To create CSV files refer to the Text::CSV_XS module.
7725
7726 • DBI with DBD::ADO or DBD::ODBC
7727
7728 Excel files contain an internal index table that allows them to act
7729 like a database file. Using one of the standard Perl database
7730 modules you can connect to an Excel file as a database.
7731
7732 For other Perl-Excel modules try the following search:
7733 <http://search.cpan.org/search?mode=module&query=excel>.
7734
7736 To read data from Excel files try:
7737
7738 • Spreadsheet::ParseXLSX
7739
7740 A module for reading data from XLSX files. It also imports most, if
7741 not all, of the metadata to be found in Excel XLSX files. As its
7742 author describes it: "This module is an adaptor for
7743 Spreadsheet::ParseExcel that reads XLSX files. For documentation
7744 about the various data that you can retrieve from these classes,
7745 please see Spreadsheet::ParseExcel,
7746 Spreadsheet::ParseExcel::Workbook,
7747 Spreadsheet::ParseExcel::Worksheet, and
7748 Spreadsheet::ParseExcel::Cell."
7749
7750 • Spreadsheet::XLSX
7751
7752 A module for reading formatted or unformatted data from XLSX files.
7753
7754 Spreadsheet::XLSX
7755
7756 • SimpleXlsx
7757
7758 A lightweight module for reading data from XLSX files.
7759
7760 SimpleXlsx
7761
7762 • Spreadsheet::ParseExcel
7763
7764 This module can read data from an Excel XLS file but it doesn't
7765 support the XLSX format.
7766
7767 Spreadsheet::ParseExcel
7768
7769 • Win32::OLE module and office automation (reading)
7770
7771 See above.
7772
7773 • DBI with DBD::ADO or DBD::ODBC.
7774
7775 See above.
7776
7777 For other Perl-Excel modules try the following search:
7778 <http://search.cpan.org/search?mode=module&query=excel>.
7779
7781 • Memory usage is very high for large worksheets.
7782
7783 If you run out of memory creating large worksheets use the
7784 set_optimization() method. See "SPEED AND MEMORY USAGE" for more
7785 information.
7786
7787 • Perl packaging programs can't find chart modules.
7788
7789 When using Excel::Writer::XLSX charts with Perl packagers such as
7790 PAR or Cava you should explicitly include the chart that you are
7791 trying to create in your "use" statements. This isn't a bug as such
7792 but it might help someone from banging their head off a wall:
7793
7794 ...
7795 use Excel::Writer::XLSX;
7796 use Excel::Writer::XLSX::Chart::Column;
7797 ...
7798
7799 If you wish to submit a bug report run the "bug_report.pl" program in
7800 the "examples" directory of the distro.
7801
7802 The bug tracker is on Github:
7803 <https://github.com/jmcnamara/excel-writer-xlsx/issues>.
7804
7806 The Excel::Writer::XLSX source code in host on github:
7807 <http://github.com/jmcnamara/excel-writer-xlsx>.
7808
7810 If you'd care to donate to the Excel::Writer::XLSX project or sponsor a
7811 new feature, you can do so via PayPal: <http://tinyurl.com/7ayes>.
7812
7814 Spreadsheet::WriteExcel:
7815 <http://search.cpan.org/dist/Spreadsheet-WriteExcel>.
7816
7817 Spreadsheet::ParseExcel:
7818 <http://search.cpan.org/dist/Spreadsheet-ParseExcel>.
7819
7820 Spreadsheet::XLSX: <http://search.cpan.org/dist/Spreadsheet-XLSX>.
7821
7823 The following people contributed to the debugging, testing or
7824 enhancement of Excel::Writer::XLSX:
7825
7826 Rob Messer of IntelliSurvey gave me the initial prompt to port
7827 Spreadsheet::WriteExcel to the XLSX format. IntelliSurvey
7828 (<http://www.intellisurvey.com>) also sponsored large files
7829 optimisations and the charting feature.
7830
7831 Bariatric Advantage (<http://www.bariatricadvantage.com>) sponsored
7832 work on chart formatting.
7833
7834 Eric Johnson provided the ability to use secondary axes with charts.
7835 Thanks to Foxtons (<http://foxtons.co.uk>) for sponsoring this work.
7836
7837 BuildFax (<http://www.buildfax.com>) sponsored the Tables feature and
7838 the Chart point formatting feature.
7839
7841 Because this software is licensed free of charge, there is no warranty
7842 for the software, to the extent permitted by applicable law. Except
7843 when otherwise stated in writing the copyright holders and/or other
7844 parties provide the software "as is" without warranty of any kind,
7845 either expressed or implied, including, but not limited to, the implied
7846 warranties of merchantability and fitness for a particular purpose. The
7847 entire risk as to the quality and performance of the software is with
7848 you. Should the software prove defective, you assume the cost of all
7849 necessary servicing, repair, or correction.
7850
7851 In no event unless required by applicable law or agreed to in writing
7852 will any copyright holder, or any other party who may modify and/or
7853 redistribute the software as permitted by the above licence, be liable
7854 to you for damages, including any general, special, incidental, or
7855 consequential damages arising out of the use or inability to use the
7856 software (including but not limited to loss of data or data being
7857 rendered inaccurate or losses sustained by you or third parties or a
7858 failure of the software to operate with any other software), even if
7859 such holder or other party has been advised of the possibility of such
7860 damages.
7861
7863 The Perl Artistic Licence <http://dev.perl.org/licenses/artistic.html>.
7864
7866 John McNamara jmcnamara@cpan.org
7867
7869 Copyright MM-MMXXI, John McNamara.
7870
7871 All Rights Reserved. This module is free software. It may be used,
7872 redistributed and/or modified under the same terms as Perl itself.
7873
7874
7875
7876perl v5.36.0 2023-01-20 Excel::Writer::XLSX(3)