From c6eefeac989d05ac2664dbe97fef6582eefc0258 Mon Sep 17 00:00:00 2001 From: jbranchaud Date: Sat, 25 Jan 2025 19:02:13 -0600 Subject: [PATCH] Add Count The Number Of Items In An Array as a Postgres TIL --- README.md | 3 +- .../count-the-number-of-items-in-an-array.md | 56 +++++++++++++++++++ 2 files changed, 58 insertions(+), 1 deletion(-) create mode 100644 postgres/count-the-number-of-items-in-an-array.md diff --git a/README.md b/README.md index 6666cb5..7a2702e 100644 --- a/README.md +++ b/README.md @@ -10,7 +10,7 @@ pairing with smart people at Hashrocket. For a steady stream of TILs, [sign up for my newsletter](https://crafty-builder-6996.ck.page/e169c61186). -_1574 TILs and counting..._ +_1575 TILs and counting..._ See some of the other learning resources I work on: - [Ruby Operator Lookup](https://www.visualmode.dev/ruby-operators) @@ -780,6 +780,7 @@ See some of the other learning resources I work on: - [Convert A String To A Timestamp](postgres/convert-a-string-to-a-timestamp.md) - [Count How Many Records There Are Of Each Type](postgres/count-how-many-records-there-are-of-each-type.md) - [Count Records By Type](postgres/count-records-by-type.md) +- [Count The Number Of Items In An Array](postgres/count-the-number-of-items-in-an-array.md) - [Count The Number Of Trues In An Aggregate Query](postgres/count-the-number-of-trues-in-an-aggregate-query.md) - [Create A Cluster In A Specific Data Directory](postgres/create-a-cluster-in-a-specific-data-directory.md) - [Create A Composite Primary Key](postgres/create-a-composite-primary-key.md) diff --git a/postgres/count-the-number-of-items-in-an-array.md b/postgres/count-the-number-of-items-in-an-array.md new file mode 100644 index 0000000..6de610a --- /dev/null +++ b/postgres/count-the-number-of-items-in-an-array.md @@ -0,0 +1,56 @@ +# Count The Number Of Items In An Array + +There are two ways to count the number of items in an array with PostgreSQL. +The one that might jump out at you or show up at the top of search results is +[`array_length`](https://www.postgresql.org/docs/current/functions-array.html). + +```sql +> select array_length(array[1,2,3], 1); ++--------------+ +| array_length | +|--------------| +| 3 | ++--------------+ + +> select array_length(array[[1,2], [3,4]], 2); ++--------------+ +| array_length | +|--------------| +| 2 | ++--------------+ +``` + +This requires specifying the dimension at which you want to check the length. +The first example, checking the 1st dimension of a one-dimensional array, seems +like the more common and useful scenario. In the second example, we are +checking the 2nd dimension. + +The other way we can determine the number of items in an array is with the +[`cardinality`](https://www.postgresql.org/docs/current/functions-array.html) +function. + +> Returns the total number of elements in the array, or 0 if the array is +> empty. + +```sql +> select cardinality(array[1,2,3]); ++-------------+ +| cardinality | +|-------------| +| 3 | ++-------------+ + +> select cardinality(array[[1,2], [3,4]]); ++-------------+ +| cardinality | +|-------------| +| 4 | ++-------------+ +``` + +This behaves the same as `array_length` for a one-dimensional array and doesn't +require a second argument. Where it gets more interesting is with +multi-dimensional arrays. It returns the total number of elements in the +arrayregardless of the nesting. + +[source](https://mattrighetti.com/2025/01/20/you-dont-need-sql-builders)