The list of all the queries

Base tables and materialized views without any index

Query goal: Find base tables and materialized views that do not have any index.
Query type: Problem detection (Each row in the result could represent a flaw in the design)
Query reliability: High (Few or no false-positive results)
Query license: MIT License
Data source: INFORMATION_SCHEMA+system catalog
SQL query: Click on query to copy it

WITH tables AS (SELECT nspname AS table_schema, relname AS table_name, 
CASE WHEN relkind='r' THEN 'BASE TABLE'
WHEN relkind='m' THEN 'MATERIALIZED VIEW'
END AS table_type
FROM pg_class INNER JOIN pg_namespace ON pg_class.relnamespace=pg_namespace.oid
WHERE relkind IN ('r','m')
AND nspname NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL)),
idx AS (SELECT 
n.nspname AS index_schema,
c.relname AS index_name,
c2.relname AS table_name
FROM pg_catalog.pg_index AS i INNER JOIN pg_catalog.pg_class AS c ON i.indexrelid=c.oid
INNER JOIN pg_catalog.pg_class AS c2 ON i.indrelid=c2.oid
INNER JOIN pg_catalog.pg_namespace n ON c.relnamespace=n.oid
WHERE nspname NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL))
SELECT table_schema, table_name, table_type
FROM tables
WHERE NOT EXISTS (SELECT 1
FROM idx 
WHERE idx.index_schema=tables.table_schema 
AND idx.table_name=tables.table_name)
ORDER BY table_schema, table_name, table_type;

Collections where the query belongs to

Collection nameCollection description
Find problems automaticallyQueries, that results point to problems in the database. Each query in the collection produces an initial assessment. However, a human reviewer has the final say as to whether there is a problem or not .

Categories where the query belongs to

Category nameCategory description
PerformanceQueries of this category provide information about indexes in a database.

The list of all the queries