Available in versions: Dev (3.20) | Latest (3.19) | 3.18 | 3.17 | 3.16 | 3.15 | 3.14 | 3.13 | 3.12 | 3.11 | 3.10

PRODUCT

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The PRODUCT() aggregate function is a synthetic aggregate function that calculates the product of all values in the group, similar to how the SUM function calculates the sum (learn about other synthetic sql syntaxes).

SELECT product(ID)
FROM BOOK
create.select(product(BOOK.ID))
      .from(BOOK)

Producing:

+---------+
| product |
+---------+
|      24 |
+---------+

Dialect support

This example using jOOQ:

product(BOOK.ID)

Translates to the following dialect specific expressions:

Access

(SWITCH(sum(SWITCH(BOOK.ID = 0, 1)) > 0, 0, (sum(SWITCH(BOOK.ID < 0, -1)) MOD 2) < 0, -1, TRUE, 1) * exp(sum(log(abs(iif(BOOK.ID = 0, NULL, BOOK.ID))))))

ASE, SQLDataWarehouse, SQLServer

(CASE
  WHEN sum(CASE BOOK.ID
    WHEN 0 THEN 1
  END) > 0 THEN 0
  WHEN (sum(CASE
    WHEN BOOK.ID < 0 THEN -1
  END) % 2) < 0 THEN -1
  ELSE 1
END * exp(sum(log(abs(nullif(BOOK.ID, 0))))))

Aurora MySQL, Aurora Postgres, BigQuery, ClickHouse, DB2, Firebird, H2, HSQLDB, Hana, MariaDB, MemSQL, MySQL, Oracle, Postgres, Snowflake, Sybase, Trino, Vertica, YugabyteDB

(CASE
  WHEN sum(CASE BOOK.ID
    WHEN 0 THEN 1
  END) > 0 THEN 0
  WHEN mod(
    sum(CASE
      WHEN BOOK.ID < 0 THEN -1
    END),
    2
  ) < 0 THEN -1
  ELSE 1
END * exp(sum(ln(abs(nullif(BOOK.ID, 0))))))

CockroachDB

(CASE
  WHEN sum(CASE BOOK.ID
    WHEN 0 THEN 1
  END) > 0 THEN 0
  WHEN mod(
    sum(CASE
      WHEN BOOK.ID < 0 THEN -1
    END),
    2
  ) < 0 THEN -1
  ELSE 1
END * exp(sum(ln(CAST(abs(nullif(BOOK.ID, 0)) AS numeric)))))

Derby

(CASE
  WHEN sum(CASE
    WHEN BOOK.ID = 0 THEN 1
  END) > 0 THEN 0
  WHEN mod(
    sum(CASE
      WHEN BOOK.ID < 0 THEN -1
    END),
    2
  ) < 0 THEN -1
  ELSE 1
END * exp(sum(ln(abs(nullif(BOOK.ID, 0))))))

DuckDB

product(BOOK.ID)

Exasol

mul(BOOK.ID)

Informix

(CASE
  WHEN sum(CASE BOOK.ID
    WHEN 0 THEN 1
  END) > 0 THEN 0
  WHEN mod(
    sum(CASE
      WHEN BOOK.ID < 0 THEN -1
    END),
    2
  ) < 0 THEN -1
  ELSE 1
END * exp(sum(logn(abs(nullif(BOOK.ID, 0))))))

Redshift

(CASE
  WHEN sum(CASE BOOK.ID
    WHEN 0 THEN 1
  END) > 0 THEN 0
  WHEN (sum(CASE
    WHEN BOOK.ID < 0 THEN -1
  END) % 2) < 0 THEN -1
  ELSE 1
END * exp(sum(ln(abs(nullif(BOOK.ID, 0))))))

Teradata

(CASE
  WHEN sum(CASE BOOK.ID
    WHEN 0 THEN 1
  END) > 0 THEN 0
  WHEN (sum(CASE
    WHEN BOOK.ID < 0 THEN -1
  END) MOD 2) < 0 THEN -1
  ELSE 1
END * exp(sum(ln(abs(nullif(BOOK.ID, 0))))))

SQLite

/* UNSUPPORTED */

(These are currently generated with jOOQ 3.20, see #10141), or translate your own on our website

Feedback

Do you have any feedback about this page? We'd love to hear it!

The jOOQ Logo