Skip to content

Commit

Permalink
Merge pull request #10 from shopwareLabs/fix-subselect-with-multiple-…
Browse files Browse the repository at this point in the history
…nodes-query

Fix subselect with multiple nodes query
  • Loading branch information
JanPietrzyk authored Oct 5, 2017
2 parents 824a86c + 29b737b commit 1879050
Show file tree
Hide file tree
Showing 3 changed files with 99 additions and 21 deletions.
61 changes: 48 additions & 13 deletions src/NestedSetQueryFactory.php
Original file line number Diff line number Diff line change
Expand Up @@ -143,35 +143,54 @@ public function createSubtreeThroughMultipleNodesQueryBuilder(string $tableExpre

$directNodeSubSelect = $this->connection->createQueryBuilder()
->select([
"{$queryAlias}directNode." . $this->pkCol,
"{$queryAlias}directNode." . $this->leftCol,
"{$queryAlias}directNode." . $this->rightCol,
"{$queryAlias}directNode." . $this->levelCol,
"{$queryAlias}directNode." . $this->rootCol,
])
->from($this->connection->quoteIdentifier($tableExpression), "{$queryAlias}directNode")
->andWhere("{$queryAlias}directNode.{$this->pkCol} IN (:{$queryAlias}nodeIds)");

$siblingQuery = $this->connection->createQueryBuilder()

$parentQuery = $this->connection->createQueryBuilder()
->select([
"{$queryAlias}SiblingNode." . $this->pkCol,
"{$queryAlias}SiblingNode." . $this->leftCol,
"{$queryAlias}SiblingNode." . $this->rightCol,
"{$queryAlias}SiblingNode." . $this->levelCol,
"{$queryAlias}SiblingNode." . $this->rootCol,
])
->from($this->connection->quoteIdentifier($tableExpression), "{$queryAlias}SiblingNode")
->innerJoin(
"{$queryAlias}SiblingNode",
$this->connection->quoteIdentifier($tableExpression),
"{$queryAlias}ParentNode",
"
{$queryAlias}SiblingNode.{$this->leftCol} >= {$queryAlias}ParentNode.{$this->leftCol}
AND {$queryAlias}SiblingNode.{$this->rightCol} <= {$queryAlias}ParentNode.{$this->rightCol}
AND {$queryAlias}SiblingNode.{$this->levelCol} = {$queryAlias}ParentNode.{$this->levelCol} + 1
AND {$queryAlias}SiblingNode.{$this->rootCol} = {$queryAlias}ParentNode.{$this->rootCol}
"
)
->innerJoin(
"{$queryAlias}ParentNode",
'(' . $directNodeSubSelect->getSQL() . ')',
"{$queryAlias}SelectedNode",
"
{$queryAlias}SiblingNode.{$this->leftCol} >= {$queryAlias}SelectedNode.{$this->leftCol}
AND {$queryAlias}SiblingNode.{$this->rightCol} >= {$queryAlias}SelectedNode.{$this->rightCol}
AND {$queryAlias}SiblingNode.{$this->levelCol} = {$queryAlias}SelectedNode.{$this->levelCol}"
{$queryAlias}ParentNode.{$this->leftCol} < {$queryAlias}SelectedNode.{$this->leftCol}
AND {$queryAlias}ParentNode.{$this->rightCol} > {$queryAlias}SelectedNode.{$this->rightCol}
AND {$queryAlias}ParentNode.{$this->rootCol} = {$queryAlias}SelectedNode.{$this->rootCol}
"
);

$childrenQuery = $this->connection->createQueryBuilder()
->select([
"{$queryAlias}ChildNode." . $this->pkCol,
"{$queryAlias}ChildNode." . $this->leftCol,
"{$queryAlias}ChildNode." . $this->rightCol,
"{$queryAlias}ChildNode." . $this->levelCol,
"{$queryAlias}ChildNode." . $this->rootCol,
])
->from($this->connection->quoteIdentifier($tableExpression), "{$queryAlias}ChildNode")
->innerJoin(
Expand All @@ -181,19 +200,35 @@ public function createSubtreeThroughMultipleNodesQueryBuilder(string $tableExpre
"
{$queryAlias}ChildNode.{$this->leftCol} > {$queryAlias}SelectedNode.{$this->leftCol}
AND {$queryAlias}ChildNode.{$this->rightCol} < {$queryAlias}SelectedNode.{$this->rightCol}
AND {$queryAlias}ChildNode.{$this->levelCol} <= ({$queryAlias}SelectedNode.{$this->levelCol} + :{$queryAlias}maxChildLevel)"
AND {$queryAlias}ChildNode.{$this->levelCol} <= ({$queryAlias}SelectedNode.{$this->levelCol} + :{$queryAlias}maxChildLevel)
AND {$queryAlias}ChildNode.{$this->rootCol} = {$queryAlias}SelectedNode.{$this->rootCol}
"
);

$idQuery = $this->connection->createQueryBuilder()
->select("{$queryAlias}Group.{$this->pkCol}")
->from($this->connection->quoteIdentifier($tableExpression), "{$queryAlias}Group")
$rootQuery = $this->connection->createQueryBuilder()
->select([
"{$queryAlias}RootNode." . $this->pkCol,
"{$queryAlias}RootNode." . $this->leftCol,
"{$queryAlias}RootNode." . $this->rightCol,
"{$queryAlias}RootNode." . $this->levelCol,
"{$queryAlias}RootNode." . $this->rootCol,
])
->from($this->connection->quoteIdentifier($tableExpression), "{$queryAlias}RootNode")
->innerJoin(
"{$queryAlias}Group",
'((' . $childrenQuery->getSQL() . ') UNION (' . $siblingQuery->getSQL() . '))',
"{$queryAlias}SourceNode",
"{$queryAlias}RootNode",
'(' . $directNodeSubSelect->getSQL() . ')',
"{$queryAlias}SelectedNode",
"
{$queryAlias}RootNode.{$this->levelCol} = 0
AND {$queryAlias}RootNode.{$this->rootCol} = {$queryAlias}SelectedNode.{$this->rootCol}
"
{$queryAlias}Group.{$this->leftCol} <= {$queryAlias}SourceNode.{$this->leftCol}
AND {$queryAlias}Group.{$this->rightCol} >= {$queryAlias}SourceNode.{$this->rightCol}"
);

$idQuery = $this->connection->createQueryBuilder()
->select("{$queryAlias}Group.{$this->pkCol}")
->from(
'((' . $childrenQuery->getSQL() . ') UNION (' . $parentQuery->getSQL() . ') UNION (' . $rootQuery->getSQL() . ')) ',
"{$queryAlias}Group"
)
->groupBy("{$queryAlias}Group.id");

Expand Down
57 changes: 50 additions & 7 deletions tests/NestedSetQueryFactoryTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -19,6 +19,7 @@ public function setUp()
$connection = \NestedSetBootstrap::getConnection();
\NestedSetBootstrap::importTable();
\NestedSetBootstrap::insertDemoTree();
\NestedSetBootstrap::insertDemoTree(2);
$this->queryFactory = NestedSetFactory::createQueryFactory($connection, new NestedSetConfig('id', 'left', 'right', 'level'));
}

Expand Down Expand Up @@ -99,11 +100,47 @@ public function test_fetch_all_roots()

$rows = $qb->execute()->fetchAll();

$this->assertCount(1, $rows);
$this->assertCount(2, $rows);
$this->assertEquals('Clothing', $rows[0]['name']);
$this->assertEquals('Clothing', $rows[1]['name']);
}

public function test_fetch_subtree_with_root_only_selected()
{
$qb = $this->queryFactory
->createSubtreeThroughMultipleNodesQueryBuilder('tree', 't', 'root_id', [1])
->select('*');

$this->assertSubTree(
[
'Clothing',
'Mens',
'Women',
],
$qb->execute()->fetchAll()
);
}

public function test_fetch_subtree_with_a_single_selected_node_slacks()
{
$qb = $this->queryFactory
->createSubtreeThroughMultipleNodesQueryBuilder('tree', 't', 'root_id', [5])
->select('*');

$this->assertSubTree(
[
'Clothing',
'Mens',
'Suits',
'Slacks',
'Jackets',
'Women',
],
$qb->execute()->fetchAll()
);
}

public function test_fetch_subtree_with_selected_nodes()
public function test_fetch_subtree_with_selected_nodes_mens_and_dresses()
{
$qb = $this->queryFactory
->createSubtreeThroughMultipleNodesQueryBuilder('tree', 't', 'root_id', [2, 7])
Expand All @@ -123,7 +160,10 @@ public function test_fetch_subtree_with_selected_nodes()
],
$qb->execute()->fetchAll()
);
}

public function test_fetch_subtree_with_selected_nodes_mens_and_women()
{
$qb = $this->queryFactory
->createSubtreeThroughMultipleNodesQueryBuilder('tree', 't', 'root_id', [3, 2])
->select('*');
Expand All @@ -142,7 +182,7 @@ public function test_fetch_subtree_with_selected_nodes()
);
}

public function test_fetch_subtree_with_selected_nodes_uses_the_depth_parameter()
public function test_fetch_subtree_with_selected_nodes_with_a_two_as_a_depth_parameter()
{
$qb = $this->queryFactory
->createSubtreeThroughMultipleNodesQueryBuilder('tree', 't', 'root_id', [2, 3], 2)
Expand All @@ -164,7 +204,10 @@ public function test_fetch_subtree_with_selected_nodes_uses_the_depth_parameter(
],
$qb->execute()->fetchAll()
);
}

public function test_fetch_subtree_with_selected_nodes_with_a_zero_depth_parameter()
{
$qb = $this->queryFactory
->createSubtreeThroughMultipleNodesQueryBuilder('tree', 't', 'root_id', [3, 2], 0)
->select('*');
Expand All @@ -181,10 +224,10 @@ public function test_fetch_subtree_with_selected_nodes_uses_the_depth_parameter(

private function assertSubTree(array $expectedNames, array $rows)
{
$this->assertCount(count($expectedNames), $rows, print_r($rows, true));
$names = array_map(function (array $node) {
return $node['name'];
}, $rows);

foreach ($expectedNames as $index => $name) {
$this->assertEquals($name, $rows[$index]['name']);
}
$this->assertEquals($expectedNames, $names, 'Got: ' . print_r($names, true) . "\n and expected: " . print_r($expectedNames, true));
}
}
2 changes: 1 addition & 1 deletion tests/_bootstrap.php
Original file line number Diff line number Diff line change
Expand Up @@ -109,7 +109,7 @@ public static function insertDemoTree(int $rootId = 1)

foreach ($data as list($id, $left, $right, $level, $name)) {
self::getConnection()->insert('tree', [
'`id`' => $id,
'`id`' => $id + (20 * ($rootId - 1)),
'`left`' => $left,
'`right`' => $right,
'`level`' => $level,
Expand Down

0 comments on commit 1879050

Please sign in to comment.