Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add a RAW JOIN source to the query #163

Closed
wants to merge 4 commits into from
Closed
Show file tree
Hide file tree
Changes from 3 commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
43 changes: 43 additions & 0 deletions docs/querying.rst
Original file line number Diff line number Diff line change
Expand Up @@ -623,6 +623,49 @@ method to control which columns get returned.
->join('person', array('p1.parent', '=', 'p2.id'), 'p2')
->find_many();

Raw JOIN clauses
'''''''''''''''''

If you need to construct a more complex query, you can use the ``raw_join``
method to specify the SQL fragment for the JOIN clause exactly. This
method takes four required arguments: the string to add to the query,
the conditions is as an *array* containing three components:
the first column, the operator, and the second column, the table alias and
(optional) the parameters array. If parameters are supplied,
the string should contain question mark characters (``?``) to represent
the values to be bound, and the parameter array should contain the values
to be substituted into the string in the correct order.

This method may be used in a method chain alongside other ``*_join``
methods as well as methods such as ``offset``, ``limit`` and
``order_by_*``. The contents of the string you supply will be connected
with preceding and following JOIN clauses.

.. code-block:: php

<?php
$people = ORM::for_table('person')
->raw_join(
'JOIN (SELECT * FROM role WHERE role.name = ?)',
array('person.role_id', '=', 'role.id'),
'role',
array('role' => 'janitor'))
->order_by_asc('person.name')
->find_many();

// Creates SQL:
SELECT * FROM `person` JOIN (SELECT * FROM role WHERE role.name = 'janitor') `role` ON `person`.`role_id` = `role`.`id` ORDER BY `person`.`name` ASC

Note that this method only supports "question mark placeholder" syntax,
and NOT "named placeholder" syntax. This is because PDO does not allow
queries that contain a mixture of placeholder types. Also, you should
ensure that the number of question mark placeholders in the string
exactly matches the number of elements in the array.

If you require yet more flexibility, you can manually specify the entire
query. See *Raw queries* below.


Aggregate functions
^^^^^^^^^^^^^^^^^^^

Expand Down
24 changes: 24 additions & 0 deletions idiorm.php
Original file line number Diff line number Diff line change
Expand Up @@ -939,6 +939,30 @@ protected function _add_join_source($join_operator, $table, $constraint, $table_
return $this;
}

/**
* Add a RAW JOIN source to the query
*/
public function raw_join($table, $constraint, $table_alias, $parameters = array()) {
// Add table alias if present
if (!is_null($table_alias)) {
$table_alias = $this->_quote_identifier($table_alias);
$table .= " {$table_alias}";
}

$this->_values = $parameters;
Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

This looks too crude, and I think it breaks when multiple raw_joins are presents and maybe in other cases. So maybe we need to make merge but with index shift.

Copy link
Collaborator

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Let me know how you get on with this.


// Build the constraint
if (is_array($constraint)) {
list($first_column, $operator, $second_column) = $constraint;
$first_column = $this->_quote_identifier($first_column);
$second_column = $this->_quote_identifier($second_column);
$constraint = "{$first_column} {$operator} {$second_column}";
}

$this->_join_sources[] = "{$table} ON {$constraint}";
return $this;
}

/**
* Add a simple JOIN source to the query
*/
Expand Down
12 changes: 12 additions & 0 deletions test/QueryBuilderPsr1Test53.php
Original file line number Diff line number Diff line change
Expand Up @@ -385,6 +385,18 @@ public function testJoinWithStringConstraint() {
$this->assertEquals($expected, ORM::getLastQuery());
}

public function testRawJoin() {
ORM::forTable('widget')->rawJoin('INNER JOIN ( SELECT * FROM `widget_handle` )', array('widget_handle.widget_id', '=', 'widget.id'), 'widget_handle')->findMany();
$expected = "SELECT * FROM `widget` INNER JOIN ( SELECT * FROM `widget_handle` ) `widget_handle` ON `widget_handle`.`widget_id` = `widget`.`id`";
$this->assertEquals($expected, ORM::getLastQuery());
}

public function testRawJoinWithParameters() {
ORM::forTable('widget')->rawJoin('INNER JOIN ( SELECT * FROM `widget_handle` WHERE `widget_handle`.name LIKE ? AND `widget_handle`.category = ?)', array('widget_handle.widget_id', '=', 'widget.id'), 'widget_handle', array('%button%', 2))->findMany();
$expected = "SELECT * FROM `widget` INNER JOIN ( SELECT * FROM `widget_handle` WHERE `widget_handle`.name LIKE '%button%' AND `widget_handle`.category = '2') `widget_handle` ON `widget_handle`.`widget_id` = `widget`.`id`";
$this->assertEquals($expected, ORM::getLastQuery());
}

public function testSelectWithDistinct() {
ORM::forTable('widget')->distinct()->select('name')->findMany();
$expected = "SELECT DISTINCT `name` FROM `widget`";
Expand Down
12 changes: 12 additions & 0 deletions test/QueryBuilderTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -385,6 +385,18 @@ public function testJoinWithStringConstraint() {
$this->assertEquals($expected, ORM::get_last_query());
}

public function testRawJoin() {
ORM::for_table('widget')->raw_join('INNER JOIN ( SELECT * FROM `widget_handle` )', array('widget_handle.widget_id', '=', 'widget.id'), 'widget_handle')->find_many();
$expected = "SELECT * FROM `widget` INNER JOIN ( SELECT * FROM `widget_handle` ) `widget_handle` ON `widget_handle`.`widget_id` = `widget`.`id`";
$this->assertEquals($expected, ORM::get_last_query());
}

public function testRawJoinWithParameters() {
ORM::for_table('widget')->raw_join('INNER JOIN ( SELECT * FROM `widget_handle` WHERE `widget_handle`.name LIKE ? AND `widget_handle`.category = ?)', array('widget_handle.widget_id', '=', 'widget.id'), 'widget_handle', array('%button%', 2))->find_many();
$expected = "SELECT * FROM `widget` INNER JOIN ( SELECT * FROM `widget_handle` WHERE `widget_handle`.name LIKE '%button%' AND `widget_handle`.category = '2') `widget_handle` ON `widget_handle`.`widget_id` = `widget`.`id`";
$this->assertEquals($expected, ORM::get_last_query());
}

public function testSelectWithDistinct() {
ORM::for_table('widget')->distinct()->select('name')->find_many();
$expected = "SELECT DISTINCT `name` FROM `widget`";
Expand Down