mirror of
https://github.com/Combodo/iTop.git
synced 2026-02-13 07:24:13 +01:00
N°1213 - Allow NOT IN SELECT in OQL syntax - support of UNION queries and "nested nested" queries
This commit is contained in:
@@ -699,6 +699,26 @@ class DBObjectSearch extends DBSearch
|
||||
}
|
||||
}
|
||||
|
||||
public function RenameAliasesInNameSpace($aClassAliases, $aAliasTranslation = array())
|
||||
{
|
||||
// Recurse in nested queries
|
||||
$this->GetCriteria()->Browse(function($oNode) use ($aClassAliases, $aAliasTranslation) {
|
||||
if ($oNode instanceof NestedQueryExpression)
|
||||
{
|
||||
$oNestedQuery = $oNode->GetNestedQuery();
|
||||
$oNestedQuery->RenameAliasesInNameSpace($aClassAliases, $aAliasTranslation);
|
||||
}
|
||||
});
|
||||
$this->AddToNameSpace($aClassAliases, $aAliasTranslation);
|
||||
$this->TranslateConditions($aAliasTranslation, false, false);
|
||||
}
|
||||
|
||||
public function TranslateConditions($aTranslationData, $bMatchAll = true, $bMarkFieldsAsResolved = true)
|
||||
{
|
||||
$oExpression = $this->GetCriteria()->Translate($aTranslationData, $bMatchAll, $bMarkFieldsAsResolved);
|
||||
$this->ResetCondition();
|
||||
$this->AddConditionExpression($oExpression);
|
||||
}
|
||||
|
||||
// Browse the tree nodes recursively
|
||||
//
|
||||
|
||||
@@ -271,6 +271,10 @@ abstract class DBSearch
|
||||
*/
|
||||
abstract public function RenameAlias($sOldName, $sNewName);
|
||||
|
||||
abstract public function RenameAliasesInNameSpace($aClassAliases, $aAliasTranslation = array());
|
||||
|
||||
abstract public function TranslateConditions($aTranslationData, $bMatchAll = true, $bMarkFieldsAsResolved = true);
|
||||
|
||||
/**
|
||||
* @internal
|
||||
* @return mixed
|
||||
|
||||
@@ -258,6 +258,24 @@ class DBUnionSearch extends DBSearch
|
||||
return $bRet;
|
||||
}
|
||||
|
||||
public function RenameAliasesInNameSpace($aClassAliases, $aAliasTranslation = array())
|
||||
{
|
||||
foreach ($this->aSearches as $oSearch)
|
||||
{
|
||||
$oSearch->RenameAliasesInNameSpace($aClassAliases, $aAliasTranslation);
|
||||
}
|
||||
}
|
||||
|
||||
public function TranslateConditions($aTranslationData, $bMatchAll = true, $bMarkFieldsAsResolved = true)
|
||||
{
|
||||
foreach ($this->aSearches as $oSearch)
|
||||
{
|
||||
$oSearch->TranslateConditions($aTranslationData, $bMatchAll, $bMarkFieldsAsResolved);
|
||||
}
|
||||
}
|
||||
|
||||
|
||||
|
||||
public function IsAny()
|
||||
{
|
||||
$bIsAny = true;
|
||||
@@ -676,6 +694,8 @@ class DBUnionSearch extends DBSearch
|
||||
}
|
||||
}
|
||||
|
||||
|
||||
|
||||
public function AddConditionForInOperatorUsingParam($sFilterCode, $aValues, $bPositiveMatch = true)
|
||||
{
|
||||
$sInParamName = $this->GenerateUniqueParamName();
|
||||
|
||||
@@ -504,12 +504,7 @@ class BinaryExpression extends Expression
|
||||
$oRight = $this->GetRightExpr()->Translate($aTranslationData, $bMatchAll, $bMarkFieldsAsResolved);
|
||||
return new BinaryExpression($oLeft, $this->GetOperator(), $oRight);
|
||||
}
|
||||
public function GetCriteria()
|
||||
{
|
||||
$oLeft = $this->GetLeftExpr()->GetCriteria();
|
||||
$oRight = $this->GetRightExpr()->GetCriteria();
|
||||
return new BinaryExpression($oLeft, $this->GetOperator(), $oRight);
|
||||
}
|
||||
|
||||
public function ListRequiredFields()
|
||||
{
|
||||
$aLeft = $this->GetLeftExpr()->ListRequiredFields();
|
||||
@@ -1968,27 +1963,17 @@ class NestedQueryExpression extends Expression
|
||||
public function Translate($aTranslationData, $bMatchAll = true, $bMarkFieldsAsResolved = true)
|
||||
{
|
||||
// Check and prepare the select information
|
||||
$oExpression = $this->m_oNestedQuery->GetCriteria()->Translate($aTranslationData, $bMatchAll , $bMarkFieldsAsResolved );
|
||||
$this->m_oNestedQuery->ResetCondition();
|
||||
$this->m_oNestedQuery->AddConditionExpression($oExpression);
|
||||
$this->m_oNestedQuery->TranslateConditions($aTranslationData, $bMatchAll , $bMarkFieldsAsResolved );
|
||||
return clone $this;
|
||||
}
|
||||
|
||||
/*TODO*/
|
||||
public function ListRequiredFields()
|
||||
{
|
||||
$aRes = array();
|
||||
foreach ($this->m_oNestedQuery->getCondition() as $oExpr)
|
||||
{
|
||||
$aRes = array_merge($aRes, $oExpr->ListRequiredFields());
|
||||
}
|
||||
return $aRes;
|
||||
return array();
|
||||
}
|
||||
|
||||
/*TODO */
|
||||
public function CollectUsedParents(&$aTable)
|
||||
{
|
||||
|
||||
}
|
||||
|
||||
public function ListConstantFields()
|
||||
|
||||
@@ -50,6 +50,7 @@ class OQLClassTreeBuilder
|
||||
*/
|
||||
public function DevelopOQLClassNode()
|
||||
{
|
||||
$this->TranslateNestedRequests();
|
||||
$this->AddExternalKeysFromSearch();
|
||||
$aPolymorphicJoinAlias = $this->TranslatePolymorphicExpressions();
|
||||
$this->AddExpectedExternalFields();
|
||||
@@ -375,4 +376,19 @@ class OQLClassTreeBuilder
|
||||
$this->oOQLClassNode->AddLeftJoin($oSelectPoly, 'id', 'id', true);
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
/**
|
||||
* Rename class aliases of nested requests to avoid collision with main request
|
||||
*/
|
||||
private function TranslateNestedRequests()
|
||||
{
|
||||
$this->oDBObjetSearch->GetCriteria()->Browse(function($oNode) {
|
||||
if ($oNode instanceof NestedQueryExpression)
|
||||
{
|
||||
$oNestedQuery = $oNode->GetNestedQuery();
|
||||
$aClassAliases = $this->oDBObjetSearch->GetJoinedClasses();
|
||||
$oNestedQuery->RenameAliasesInNameSpace($aClassAliases);
|
||||
}
|
||||
});
|
||||
}
|
||||
}
|
||||
|
||||
@@ -114,7 +114,7 @@ class SQLUnionQuery extends SQLQuery
|
||||
|
||||
if ($bGetCount)
|
||||
{
|
||||
$sSelects = '('.implode(" $sLimit)$sLineSep UNION$sLineSep(", $aSelects)." $sLimit)";
|
||||
$sSelects = '('.implode(" $sLimit $sLineSep UNION$sLineSep ", $aSelects)." $sLimit)";
|
||||
$sFrom = "($sLineSep$sSelects$sLineSep) as __selects__";
|
||||
$sSQL = "SELECT COUNT(*) AS COUNT FROM (SELECT$sLineSep 1 $sLineSep FROM $sFrom$sLineSep) AS _union_alderaan_";
|
||||
}
|
||||
@@ -124,11 +124,11 @@ class SQLUnionQuery extends SQLQuery
|
||||
if (!empty($sOrderBy))
|
||||
{
|
||||
$sOrderBy = "ORDER BY $sOrderBy$sLineSep $sLimit";
|
||||
$sSQL = '('.implode(")$sLineSep UNION$sLineSep (", $aSelects).')'.$sLineSep.$sOrderBy;
|
||||
$sSQL = '('.implode(" $sLineSep UNION$sLineSep ", $aSelects).')'.$sLineSep.$sOrderBy;
|
||||
}
|
||||
else
|
||||
{
|
||||
$sSQL = '('.implode(" $sLimit)$sLineSep UNION$sLineSep (", $aSelects)." $sLimit)";
|
||||
$sSQL = '('.implode(" $sLimit $sLineSep UNION$sLineSep ", $aSelects)." $sLimit)";
|
||||
}
|
||||
}
|
||||
return $sSQL;
|
||||
|
||||
@@ -167,10 +167,14 @@ class OQLToSQLNestedSelectTest extends ItopDataTestCase
|
||||
private function OQLSelectProviderStatic()
|
||||
{
|
||||
return array(
|
||||
array('SELECT `UserRequest` FROM UserRequest AS `UserRequest` JOIN Person AS `P` ON `UserRequest`.agent_id = `P`.id JOIN Organization AS `Organization` ON `P`.org_id = `Organization`.id WHERE (`UserRequest`.`org_id` IN (SELECT `Organization` FROM Organization AS `Organization` WHERE (`Organization`.`id` = `UserRequest`.`org_id`)))'),
|
||||
"SELECT UserRequest 112" => array('SELECT `UserRequest` FROM UserRequest AS `UserRequest` WHERE (`UserRequest`.org_id IN (SELECT `Organization` FROM Organization AS `Organization` WHERE (`Organization`.`id` = `UserRequest`.`org_id`)))'),
|
||||
"SELECT UserRequest 113" => array("SELECT `UserRequest` FROM UserRequest AS `UserRequest` WHERE `UserRequest`.org_id IN (SELECT `Organization` FROM Organization AS `Organization` JOIN Organization AS `Organization1` ON `Organization`.parent_id BELOW `Organization1`.id WHERE (`Organization1`.`id` = '3'))", array('UserRequest.friendlyname' => true)),
|
||||
"SELECT UserRequest 111" => array("SELECT `UserRequest` FROM UserRequest AS `UserRequest` WHERE `UserRequest`.org_id IN (1,2,3)", array('UserRequest.friendlyname' => true)),
|
||||
array('SELECT `UserRequest` FROM UserRequest AS `UserRequest` JOIN Person AS `P` ON `UserRequest`.agent_id = `P`.id JOIN Organization AS `Organization` ON `P`.org_id = `Organization`.id WHERE (`UserRequest`.`org_id` IN (SELECT `Organization` FROM Organization AS `Organization` WHERE (`Organization`.`id` = `UserRequest`.`org_id`)))',),
|
||||
array('SELECT `UserRequest` FROM UserRequest AS `UserRequest` WHERE (`UserRequest`.org_id IN (SELECT `Organization` FROM Organization AS `Organization` WHERE (`Organization`.`id` = `UserRequest`.`org_id`)))'),
|
||||
array("SELECT `UserRequest` FROM UserRequest AS `UserRequest` WHERE `UserRequest`.org_id IN (SELECT `Organization` FROM Organization AS `Organization` JOIN Organization AS `Organization1` ON `Organization`.parent_id BELOW `Organization1`.id WHERE (`Organization1`.`id` = '3'))"),
|
||||
array("SELECT `UserRequest` FROM UserRequest AS `UserRequest` WHERE `UserRequest`.org_id IN (1,2,3)"),
|
||||
array("SELECT User AS U JOIN Person AS P ON U.contactid = P.id WHERE U.status='enabled' AND U.id NOT IN (SELECT User AS U JOIN Person AS P ON U.contactid=P.id JOIN URP_UserOrg AS L ON L.userid = U.id WHERE U.status='enabled' AND L.allowed_org_id = P.org_id UNION SELECT User AS U WHERE U.status='enabled' AND U.id NOT IN (SELECT User AS U JOIN URP_UserOrg AS L ON L.userid = U.id WHERE U.status='enabled'))"),
|
||||
array("SELECT UserRequest AS Ur WHERE Ur.id NOT IN (SELECT UserRequest AS Ur JOIN lnkFunctionalCIToTicket AS lnk ON lnk.ticket_id = Ur.id)"),
|
||||
array("SELECT Ticket AS T WHERE T. finalclass IN ('userrequest' , 'change') AND T.id NOT IN (SELECT UserRequest AS Ur JOIN lnkFunctionalCIToTicket AS lnk ON lnk.ticket_id = Ur.id UNION SELECT Change AS C JOIN lnkFunctionalCIToTicket AS lnk ON lnk.ticket_id = C.id)"),
|
||||
array("SELECT PhysicalDevice WHERE status='production' AND id NOT IN (SELECT PhysicalDevice AS p JOIN lnkFunctionalCIToProviderContract AS l ON l.functionalci_id=p.id)"),
|
||||
);
|
||||
}
|
||||
|
||||
|
||||
@@ -11,7 +11,6 @@ namespace Combodo\iTop\Test\UnitTest\Core;
|
||||
|
||||
|
||||
use Combodo\iTop\Test\UnitTest\ItopDataTestCase;
|
||||
use Combodo\iTop\Test\UnitTest\ItopTestCase;
|
||||
use DBObjectSearch;
|
||||
|
||||
/**
|
||||
@@ -42,6 +41,10 @@ class OQLParserTest extends ItopDataTestCase
|
||||
public function NestedQueryProvider()
|
||||
{
|
||||
return array(
|
||||
array("SELECT `U` FROM User AS `U` JOIN Person AS `P` ON `U`.contactid = `P`.id WHERE ((`U`.`status` = 'enabled') AND (`U`.`id` NOT IN (SELECT `U` FROM User AS `U` JOIN Person AS `P` ON `U`.contactid = `P`.id JOIN URP_UserOrg AS `L` ON `L`.userid = `U`.id WHERE ((`U`.`status` = 'enabled') AND (`L`.`allowed_org_id` = `P`.`org_id`)) UNION SELECT `U` FROM User AS `U` WHERE ((`U`.`status` = 'enabled') AND (`U`.`id` NOT IN (SELECT `U` FROM User AS `U` JOIN URP_UserOrg AS `L` ON `L`.userid = `U`.id WHERE (`U`.`status` = 'enabled')))))))"),
|
||||
array("SELECT `Ur` FROM UserRequest AS `Ur` WHERE (`Ur`.`id` NOT IN (SELECT `Ur` FROM UserRequest AS `Ur` JOIN lnkFunctionalCIToTicket AS `lnk` ON `lnk`.ticket_id = `Ur`.id WHERE 1))"),
|
||||
array("SELECT `T` FROM Ticket AS `T` WHERE ((`T`.`finalclass` IN ('userrequest', 'change')) AND (`T`.`id` NOT IN (SELECT `Ur` FROM UserRequest AS `Ur` JOIN lnkFunctionalCIToTicket AS `lnk` ON `lnk`.ticket_id = `Ur`.id WHERE 1 UNION SELECT `C` FROM Change AS `C` JOIN lnkFunctionalCIToTicket AS `lnk` ON `lnk`.ticket_id = `C`.id WHERE 1)))"),
|
||||
array("SELECT `PhysicalDevice` FROM PhysicalDevice AS `PhysicalDevice` WHERE ((`PhysicalDevice`.`status` = 'production') AND (`PhysicalDevice`.`id` NOT IN (SELECT `p` FROM PhysicalDevice AS `p` JOIN lnkFunctionalCIToProviderContract AS `l` ON `l`.functionalci_id = `p`.id WHERE 1)))"),
|
||||
array('SELECT `UserRequest` FROM UserRequest AS `UserRequest` JOIN Person AS `P` ON `UserRequest`.agent_id = `P`.id JOIN Organization AS `Organization` ON `P`.org_id = `Organization`.id WHERE (`UserRequest`.`org_id` IN (SELECT `Organization` FROM Organization AS `Organization` WHERE (`Organization`.`id` = `UserRequest`.`org_id`)))'),
|
||||
array('SELECT `UserRequest` FROM UserRequest AS `UserRequest` WHERE (`UserRequest`.`org_id` IN (SELECT `Organization` FROM Organization AS `Organization` WHERE (`Organization`.`id` = `UserRequest`.`org_id`)))'),
|
||||
array('SELECT `UserRequest` FROM UserRequest AS `UserRequest` WHERE (`UserRequest`.`org_id` IN (SELECT `Organization` FROM Organization AS `Organization` WHERE 1))'),
|
||||
|
||||
@@ -69,19 +69,7 @@ class OQLTest extends ItopDataTestCase
|
||||
array('SELECT toto WHERE id IN (SELECT titi AS ti JOIN toto AS to ON to.a=ti.b)'),
|
||||
array('SELECT toto WHERE id IN (SELECT titi AS ti JOIN toto AS to ON to.a=ti.b WHERE to.a=1)'),
|
||||
array('SELECT toto WHERE id NOT IN (SELECT titi)'),
|
||||
array("SELECT User AS U JOIN Person AS P ON U.contactid = P.id
|
||||
WHERE U.status='enabled' AND U.id NOT IN (
|
||||
SELECT User AS U
|
||||
JOIN Person AS P ON U.contactid=P.id
|
||||
JOIN URP_UserOrg AS L ON L.userid = U.id
|
||||
WHERE U.status='enabled' AND L.allowed_org_id = P.org_id
|
||||
UNION SELECT User AS U
|
||||
WHERE U.status='enabled' AND U.id NOT IN (
|
||||
SELECT User AS U
|
||||
JOIN URP_UserOrg AS L ON L.userid = U.id
|
||||
WHERE U.status='enabled'
|
||||
)
|
||||
)"),
|
||||
array("SELECT User AS U JOIN Person AS P ON U.contactid = P.id WHERE U.status='enabled' AND U.id NOT IN (SELECT User AS U JOIN Person AS P ON U.contactid=P.id JOIN URP_UserOrg AS L ON L.userid = U.id WHERE U.status='enabled' AND L.allowed_org_id = P.org_id UNION SELECT User AS U WHERE U.status='enabled' AND U.id NOT IN ( SELECT User AS U JOIN URP_UserOrg AS L ON L.userid = U.id WHERE U.status='enabled'))"),
|
||||
array("SELECT UserRequest AS Ur WHERE Ur.id NOT IN (SELECT UserRequest AS Ur JOIN lnkFunctionalCIToTicket AS lnk ON lnk.ticket_id = Ur.id)"),
|
||||
array("SELECT Ticket AS T WHERE T. finalclass IN ('userrequest' , 'change') AND T.id NOT IN (SELECT UserRequest AS Ur JOIN lnkFunctionalCIToTicket AS lnk ON lnk.ticket_id = Ur.id UNION SELECT Change AS C JOIN lnkFunctionalCIToTicket AS lnk ON lnk.ticket_id = C.id)"),
|
||||
array("SELECT PhysicalDevice WHERE status='production' AND id NOT IN (SELECT PhysicalDevice AS p JOIN lnkFunctionalCIToProviderContract AS l ON l.functionalci_id=p.id)"),
|
||||
|
||||
Reference in New Issue
Block a user