Skip to content

Commit

Permalink
PR ebean-orm#3144 - FEATURE: NEW: QueryPlanLogger for DB2
Browse files Browse the repository at this point in the history
  • Loading branch information
rPraml committed Aug 10, 2023
1 parent 590cecd commit 063cb3d
Show file tree
Hide file tree
Showing 4 changed files with 355 additions and 0 deletions.
20 changes: 20 additions & 0 deletions ebean-api/src/main/java/io/ebean/config/DatabaseConfig.java
Original file line number Diff line number Diff line change
Expand Up @@ -502,6 +502,11 @@ public class DatabaseConfig {
*/
private boolean queryPlanEnable;

/**
* Additional platform specific options for query-plan generation.
*/
private String queryPlanOptions;

/**
* The default threshold in micros for collecting query plans.
*/
Expand Down Expand Up @@ -2878,6 +2883,7 @@ protected void loadSettings(PropertiesWrapper p) {
queryPlanTTLSeconds = p.getInt("queryPlanTTLSeconds", queryPlanTTLSeconds);
slowQueryMillis = p.getLong("slowQueryMillis", slowQueryMillis);
queryPlanEnable = p.getBoolean("queryPlan.enable", queryPlanEnable);
queryPlanOptions = p.get("queryPlan.options", queryPlanOptions);
queryPlanThresholdMicros = p.getLong("queryPlan.thresholdMicros", queryPlanThresholdMicros);
queryPlanCapture = p.getBoolean("queryPlan.capture", queryPlanCapture);
queryPlanCapturePeriodSecs = p.getLong("queryPlan.capturePeriodSecs", queryPlanCapturePeriodSecs);
Expand Down Expand Up @@ -3277,6 +3283,20 @@ public void setQueryPlanEnable(boolean queryPlanEnable) {
this.queryPlanEnable = queryPlanEnable;
}

/**
* Returns platform specific query plan options.
*/
public String getQueryPlanOptions() {
return queryPlanOptions;
}

/**
* Set platform specific query plan options.
*/
public void setQueryPlanOptions(String queryPlanOptions) {
this.queryPlanOptions = queryPlanOptions;
}

/**
* Return the query plan collection threshold in microseconds.
*/
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -597,6 +597,8 @@ QueryPlanLogger queryPlanLogger(Platform platform) {
return new QueryPlanLoggerSqlServer();
case ORACLE:
return new QueryPlanLoggerOracle();
case DB2:
return new QueryPlanLoggerDb2(config.getQueryPlanOptions());
default:
return new QueryPlanLoggerExplain();
}
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,122 @@

package io.ebeaninternal.server.query;

import io.ebean.util.IOUtils;
import io.ebean.util.StringHelper;
import io.ebeaninternal.api.CoreLog;
import io.ebeaninternal.api.SpiDbQueryPlan;
import io.ebeaninternal.api.SpiQueryPlan;
import io.ebeaninternal.server.bind.capture.BindCapture;

import java.io.BufferedReader;
import java.io.IOException;
import java.io.InputStream;
import java.sql.Connection;
import java.sql.PreparedStatement;
import java.sql.ResultSet;
import java.sql.SQLException;
import java.sql.Statement;
import java.util.Map;
import java.util.Random;

import static java.lang.System.Logger.Level.WARNING;

/**
* A QueryPlanLogger for DB2.
* <p>
* To use query plan capturing, you have to install the explain tables with
* <code>SYSPROC.SYSINSTALLOBJECTS( 'EXPLAIN', 'C' , '', CURRENT SCHEMA )</code>.
* To do this in a repeatable script, you may use this statement:
*
* <pre>
* BEGIN
* IF NOT EXISTS (SELECT * FROM SYSCAT.TABLES WHERE TABSCHEMA = CURRENT SCHEMA AND TABNAME = 'EXPLAIN_STREAM') THEN
* call SYSPROC.SYSINSTALLOBJECTS( 'EXPLAIN', 'C' , '', CURRENT SCHEMA );
* END IF;
* END
* </pre>
*
* @author Roland Praml, FOCONIS AG
*/
public final class QueryPlanLoggerDb2 extends QueryPlanLogger {

private Random rnd = new Random();

private final String schema;

private final boolean create;

private static final String GET_PLAN_TEMPLATE = readReasource("QueryPlanLoggerDb2.sql");

private static final String CREATE_TEMPLATE = "BEGIN\n"
+ "IF NOT EXISTS (SELECT * FROM SYSCAT.TABLES WHERE TABSCHEMA = ${SCHEMA} AND TABNAME = 'EXPLAIN_STREAM') THEN\n"
+ " CALL SYSPROC.SYSINSTALLOBJECTS( 'EXPLAIN', 'C' , '', ${SCHEMA} );\n"
+ "END IF;\n"
+ "END";

public QueryPlanLoggerDb2(String opts) {
Map<String, String> map = StringHelper.delimitedToMap(opts, ";", "=");
create = !"false" .equals(map.get("create")); // default is create
String schema = map.get("schema"); // should be null or SYSTOOLS
if (schema == null || schema.isEmpty()) {
this.schema = null;
} else {
this.schema = schema.toUpperCase();
}
}

private static String readReasource(String resName) {
try (InputStream stream = QueryPlanLoggerDb2.class.getResourceAsStream(resName)) {
if (stream == null) {
throw new IllegalStateException("Could not find resource " + resName);
}
BufferedReader reader = IOUtils.newReader(stream);
StringBuilder sb = new StringBuilder();
reader.lines().forEach(line -> sb.append(line).append('\n'));
return sb.toString();
} catch (IOException e) {
throw new IllegalStateException("Could not read resource " + resName, e);
}
}

@Override
public SpiDbQueryPlan collectPlan(Connection conn, SpiQueryPlan plan, BindCapture bind) {
try (Statement stmt = conn.createStatement()) {
if (create) {
// create explain tables if neccessary
if (schema == null) {
stmt.execute(CREATE_TEMPLATE.replace("${SCHEMA}", "CURRENT USER"));
} else {
stmt.execute(CREATE_TEMPLATE.replace("${SCHEMA}", "'" + schema + "'"));
}
conn.commit();
}

try {
int queryNo = rnd.nextInt(Integer.MAX_VALUE);

String sql = "EXPLAIN PLAN SET QUERYNO = " + queryNo + " FOR " + plan.sql();
try (PreparedStatement explainStmt = conn.prepareStatement(sql)) {
bind.prepare(explainStmt, conn);
explainStmt.execute();
}

sql = schema == null
? GET_PLAN_TEMPLATE.replace("${SCHEMA}", conn.getMetaData().getUserName().toUpperCase())
: GET_PLAN_TEMPLATE.replace("${SCHEMA}", schema);

try (PreparedStatement pstmt = conn.prepareStatement(sql)) {
pstmt.setInt(1, queryNo);
try (ResultSet rset = pstmt.executeQuery()) {
return readQueryPlan(plan, bind, rset);
}
}
} finally {
conn.rollback(); // do not keep query plans in DB
}
} catch (SQLException e) {
CoreLog.log.log(WARNING, "Could not log query plan", e);
return null;
}
}
}
Original file line number Diff line number Diff line change
@@ -0,0 +1,211 @@
WITH tree(operator_ID, level, path, explain_time, cycle)
AS
(
SELECT 1 operator_id
, 0 level
, CAST('001' AS VARCHAR(1000)) path
, max(explain_time) explain_time
, 0
FROM ${SCHEMA}.EXPLAIN_OPERATOR O
WHERE O.EXPLAIN_REQUESTER = SESSION_USER

UNION ALL

SELECT s.source_id
, level + 1
, tree.path || '/' || LPAD(CAST(s.source_id AS VARCHAR(3)), 3, '0') path
, tree.explain_time
, POSITION('/' || LPAD(CAST(s.source_id AS VARCHAR(3)), 3, '0') || '/' IN path USING OCTETS)
FROM tree
, ${SCHEMA}.EXPLAIN_STREAM S
WHERE s.target_id = tree.operator_id
AND s.explain_time = tree.explain_time
AND S.Object_Name IS NULL
AND S.explain_requester = SESSION_USER
AND tree.cycle = 0
AND level < 100
)
SELECT *
FROM (
SELECT "Explain Plan"
FROM (
SELECT CAST( LPAD(id, MAX(LENGTH(id)) OVER(), ' ')
|| ' | '
|| RPAD(operation, MAX(LENGTH(operation)) OVER(), ' ')
|| ' | '
|| LPAD(rows, MAX(LENGTH(rows)) OVER(), ' ')
|| ' | '
-- Don't show ActualRows columns if there are no actuals available at all
|| CASE WHEN COUNT(ActualRows) OVER () > 1 -- the heading 'ActualRows' is always present, so "1" means no OTHER values
THEN LPAD(ActualRows, MAX(LENGTH(ActualRows)) OVER(), ' ') || ' | '
ELSE ''
END
|| LPAD(cost, MAX(LENGTH(cost)) OVER(), ' ')
AS VARCHAR(100)) "Explain Plan"
, path
FROM (
SELECT 'ID' ID
, 'Operation' Operation
, 'Rows' Rows
, 'ActualRows' ActualRows
, 'Cost' Cost
, '0' Path
FROM SYSIBM.SYSDUMMY1
-- TODO: UNION ALL yields duplicate. where do they come from?
UNION
SELECT CAST(tree.operator_id as VARCHAR(254)) ID
, CAST(LPAD(' ', tree.level, ' ')
|| CASE WHEN tree.cycle = 1
THEN '(cycle) '
ELSE ''
END
|| COALESCE (
TRIM(O.Operator_Type)
|| COALESCE(' (' || argument || ')', '')
|| ' '
|| COALESCE(S.Object_Name,'')
, ''
)
AS VARCHAR(254)) AS OPERATION
, COALESCE(CAST(rows AS VARCHAR(254)), '') Rows
, CAST(ActualRows as VARCHAR(254)) ActualRows -- note: no coalesce
, COALESCE(CAST(CAST(O.Total_Cost AS BIGINT) AS VARCHAR(254)), '') Cost
, path
FROM tree
LEFT JOIN ( SELECT i.source_id
, i.target_id
, CAST(CAST(ROUND(o.stream_count) AS BIGINT) AS VARCHAR(12))
|| ' of '
|| CAST (total_rows AS VARCHAR(12))
|| CASE WHEN total_rows > 0
AND ROUND(o.stream_count) <= total_rows THEN
' ('
|| LPAD(CAST (ROUND(ROUND(o.stream_count)/total_rows*100,2)
AS NUMERIC(5,2)), 6, ' ')
|| '%)'
ELSE ''
END rows
, CASE WHEN act.actual_value is not null then
CAST(CAST(ROUND(act.actual_value) AS BIGINT) AS VARCHAR(12))
|| ' of '
|| CAST (total_rows AS VARCHAR(12))
|| CASE WHEN total_rows > 0 THEN
' ('
|| LPAD(CAST (ROUND(ROUND(act.actual_value)/total_rows*100,2)
AS NUMERIC(5,2)), 6, ' ')
|| '%)'
ELSE NULL
END END ActualRows
, i.object_name
, i.explain_time
FROM (SELECT MAX(source_id) source_id
, target_id
, MIN(CAST(ROUND(stream_count,0) AS BIGINT)) total_rows
, CAST(LISTAGG(object_name) AS VARCHAR(50)) object_name
, explain_time
FROM ${SCHEMA}.EXPLAIN_STREAM
WHERE explain_time = (SELECT MAX(explain_time)
FROM ${SCHEMA}.EXPLAIN_OPERATOR
WHERE EXPLAIN_REQUESTER = SESSION_USER
)
GROUP BY target_id, explain_time
) I
LEFT JOIN ${SCHEMA}.EXPLAIN_STREAM O
ON ( I.target_id=o.source_id
AND I.explain_time = o.explain_time
AND O.EXPLAIN_REQUESTER = SESSION_USER
)
LEFT JOIN ${SCHEMA}.EXPLAIN_ACTUALS act
ON ( act.operator_id = i.target_id
AND act.explain_time = i.explain_time
AND act.explain_requester = SESSION_USER
AND act.ACTUAL_TYPE like 'CARDINALITY%'
)
) s
ON ( s.target_id = tree.operator_id
AND s.explain_time = tree.explain_time
)
LEFT JOIN ${SCHEMA}.EXPLAIN_OPERATOR O
ON ( o.operator_id = tree.operator_id
AND o.explain_time = tree.explain_time
AND o.explain_requester = SESSION_USER
)
LEFT JOIN (SELECT LISTAGG (CASE argument_type
WHEN 'UNIQUE' THEN
CASE WHEN argument_value = 'TRUE'
THEN 'UNIQUE'
ELSE NULL
END
WHEN 'TRUNCSRT' THEN
CASE WHEN argument_value = 'TRUE'
THEN 'TOP-N'
ELSE NULL
END
WHEN 'SCANDIR' THEN
CASE WHEN argument_value != 'FORWARD'
THEN argument_value
ELSE NULL
END
ELSE argument_value
END
, ' ') argument
, operator_id
, explain_time
FROM ${SCHEMA}.EXPLAIN_ARGUMENT EA
WHERE argument_type IN ('AGGMODE' -- GRPBY
, 'UNIQUE', 'TRUNCSRT' -- SORT
, 'SCANDIR' -- IXSCAN, TBSCAN
, 'OUTERJN' -- JOINs
)
AND explain_requester = SESSION_USER
GROUP BY explain_time, operator_id

) A
ON ( a.operator_id = tree.operator_id
AND a.explain_time = tree.explain_time
)
) O
UNION ALL
VALUES ('Explain plan (c) 2014-2017 by Markus Winand - NO WARRANTY - V20171102','Z0')
, ('Modifications by Ember Crooks - NO WARRANTY','Z1')
, ('http://use-the-index-luke.com/s/last_explained','Z2')
, ('', 'A')
, ('', 'Y')
, ('Predicate Information', 'AA')
UNION ALL
SELECT CAST (LPAD(CASE WHEN operator_id = LAG (operator_id)
OVER (PARTITION BY operator_id
ORDER BY pred_order
)
THEN ''
ELSE operator_id || ' - '
END
, MAX(LENGTH(operator_id )+4) OVER()
, ' ')
|| how_applied
|| ' '
|| predicate_text
AS VARCHAR(100)) "Predicate Information"
, 'P' || LPAD(id_order, 5, '0') || pred_order path
FROM (SELECT CAST(operator_id AS VARCHAR(254)) operator_id
, LPAD(trim(how_applied)
, MAX (LENGTH(TRIM(how_applied)))
OVER (PARTITION BY operator_id)
, ' '
) how_applied
-- next: capped to length 80 to avoid
-- SQL0445W Value "..." has been truncated. SQLSTATE=01004
-- error when long literal values may appear (space padded!)
, CAST(substr(predicate_text, 1, 80) AS VARCHAR(80)) predicate_text
, CASE how_applied WHEN 'START' THEN '1'
WHEN 'STOP' THEN '2'
WHEN 'SARG' THEN '3'
ELSE '9'
END pred_order
, operator_id id_order
FROM ${SCHEMA}.EXPLAIN_PREDICATE p
WHERE explain_time = (SELECT max(explain_time) FROM ${SCHEMA}.EXPLAIN_STATEMENT WHERE queryno = ?)
)
)
ORDER BY path
)

0 comments on commit 063cb3d

Please sign in to comment.