The list of all the queries

Insufficient number of user-defined views

Query goal: There must be at least n (four in this case) user-defined views in the database.
Notes about the query: This query implements a requirement that might occur in a learning situation. The condition in the query ensures that if the requirement is not fulfilled, then the query returns one row, otherwise it does not return a row. The result is achieved by using a PostgreSQL feature that permits SELECT statements without the FROM clause. The number of views (four in this case) serves here as an example. It could be replaced with some other threshold.
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
Fixing suggestion: Create additional views.
Data source: INFORMATION_SCHEMA only
SQL query: Click on query to copy it

WITH views AS (SELECT tables.table_schema, tables.table_name
FROM information_schema.tables
WHERE tables.table_type IN ('VIEW') AND 
table_schema NOT IN (SELECT schema_name
FROM INFORMATION_SCHEMA.schemata
WHERE schema_name<>'public' AND
schema_owner='postgres' AND schema_name IS NOT NULL))
SELECT 'Too few views, must be at least four' As comment, (SELECT Count(*) AS cnt FROM views) AS number_of_views
WHERE (SELECT Count(*) AS cnt FROM views)<4;

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
AssessmentQueries of this category could be used specifically in the learning environment to assess as to whether student projects have filled certain criteria.
Derived tablesQueries of this category provide information about the derived tables (views, materialized views), which are used to implement virtual data layer.

The list of all the queries