diff --git a/dbPort/src/org/compiere/dbPort/Convert_PostgreSQL.java b/dbPort/src/org/compiere/dbPort/Convert_PostgreSQL.java index 3c12745fe2..573e242b76 100644 --- a/dbPort/src/org/compiere/dbPort/Convert_PostgreSQL.java +++ b/dbPort/src/org/compiere/dbPort/Convert_PostgreSQL.java @@ -1116,7 +1116,7 @@ public class Convert_PostgreSQL extends Convert_SQL92 { String otherUpdateFields = ""; //get update where clause token = new StringBuffer(); - for(int i = subQueryEnd+1; i < select.length(); i++) + for(int i = subQueryEnd; i < select.length(); i++) { char c = select.charAt(i); if (Character.isWhitespace(c)) @@ -1125,7 +1125,7 @@ public class Convert_PostgreSQL extends Convert_SQL92 { { if ("WHERE".equalsIgnoreCase(token.toString())) { - otherUpdateFields = select.substring(subQueryEnd+1, i - 5).trim(); + otherUpdateFields = select.substring(subQueryEnd, i - 5).trim(); mainWhere = select.substring(i + 1); break; } @@ -1206,6 +1206,14 @@ public class Convert_PostgreSQL extends Convert_SQL92 { int fj = joinFields.length(); String updateField = null; String joinField = null; + + boolean useSubQuery = false; + String joinFieldsUpper = joinFields.toUpperCase(); + if (joinFieldsUpper.indexOf("SUM(") >=0 || joinFieldsUpper.indexOf("SUM (") >= 0 + || joinFieldsUpper.indexOf("MAX(") >=0 || joinFieldsUpper.indexOf("MAX (") >= 0 + || joinFieldsUpper.indexOf("MIN(") >=0 || joinFieldsUpper.indexOf("MIN (") >= 0 + || joinFieldsUpper.indexOf("COUNT(") >=0 || joinFieldsUpper.indexOf("COUNT (") >= 0) + useSubQuery = true; while (f > 0) { f = Util.findIndexOf(updateFields, ','); @@ -1218,22 +1226,41 @@ public class Convert_PostgreSQL extends Convert_SQL92 { Update.append(updateField.trim()); Update.append("="); - Update.append(joinField); - Update.append(otherUpdateFields); - Update.append(" FROM "); - Update.append(joinFromClause); - Update.append(" WHERE "); - subWhere = addAliasToIdentifier(subWhere, joinAlias); - Update.append(subWhere.trim()); - - if (mainWhere != null) - mainWhere = " AND " + mainWhere; - + if (useSubQuery) + { + Update.append("( SELECT "); + Update.append(joinField); + Update.append(" FROM "); + Update.append(joinFromClause); + Update.append(" WHERE "); + Update.append(subWhere.trim()); + Update.append(" ) "); + Update.append(otherUpdateFields); + if (mainWhere != null) + { + Update.append(" WHERE "); + Update.append(mainWhere); + } + } else - mainWhere = ""; - - mainWhere = addAliasToIdentifier(mainWhere, targetAlias); - Update.append(mainWhere); + { + Update.append(joinField); + Update.append(otherUpdateFields); + Update.append(" FROM "); + Update.append(joinFromClause); + Update.append(" WHERE "); + subWhere = addAliasToIdentifier(subWhere, joinAlias); + Update.append(subWhere.trim()); + + if (mainWhere != null) + mainWhere = " AND " + mainWhere; + + else + mainWhere = ""; + + mainWhere = addAliasToIdentifier(mainWhere, targetAlias); + Update.append(mainWhere); + } } else { updateField = updateFields.substring(0, f); @@ -1247,7 +1274,20 @@ public class Convert_PostgreSQL extends Convert_SQL92 { } Update.append(updateField.trim()); Update.append("="); - Update.append(joinField); + if (useSubQuery) + { + Update.append("( SELECT "); + Update.append(joinField); + Update.append(" FROM "); + Update.append(joinFromClause); + Update.append(" WHERE "); + Update.append(subWhere.trim()); + Update.append(" ) "); + } + else + { + Update.append(joinField); + } Update.append(","); joinFields = joinFields.substring(fj + 1); } @@ -1285,6 +1325,46 @@ public class Convert_PostgreSQL extends Convert_SQL92 { String test = token.startsWith("(") ? token.substring(1) : token; if (sqlkey.indexOf(test) == -1) { + token = token.trim(); + //skip subquery, non identifier and fully qualified identifier + if (o != -1) + result = result + " " + token; + else + { + result = result + " "; + StringBuffer t = new StringBuffer(); + for (int i = 0; i < token.length(); i++) { + char c = token.charAt(i); + if(isOperator(c)) + { + if (t.length() > 0) + { + if (c == '(') + result = result + t.toString(); + else if (isIdentifier(t.toString()) && + t.toString().indexOf(".") == -1) + result = result + alias + "." + t.toString(); + else + result = result + t.toString(); + t = new StringBuffer(); + } + result = result + c; + } + else + { + t.append(c); + } + } + if (t.length() > 0) + { + if (isIdentifier(t.toString()) && + t.toString().indexOf(".") == -1) + result = result + alias + "." + t.toString(); + else + result = result + t.toString(); + } + } + if (o != -1) { for (int i = 0; i < token.length(); i++) { char c = token.charAt(i); @@ -1294,18 +1374,6 @@ public class Convert_PostgreSQL extends Convert_SQL92 { o--; } } - token = token.trim(); - //skip subquery, non identifier and fully qualified identifier - if (o == -1 - && (!token.contains(")") || !token - .contains("(")) - && isIdentifier(token) - && token.indexOf(".") == - 1) { - - result = result + " " + alias + "." + token; - } else { - result = result + " " + token; - } } else { result = result + " " + token; @@ -1319,6 +1387,65 @@ public class Convert_PostgreSQL extends Convert_SQL92 { return result; } + private boolean isOperator(char c) + { + if ('=' == c) + return true; + else if ('<' == c) + return true; + else if ('>' == c) + return true; + else if ('|' == c) + return true; + else if ('(' == c) + return true; + else if (')' == c) + return true; + else if ('+' == c) + return true; + else if ('-' == c) + return true; + else if ('*' == c) + return true; + else if ('/' == c) + return true; + else if ('!' == c) + return true; + else if (',' == c) + return true; + else + return false; + } + + private boolean isOperator(String token) + { + if ("=".equals(token)) + return true; + else if ("<>".equals(token)) + return true; + else if (">".equals(token)) + return true; + else if ("<".equals(token)) + return true; + else if ("<=".equals(token)) + return true; + else if (">=".equals(token)) + return true; + else if ("||".equals(token)) + return true; + else if ("+".equals(token)) + return true; + else if ("-".equals(token)) + return true; + else if ("*".equals(token)) + return true; + else if ("/".equals(token)) + return true; + else if ("!=".equals(token)) + return true; + else + return false; + } /** * Check if token is a valid sql identifier * @param token @@ -1326,29 +1453,9 @@ public class Convert_PostgreSQL extends Convert_SQL92 { */ private boolean isIdentifier(String token) { - if ("=".equals(token)) + if (isOperator(token)) return false; - else if ("<>".equals(token)) - return false; - else if (">".equals(token)) - return false; - else if ("<".equals(token)) - return false; - else if ("<=".equals(token)) - return false; - else if (">=".equals(token)) - return false; - else if ("||".equals(token)) - return false; - else if ("+".equals(token)) - return false; - else if ("-".equals(token)) - return false; - else if ("*".equals(token)) - return false; - else if ("/".equals(token)) - return false; - else if ("!=".equals(token)) + else if (token.startsWith("'") && token.startsWith("'")) return false; else { diff --git a/dbPort/src/org/compiere/dbPort/Convert_PostgreSQLTest.java b/dbPort/src/org/compiere/dbPort/Convert_PostgreSQLTest.java index b1843a20b9..b33a0fa3dc 100644 --- a/dbPort/src/org/compiere/dbPort/Convert_PostgreSQLTest.java +++ b/dbPort/src/org/compiere/dbPort/Convert_PostgreSQLTest.java @@ -139,6 +139,30 @@ public final class Convert_PostgreSQLTest { + " WHERE AD_Language='" + "es_MX" + "')"; r = convert.convert(sql); verify(sql, r, "INSERT INTO AD_Column_Trl(AD_Language,IsTranslated, AD_Client_ID,AD_Org_ID, Createdby,UpdatedBy, AD_Column_ID,Name) SELECT 'es_MX','N', AD_Client_ID,AD_Org_ID, 100,100, AD_Column_ID,Name FROM AD_Column WHERE AD_Column_ID NOT IN (SELECT AD_Column_ID FROM AD_Column_Trl WHERE AD_Language='es_MX')"); + + //https://sourceforge.net/forum/message.php?msg_id=4083672 + sql=" UPDATE AD_COLUMN c" + +" SET (ColumnName, Name, Description, Help) =" + +" (SELECT ColumnName, Name, Description, Help" + +" FROM AD_ELEMENT e WHERE c.AD_Element_ID=e.AD_Element_ID)," + +" Updated = SYSDATE" + +" WHERE EXISTS (SELECT 1 FROM AD_ELEMENT e " + +" WHERE c.AD_Element_ID=e.AD_Element_ID" + +" AND (c.ColumnName <> e.ColumnName OR c.Name <> e.Name " + +" OR NVL(c.Description,' ') <> NVL(e.Description,' ') OR NVL(c.Help,' ') <> NVL(e.Help,' ')))"; + r = convert.convert(sql); + verify(sql, r, "UPDATE AD_COLUMN SET ColumnName=e.ColumnName,Name=e.Name,Description=e.Description,Help=e.Help, Updated = CURRENT_TIMESTAMP FROM AD_ELEMENT e WHERE AD_COLUMN.AD_Element_ID=e.AD_Element_ID AND EXISTS (SELECT 1 FROM AD_ELEMENT e WHERE AD_COLUMN.AD_Element_ID=e.AD_Element_ID AND (AD_COLUMN.ColumnName <> e.ColumnName OR AD_COLUMN.Name <> e.Name OR COALESCE(AD_COLUMN.Description,' ') <> COALESCE(e.Description,' ') OR COALESCE(AD_COLUMN.Help,' ') <> COALESCE(e.Help,' ')))"); + + sql="UPDATE AD_WF_NODE n" + +" SET (Name, Description, Help) = (SELECT f.Name, f.Description, f.Help" + +" FROM AD_PROCESS f" + +" WHERE f.AD_Process_ID=n.AD_Process_ID)" + +" WHERE n.IsCentrallyMaintained = 'Y'" + +" AND EXISTS (SELECT 1 FROM AD_PROCESS f" + +" WHERE f.AD_Process_ID=n.AD_Process_ID" + +" AND (f.Name <> n.Name OR NVL(f.Description,' ') <> NVL(n.Description,' ') OR NVL(f.Help,' ') <> NVL(n.Help,' ')))"; + r = convert.convert(sql); + verify(sql, r, "UPDATE AD_WF_NODE SET Name=f.Name,Description=f.Description,Help=f.Help FROM AD_PROCESS f WHERE f.AD_Process_ID=AD_WF_NODE.AD_Process_ID AND AD_WF_NODE.IsCentrallyMaintained = 'Y' AND EXISTS (SELECT 1 FROM AD_PROCESS f WHERE f.AD_Process_ID=AD_WF_NODE.AD_Process_ID AND (f.Name <> AD_WF_NODE.Name OR COALESCE(f.Description,' ') <> COALESCE(AD_WF_NODE.Description,' ') OR COALESCE(f.Help,' ') <> COALESCE(AD_WF_NODE.Help,' ')))"); } private void verify(String original, String[] converted, String expected) {