library(openxlsx2)
<- wb_workbook()
wb <- create_dxfs_style(font_color = wb_colour(hex = "FF9C0006"), bgFill = wb_colour(hex = "FFFFC7CE"))
negStyle <- create_dxfs_style(font_color = wb_colour(hex = "FF006100"), bgFill = wb_colour(hex = "FFC6EFCE"))
posStyle $styles_mgr$add(negStyle, "negStyle")
wb$styles_mgr$add(posStyle, "posStyle") wb
$add_worksheet("cellIs")
wb$add_data("cellIs", -5:5)
wb$add_data("cellIs", LETTERS[1:11], startCol = 2)
wb$add_conditional_formatting(
wb"cellIs",
cols = 1,
rows = 1:11,
rule = "!=0",
style = "negStyle"
)$add_conditional_formatting(
wb"cellIs",
cols = 1,
rows = 1:11,
rule = "==0",
style = "posStyle"
)
$add_worksheet("Moving Row")
wb$add_data("Moving Row", -5:5)
wb$add_data("Moving Row", LETTERS[1:11], startCol = 2)
wb$add_conditional_formatting(
wb"Moving Row",
cols = 1:2,
rows = 1:11,
rule = "$A1<0",
style = "negStyle"
)$add_conditional_formatting(
wb"Moving Row",
cols = 1:2,
rows = 1:11,
rule = "$A1>0",
style = "posStyle"
)
$add_worksheet("Moving Col")
wb$add_data("Moving Col", -5:5)
wb$add_data("Moving Col", LETTERS[1:11], startCol = 2)
wb$add_conditional_formatting(
wb"Moving Col",
cols = 1:2,
rows = 1:11,
rule = "A$1<0",
style = "negStyle"
)$add_conditional_formatting(
wb"Moving Col",
cols = 1:2,
rows = 1:11,
rule = "A$1>0",
style = "posStyle"
)
$add_worksheet("Dependent on")
wb$add_data("Dependent on", -5:5)
wb$add_data("Dependent on", LETTERS[1:11], startCol = 2)
wb$add_conditional_formatting(
wb"Dependent on",
cols = 1:2,
rows = 1:11,
rule = "$A$1 < 0",
style = "negStyle"
)$add_conditional_formatting(
wb"Dependent on",
cols = 1:2,
rows = 1:11,
rule = "$A$1>0",
style = "posStyle"
)
$add_data("Dependent on", data.frame(x = 1:10, y = runif(10)), startRow = 15)
wb$add_conditional_formatting(
wb"Dependent on",
cols = 1,
rows = 16:25,
rule = "B16<0.5",
style = "negStyle"
)$add_conditional_formatting(
wb"Dependent on",
cols = 1,
rows = 16:25,
rule = "B16>=0.5",
style = "posStyle"
)
$add_worksheet("Duplicates")
wb$add_data("Duplicates", sample(LETTERS[1:15], size = 10, replace = TRUE))
wb$add_conditional_formatting(
wb"Duplicates",
cols = 1,
rows = 1:10,
type = "duplicatedValues"
)
<- function(x) paste(sample(LETTERS, 10), collapse = "-")
fn $add_worksheet("containsText")
wb$add_data("containsText", sapply(1:10, fn))
wb$add_conditional_formatting(
wb"containsText",
cols = 1,
rows = 1:10,
type = "contains",
rule = "A"
)$add_worksheet("notcontainsText") wb
<- function(x) paste(sample(LETTERS, 10), collapse = "-")
fn $add_data("notcontainsText", sapply(1:10, fn))
wb$add_conditional_formatting(
wb"notcontainsText",
cols = 1,
rows = 1:10,
type = "notContainsText",
rule = "A"
)
<- function(x) paste(sample(LETTERS, 10), collapse = "-")
fn $add_worksheet("beginsWith")
wb$add_data("beginsWith", sapply(1:100, fn))
wb$add_conditional_formatting(
wb"beginsWith",
cols = 1,
rows = 1:100,
type = "beginsWith",
rule = "A"
)
<- function(x) paste(sample(LETTERS, 10), collapse = "-")
fn $add_worksheet("endsWith")
wb$add_data("endsWith", sapply(1:100, fn))
wb$add_conditional_formatting(
wb"endsWith",
cols = 1,
rows = 1:100,
type = "endsWith",
rule = "A"
)
Yep, that is a color scale image.
<- read_xlsx(system.file("extdata", "readTest.xlsx", package = "openxlsx2"), sheet = 5)
df $add_worksheet("colorScale", zoom = 30)
wb$add_data("colorScale", df, colNames = FALSE) ## write data.frame wb
Rule is a vector or colors of length 2 or 3 (any hex color or any of
colors()
). If rule is NULL
, min and max of
cells is used. Rule must be the same length as style or L.
$add_conditional_formatting(
wb"colorScale",
cols = seq_along(df),
rows = seq_len(nrow(df)),
style = c("black", "white"),
rule = c(0, 255),
type = "colorScale"
)$set_col_widths("colorScale", cols = seq_along(df), widths = 1.07)
wb$set_row_heights("colorScale", rows = seq_len(nrow(df)), heights = 7.5) wb
$add_worksheet("databar")
wb## Databars
$add_data("databar", -5:5, startCol = 1)
wb<- wb_add_conditional_formatting(
wb
wb,"databar",
cols = 1,
rows = 1:11,
type = "dataBar"
## Default colours
)
$add_data("databar", -5:5, startCol = 3)
wb<- wb_add_conditional_formatting(
wb
wb,"databar",
cols = 3,
rows = 1:11,
type = "dataBar",
params = list(
showValue = FALSE,
gradient = FALSE
)## Default colours
)
$add_data("databar", -5:5, startCol = 5)
wb<- wb_add_conditional_formatting(
wb
wb,"databar",
cols = 5,
rows = 1:11,
type = "dataBar",
style = c("#a6a6a6"),
params = list(showValue = FALSE)
)
$add_data("databar", -5:5, startCol = 7)
wb<- wb_add_conditional_formatting(
wb
wb,"databar",
cols = 7,
rows = 1:11,
type = "dataBar",
style = c("red"),
params = list(
showValue = TRUE,
gradient = FALSE
)
)
# custom color
$add_data("databar", -5:5, startCol = 9)
wb<- wb_add_conditional_formatting(
wb
wb,"databar",
cols = 9,
rows = 1:11,
type = "dataBar",
style = c("#a6a6a6", "#a6a6a6"),
params = list(showValue = TRUE, gradient = FALSE)
)
# with rule
$add_data(x = -5:5, startCol = 11)
wb<- wb_add_conditional_formatting(
wb
wb,"databar",
cols = 11,
rows = 1:11,
type = "dataBar",
rule = c(0, 5),
style = c("#a6a6a6", "#a6a6a6"),
params = list(showValue = TRUE, gradient = FALSE)
)
Highlight cells in interval [-2, 2]
$add_worksheet("between")
wb$add_data("between", -5:5)
wb$add_conditional_formatting(
wb"between",
cols = 1,
rows = 1:11,
type = "between",
rule = c(-2, 2)
)$add_worksheet("topN") wb
$add_data("topN", data.frame(x = 1:10, y = rnorm(10))) wb
Highlight top 5 values in column x
$add_conditional_formatting(
wb"topN",
cols = 1,
rows = 2:11,
style = "posStyle",
type = "topN",
params = list(rank = 5)
)
Highlight top 20 percentage in column y
$add_conditional_formatting(
wb"topN",
cols = 2,
rows = 2:11,
style = "posStyle",
type = "topN",
params = list(rank = 20, percent = TRUE)
)$add_worksheet("bottomN") wb
$add_data("bottomN", data.frame(x = 1:10, y = rnorm(10))) wb
Highlight bottom 5 values in column x
$add_conditional_formatting(
wb"bottomN",
cols = 1,
rows = 2:11,
style = "negStyle",
type = "bottomN",
params = list(rank = 5)
)
Highlight bottom 20 percentage in column y
$add_conditional_formatting(
wb"bottomN",
cols = 2,
rows = 2:11,
style = "negStyle",
type = "bottomN",
params = list(rank = 20, percent = TRUE)
)$add_worksheet("logical operators") wb
You can use Excels logical Operators
$add_data("logical operators", 1:10)
wb$add_conditional_formatting(
wb"logical operators",
cols = 1,
rows = 1:10,
rule = "OR($A1=1,$A1=3,$A1=5,$A1=7)"
)