Search icon CANCEL
Subscription
0
Cart icon
Your Cart (0 item)
Close icon
You have no products in your basket yet
Arrow left icon
Explore Products
Best Sellers
New Releases
Books
Videos
Audiobooks
Learning Hub
Free Learning
Arrow right icon
Arrow up icon
GO TO TOP
PostgreSQL 14 Administration Cookbook

You're reading from   PostgreSQL 14 Administration Cookbook Over 175 proven recipes for database administrators to manage enterprise databases effectively

Arrow left icon
Product type Paperback
Published in Mar 2022
Publisher Packt
ISBN-13 9781803248974
Length 608 pages
Edition 1st Edition
Concepts
Arrow right icon
Authors (2):
Arrow left icon
Gianni Ciolli Gianni Ciolli
Author Profile Icon Gianni Ciolli
Gianni Ciolli
Simon Riggs Simon Riggs
Author Profile Icon Simon Riggs
Simon Riggs
Arrow right icon
View More author details
Toc

Table of Contents (14) Chapters Close

Preface 1. Chapter 1: First Steps 2. Chapter 2: Exploring the Database FREE CHAPTER 3. Chapter 3: Server Configuration 4. Chapter 4: Server Control 5. Chapter 5: Tables and Data 6. Chapter 6: Security 7. Chapter 7: Database Administration 8. Chapter 8: Monitoring and Diagnosis 9. Chapter 9: Regular Maintenance 10. Chapter 10: Performance and Concurrency 11. Chapter 11: Backup and Recovery 12. Chapter 12: Replication and Upgrades 13. Other Books You May Enjoy

How many tables are there in a database?

The number of tables in a relational database is a good measure of the complexity of a database, so it is a simple way to get to know any database. But the complexity of what? Well, a complex database may have been designed to be deliberately flexible in order to cover a variety of business situations, or a complex business process may have a limited portion of its details covered in the database. So, a large number of tables might reveal a complex business process or just a complex piece of software.

In this recipe, we will show you how to compute the number of tables.

How to do it...

From any interface, type the following SQL command:

SELECT count(*) FROM information_schema.tables
WHERE table_schema NOT IN ('information_schema','pg_catalog');

You can also look at the list of tables directly, and judge whether the list is a small or large number.

In psql, you can see your own tables by using the following command:

$ psql -c "\d"
        List of relations
 Schema |   Name   | Type  |  Owner  
--------+----------+-------+----------
 public | accounts | table | postgres
 public | branches | table | postgres

In pgAdmin 4, you can see the tables in the tree view on the left-hand side, as shown in the following screenshot:

Figure 2.4 – The tree view of database objects in pgAdmin

Figure 2.4 – The tree view of database objects in pgAdmin

How it works…

PostgreSQL stores information about the database in catalog tables. They describe every aspect of the way the database has been defined. There is a main set of catalog tables stored in a schema, called pg_catalog. There is a second set of catalog objects called the information schema, which is the standard SQL way of accessing information in a relational database.

We want to exclude both of these schemas from our query, to avoid counting non-user objects. We excluded them in the preceding query using the NOT IN phrase in the WHERE clause.

Excluding partitions from the count is more involved. The information schema shows partitions as the same as tables, which is true for PostgreSQL, so somewhat misleading. So, what we want to do is exclude tables that are also partitions. Partitions are marked in the pg_catalog.pg_class table, with a Boolean column of relispartition. If we use pg_class, we also need to exclude non-tables and ensure we don't include internal schemas, which leaves us with this much more complex query:

SELECT count(*) FROM pg_class
WHERE relkind = 'r'
AND not relispartition
AND relnamespace NOT IN (
     SELECT oid FROM pg_namespace
     WHERE nspname IN ('information_schema','pg_catalog', 'pg_toast')
     AND nspname NOT LIKE 'pg_temp%' AND nspname NOT LIKE 'pg_toast_temp%'
);

Note

Note that this query shows only the number of tables in one of the databases on the PostgreSQL server. You can only see the tables in the database to which you are currently connected, so you'll need to run the same query on each database in turn.

There's more…

The highest number of distinct, major tables I've ever seen in a database is 20,000, without counting partitions, views, and worktables. That clearly rates as a very complex system.

Figure 2.5 – Estimating database complexity based on the number of tables

Figure 2.5 – Estimating database complexity based on the number of tables

Of course, you can't always easily tell which tables are entities, so we just need to count the tables. Some databases use a lot of partitions or similar tables, so the numbers can grow dramatically. I've seen databases with up to 200,000 tables (of any kind). That's not recommended, however, as the database catalog tables then begin to become awfully large.

You have been reading a chapter from
PostgreSQL 14 Administration Cookbook
Published in: Mar 2022
Publisher: Packt
ISBN-13: 9781803248974
Register for a free Packt account to unlock a world of extra content!
A free Packt account unlocks extra newsletters, articles, discounted offers, and much more. Start advancing your knowledge today.
Unlock this book and the full library FREE for 7 days
Get unlimited access to 7000+ expert-authored eBooks and videos courses covering every tech area you can think of
Renews at $19.99/month. Cancel anytime
Banner background image