Database Research & Development

  • Home
  • NoSQL
    • NoSQL
    • Cassandra
  • Databases
    • Database Theory
    • Database Designing
    • SQL Server Coding Standards
    • SQL Server
    • PostgreSQL
    • MySQL
    • Greenplum
    • Linux
  • Interviews
    • SQL Server Interviews
    • MySQL Interviews
    • SQL Puzzles
  • DBA Scripts
    • SQL Server DBA Scripts
    • PostgreSQL DBA Scripts
    • MySQL DBA Scripts
    • Greenplum DBA Scripts
  • Home
  • Blog Archives !
  • (: Laugh@dbrnd :)
  • Contact Me !
sqlserverinterviews
Home 2016 August PostgreSQL 9.4: Using FILTER CLAUSE, multiple COUNT(*) in one SELECT Query for Different Groups

PostgreSQL 9.4: Using FILTER CLAUSE, multiple COUNT(*) in one SELECT Query for Different Groups

This article is half-done without your Comment! *** Please share your thoughts via Comment ***

PostgreSQL 9.4 has introduced one of the very good FILTER CLAUSE which is used to apply filters in aggregate functions.

Using FILTER, You can use different types of aggregate functions without applying any GROUP BY CLAUSE.

Now Imagine, that I have one Student table and I want total number of Students based different grades.
What happened without FILTER CLAUSE, We have to perform this calculation in the individual SELECT query.

But with the use of FILTER CLAUSE we can perform aggregation based on different FILTER values in a single SQL Query.

Below is a small demonstration of this:

Create one Student table with sample data:

1
2
3
4
5
6
7
8
9
10
11
12
CREATE TABLE tbl_Students
(
StudID INT PRIMARY KEY
,StudentName CHARACTER VARYING
,Marks INTEGER
);
 
INSERT INTO tbl_Students
VALUES (1,'Anvesh',88),(2,'Jenny',55),(3,'Tushar',85)
,(4,'Kavita',75),(5,'Manas',42),(6,'Martin',69)
,(7,'Roy',95),(8,'Benny',92),(9,'Neevan',82)
,(10,'Lee',43),(11,'Loother',65),(12,'Eric',58);

Apply FILTER clause to count number of Students based on Marks:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
SELECT
COUNT(1) AS TotalStudents
,COUNT(1) FILTER (WHERE Marks BETWEEN 40 AND 60) AS TotalGrade_C
,COUNT(1) FILTER (WHERE Marks BETWEEN 60 AND 80) AS TotalGrade_B
,COUNT(1) FILTER (WHERE Marks BETWEEN 80 AND 100) AS TotalGrade_A
FROM tbl_Students;
 
/* Result:
-------------- --------------- --------------- ---------------
TotalStudents | TotalGrade_C | TotalGrade_B | TotalGrade_A
--------------|---------------|---------------|---------------
12 | 4 | 3 | 5
-------------- --------------- --------------- ---------------
*/

Aug 11, 2016Anvesh Patel
PostgreSQL: Force Autovacuum for running AggressivePostgreSQL: CREATE DOMAIN to Abstract Data Type and Enforce Business Rules
Comments: 3
  1. Bruno Felipe
    August 11, 2016 at 8:53 pm

    It’s very nice post!!!!
    can you post about cube and group cube?

    • Anvesh Patel
      Anvesh Patel
      August 12, 2016 at 5:57 pm

      Sure will post very soon .

  2. Bob Smith
    October 21, 2016 at 6:19 pm

    Thanks for posting about a lessor known feature. FYI – The way you have set up the BETWEEN would give incorrect results if any student has a mark that is 60 or 80. BETWEEN is inclusive so a mark of 60 would be counted for both TotalGrade_C and TotalGrade_B. Add the following and re-run the select:

    insert into tbl_Students
    values (13, ‘Bob’, 60);

Anvesh Patel
Anvesh Patel

Database Engineer

August 11, 2016 PostgreSQLAggregate Function, Anvesh Patel, database, database research and development, dbrnd, FILTER CLAUSE, FILTER GROUP BY, plpgsql, Postgres Query, postgresql, PostgreSQL 9.4, PostgreSQL Administrator, PostgreSQL Error, PostgreSQL Programming, PostgreSQL Tips and Tricks
About Me!

I'm Anvesh Patel, a Database Engineer certified by Oracle and IBM. I'm working as a Database Architect, Database Optimizer, Database Administrator, Database Developer. Providing the best articles and solutions for different problems in the best manner through my blogs is my passion. I have more than six years of experience with various RDBMS products like MSSQL Server, PostgreSQL, MySQL, Greenplum and currently learning and doing research on BIGData and NoSQL technology. -- Hyderabad, India.

About DBRND !

dbrnd

This is a personal blog (www.dbrnd.com).

Any views or opinions represented in this blog are personal and belong solely to the blog owner and do not represent those of people, institutions or organizations that the owner may or may not be associated with in professional or personal capacity, unless explicitly stated.

Feel free to challenge me, disagree with me, or tell me I’m completely nuts in the comments section of each blog entry, but I reserve the right to delete any comment for any reason whatsoever (abusive, profane, rude, or anonymous comments) - so keep it polite.

The content of this website is protected by copyright. No portion of this website may be copied or replicated in any form without the written consent of the website owner.

Recent Comments !
  • Anvesh Patel { Sure will do... } – May 27, 12:43 PM
  • Anvesh Patel { Great... } – May 27, 12:41 PM
  • Anvesh Patel { Great... } – May 27, 12:39 PM
  • Anvesh Patel { Great... } – May 27, 12:36 PM
  • Anvesh Patel { Great... } – May 27, 12:28 PM
  • Anvesh Patel { Great... } – May 27, 12:27 PM
  • Anvesh Patel { Great... } – May 27, 12:16 PM
  • Older »
Follow Me !
  • facebook
  • linkedin
  • twitter
  • youtube
  • google
  • flickr
© 2015 – 2019 All rights reserved. Database Research & Development (dbrnd.com)
Posting....