Analytic Functions - Filtering

Let us go through the solution for getting top 5 daily products based up on the revenue. In that process we will understand how to apply filtering on top of the derived values using analytic functions.

%load_ext sql
The sql extension is already loaded. To reload it, use:
  %reload_ext sql
%env DATABASE_URL=postgresql://itversity_retail_user:retail_password@localhost:5432/itversity_retail_db
env: DATABASE_URL=postgresql://itversity_retail_user:retail_password@localhost:5432/itversity_retail_db

Order of execution of SQL

Let us review the order of execution of SQL. First let us review the order of writing the query.

  1. SELECT

  2. FROM

  3. JOIN or OUTER JOIN with ON

  4. WHERE

  5. GROUP BY and optionally HAVING

  6. ORDER BY

Let us come up with a query which will compute daily revenue using COMPLETE or CLOSED orders and also sorted by order_date.

%%sql

SELECT o.order_date,
    round(sum(oi.order_item_subtotal)::numeric, 2) AS revenue
FROM orders o JOIN order_items oi
ON o.order_id = oi.order_item_order_id
WHERE o.order_status IN ('COMPLETE', 'CLOSED')
GROUP BY o.order_date
ORDER BY o.order_date
LIMIT 10
 * postgresql://itversity_retail_user:***@localhost:5432/itversity_retail_db
10 rows affected.
order_date revenue
2013-07-25 00:00:00 31547.23
2013-07-26 00:00:00 54713.23
2013-07-27 00:00:00 48411.48
2013-07-28 00:00:00 35672.03
2013-07-29 00:00:00 54579.70
2013-07-30 00:00:00 49329.29
2013-07-31 00:00:00 59212.49
2013-08-01 00:00:00 49160.08
2013-08-02 00:00:00 50688.58
2013-08-03 00:00:00 43416.74
%%sql

SELECT o.order_date,
    round(sum(oi.order_item_subtotal)::numeric, 2) AS revenue
FROM orders o JOIN order_items oi
ON o.order_id = oi.order_item_order_id
WHERE o.order_status IN ('COMPLETE', 'CLOSED')
GROUP BY o.order_date
    HAVING round(sum(oi.order_item_subtotal)::numeric, 2) >= 50000
ORDER BY order_date
LIMIT 10
 * postgresql://itversity_retail_user:***@localhost:5432/itversity_retail_db
10 rows affected.
order_date revenue
2013-07-26 00:00:00 54713.23
2013-07-29 00:00:00 54579.70
2013-07-31 00:00:00 59212.49
2013-08-02 00:00:00 50688.58
2013-08-06 00:00:00 57843.89
2013-08-12 00:00:00 59014.74
2013-08-17 00:00:00 63226.83
2013-08-24 00:00:00 52650.15
2013-09-05 00:00:00 59942.43
2013-09-06 00:00:00 61976.10

However order of execution is typically as follows.

  1. FROM

  2. JOIN or OUTER JOIN with ON

  3. WHERE

  4. GROUP BY and optionally HAVING

  5. SELECT

  6. ORDER BY

As SELECT is executed before ORDER BY clause, we will not be able to refer the aliases defined in SELECT caluse in other clauses except for ORDER BY in most of the traditional databases including Postgresql.

Error

This will fail as revenue which is an alias defined in SELECT cannot be used in WHERE.

%%sql

SELECT o.order_date,
    round(sum(oi.order_item_subtotal)::numeric, 2) AS revenue
FROM orders o JOIN order_items oi
ON o.order_id = oi.order_item_order_id
WHERE o.order_status IN ('COMPLETE', 'CLOSED')
    AND revenue >= 50000
GROUP BY o.order_date
ORDER BY order_date
LIMIT 10
 * postgresql://itversity_retail_user:***@localhost:5432/itversity_retail_db
(psycopg2.errors.UndefinedColumn) column "revenue" does not exist
LINE 5:     AND revenue >= 50000
                ^

[SQL: SELECT o.order_date, round(sum(oi.order_item_subtotal)::numeric, 2) AS revenue
FROM orders o JOIN order_items oi
ON o.order_id = oi.order_item_order_id
WHERE o.order_status IN ('COMPLETE', 'CLOSED')
    AND revenue >= 50000
GROUP BY o.order_date
ORDER BY order_date
LIMIT 10]
(Background on this error at: http://sqlalche.me/e/13/f405)

Note

This will also fail as we cannot use aggregate functions in WHERE clause.

%%sql

SELECT o.order_date,
    round(sum(oi.order_item_subtotal)::numeric, 2) AS revenue
FROM orders o JOIN order_items oi
ON o.order_id = oi.order_item_order_id
WHERE o.order_status IN ('COMPLETE', 'CLOSED')
    AND round(sum(oi.order_item_subtotal)::numeric, 2) >= 50000
GROUP BY o.order_date
ORDER BY order_date
LIMIT 10
 * postgresql://itversity_retail_user:***@localhost:5432/itversity_retail_db
(psycopg2.errors.GroupingError) aggregate functions are not allowed in WHERE
LINE 5:     AND round(sum(oi.order_item_subtotal)::numeric, 2) >= 50...
                      ^

[SQL: SELECT o.order_date, round(sum(oi.order_item_subtotal)::numeric, 2) AS revenue
FROM orders o JOIN order_items oi
ON o.order_id = oi.order_item_order_id
WHERE o.order_status IN ('COMPLETE', 'CLOSED')
    AND round(sum(oi.order_item_subtotal)::numeric, 2) >= 50000
GROUP BY o.order_date
ORDER BY order_date
LIMIT 10]
(Background on this error at: http://sqlalche.me/e/13/f405)
%%sql

SELECT o.order_date,
    round(sum(oi.order_item_subtotal)::numeric, 2) AS revenue
FROM orders o JOIN order_items oi
ON o.order_id = oi.order_item_order_id
WHERE o.order_status IN ('COMPLETE', 'CLOSED')
GROUP BY o.order_date
ORDER BY order_date,
    revenue DESC
LIMIT 10
 * postgresql://itversity_retail_user:***@localhost:5432/itversity_retail_db
10 rows affected.
order_date revenue
2013-07-25 00:00:00 31547.23
2013-07-26 00:00:00 54713.23
2013-07-27 00:00:00 48411.48
2013-07-28 00:00:00 35672.03
2013-07-29 00:00:00 54579.70
2013-07-30 00:00:00 49329.29
2013-07-31 00:00:00 59212.49
2013-08-01 00:00:00 49160.08
2013-08-02 00:00:00 50688.58
2013-08-03 00:00:00 43416.74
%%sql

SELECT o.order_date,
    round(sum(oi.order_item_subtotal)::numeric, 2) AS revenue
FROM orders o JOIN order_items oi
ON o.order_id = oi.order_item_order_id
WHERE o.order_status IN ('COMPLETE', 'CLOSED')
GROUP BY o.order_date
    HAVING round(sum(oi.order_item_subtotal)::numeric, 2) >= 50000
ORDER BY order_date
LIMIT 10
 * postgresql://itversity_retail_user:***@localhost:5432/itversity_retail_db
10 rows affected.
order_date revenue
2013-07-26 00:00:00 54713.23
2013-07-29 00:00:00 54579.70
2013-07-31 00:00:00 59212.49
2013-08-02 00:00:00 50688.58
2013-08-06 00:00:00 57843.89
2013-08-12 00:00:00 59014.74
2013-08-17 00:00:00 63226.83
2013-08-24 00:00:00 52650.15
2013-09-05 00:00:00 59942.43
2013-09-06 00:00:00 61976.10

Error

This one will also fail as we are trying to use alias drnk from SELECT clause in WHERE clause.

%%sql


SELECT t.*,
dense_rank() OVER (
  PARTITION BY order_date
  ORDER BY revenue DESC
) AS drnk
FROM daily_product_revenue t
WHERE drnk <= 5
 * postgresql://itversity_retail_user:***@localhost:5432/itversity_retail_db
(psycopg2.errors.UndefinedColumn) column "drnk" does not exist
LINE 6: WHERE drnk <= 5
              ^

[SQL: SELECT t.*, dense_rank() OVER (
  PARTITION BY order_date
  ORDER BY revenue DESC
) AS drnk
FROM daily_product_revenue t
WHERE drnk <= 5]
(Background on this error at: http://sqlalche.me/e/13/f405)

Overview of Sub Queries

Let us recap about Sub Queries.

  • We typically have Sub Queries in FROM Clause.

  • We need to provide alias to the Sub Queries in FROM Clause in Postgresql.

  • We use sub queries quite often over queries using Analytics/Windowing Functions

%%sql

SELECT * FROM (SELECT current_date) AS q
 * postgresql://itversity_retail_user:***@localhost:5432/itversity_retail_db
1 rows affected.
current_date
2020-12-01

Let us see few more examples with respect to Sub Queries.

%%sql

SELECT * FROM (
  SELECT order_date, count(1) AS order_count
  FROM orders
  GROUP BY order_date
) AS q
ORDER BY order_date
LIMIT 10
 * postgresql://itversity_retail_user:***@localhost:5432/itversity_retail_db
10 rows affected.
order_date order_count
2013-07-25 00:00:00 143
2013-07-26 00:00:00 269
2013-07-27 00:00:00 202
2013-07-28 00:00:00 187
2013-07-29 00:00:00 253
2013-07-30 00:00:00 227
2013-07-31 00:00:00 252
2013-08-01 00:00:00 246
2013-08-02 00:00:00 224
2013-08-03 00:00:00 183
%%sql

SELECT * FROM (
  SELECT order_date, count(1) AS order_count
  FROM orders
  GROUP BY order_date
) q
WHERE q.order_count > 150
ORDER BY order_date
LIMIT 10
 * postgresql://itversity_retail_user:***@localhost:5432/itversity_retail_db
10 rows affected.
order_date order_count
2013-07-26 00:00:00 269
2013-07-27 00:00:00 202
2013-07-28 00:00:00 187
2013-07-29 00:00:00 253
2013-07-30 00:00:00 227
2013-07-31 00:00:00 252
2013-08-01 00:00:00 246
2013-08-02 00:00:00 224
2013-08-03 00:00:00 183
2013-08-04 00:00:00 187

Note

Above query is an example for sub queries. We can achieve using HAVING clause (no need to have sub query to filter)

Filtering - Analytic Function Results

Let us understand how to filter on top of results of Analytic Functions.

  • We can use Analytic Functions only in SELECT Clause.

  • If we have to filter based on Analytic Function results, then we need to use Sub Queries.

  • Once the query is added as subquery, we can apply filter using aliases of the Analytic Functions.

Here is the example where we can filter data based on Analytic Functions.

%%sql

SELECT t.*,
dense_rank() OVER (
  PARTITION BY order_date
  ORDER BY revenue DESC
) AS drnk
FROM daily_product_revenue t
WHERE drnk <= 5
 * postgresql://itversity_retail_user:***@localhost:5432/itversity_retail_db
(psycopg2.errors.UndefinedColumn) column "drnk" does not exist
LINE 6: WHERE drnk <= 5
              ^

[SQL: SELECT t.*, dense_rank() OVER (
  PARTITION BY order_date
  ORDER BY revenue DESC
) AS drnk
FROM daily_product_revenue t
WHERE drnk <= 5]
(Background on this error at: http://sqlalche.me/e/13/f405)
%%sql

SELECT * FROM (
  SELECT t.*,
    dense_rank() OVER (
      PARTITION BY order_date
      ORDER BY revenue DESC
    ) AS drnk
  FROM daily_product_revenue t
) q
WHERE q.drnk <= 5
ORDER BY q.order_date, q.revenue DESC
LIMIT 10
 * postgresql://itversity_retail_user:***@localhost:5432/itversity_retail_db
10 rows affected.
order_date order_item_product_id revenue drnk
2013-07-25 00:00:00 1004 5599.72 1
2013-07-25 00:00:00 191 5099.49 2
2013-07-25 00:00:00 957 4499.70 3
2013-07-25 00:00:00 365 3359.44 4
2013-07-25 00:00:00 1073 2999.85 5
2013-07-26 00:00:00 1004 10799.46 1
2013-07-26 00:00:00 365 7978.67 2
2013-07-26 00:00:00 957 6899.54 3
2013-07-26 00:00:00 191 6799.32 4
2013-07-26 00:00:00 1014 4798.08 5