IDEMPIERE-6123 Query in search window causing slowness and load spikes in the database (FHCA-5356) (#2354)

* IDEMPIERE-6123 Query in search window causing slowness and load spikes in the database (FHCA-5356)

- make also configurable the timeout and number of records from windows
- improve timing of reports avoiding unncessary load of array when not jasper

* - implement suggestions from Heng Sin
This commit is contained in:
Carlos Ruiz 2024-05-08 14:16:12 +02:00
parent e1ed11f224
commit 4409415d55
9 changed files with 87 additions and 20 deletions

View File

@ -0,0 +1,22 @@
-- IDEMPIERE-6123 Query in search window causing slowness and load spikes in the database (FHCA-5356)
SELECT register_migration_script('202405080101_IDEMPIERE-6123.sql') FROM dual;
SET SQLBLANKLINES ON
SET DEFINE OFF
-- May 8, 2024, 1:01:16 AM CEST
INSERT INTO AD_SysConfig (AD_SysConfig_ID,AD_Client_ID,AD_Org_ID,Created,Updated,CreatedBy,UpdatedBy,IsActive,Name,Value,Description,EntityType,ConfigurationLevel,AD_SysConfig_UU) VALUES (200247,0,0,TO_TIMESTAMP('2024-05-08 01:01:16','YYYY-MM-DD HH24:MI:SS'),TO_TIMESTAMP('2024-05-08 01:01:16','YYYY-MM-DD HH24:MI:SS'),100,100,'Y','REPORT_LOAD_TIMEOUT_IN_SECONDS','120','Timeout in seconds when loading a report','D','C','14e838b1-c25c-400e-b39c-61da9bf92099')
;
-- May 8, 2024, 1:01:42 AM CEST
INSERT INTO AD_SysConfig (AD_SysConfig_ID,AD_Client_ID,AD_Org_ID,Created,Updated,CreatedBy,UpdatedBy,IsActive,Name,Value,Description,EntityType,ConfigurationLevel,AD_SysConfig_UU) VALUES (200248,0,0,TO_TIMESTAMP('2024-05-08 01:01:41','YYYY-MM-DD HH24:MI:SS'),TO_TIMESTAMP('2024-05-08 01:01:41','YYYY-MM-DD HH24:MI:SS'),100,100,'Y','GLOBAL_MAX_REPORT_RECORDS','100000','Max number of records allowed in a report','D','C','7030640a-1aa7-4ac7-a894-b4fe0dfde530')
;
-- May 8, 2024, 1:06:19 AM CEST
INSERT INTO AD_Message (MsgType,MsgText,AD_Client_ID,AD_Org_ID,IsActive,Created,CreatedBy,Updated,UpdatedBy,AD_Message_ID,Value,EntityType,AD_Message_UU) VALUES ('I','The data query for the report took too much time to execute (over {0} seconds) exceeding the allowed limit',0,0,'Y',TO_TIMESTAMP('2024-05-08 01:06:18','YYYY-MM-DD HH24:MI:SS'),100,TO_TIMESTAMP('2024-05-08 01:06:18','YYYY-MM-DD HH24:MI:SS'),100,200893,'ReportQueryTimeout','D','5f17f55f-adbe-4d97-bf83-9447983b4946')
;
-- May 8, 2024, 1:07:10 AM CEST
INSERT INTO AD_Message (MsgType,MsgText,AD_Client_ID,AD_Org_ID,IsActive,Created,CreatedBy,Updated,UpdatedBy,AD_Message_ID,Value,EntityType,AD_Message_UU) VALUES ('I','The report data exceeds the maximum limit of {0} rows',0,0,'Y',TO_TIMESTAMP('2024-05-08 01:07:09','YYYY-MM-DD HH24:MI:SS'),100,TO_TIMESTAMP('2024-05-08 01:07:09','YYYY-MM-DD HH24:MI:SS'),100,200894,'ReportMaxRowsReached','D','a4b55c31-0df0-4302-a62a-91cb7e79be0d')
;

View File

@ -0,0 +1,19 @@
-- IDEMPIERE-6123 Query in search window causing slowness and load spikes in the database (FHCA-5356)
SELECT register_migration_script('202405080101_IDEMPIERE-6123.sql') FROM dual;
-- May 8, 2024, 1:01:16 AM CEST
INSERT INTO AD_SysConfig (AD_SysConfig_ID,AD_Client_ID,AD_Org_ID,Created,Updated,CreatedBy,UpdatedBy,IsActive,Name,Value,Description,EntityType,ConfigurationLevel,AD_SysConfig_UU) VALUES (200247,0,0,TO_TIMESTAMP('2024-05-08 01:01:16','YYYY-MM-DD HH24:MI:SS'),TO_TIMESTAMP('2024-05-08 01:01:16','YYYY-MM-DD HH24:MI:SS'),100,100,'Y','REPORT_LOAD_TIMEOUT_IN_SECONDS','120','Timeout in seconds when loading a report','D','C','14e838b1-c25c-400e-b39c-61da9bf92099')
;
-- May 8, 2024, 1:01:42 AM CEST
INSERT INTO AD_SysConfig (AD_SysConfig_ID,AD_Client_ID,AD_Org_ID,Created,Updated,CreatedBy,UpdatedBy,IsActive,Name,Value,Description,EntityType,ConfigurationLevel,AD_SysConfig_UU) VALUES (200248,0,0,TO_TIMESTAMP('2024-05-08 01:01:41','YYYY-MM-DD HH24:MI:SS'),TO_TIMESTAMP('2024-05-08 01:01:41','YYYY-MM-DD HH24:MI:SS'),100,100,'Y','GLOBAL_MAX_REPORT_RECORDS','100000','Max number of records allowed in a report','D','C','7030640a-1aa7-4ac7-a894-b4fe0dfde530')
;
-- May 8, 2024, 1:06:19 AM CEST
INSERT INTO AD_Message (MsgType,MsgText,AD_Client_ID,AD_Org_ID,IsActive,Created,CreatedBy,Updated,UpdatedBy,AD_Message_ID,Value,EntityType,AD_Message_UU) VALUES ('I','The data query for the report took too much time to execute (over {0} seconds) exceeding the allowed limit',0,0,'Y',TO_TIMESTAMP('2024-05-08 01:06:18','YYYY-MM-DD HH24:MI:SS'),100,TO_TIMESTAMP('2024-05-08 01:06:18','YYYY-MM-DD HH24:MI:SS'),100,200893,'ReportQueryTimeout','D','5f17f55f-adbe-4d97-bf83-9447983b4946')
;
-- May 8, 2024, 1:07:10 AM CEST
INSERT INTO AD_Message (MsgType,MsgText,AD_Client_ID,AD_Org_ID,IsActive,Created,CreatedBy,Updated,UpdatedBy,AD_Message_ID,Value,EntityType,AD_Message_UU) VALUES ('I','The report data exceeds the maximum limit of {0} rows',0,0,'Y',TO_TIMESTAMP('2024-05-08 01:07:09','YYYY-MM-DD HH24:MI:SS'),100,TO_TIMESTAMP('2024-05-08 01:07:09','YYYY-MM-DD HH24:MI:SS'),100,200894,'ReportMaxRowsReached','D','a4b55c31-0df0-4302-a62a-91cb7e79be0d')
;

View File

@ -312,7 +312,7 @@ public interface AdempiereDatabase
public boolean isPagingSupported(); public boolean isPagingSupported();
/** /**
* modify sql to return a subset of the query result * modify sql to return a subset of the query result. use 1 base index for start and end parameter
* @param sql * @param sql
* @param start * @param start
* @param end * @param end

View File

@ -744,7 +744,7 @@ public class MAcctSchema extends X_C_AcctSchema implements ImmutablePOSupport
StringBuilder sql = new StringBuilder("SELECT DISTINCT p.Value FROM M_Product p JOIN M_CostDetail d ON p.M_Product_ID=d.M_Product_ID"); StringBuilder sql = new StringBuilder("SELECT DISTINCT p.Value FROM M_Product p JOIN M_CostDetail d ON p.M_Product_ID=d.M_Product_ID");
sql.append(" JOIN M_Product_Category_Acct pc ON p.M_Product_Category_ID=pc.M_Product_Category_ID AND d.C_AcctSchema_ID=pc.C_AcctSchema_ID"); sql.append(" JOIN M_Product_Category_Acct pc ON p.M_Product_Category_ID=pc.M_Product_Category_ID AND d.C_AcctSchema_ID=pc.C_AcctSchema_ID");
sql.append(" WHERE p.IsActive='Y' AND pc.IsActive='Y' AND pc.CostingLevel IS NULL AND d.C_AcctSchema_ID=?"); sql.append(" WHERE p.IsActive='Y' AND pc.IsActive='Y' AND pc.CostingLevel IS NULL AND d.C_AcctSchema_ID=?");
String query = DB.getDatabase().addPagingSQL(sql.toString(), 0, 50); String query = DB.getDatabase().addPagingSQL(sql.toString(), 1, 50);
List<List<Object>> list = DB.getSQLArrayObjectsEx(get_TrxName(), query, getC_AcctSchema_ID()); List<List<Object>> list = DB.getSQLArrayObjectsEx(get_TrxName(), query, getC_AcctSchema_ID());
if (list != null) { if (list != null) {
for(List<Object> entry : list) { for(List<Object> entry : list) {

View File

@ -1230,6 +1230,8 @@ public final class MLookup extends Lookup implements Serializable
// SELECT Key, Value, Name, IsActive FROM ... // SELECT Key, Value, Name, IsActive FROM ...
String sqlFirstRows = DB.getDatabase().addPagingSQL(sql.toString(), 1, MAX_ROWS+1); String sqlFirstRows = DB.getDatabase().addPagingSQL(sql.toString(), 1, MAX_ROWS+1);
pstmt = DB.prepareStatement(sqlFirstRows, null); pstmt = DB.prepareStatement(sqlFirstRows, null);
if (! DB.getDatabase().isPagingSupported())
pstmt.setMaxRows(MAX_ROWS+1);
int timeout = MSysConfig.getIntValue(MSysConfig.GRIDTABLE_LOAD_TIMEOUT_IN_SECONDS, GridTable.DEFAULT_GRIDTABLE_LOAD_TIMEOUT_IN_SECONDS, Env.getAD_Client_ID(Env.getCtx())); int timeout = MSysConfig.getIntValue(MSysConfig.GRIDTABLE_LOAD_TIMEOUT_IN_SECONDS, GridTable.DEFAULT_GRIDTABLE_LOAD_TIMEOUT_IN_SECONDS, Env.getAD_Client_ID(Env.getCtx()));
if (timeout > 0) if (timeout > 0)
pstmt.setQueryTimeout(timeout); pstmt.setQueryTimeout(timeout);

View File

@ -236,7 +236,7 @@ public class MProductCategoryAcct extends X_M_Product_Category_Acct implements I
StringBuilder products = new StringBuilder(); StringBuilder products = new StringBuilder();
StringBuilder sql = new StringBuilder("SELECT DISTINCT p.Value FROM M_Product p JOIN M_CostDetail d ON p.M_Product_ID=d.M_Product_ID"); StringBuilder sql = new StringBuilder("SELECT DISTINCT p.Value FROM M_Product p JOIN M_CostDetail d ON p.M_Product_ID=d.M_Product_ID");
sql.append(" WHERE p.IsActive='Y' AND p.M_Product_Category_ID=? AND d.C_AcctSchema_ID=?"); sql.append(" WHERE p.IsActive='Y' AND p.M_Product_Category_ID=? AND d.C_AcctSchema_ID=?");
String query = DB.getDatabase().addPagingSQL(sql.toString(), 0, 50); String query = DB.getDatabase().addPagingSQL(sql.toString(), 1, 50);
List<List<Object>> list = DB.getSQLArrayObjectsEx(get_TrxName(), query, getM_Product_Category_ID(), getC_AcctSchema_ID()); List<List<Object>> list = DB.getSQLArrayObjectsEx(get_TrxName(), query, getM_Product_Category_ID(), getC_AcctSchema_ID());
if (list != null) { if (list != null) {
for(List<Object> entry : list) { for(List<Object> entry : list) {

View File

@ -46,7 +46,7 @@ public class MSysConfig extends X_AD_SysConfig
/** /**
* *
*/ */
private static final long serialVersionUID = 8121897973805635995L; private static final long serialVersionUID = 5739824752288579881L;
/** Constant for Predefine System Configuration Names (in alphabetical order) */ /** Constant for Predefine System Configuration Names (in alphabetical order) */
@ -120,6 +120,7 @@ public class MSysConfig extends X_AD_SysConfig
public static final String FORM_SQL_QUERY_MAX_RECORDS = "FORM_SQL_QUERY_MAX_RECORDS"; public static final String FORM_SQL_QUERY_MAX_RECORDS = "FORM_SQL_QUERY_MAX_RECORDS";
public static final String FORM_SQL_QUERY_TIMEOUT_IN_SECONDS = "FORM_SQL_QUERY_TIMEOUT_IN_SECONDS"; public static final String FORM_SQL_QUERY_TIMEOUT_IN_SECONDS = "FORM_SQL_QUERY_TIMEOUT_IN_SECONDS";
public static final String GLOBAL_MAX_QUERY_RECORDS = "GLOBAL_MAX_QUERY_RECORDS"; public static final String GLOBAL_MAX_QUERY_RECORDS = "GLOBAL_MAX_QUERY_RECORDS";
public static final String GLOBAL_MAX_REPORT_RECORDS = "GLOBAL_MAX_REPORT_RECORDS";
public static final String GRIDTABLE_LOAD_TIMEOUT_IN_SECONDS = "GRIDTABLE_LOAD_TIMEOUT_IN_SECONDS"; public static final String GRIDTABLE_LOAD_TIMEOUT_IN_SECONDS = "GRIDTABLE_LOAD_TIMEOUT_IN_SECONDS";
public static final String GRIDTABLE_INITIAL_COUNT_TIMEOUT_IN_SECONDS = "GRIDTABLE_INITIAL_COUNT_TIMEOUT_IN_SECONDS"; public static final String GRIDTABLE_INITIAL_COUNT_TIMEOUT_IN_SECONDS = "GRIDTABLE_INITIAL_COUNT_TIMEOUT_IN_SECONDS";
public static final String HTML_REPORT_MINIFY = "HTML_REPORT_MINIFY"; public static final String HTML_REPORT_MINIFY = "HTML_REPORT_MINIFY";
@ -185,6 +186,7 @@ public class MSysConfig extends X_AD_SysConfig
public static final String REAL_TIME_POS = "REAL_TIME_POS"; public static final String REAL_TIME_POS = "REAL_TIME_POS";
public static final String RecentItems_MaxSaved = "RecentItems_MaxSaved"; public static final String RecentItems_MaxSaved = "RecentItems_MaxSaved";
public static final String RecentItems_MaxShown = "RecentItems_MaxShown"; public static final String RecentItems_MaxShown = "RecentItems_MaxShown";
public static final String REPORT_LOAD_TIMEOUT_IN_SECONDS = "REPORT_LOAD_TIMEOUT_IN_SECONDS";
public static final String REPORT_SWAP_MAX_ROWS = "REPORT_SWAP_MAX_ROWS"; public static final String REPORT_SWAP_MAX_ROWS = "REPORT_SWAP_MAX_ROWS";
public static final String SHIPPING_DEFAULT_WEIGHT_PER_PACKAGE = "SHIPPING_DEFAULT_WEIGHT_PER_PACKAGE"; public static final String SHIPPING_DEFAULT_WEIGHT_PER_PACKAGE = "SHIPPING_DEFAULT_WEIGHT_PER_PACKAGE";
public static final String STANDARD_REPORT_FOOTER_TRADEMARK_TEXT = "STANDARD_REPORT_FOOTER_TRADEMARK_TEXT"; public static final String STANDARD_REPORT_FOOTER_TRADEMARK_TEXT = "STANDARD_REPORT_FOOTER_TRADEMARK_TEXT";

View File

@ -41,6 +41,7 @@ import org.compiere.model.MLookupFactory;
import org.compiere.model.MQuery; import org.compiere.model.MQuery;
import org.compiere.model.MReportView; import org.compiere.model.MReportView;
import org.compiere.model.MRole; import org.compiere.model.MRole;
import org.compiere.model.MSysConfig;
import org.compiere.model.MTable; import org.compiere.model.MTable;
import org.compiere.model.SystemIDs; import org.compiere.model.SystemIDs;
import org.compiere.util.CLogMgt; import org.compiere.util.CLogMgt;
@ -142,6 +143,10 @@ public class DataEngine
private Map<Object, Object> m_summarized = new HashMap<Object, Object>(); private Map<Object, Object> m_summarized = new HashMap<Object, Object>();
public static final int DEFAULT_REPORT_LOAD_TIMEOUT_IN_SECONDS = 120;
public static final int DEFAULT_GLOBAL_MAX_REPORT_RECORDS = 100000;
/************************************************************************** /**************************************************************************
* Load Data * Load Data
* *
@ -927,11 +932,20 @@ public class DataEngine
int reportLineID = 0; int reportLineID = 0;
ArrayList<PrintDataColumn> scriptColumns = new ArrayList<PrintDataColumn>(); ArrayList<PrintDataColumn> scriptColumns = new ArrayList<PrintDataColumn>();
// //
int timeout = MSysConfig.getIntValue(MSysConfig.REPORT_LOAD_TIMEOUT_IN_SECONDS, DEFAULT_REPORT_LOAD_TIMEOUT_IN_SECONDS, Env.getAD_Client_ID(Env.getCtx()));
PreparedStatement pstmt = null; PreparedStatement pstmt = null;
ResultSet rs = null; ResultSet rs = null;
String sql = pd.getSQL();
try try
{ {
pstmt = DB.prepareNormalReadReplicaStatement(pd.getSQL(), m_trxName); int maxRows = MSysConfig.getIntValue(MSysConfig.GLOBAL_MAX_REPORT_RECORDS, DEFAULT_GLOBAL_MAX_REPORT_RECORDS, Env.getAD_Client_ID(Env.getCtx()));
if (maxRows > 0 && DB.getDatabase().isPagingSupported())
sql = DB.getDatabase().addPagingSQL(sql, 1, maxRows+1);
pstmt = DB.prepareNormalReadReplicaStatement(sql, m_trxName);
if (maxRows > 0 && ! DB.getDatabase().isPagingSupported())
pstmt.setMaxRows(maxRows+1);
if (timeout > 0)
pstmt.setQueryTimeout(timeout);
rs = pstmt.executeQuery(); rs = pstmt.executeQuery();
boolean isExistsT_Report_PA_ReportLine_ID = false; boolean isExistsT_Report_PA_ReportLine_ID = false;
@ -948,9 +962,13 @@ public class DataEngine
} }
} }
int cnt = 0;
// Row Loop // Row Loop
while (rs.next()) while (rs.next())
{ {
cnt++;
if (maxRows > 0 && cnt > maxRows)
throw new AdempiereException(Msg.getMsg(Env.getCtx(), "ReportMaxRowsReached", new Object[] {maxRows}));
if (hasLevelNo) if (hasLevelNo)
{ {
levelNo = rs.getInt("LevelNo"); levelNo = rs.getInt("LevelNo");
@ -1184,7 +1202,9 @@ public class DataEngine
} }
catch (SQLException e) catch (SQLException e)
{ {
log.log(Level.SEVERE, pdc + " - " + e.getMessage() + "\nSQL=" + pd.getSQL()); if (DB.getDatabase().isQueryTimeout(e))
throw new AdempiereException(Msg.getMsg(Env.getCtx(), "ReportQueryTimeout", new Object[] {timeout}));
log.log(Level.SEVERE, pdc + " - " + e.getMessage() + "\nSQL=" + sql);
throw new AdempiereException(e); throw new AdempiereException(e);
} }
finally finally
@ -1303,7 +1323,7 @@ public class DataEngine
{ {
if (CLogMgt.isLevelFiner()) if (CLogMgt.isLevelFiner())
log.finer("NO Rows - ms=" + (System.currentTimeMillis()-m_startTime) log.finer("NO Rows - ms=" + (System.currentTimeMillis()-m_startTime)
+ " - " + pd.getSQL()); + " - " + sql);
else else
log.info("NO Rows - ms=" + (System.currentTimeMillis()-m_startTime)); log.info("NO Rows - ms=" + (System.currentTimeMillis()-m_startTime));
} }

View File

@ -291,8 +291,8 @@ public class ReportAction implements EventListener<Event>
boolean currentRowOnly = chkCurrentRowOnly.isChecked(); boolean currentRowOnly = chkCurrentRowOnly.isChecked();
int Record_ID = 0; int Record_ID = 0;
String Record_UU = null; String Record_UU = null;
List <Integer> RecordIDs = null; List <Integer> jasperRecordIDs = null;
List <String> RecordUUs = null; List <String> jasperRecordUUs = null;
MQuery query = new MQuery(gridTab.getTableName()); MQuery query = new MQuery(gridTab.getTableName());
MTable table = MTable.get(gridTab.getAD_Table_ID()); MTable table = MTable.get(gridTab.getAD_Table_ID());
StringBuilder whereClause = new StringBuilder(""); StringBuilder whereClause = new StringBuilder("");
@ -309,15 +309,17 @@ public class ReportAction implements EventListener<Event>
else else
{ {
whereClause.append(gridTab.getTableModel().getSelectWhereClause()); whereClause.append(gridTab.getTableModel().getSelectWhereClause());
if (table.isUUIDKeyTable()) { if (pf != null && pf.getJasperProcess_ID() > 0) {
RecordUUs = new ArrayList<String>(); if (table.isUUIDKeyTable()) {
for(int i = 0; i < gridTab.getRowCount(); i++) { jasperRecordUUs = new ArrayList<String>();
RecordUUs.add(gridTab.getKeyUUID(i)); for(int i = 0; i < gridTab.getRowCount(); i++) {
} jasperRecordUUs.add(gridTab.getKeyUUID(i));
} else { }
RecordIDs = new ArrayList<Integer>(); } else {
for(int i = 0; i < gridTab.getRowCount(); i++) { jasperRecordIDs = new ArrayList<Integer>();
RecordIDs.add(gridTab.getKeyID(i)); for(int i = 0; i < gridTab.getRowCount(); i++) {
jasperRecordIDs.add(gridTab.getKeyID(i));
}
} }
} }
} }
@ -358,8 +360,8 @@ public class ReportAction implements EventListener<Event>
{ {
// It's a report using the JasperReports engine // It's a report using the JasperReports engine
ProcessInfo pi = new ProcessInfo ("", pf.getJasperProcess_ID(), pf.getAD_Table_ID(), Record_ID, Record_UU); ProcessInfo pi = new ProcessInfo ("", pf.getJasperProcess_ID(), pf.getAD_Table_ID(), Record_ID, Record_UU);
pi.setRecord_IDs(RecordIDs); pi.setRecord_IDs(jasperRecordIDs);
pi.setRecord_UUs(RecordUUs); pi.setRecord_UUs(jasperRecordUUs);
//pi.setIsBatch(true); //pi.setIsBatch(true);
if (export) if (export)