Skip to content

DOCS-53 SQL to agg framework #252

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

Merged
merged 2 commits into from
Sep 26, 2012
Merged
Show file tree
Hide file tree
Changes from all 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
4 changes: 3 additions & 1 deletion source/aggregation.txt
Original file line number Diff line number Diff line change
Expand Up @@ -10,7 +10,8 @@ a natural method for aggregating data inside of MongoDB.
For a description of MongoDB aggregation, see
:doc:`/applications/aggregation`. For examples of aggregation, see
:doc:`/tutorial/aggregation-examples`. For descriptions of aggregation
operators, see :doc:`/reference/aggregation`.
operators, see :doc:`/reference/aggregation`. For SQL to aggregation
framework mapping, see :doc:`/sql-reference/sql-aggregation`.

The following is the outline of the aggregation documentation:

Expand All @@ -20,3 +21,4 @@ The following is the outline of the aggregation documentation:
applications/aggregation
tutorial/aggregation-examples
reference/aggregation
sql-reference/sql-aggregation
351 changes: 351 additions & 0 deletions source/sql-reference/sql-aggregation.txt
Original file line number Diff line number Diff line change
@@ -0,0 +1,351 @@
.. default-domain:: mongodb

SQL to Aggregation Framework
----------------------------

With the :doc:`/applications/aggregation`, MongoDB provides analogous
functionality to common SQL aggregation functions.

COUNT(*)
~~~~~~~~

MongoDB provides three ways to perform the SQL operation of ``count(*)``:

- the :dbcommand:`count()` command
- the :method:`count() <cursor.count()>` method
- the :agg:pipeline:`$group` operator in conjunction with the
:agg:expression:`$sum` operator in the
:doc:`/applications/aggregation`.

Consider the following SQL command which performs a count of the rows
in the ``orders`` table:

.. code-block:: sql

SELECT COUNT(*) AS count
FROM orders

In MongoDB,

- the analogous query using the :dbcommand:`count()` command is:

.. code-block:: javascript
:emphasize-lines: 1

db.orders.count()

- the analogous query using the :method:`count() <cursor.count()>`
method is:

.. code-block:: javascript
:emphasize-lines: 1

db.orders.find().count()

- the analogous query using the :doc:`/applications/aggregation` is:

.. code-block:: javascript
:emphasize-lines: 1

db.orders.aggregate( [ { $group: { _id: null, count: { $sum: 1 } } } ] )

The :doc:`/applications/aggregation` query performs a
:agg:pipeline:`$group` operation that uses the :agg:expression:`$sum`
operator to calculate the ``count`` with no grouping. Within the :agg:pipeline:`$group`
operation, the :agg:expression:`$sum` operator calculates the ``count``
by adding ``1`` for each document in the ``orders`` collection as grouped by ``null``.

SUM(<column>)
~~~~~~~~~~~~~

MongoDB provides aggregation :agg:expression:`$sum` operator to perform the
SQL operation of ``sum(<column>)``.

Consider the following SQL command which sums the ``price`` column in
the ``orders`` table:

.. code-block:: sql

SELECT SUM(price) AS total
FROM orders

In MongoDB, the analogous query using the
:doc:`/applications/aggregation` is:

.. code-block:: javascript
:emphasize-lines: 1

db.orders.aggregate( [ { $group: { _id: null, total: { $sum: "$price" } } } ] )

The :doc:`/applications/aggregation` query performs a
:agg:pipeline:`$group` operation that uses the :agg:expression:`$sum`
operator to calculate the ``total`` on the ``price`` field grouped by
``null`` (i.e. with no grouping.)

Note the ``$`` in front of the field ``price`` as it appears as an
operand to the aggregation operators.

GROUP BY(<column>...)
~~~~~~~~~~~~~~~~~~~~~

MongoDB provides aggregation :agg:expression:`$group` operator to perform the
SQL operation of ``GROUP BY ()``.

*Grouping by single column*

Consider the following SQL command which groups the ``price`` information by
``cust_id``:

.. code-block:: sql

SELECT cust_id, SUM(price) AS total
FROM orders
GROUP BY cust_id

In MongoDB, the analogous query using the
:doc:`/applications/aggregation` is:

.. code-block:: javascript
:emphasize-lines: 1

db.orders.aggregate( [ { $group: { _id: "$cust_id" , total: { $sum: "$price" } } } ] )

The :doc:`/applications/aggregation` query performs a
:agg:pipeline:`$group` operation that uses the :agg:expression:`$sum`
operator to calculate the ``total`` on the ``price`` field as grouped
by the ``cust_id`` field.

Note the ``$`` in front of the fields ``cust_id`` and ``price`` as they
appear as operands to the aggregation operators.

*Grouping by multiple columns*

Consider the following SQL command which groups the ``price``
information by both ``cust_id`` and ``ord_date``:

.. code-block:: sql

SELECT cust_id, ord_date, SUM(price) AS total
FROM orders
GROUP BY cust_id, ord_date

In MongoDB, the analogous query using the
:doc:`/applications/aggregation` is:

.. code-block:: javascript
:emphasize-lines: 1

db.orders.aggregate( [ { $group: { _id: { cust_id: "$cust_id", ord_date: "$ord_date" }, total: { $sum: "$price" } } } ] )

The :doc:`/applications/aggregation` query performs the
:agg:pipeline:`$group` operation that uses the :agg:expression:`$sum`
operator to calculate the ``total`` on the ``price`` field as grouped
by the ``cust_id`` and ``ord_date`` fields.

Note the ``$`` in front of the fields ``cust_id``, ``ord_date``, and
``price`` as they appear as operands to the aggregation operators.

GROUP BY ... HAVING ...
~~~~~~~~~~~~~~~~~~~~~~~

MongoDB provides aggregation :agg:expression:`$group` and
:agg:expression:`$match` operators to perform the SQL operation of
``GROUP BY ... HAVING ...``.

*Grouping by single column ... having*

Consider the following SQL command which can be used to find the
``cust_id`` 's with multiple rows:

.. code-block:: sql

SELECT cust_id, count(*)
FROM orders
GROUP BY cust_id
HAVING count(*) > 1

In MongoDB, the analogous query using the
:doc:`/applications/aggregation` is:

.. code-block:: javascript
:emphasize-lines: 2-3

db.orders.aggregate( [
{ $group: { _id: "$cust_id", count: { $sum: 1 } } },
{ $match: { count: { $gt: 1 } } }
] )

The :doc:`/applications/aggregation` query first performs a
:agg:pipeline:`$group` operation that uses the :agg:expression:`$sum`
operator to calculate the ``count`` of the documents grouped by
``cust_id``. Then the query pipes the results to the
:agg:expression:`$match` operator that returns only those results that
have ``count`` greater than ``1``.

Note the ``$`` in front of the fields ``cust_id`` as it appear as an
operand to the aggregation operators.

*Grouping by multiple columns ... having*

Consider the following SQL command which can be used to find the
calculated column ``total`` greater than ``250`` grouped by ``cust_id`` and
``ord_date``:

.. code-block:: sql

SELECT cust_id, ord_date, SUM(price) AS total
FROM orders
GROUP BY cust_id, ord_date
HAVING total > 250

In MongoDB, the analogous query using the
:doc:`/applications/aggregation` is:

.. code-block:: javascript
:emphasize-lines: 2-3

db.orders.aggregate( [
{ $group: { _id: { cust_id: "$cust_id", ord_date: "$ord_date" }, total: { $sum: "$price" } } },
{ $match: { total: { $gt: 250 } } }
] )

The :doc:`/applications/aggregation` query first performs a
:agg:pipeline:`$group` operation that uses the :agg:expression:`$sum`
operator to calculate the ``total`` on the ``price`` field as grouped
by the ``cust_id`` and ``ord_date`` fields. Then the query pipes the
results to the :agg:expression:`$match` operator that returns only
those results that have ``total`` greater than ``250``.

Note the ``$`` in front of the fields ``cust_id``, ``ord_date``, and
``price`` as they appear as operands to the aggregation operators.

WHERE ... GROUP BY
~~~~~~~~~~~~~~~~~~
MongoDB provides aggregation :agg:expression:`$group` and
:agg:expression:`$match` operators to perform the SQL operation of
``WHERE ... GROUP BY``.

Consider the following SQL command which can be used to find the
``cust_id`` and the calculated column ``total`` for orders with status
``A`` grouped by ``cust_id``:

.. code-block:: sql

SELECT cust_id, SUM(price) as total
FROM orders
WHERE status = 'A'
GROUP BY cust_id

In MongoDB, the analogous query using the
:doc:`/applications/aggregation` is:

.. code-block:: javascript
:emphasize-lines: 2-3

db.orders.aggregate( [
{ $match: { status: 'A' } },
{ $group: { _id: "$cust_id", total: { $sum: "$price" } } }
] )

The :doc:`/applications/aggregation` query first performs a
:agg:expression:`$match` operation that returns only those documents
that have ``status`` field equal to ``A``. Then the query pipes the
results to the :agg:pipeline:`$group` operation that uses the
:agg:expression:`$sum` operator to calculate the ``total`` on the
``price`` field as grouped by the ``cust_id`` field.

Note the ``$`` in front of the fields ``cust_id`` and
``price`` as they appear as operands to the aggregation operators.

WHERE ... GROUP BY ... HAVING ...
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~

MongoDB provides aggregation :agg:expression:`$group` and
:agg:expression:`$match` operators to perform the SQL operation of
``WHERE ... GROUP BY ... HAVING``.

Consider the following SQL command which can be used to find the
``cust_id`` and the calculated column ``total`` for orders with status
``A`` grouped by ``cust_id`` having ``total`` greater than ``250``:

.. code-block:: sql

SELECT cust_id, SUM(price) as total
FROM orders
WHERE status = 'A'
GROUP BY cust_id
HAVING total > 250

In MongoDB, the analogous query using the
:doc:`/applications/aggregation` is:

.. code-block:: javascript
:emphasize-lines: 2-4

db.orders.aggregate( [
{ $match: { status: 'A' } },
{ $group: { _id: "$cust_id", total: { $sum: "$price" } } } ,
{ $match: { total: { $gt: 250 } } }
] )

The :doc:`/applications/aggregation` query first performs a
:agg:expression:`$match` operation that returns only those documents
that have ``status`` field equal to ``A``. Then the query pipes the
results to the :agg:pipeline:`$group` operation that uses the
:agg:expression:`$sum` operator to calculate the ``total`` on the
``price`` field as grouped by the ``cust_id`` field. Finally the query
pipes those results to the :agg:expression:`$match` operator that
returns only those results that have ``total`` greater than ``250``.

Note the ``$`` in front of the fields ``cust_id`` and
``price`` as they appear as operands to the aggregation operators.

WHERE ... GROUP BY ... HAVING ... ORDER BY
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~

MongoDB provides aggregation :agg:expression:`$group` and
:agg:expression:`$match` operators to perform the SQL operation of
``WHERE ... GROUP BY ... HAVING ... ORDER BY``.

Consider the following SQL command which can be used to find the
``cust_id`` and the calculated column ``total`` for orders with status
``A`` grouped by ``cust_id`` having ``total`` greater than ``250``. The
results will be sorted first by descending ``total`` and then by
ascending ``cust_id``:

.. code-block:: sql

SELECT cust_id, SUM(price) as total
FROM orders
WHERE status = 'A'
GROUP BY cust_id
HAVING total > 250
ORDER BY total DESC, cust_id ASC

In MongoDB, the analogous query using the
:doc:`/applications/aggregation` is:

.. code-block:: javascript
:emphasize-lines: 2-5

db.orders.aggregate( [
{ $match: { status: 'A' } },
{ $group: { _id: "$cust_id", total: { $sum: "$price" } } } ,
{ $match: { total: { $gt: 250 } } },
{ $sort: { total: -1, _id: 1 } }
] )

The :doc:`/applications/aggregation` query first performs a
:agg:expression:`$match` operation that returns only those documents
that have ``status`` field equal to ``A``. Next, the query pipes the
results to the :agg:pipeline:`$group` operation that uses the
:agg:expression:`$sum` operator to calculate the ``total`` on the
``price`` field as grouped by the ``cust_id`` field. Then, the query
pipes those results to the :agg:expression:`$match` operator that
returns only those results that have ``total`` greater than ``250``.
Finally, the query pipes those results to the :agg:expression:`$sort`
operator that will first sort by ``total`` descending and then by
``_id`` ascending.

Note the ``$`` in front of the fields ``cust_id`` and
``price`` as they appear as operands to the aggregation operators.
8 changes: 8 additions & 0 deletions themes/epub_mongodb/static/epub.css
Original file line number Diff line number Diff line change
Expand Up @@ -384,6 +384,14 @@ h1 tt, h2 tt, h3 tt, h4 tt, h5 tt, h6 tt {
background-color: transparent;
}

div.highlight-javascript>div.highlight>pre>span.hll {
background-color: transparent;
}

div.highlight-javascript>div.highlight>pre>span.hll>span.nx {
font-weight: bold;
}

/* -- math display ---------------------------------------------------------- */

img.math {
Expand Down
8 changes: 8 additions & 0 deletions themes/mongodb/static/mongodb-docs.css_t
Original file line number Diff line number Diff line change
Expand Up @@ -311,6 +311,14 @@ table.docutils.field-list ul.first.last.simple>li {
table.docutils.field-list ul.first.last.simple>li>p {
padding-top: 1em;
}

div.highlight-javascript>div.highlight>pre>span.hll {
background-color: transparent;
}
div.highlight-javascript>div.highlight>pre>span.hll>span.nx {
font-weight: bold;
}

/* for main page to knock out the bullets & padding for main columns */

div#mongodb ul{
Expand Down