I am trying to change the default cell style for an entire Excel workbook (XSSF
) using Apache POI
. This should be applied to new cells a user might create (after the workbook has been saved by POI
). I am trying to do this by calling workbook.getCellStyleAt(0)
-- which I understand to be the default style for the workbook -- and then by modifying this style to what I want for the new default.
This works when I read in an existing XSLX
file (a "template" file) and modify the default style. But when I create a new XSLX
file from scratch using POI
, it does not work.
When stepping through using a debugger I can see that, when using a "template" file, there is a "theme" assigned to the cell style at index 0 (probably because the template file was originally created using Excel). But when creating a file from scratch (using POI
), the cell style at index 0 has a null theme. (This might be a factor in why this works using one approach but not the other.)
Any suggestions on how to reliably change the default cell style for a workbook (XSSF
) regardless of how the workbook was originally created? Thanks!
There are two possibilities to achieve this with XSSF.
First: If you select all cells in a XSSF worksheet in Excel and apply a style to them, then a cols
element is added to the sheet with a style definition for all columns:
<cols>
<col min="1" max="16384" style="1"/>
</cols>
This can be achieved with apache poi like so:
import org.apache.poi.ss.usermodel.*;
import org.apache.poi.xssf.usermodel.*;
import java.io.FileOutputStream;
import java.io.IOException;
class ExcelCellStyleAllColumns
{
public static void main(String[] args) {
try {
Workbook wb = new XSSFWorkbook();
Font font = wb.createFont();
font.setFontHeightInPoints((short)24);
font.setFontName("Courier New");
font.setItalic(true);
font.setBold(true);
CellStyle style = wb.createCellStyle();
style.setFont(font);
Sheet sheet = wb.createSheet();
org.openxmlformats.schemas.spreadsheetml.x2006.main.CTCol cTCol =
((XSSFSheet)sheet).getCTWorksheet().getColsArray(0).addNewCol();
cTCol.setMin(1);
cTCol.setMax(16384);
cTCol.setWidth(12.7109375);
cTCol.setStyle(style.getIndex());
Row row = sheet.createRow(0);
Cell cell = row.createCell(0);
cell.setCellValue("test");
cell.setCellStyle(style);
FileOutputStream os = new FileOutputStream("ExcelCellStyleAllColumns.xlsx");
wb.write(os);
os.close();
} catch (IOException ioex) {
}
}
}
This will change the default cell style of all cells in the sheet.
Second: You can modify the style definitions of the normal cell style like so:
import org.apache.poi.ss.usermodel.*;
import org.apache.poi.xssf.usermodel.*;
import java.io.FileOutputStream;
import java.io.IOException;
class ExcelDefaultCellStyle {
public static void main(String[] args) {
try {
Workbook wb = new XSSFWorkbook();
Font font = wb.getFontAt((short)0);
font.setFontHeightInPoints((short)24);
font.setFontName("Courier New");
((XSSFFont)font).setFamily(3);
((XSSFFont)font).setScheme(FontScheme.NONE);
font.setItalic(true);
font.setBold(true);
CellStyle style = wb.getCellStyleAt(0);
style.setVerticalAlignment(CellStyle.VERTICAL_CENTER);
style.setWrapText(true);
((XSSFWorkbook) wb).getStylesSource().getCTStylesheet().addNewCellStyles().addNewCellStyle().setXfId(0);
((XSSFCellStyle)style).getStyleXf().addNewAlignment().setVertical(
org.openxmlformats.schemas.spreadsheetml.x2006.main.STVerticalAlignment.CENTER);
((XSSFCellStyle)style).getStyleXf().getAlignment().setWrapText(true);
Sheet sheet = wb.createSheet();
Row row = sheet.createRow(0);
Cell cell = row.createCell(0);
cell.setCellValue("test");
FileOutputStream os = new FileOutputStream("ExcelDefaultCellStyle.xlsx");
wb.write(os);
os.close();
} catch (IOException ioex) {
}
}
}
This will change the default cell style of all cells in the whole workbook.
The XML in styles.xml
shows:
<cellStyleXfs count="1">
<xf numFmtId="0" fontId="0" fillId="0" borderId="0">
<alignment vertical="center" wrapText="true"/>
</xf>
</cellStyleXfs>
<cellXfs count="1">
<xf numFmtId="0" fontId="0" fillId="0" borderId="0" xfId="0">
<alignment vertical="center" wrapText="true"/>
</xf>
</cellXfs>
<cellStyles>
<cellStyle xfId="0"/>
</cellStyles>
As you see the normal cell style is the first one in cellStyles
. It refers to xfId="0"
which refers to numFmtId="0"
fontId="0"
fillId="0"
borderId="0"
. That means the very first definitions of number format, font, fill format and border is used in normal cell style.