| Type(s) | Query | Notes |
57 | | AbstractRule |
58 |
59 | ```sql
60 | SELECT
61 | COUNT({ar:pk}),
62 | MIN({ar:modifiedtime}) AS "oldest",
63 | MAX({ar:modifiedtime}) AS "newest"
64 | FROM
65 | {AbstractRule AS ar},
66 | {RuleStatus AS rs}
67 | WHERE
68 | {ar:status} = {rs:pk}
69 | AND {rs:code} = 'PUBLISHED'
70 | AND {ar:enddate} IS NOT NULL
71 | AND {ar:enddate} < getutcdate()
72 | ```
73 |
74 | |
75 |
76 | Are there any outdated rules? i.e rules that aren't valid anymore because their enddate is in the past.
77 |
78 | Warning: change `getutcdate()` to your DBMS (for HANA/MySQL: `now()` )
79 |
80 | |
81 | | BusinessProcess |
82 |
83 | ```sql
84 | SELECT
85 | {p:processDefinitionName},
86 | {s:code} AS "status",
87 | COUNT({p:pk}) AS "total",
88 | MIN({p:modifiedTime}) AS "oldest",
89 | MAX({p:modifiedTime}) AS "newest"
90 | FROM
91 | {BusinessProcess AS p
92 | LEFT JOIN
93 | ProcessState AS s
94 | ON {p:state} = {s:pk} }
95 | GROUP BY
96 | {p:processDefinitionName},
97 | {s:code}
98 | ORDER BY
99 | "total" DESC
100 | ```
101 |
102 | |
103 |
104 | Are there too many (let's say > 1000) or very old BusinessProcess in your system?
105 |
106 | Also, if a lot of processes are stuck in "RUNNING" / "WAITING", you have to investigate what's wrong.
107 | (What is causing your processes to be stuck?)
108 |
109 | |
110 | | Cart |
111 |
112 | ```sql
113 | SELECT
114 | {b:uid} AS "BaseSite",
115 | {u:uid} AS "USER",
116 | CASE
117 | WHEN
118 | {c:saveTime} IS NULL
119 | THEN
120 | 'regular'
121 | ELSE
122 | 'saved'
123 | END
124 | AS "cart type",
125 | COUNT({c:pk}) AS "total",
126 | MIN({c:modifiedtime}) AS "oldest",
127 | MAX({c:modifiedtime}) AS "newest"
128 | FROM
129 | { Cart AS c
130 | LEFT JOIN
131 | USER AS u
132 | ON {c:user} = {u:pk}
133 | LEFT JOIN
134 | BaseSite AS b
135 | ON {c:site} = {b:pk} }
136 | GROUP BY
137 | {b:uid}, {u:uid},
138 | CASE
139 | WHEN
140 | {c:saveTime} IS NULL
141 | THEN
142 | 'regular'
143 | ELSE
144 | 'saved'
145 | END
146 | ORDER BY
147 | "total" DESC
148 | ```
149 |
150 | |
151 |
152 | - Are there excessive amount of carts per site or per user?
153 | - Too many saved carts?
154 | - Stale (= old) carts?
155 |
156 | |
157 | | CronJob (auto-generated) |
158 |
159 | ```sql
160 | SELECT
161 | {t:code} AS "CronJob Type",
162 | COUNT({c:pk}) AS "total",
163 | MIN({c:modifiedtime}) AS "oldest",
164 | MAX({c:modifiedtime}) AS "newest"
165 | FROM
166 | {CronJob AS c
167 | JOIN
168 | ComposedType AS t
169 | ON {c:itemtype} = {t:pk}
170 | LEFT JOIN
171 | TRIGGER AS trg
172 | ON {trg:cronjob} = {c:pk} }
173 | WHERE
174 | {trg:pk} IS NULL
175 | AND {c:code} LIKE '00%'
176 | AND {t:code} IN
177 | (
178 | 'ImpExImportCronJob',
179 | 'CatalogVersionSyncCronJob',
180 | 'SolrIndexerCronJob'
181 | )
182 | GROUP BY
183 | {t:code}
184 | ORDER BY
185 | "total" DESC
186 | ```
187 |
188 | |
189 |
190 | Are there too many (>10) outdated, auto-geneated jobs in your system?
191 |
192 | |
193 | | CronJobHistory |
194 |
195 | ```sql
196 | SELECT
197 | {cj:code},
198 | COUNT({h:pk}) AS "total",
199 | MIN({h:modifiedtime}) AS "oldest",
200 | MAX({h:modifiedtime}) AS "newest"
201 | FROM
202 | {cronjobhistory AS h
203 | JOIN
204 | cronjob AS cj
205 | ON {h:cronjob} = {cj:pk} }
206 | GROUP BY
207 | {cj:code}
208 | ORDER BY
209 | "total" DESC
210 | ```
211 |
212 | |
213 |
214 | Is there any job with > 50 histories and/or histories older than an hour?
215 |
216 | This cleanup is enabled by default in recent SAP Commerce patch releases, so this query shouldn't find anything.
217 |
218 | |
219 | | EmailMessage |
220 |
221 | ```sql
222 | SELECT
223 | {bp:processDefinitionName} AS "source",
224 | {m:sent},
225 | COUNT({m:pk}) AS "total",
226 | MIN({m:modifiedtime}) AS "oldest",
227 | MAX({m:modifiedtime}) AS "newest"
228 | FROM
229 | {EmailMessage AS m
230 | LEFT JOIN
231 | BusinessProcess AS bp
232 | ON {m:process} = {bp:pk} }
233 | GROUP BY
234 | {bp:processDefinitionName},
235 | {m:sent}
236 | ORDER BY
237 | "total" DESC
238 | ```
239 |
240 | |
241 |
242 | - Are there more than a handful sent/unsent messages?
243 | - Are there messages that do not belong to any process?
244 |
245 | |
246 | | ImpExImportCronJob (distributed impex) |
247 |
248 | ```sql
249 | SELECT
250 | {s:code} AS "status",
251 | COUNT({i:pk}) AS "total",
252 | MIN({i:modifiedtime}) AS "oldest",
253 | MAX({i:modifiedtime}) AS "newest"
254 | FROM
255 | {ImpExImportCronJob AS i
256 | LEFT JOIN
257 | CronJobStatus AS s
258 | ON {i:status} = {s:pk} }
259 | WHERE
260 | {i:code} LIKE 'distributed-impex-%'
261 | GROUP BY
262 | {s:code}
263 | ```
264 |
265 | |
266 |
267 | - More than ~10 `FINISHED` distributed impex jobs?
268 | - More than a few `PAUSED` jobs? You may have a faulty distributed impex script.
269 |
270 | |
271 | | ImpexMedia |
272 |
273 | ```sql
274 | SELECT
275 | COUNT(*)
276 | FROM
277 | {ImpexMedia AS i}
278 | WHERE
279 | (
280 | {i:code} LIKE '0_______'
281 | OR {i:code} LIKE
282 | 'generated impex media - %'
283 | )
284 | ```
285 |
286 | |
287 |
288 | Are there more than a handful (>100) of generated impex medias?
289 |
290 | |
291 | | ImportBatchContent |
292 |
293 | ```sql
294 | SELECT
295 | COUNT({c:pk}) AS "total",
296 | MIN({c:modifiedTime}) AS "oldest",
297 | MAX({c:modifiedTime}) AS "newest"
298 | FROM
299 | {ImportBatchContent AS c
300 | LEFT JOIN
301 | ImportBatch AS b
302 | ON {b:importContentCode} = {c:code} }
303 | WHERE
304 | {b:pk} IS NULL
305 | ```
306 |
307 | |
308 |
309 | Are there any left-over distributed import batches?
310 |
311 | |
312 | | LogFile |
313 |
314 | ```sql
315 | SELECT
316 | COALESCE({cj:code}, ''),
317 | COUNT({l:pk}) AS "total",
318 | MIN({l:modifiedtime}) AS "oldest",
319 | MAX({l:modifiedtime}) AS "newest"
320 | FROM
321 | {LogFile AS l
322 | LEFT JOIN
323 | CronJob AS cj
324 | ON {l:owner} = {cj:pk} }
325 | GROUP BY
326 | {cj:code}
327 | ORDER BY
328 | "total" DESC
329 | ```
330 |
331 | |
332 |
333 | Are there are cronjob with more than ~10 logs and/or logs older than 14 days?
334 | (those are default values for log file retention)
335 |
336 | |
337 | | ProcessTaskLog |
338 |
339 | ```sql
340 | -- Query tested with MS SQL
341 | -- Adjust the date calculation for
342 | -- other databases
343 | SELECT
344 | COUNT({l:pk}) AS "total",
345 | MIN({l:modifiedtime}) AS "oldest",
346 | MAX({l:modifiedtime}) AS "newest"
347 | FROM
348 | {ProcessTaskLog AS l}
349 | WHERE
350 | {l:creationTime} < DATEADD(
351 | MONTH,
352 | -2,
353 | GETUTCDATE()
354 | )
355 | ```
356 |
357 | |
358 |
359 | We recommend customer to BusinessProcess cleanup, which will eventually take care of TaskLogs cleanup.
360 | There might be the few scenarios for ProcessTaskLog cleanup:
361 | 1. The customer wants to keep the BusinessProcess for reporting, although we don't recommend it.
362 | 1. The customer might be using the custom task without any business process.
363 |
364 | |
365 | | SavedValues,SavedValueEntry |
366 |
367 | ```sql
368 | -- total SavedValue / SavedValueEntry
369 | SELECT
370 | *
371 | FROM
372 | (
373 | {{
374 | SELECT
375 | 'SavedValues' AS "type",
376 | COUNT({s:pk}) AS "total"
377 | FROM
378 | {savedvalues AS s} }}
379 | UNION ALL
380 | {{
381 | SELECT
382 | 'SavedValueEntry' AS "type",
383 | COUNT({e:pk}) AS "total"
384 | FROM
385 | {savedvalueentry AS e} }}
386 | )
387 | summary
388 |
389 | -- SavedValues per item
390 | SELECT
391 | {s:modifiedItem} AS "item",
392 | COUNT({s:pk}) AS "total",
393 | MIN({s:modifiedtime}) AS "oldest",
394 | MAX({s:modifiedtime}) AS "newest"
395 | FROM
396 | {SavedValues AS s }
397 | GROUP BY
398 | {s:modifiedItem}
399 | ORDER BY
400 | "total" DESC
401 |
402 | -- orphaned SavedValueEntry
403 | -- (there shouldn't be any)
404 | SELECT
405 | COUNT({e:pk}) AS "total",
406 | MIN({e:modifiedtime}) AS "oldest",
407 | MAX({e:modifiedtime}) AS "newest"
408 | FROM
409 | {SavedValueEntry AS e
410 | LEFT JOIN
411 | SavedValues AS s
412 | ON {e:parent} = {s:pk} }
413 | WHERE
414 | {s:pk} IS NULL
415 | ```
416 |
417 | |
418 |
419 | A lot of those items accumulated over the project lifetime.
420 | If possible, disable storing saved values. (`hmc.storing.modifiedvalues.size=0`)
421 |
422 | |
423 | | SolrIndexOperation |
424 |
425 | ```sql
426 | SELECT
427 | {i:qualifier},
428 | COUNT({o:pk}) AS "total",
429 | MIN({o:modifiedTime}) AS "oldest",
430 | MAX({o:modifiedTime}) AS "newest"
431 | FROM
432 | {SolrIndexOperation AS o
433 | LEFT JOIN
434 | SolrIndex AS i
435 | ON {o:index} = {i:pk} }
436 | GROUP BY
437 | {i:qualifier}
438 | ORDER BY
439 | "total" DESC
440 | ```
441 |
442 | |
443 |
444 | Too many solr operations (more than ~100 per index)?
445 |
446 | |
447 | | StoredHttpSession |
448 |
449 | ```sql
450 | SELECT
451 | COUNT({s:pk}) AS "total",
452 | MIN({s:modifiedtime}) AS "oldest",
453 | MAX({s:modifiedtime}) AS "newest"
454 | FROM
455 | {StoredHttpSession AS s}
456 | ```
457 |
458 | |
459 |
460 | Excessive amount of session? This is hard to generalize as it highly depends on your site's traffic, but if you are near or over 5 digits, it's probably too much.
461 |
462 | Simarly, stale sessions (e.g older than a day) don't need to be retained.
463 |
464 | |
465 | | TaskCondition |
466 |
467 | ```sql
468 | SELECT
469 | COUNT({tc:pk}),
470 | MIN({tc:modifiedtime}) AS "oldest",
471 | MAX({tc:modifiedtime}) AS "newest"
472 | FROM
473 | {TaskCondition AS tc }
474 | WHERE
475 | {tc:task} IS NULL
476 | ```
477 |
478 | |
479 |
480 | Is there an excessive amount of ["premature events"](https://help.sap.com/docs/SAP_COMMERCE_CLOUD_PUBLIC_CLOUD/aa417173fe4a4ba5a473c93eb730a417/7e8ff9d7653f43e8890bc8eb395d52a7.html?locale=en-US#premature-events)? Or very old (older than a a few weeks) events?
481 |
482 | |
483 |
484 |
485 |
486 |
487 | ## Support
488 |
489 | Please open an [issue] describing your problem or your feature request.
490 |
491 | ## Contributing
492 |
493 | Any and all pull requests are welcome.\
494 | Please describe your change and the motiviation behind it.
495 |
496 | [issue]: https://github.com/sap-commerce-tools/sanecleanup/issues
497 | [article]: https://blogs.sap.com/2023/09/20/data-maintenance-and-cleanup-of-a-sap-commerce-cloud-project/
498 | [one]: https://blogs.sap.com/2023/09/20/data-maintenance-and-cleanup-of-a-sap-commerce-cloud-project/#DataMaintenanceandCleanup-One-timeCleanUp
499 | [stored]: https://help.sap.com/docs/SAP_COMMERCE_CLOUD_PUBLIC_CLOUD/aa417173fe4a4ba5a473c93eb730a417/076cde47206048b9ada3fa0d336c1060.html?locale=en-US
500 | [stored-kill]: https://blogs.sap.com/2023/09/20/data-maintenance-and-cleanup-of-a-sap-commerce-cloud-project/#DataMaintenanceandCleanup-SavedValues
501 |
--------------------------------------------------------------------------------
/excessive-platform-types.groovy:
--------------------------------------------------------------------------------
1 | import de.hybris.platform.catalog.model.CatalogUnawareMediaModel
2 | import de.hybris.platform.servicelayer.search.FlexibleSearchQuery
3 | import groovy.transform.Field
4 |
5 | import java.nio.charset.StandardCharsets
6 | import java.time.ZonedDateTime
7 |
8 | de.hybris.platform.tx.Transaction.current().commit()
9 |
10 | def @Field now = ZonedDateTime.now()
11 | def @Field builder = new StringBuilder()
12 | def @Field resultMedia = modelService.create(CatalogUnawareMediaModel.class)
13 | def @Field fsq = spring.getBean("flexibleSearchService")
14 | def @Field configuration = spring.getBean("configurationService").configuration
15 |
16 | resultMedia.code = "sanecleanup-check-${now.toInstant()}"
17 | resultMedia.mime = "text/plain"
18 | modelService.save(resultMedia)
19 |
20 |
21 | // java.util.Date is used in queries for maximum JDBC compatibility
22 | // -> helper method to convert them to Instant
23 | def dateToInstant(input) {
24 | def result = input
25 | if (input instanceof Collection) {
26 | result = input.collect { it instanceof Date ? it.toInstant() : it }
27 | } else if (input instanceof Date) {
28 | result = input.toInstant()
29 | }
30 | return result
31 | }
32 |
33 | def info(message) {
34 | builder << message << "\n"
35 | }
36 |
37 | def error(message) {
38 | builder << "ERROR - " << message << "\n"
39 | }
40 |
41 | def warning(message) {
42 | builder << "WARNING - " << message << "\n"
43 | }
44 |
45 | // --- TYPE CHECKS ---
46 |
47 | def TYPE_CHECKS = [
48 | "AbstractRule" : [
49 | "query" : """SELECT
50 | COUNT({ar:pk}),
51 | MIN({ar:modifiedtime}) AS "oldest",
52 | MAX({ar:modifiedtime}) AS "newest"
53 | FROM
54 | {AbstractRule AS ar},
55 | {RuleStatus AS rs}
56 | WHERE
57 | {ar:status} = {rs:pk}
58 | AND {rs:code} = 'PUBLISHED'
59 | AND {ar:enddate} IS NOT NULL
60 | AND {ar:enddate} < ?now""",
61 | 'parameters' : { ['now': Date.from(now.toInstant())] },
62 | 'resultClassList': [Long.class, Date.class, Date.class],
63 | 'check' : { r ->
64 | def summary = r.result.collect { dateToInstant(it) }[0]
65 | if (summary[0] > 0) {
66 | error("Outdated rules found! Count: ${summary[0]} | Oldest: ${summary[1]} | Newest: ${summary[2]}")
67 | }
68 | }
69 | ],
70 |
71 | "BusinessProcess" : [
72 | "query" : """SELECT
73 | {p:processDefinitionName},
74 | {s:code} AS "status",
75 | COUNT({p:pk}) AS "total",
76 | MIN({p:modifiedTime}) AS "oldest",
77 | MAX({p:modifiedTime}) AS "newest"
78 | FROM
79 | {BusinessProcess AS p
80 | LEFT JOIN
81 | ProcessState AS s
82 | ON {p:state} = {s:pk} }
83 | WHERE
84 | {p:creationtime} <= ?max
85 | GROUP BY
86 | {p:processDefinitionName},
87 | {s:code}
88 | ORDER BY
89 | "total" DESC""",
90 | 'parameters' : {
91 | def cutoffDate = Date.from(now.minusMonths(6).toInstant())
92 | ['max': cutoffDate]
93 | },
94 | 'resultClassList': [String.class, String.class, Long.class, Date.class, Date.class],
95 | 'check' : { r ->
96 | def allResults = r.result.collect { dateToInstant(it) }
97 | if (allResults) {
98 | def total = allResults.collect { it[2] }.sum()
99 | def msg = "Found ${total} outdated BusinessProcess (older than 6 month)!\n"
100 | msg += "Process\tCount\tStatus\tOldest\tNewest"
101 | msg += allResults.collect {
102 | "${it[0]}\t${it[1]}\t${it[2]}\t${it[3]}\t${it[4]}"
103 | }.join("\n")
104 | warning(msg)
105 | }
106 | }
107 | ],
108 |
109 | "Cart (orphaned)" : [
110 | 'query' : """
111 | SELECT count(1)
112 | FROM
113 | { Cart AS c
114 | LEFT JOIN
115 | USER AS u
116 | ON {c:user} = {u:pk}
117 | LEFT JOIN
118 | BaseSite AS b
119 | ON {c:site} = {b:pk} }
120 | WHERE {u:uid} IS NULL
121 | OR {b:uid} IS NULL
122 | """,
123 | 'resultClassList': [Long.class],
124 | 'check' : { r ->
125 | def total = r.result[0]
126 | if (total > 0) {
127 | error("Found ${total} carts not belonging to a user or a base site! -> delete")
128 | }
129 | }
130 | ],
131 | "Cart (old, anonymous)" : [
132 | 'query' : """
133 | SELECT count(1)
134 | FROM
135 | { Cart AS c
136 | LEFT JOIN
137 | USER AS u
138 | ON {c:user} = {u:pk}
139 | LEFT JOIN
140 | BaseSite AS b
141 | ON {c:site} = {b:pk} }
142 | WHERE {c:saveTime} IS NULL
143 | AND {u:uid} = 'anonymous'
144 | AND {c:modifiedtime} <= ?max
145 | """,
146 | 'resultClassList': [Long.class],
147 | 'parameters' : {
148 | def cutoffDate = Date.from(now.minusWeeks(2).toInstant())
149 | ['max': cutoffDate]
150 | },
151 | 'check' : { r ->
152 | def total = r.result[0]
153 | if (total > 0) {
154 | error("Found ${total} anonymous carts older then two weeks! -> delete")
155 | }
156 | }
157 | ],
158 | "Cart (old, regular)" : [
159 | 'query' : """
160 | SELECT count(1)
161 | FROM
162 | { Cart AS c
163 | LEFT JOIN
164 | USER AS u
165 | ON {c:user} = {u:pk}
166 | LEFT JOIN
167 | BaseSite AS b
168 | ON {c:site} = {b:pk} }
169 | WHERE {c:saveTime} IS NULL
170 | AND ( {u:uid} IS NOT NULL AND {u:uid} <> 'anonymous' )
171 | AND {c:modifiedtime} <= ?max
172 | """,
173 | 'resultClassList': [Long.class],
174 | 'parameters' : {
175 | def cutoffDate = Date.from(now.minusWeeks(4).toInstant())
176 | ['max': cutoffDate]
177 | },
178 | 'check' : { r ->
179 | def total = r.result[0]
180 | if (total > 0) {
181 | error("Found ${total} user carts older then four weeks! -> delete")
182 | }
183 | }
184 | ],
185 | "Cart (old, saved)" : [
186 | 'query' : """
187 | SELECT count(1)
188 | FROM
189 | { Cart AS c
190 | LEFT JOIN
191 | USER AS u
192 | ON {c:user} = {u:pk}
193 | LEFT JOIN
194 | BaseSite AS b
195 | ON {c:site} = {b:pk} }
196 | WHERE {c:saveTime} IS NOT NULL
197 | AND {c:modifiedtime} <= ?max
198 | """,
199 | 'resultClassList': [Long.class],
200 | 'parameters' : {
201 | def cutoffDate = Date.from(now.minusMonths(6).toInstant())
202 | ['max': cutoffDate]
203 | },
204 | 'check' : { r ->
205 | def total = r.result[0]
206 | if (total > 0) {
207 | error("Found ${total} saved carts then six months! -> delete")
208 | }
209 | }
210 | ],
211 |
212 | "CronJobs" : [
213 | 'query' : """
214 | SELECT
215 | {t:code} AS "CronJob Type",
216 | COUNT(1) AS "total",
217 | MIN({c:modifiedtime}) AS "oldest",
218 | MAX({c:modifiedtime}) AS "newest"
219 | FROM
220 | {CronJob AS c
221 | JOIN
222 | ComposedType AS t
223 | ON {c:itemtype} = {t:pk}
224 | LEFT JOIN
225 | TRIGGER AS trg
226 | ON {trg:cronjob} = {c:pk} }
227 | WHERE
228 | {trg:pk} IS NULL
229 | AND ( {c:code} LIKE '00%' OR {c:code} LIKE 'distributed-impex-%' )
230 | AND {t:code} IN
231 | (
232 | 'ImpExImportCronJob',
233 | 'CatalogVersionSyncCronJob',
234 | 'SolrIndexerCronJob'
235 | )
236 | GROUP BY
237 | {t:code}
238 | ORDER BY
239 | "total" DESC
240 | """,
241 | 'resultClassList': [String.class, Long.class, Date.class, Date.class],
242 | 'check' : { r ->
243 | def allResults = r.result.collect { dateToInstant(it) }
244 | allResults = allResults.collect { [['type', 'count', 'oldest', 'newest'], it].transpose().collectEntries() }
245 | def total = allResults.collect { it.count }.sum()
246 | if (total > 0) {
247 | def msg = "${total} autogenerated Cronjobs without triggers detected -> delete\n"
248 | msg += "Type\tTotal\tOldest\tNewest\n"
249 | msg += allResults
250 | .collect { "${it.type}\t${it.count}\t${it.oldest}\t${it.newest}" }
251 | .join("\n")
252 | error(msg)
253 | }
254 | }
255 | ],
256 |
257 | "CronJobHistory" : [
258 | 'query' : """
259 | SELECT
260 | {cj:code},
261 | COUNT({h:pk}) AS "total",
262 | MIN({h:modifiedtime}) AS "oldest",
263 | MAX({h:modifiedtime}) AS "newest"
264 | FROM
265 | {cronjobhistory AS h
266 | JOIN
267 | cronjob AS cj
268 | ON {h:cronjob} = {cj:pk} }
269 | GROUP BY
270 | {cj:code}
271 | HAVING COUNT({h:pk}) > 1
272 | AND MIN({h:modifiedtime}) <= ?maxage
273 | ORDER BY
274 | "total" DESC
275 | """,
276 | 'parameters' : {
277 | ['maxage': Date.from(now.minusHours(2).toInstant())]
278 | },
279 | 'resultClassList': [String.class, Long.class, Date.class, Date.class],
280 | 'check' : { r ->
281 | def allResults = r.result
282 | if (allResults.isEmpty()) {
283 | return
284 | }
285 | allResults = allResults.collect { dateToInstant(it) }
286 | allResults = allResults.collect { [['cronJob', 'total', 'oldest', 'newest'], it].transpose().collectEntries() }
287 | def total = allResults.collect { it.total }.sum()
288 | error("${total} outdated CronJobHistory detected (Max Age: 2 hours) -> delete")
289 | }
290 | ],
291 |
292 | "EmailMessage (orphan)" : [
293 | 'query' : """
294 | SELECT
295 | COUNT(1)
296 | FROM
297 | {EmailMessage AS m
298 | LEFT JOIN
299 | BusinessProcess AS bp
300 | ON {m:process} = {bp:pk} }
301 | WHERE {bp:pk} IS NULL
302 | """,
303 | 'resultClassList': [Long.class],
304 | 'check' : { r ->
305 | def total = r.result[0]
306 | if (total > 0) {
307 | error("Detect ${total} EmailMessage without a BusinessProcess -> delete")
308 | }
309 | }
310 | ],
311 | "EmailMessage (old)" : [
312 | 'query' : """
313 | SELECT
314 | COUNT(1)
315 | FROM
316 | {EmailMessage AS m }
317 | WHERE {m:modifiedtime} <= ?max
318 | """,
319 | 'parameters' : {
320 | ['max': Date.from(now.minusMonths(6).toInstant())]
321 | },
322 | 'resultClassList': [Long.class],
323 | 'check' : { r ->
324 | def total = r.result[0]
325 | if (total > 0) {
326 | error("""\
327 | Detect ${total} EmailMessage older than 6 months -> delete outdated data and investigate:
328 | - faulty email delivery?
329 | - faulty business process?
330 | - no retention rules for business processes and/or email messages?
331 | """.stripIndent())
332 | }
333 | }
334 | ],
335 | "Distributed ImpExImportCronJob (old, PAUSED)": [
336 | 'query' : """
337 | SELECT
338 | COUNT(1)
339 | FROM
340 | {ImpExImportCronJob AS i
341 | LEFT JOIN
342 | CronJobStatus AS s
343 | ON {i:status} = {s:pk} }
344 | WHERE {i:code} LIKE 'distributed-impex-%'
345 | AND {s:code} = 'PAUSED'
346 | AND {i:modifiedtime} <= ?max
347 | """,
348 | 'parameters' : {
349 | ['max': Date.from(now.minusDays(1).toInstant())]
350 | },
351 | 'resultClassList': [Long.class],
352 | 'check' : { r ->
353 | def total = r.result[0]
354 | if (total > 0) {
355 | error("""\
356 | Detect ${total} PAUSED distributed ImpExImportCronJob older than a day -> investigate:
357 | - faulty distributed impex scripts?
358 | - delete outdated jobs
359 | """.stripIndent())
360 | }
361 | }
362 | ],
363 |
364 | "ImpexMedia (generated)" : [
365 | 'query' : """
366 | SELECT
367 | COUNT(1)
368 | FROM
369 | {ImpexMedia AS i}
370 | WHERE {i:code} LIKE '0_______'
371 | OR {i:code} LIKE 'generated impex media - %'
372 |
373 | """,
374 | 'resultClassList': [Long.class],
375 | 'check' : { r ->
376 | def total = r.result[0]
377 | if (total > 0) {
378 | error("Detected ${total} generated impex medias -> delete")
379 | }
380 | }
381 | ],
382 |
383 | "ImportBatchContent" : [
384 | 'query' : """
385 | SELECT
386 | COUNT(1)
387 | FROM
388 | {ImportBatchContent AS c
389 | LEFT JOIN
390 | ImportBatch AS b
391 | ON {b:importContentCode} = {c:code} }
392 | WHERE
393 | {b:pk} IS NULL
394 | """,
395 | 'resultClassList': [Long.class],
396 | 'check' : { r ->
397 | def total = r.result[0]
398 |
399 | if (total > 0) {
400 | error("Detected ${total} orphaned ImportBatchContent - delete!")
401 | }
402 | }
403 |
404 | ],
405 |
406 | "LogFile" : [
407 | 'query' : """
408 | SELECT SUM("total") FROM ({{
409 | SELECT
410 | COUNT(1) AS "total"
411 | FROM
412 | {LogFile AS l
413 | LEFT JOIN
414 | CronJob AS cj
415 | ON {l:owner} = {cj:pk} }
416 | GROUP BY
417 | {cj:code}
418 | HAVING COUNT({l:pk}) > ?maxCount
419 | OR {cj:code} IS NULL
420 | }}) summary
421 | """,
422 | 'parameters' : {
423 | def maxCount = configuration.getLong("cronjob.logs.filescount", 5L)
424 | def maxAge = configuration.getLong("cronjob.logs.filesdaysold", 14L)
425 |
426 | ['maxCount': maxCount, 'maxAge': Date.from(now.minusDays(maxAge).toInstant())]
427 | },
428 | 'resultClassList': [Long.class],
429 | 'check' : { r ->
430 | def total = r.result[0]
431 | if (total > 0) {
432 | error("${total} outdated LogFile detected -> delete outdated data, activate cronjob LogFile retention job!!")
433 | }
434 | }
435 | ],
436 |
437 | "ProcessTaskLog" : [
438 | 'query' : """
439 | SELECT
440 | COUNT(1) AS "total"
441 | FROM
442 | {ProcessTaskLog AS l}
443 | WHERE
444 | {l:creationTime} < ?maxAge
445 | """,
446 | 'parameters' : {
447 | ['maxAge': Date.from(now.minusMonths(3).toInstant())]
448 | },
449 | 'resultClassList': [Long.class],
450 | 'check' : { r ->
451 | def total = r.result[0]
452 | if (total > 0) {
453 | warning("""\
454 | ${total} ProcessTaskLog older then three months detected! -> investigate
455 | - Old, outdated BusinessProcesses?
456 | - Excessive Logging?
457 | - Missing retention rule for ProcessTaskLog?
458 | """.stripIndent())
459 | }
460 | }
461 | ],
462 |
463 | "SavedValues" : [
464 | 'query' : """
465 | SELECT SUM("total") FROM ({{
466 | SELECT
467 | COUNT(1) AS "total"
468 | FROM
469 | {SavedValues AS s }
470 | GROUP BY
471 | {s:modifiedItem}
472 | HAVING COUNT({s:pk}) > ?max
473 | }}) summary
474 | """,
475 | 'parameters' : {
476 | def maxSize = configuration.getLong("hmc.storing.modifiedvalues.size", 20)
477 | ['max': maxSize]
478 | },
479 | 'resultClassList': [Long.class],
480 | 'check' : { r ->
481 | def total = r.result[0]
482 |
483 | if (total > 0) {
484 | error("Found ${total} more SavedValues than expected -> delete")
485 | }
486 |
487 | def setting = configuration.getLong("hmc.storing.modifiedvalues.size", 20)
488 | if (setting > 10) {
489 | warning("Consider setting hmc.storing.modifiedvalues.size=0 (disabling stored values).\n(at least reduce it from ${setting} to 10 or lower)")
490 | }
491 | }
492 | ],
493 |
494 | "SavedValueEntry (orphans)" : [
495 | 'query' : """
496 | SELECT
497 | COUNT(1) AS "total"
498 | FROM
499 | {SavedValueEntry AS e
500 | LEFT JOIN
501 | SavedValues AS s
502 | ON {e:parent} = {s:pk} }
503 | WHERE
504 | {s:pk} IS NULL
505 | """,
506 | 'resultClassList': [Long.class],
507 | 'check' : { r ->
508 | def total = r.result[0]
509 | if (total > 0) {
510 | error("Found ${total} orphaned SavedValueEntry (parent SavedValue is gone) -> delete")
511 | }
512 | }
513 | ],
514 |
515 | "SolrIndexOperation" : [
516 | 'query' : """
517 | SELECT
518 | COUNT(1) AS "total"
519 | FROM
520 | {SolrIndexOperation AS o}
521 | WHERE
522 | {o:modifiedtime} <= ?max
523 | """,
524 | 'parameters' : {
525 | ['max': Date.from(now.minusDays(1).toInstant())]
526 | },
527 | 'resultClassList': [Long.class],
528 | 'check' : { r ->
529 | def total = r.result[0]
530 | if (total > 0) {
531 | error("Found ${total} SolrIndexOperation older than a day -> delete")
532 | }
533 | }
534 | ],
535 |
536 | "StoredHttpSession" : [
537 | 'query' : """
538 | StoredHttpSession\t
539 | SELECT
540 | COUNT(1) AS "total"
541 | FROM
542 | {StoredHttpSession AS s}
543 | WHERE
544 | {s:modifiedtime} <= ?max
545 | """,
546 | 'parameters' : {
547 | def defaultTimeout = configuration.getLong("default.session.timeout", 3600L)
548 | ['max': Date.from(now.minusSeconds(defaultTimeout).toInstant())]
549 | },
550 | 'resultClassList': [Long.class],
551 | 'check' : { r ->
552 | def total = r.result[0]
553 | if (total > 0) {
554 | error("${total} StoredHttpSession older than 'default.session.timeout' found -> delete and make sure to configure a retention job!")
555 | }
556 | }
557 | ],
558 |
559 | "TaskCondition" : [
560 | 'query' : """
561 | SELECT
562 | COUNT(1)
563 | FROM
564 | {TaskCondition AS tc }
565 | WHERE {tc:task} IS NULL
566 | AND {tc:modifiedtime} <= ?max
567 | """,
568 | 'parameters' : {
569 | ['max': Date.from(now.minusMonths(1).toInstant())]
570 | },
571 | 'resultClassList': [Long.class],
572 | 'check' : { r ->
573 | def total = r.result[0]
574 | if (total > 0) {
575 | warning("${total} 'premature' TaskConditions older than a month detected -> investigate why, delete outdated data")
576 | }
577 | }
578 | ]
579 | ]
580 |
581 | def t = tenantAwareThreadFactory.newThread(new Runnable() {
582 | @Override
583 | void run() {
584 | TYPE_CHECKS.each { type, check ->
585 | info("--- Checking ${type} ---")
586 | def query = new FlexibleSearchQuery(check.query)
587 | query.setResultClassList(check.resultClassList)
588 | if (check.parameters) {
589 | query.addQueryParameters(check.parameters())
590 | }
591 | def result = fsq.search(query)
592 | check.check(result)
593 |
594 | def is = new ByteArrayInputStream(builder.toString().getBytes(StandardCharsets.UTF_8));
595 | mediaService.setStreamForMedia(resultMedia, is, "sanecleanup-report.txt", "text/plain")
596 | }
597 | }
598 | })
599 | t.daemon = true
600 | t.start()
601 |
602 | println "Started check!"
603 | println "report will be availalbe in media ${resultMedia.code} / https://