-
Notifications
You must be signed in to change notification settings - Fork 4
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
This is an initial phase of supporting a builtin menu of useful queries when using `cb psql`. Currently, it only supports predefined queries. To access this menu, simply enter `:menu` into psql and it will present the available query options. Example: ``` Example Team/example-cluster/postgres=> :menu Cache 1 – Cache and index hit rates Size Information 2 – Database sizes 3 – Table sizes Query Performance 4 – Queries consuming the most system time 5 – Queries running over 1 minute 6 – Slowest average queries Connection Management 7 – Connection count by state 8 – Connection count by user and application Indexes 9 – Duplicate indexes 10 – List of indexes 11 – Unused indexes Locks 12 – Blocking queries Extensions 13 – Available extensions 14 – Installed extensions Type choice and press <Enter> (q to quit): ```
- Loading branch information
1 parent
1e40e1e
commit 3ddfe79
Showing
21 changed files
with
763 additions
and
0 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,32 @@ | ||
<%- option : Int32 = 1 %> | ||
<%- @queries.each do |category, queries| -%> | ||
\echo <%= "#{category.colorize.bold}" %> | ||
<%- queries.each do |query| -%> | ||
\echo ' <%= "#{option} \u2013 #{query.label}" %>' | ||
<%- option += 1 -%> | ||
<%- end -%> | ||
<%- end -%> | ||
\echo | ||
\prompt 'Type choice and press <%= "<Enter>".colorize.bold %> (<%= "q".colorize.bold %> to quit): ' choice | ||
\echo | ||
|
||
<%- option = 1 %> | ||
SELECT CASE | ||
<%- @queries.each_value do |queries| -%> | ||
<%- queries.each do |query| %> | ||
WHEN :'choice'::text = '<%= option %>' THEN | ||
'\i `echo <%= query.path %>`' | ||
'\echo' | ||
'\i <%= @path %>' | ||
<%- option += 1 -%> | ||
<%- end -%> | ||
<%- end -%> | ||
WHEN :'choice'::text = 'q' | ||
THEN '\echo Quitting!' | ||
ELSE | ||
'\echo <%= "Error:".colorize.red.bold %> Unknown option! Try again.' | ||
'\echo' | ||
'\i <%= @path %>' | ||
END AS action \gset | ||
|
||
:action |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,118 @@ | ||
require "./query" | ||
|
||
module CB::QueryMenu | ||
# Here we define the builtin queries that are included when using the `:menu` | ||
# command in `psql`. | ||
# | ||
# Each query MUST do the following: | ||
# * Extend `CB::QueryMenu::Query` | ||
# * Define a `Metadata` annotation that includes the `label` and `category` | ||
# for the query. | ||
# * Embed the SQL for the query. This is done using the `embed_sql` macro. | ||
# | ||
# Example: | ||
# ``` | ||
# @[Metadata(label: "Example query label", category: Category.new("Example", 1))] | ||
# struct Foo < Query | ||
# ::CB::QueryMenu.embed_sql("#{__DIR__}/sql/example.sql") | ||
# end | ||
# ``` | ||
|
||
# | ||
# Cache | ||
# | ||
|
||
@[Metadata(label: "Cache and index hit rates", category: CATEGORY_CACHE)] | ||
struct CacheHitRates < Query | ||
::CB::QueryMenu.embed_sql("#{__DIR__}/sql/cache_hit_rates.sql") | ||
end | ||
|
||
# | ||
# Connection Management | ||
# | ||
|
||
@[Metadata(label: "Connection count by state", category: CATEGORY_CONNECTION_MANAGEMENT)] | ||
struct ConnectionManagementCountByStates < Query | ||
::CB::QueryMenu.embed_sql("#{__DIR__}/sql/connection_management_count_by_state.sql") | ||
end | ||
|
||
@[Metadata(label: "Connection count by user and application", category: CATEGORY_CONNECTION_MANAGEMENT)] | ||
struct ConnectionManagementCountByUser < Query | ||
::CB::QueryMenu.embed_sql("#{__DIR__}/sql/connection_management_count_by_user_and_application.sql") | ||
end | ||
|
||
# | ||
# Extensions Queries | ||
# | ||
|
||
@[Metadata(label: "Available extensions", category: CATEGORY_EXTENSIONS)] | ||
struct AvailableExtensions < Query | ||
::CB::QueryMenu.embed_sql("#{__DIR__}/sql/extensions_available.sql") | ||
end | ||
|
||
@[Metadata(label: "Installed extensions", category: CATEGORY_EXTENSIONS)] | ||
struct InstalledExtensions < Query | ||
::CB::QueryMenu.embed_sql("#{__DIR__}/sql/extensions_installed.sql") | ||
end | ||
|
||
# | ||
# Index Queries | ||
# | ||
|
||
@[Metadata(label: "Duplicate indexes", category: CATEGORY_INDEXES)] | ||
struct IndexesDuplicates < Query | ||
::CB::QueryMenu.embed_sql("#{__DIR__}/sql/indexes_duplicates.sql") | ||
end | ||
|
||
@[Metadata(label: "List of indexes", category: CATEGORY_INDEXES)] | ||
struct IndexesList < Query | ||
::CB::QueryMenu.embed_sql("#{__DIR__}/sql/indexes_list.sql") | ||
end | ||
|
||
@[Metadata(label: "Unused indexes", category: CATEGORY_INDEXES)] | ||
struct IndexesUnused < Query | ||
::CB::QueryMenu.embed_sql("#{__DIR__}/sql/indexes_unused.sql") | ||
end | ||
|
||
# | ||
# Locks Queries | ||
# | ||
|
||
@[Metadata(label: "Blocking queries", category: CATEGORY_LOCKS)] | ||
struct LocksBlockingQueries < Query | ||
::CB::QueryMenu.embed_sql("#{__DIR__}/sql/locks_blocking_queries.sql") | ||
end | ||
|
||
# | ||
# Query Performance Queries | ||
# | ||
|
||
@[Metadata(label: "Queries consuming the most system time", category: CATEGORY_QUERY_PERFORMANCE)] | ||
struct MostConsumingQueries < Query | ||
::CB::QueryMenu.embed_sql("#{__DIR__}/sql/query_performance_most_consuming_system_time.sql") | ||
end | ||
|
||
@[Metadata(label: "Queries running over 1 minute", category: CATEGORY_QUERY_PERFORMANCE)] | ||
struct OverOneMinuteQueries < Query | ||
::CB::QueryMenu.embed_sql("#{__DIR__}/sql/query_performance_over_one_minute.sql") | ||
end | ||
|
||
@[Metadata(label: "Slowest average queries", category: CATEGORY_QUERY_PERFORMANCE)] | ||
struct SlowestAverageQueries < Query | ||
::CB::QueryMenu.embed_sql("#{__DIR__}/sql/query_performance_slowest_average.sql") | ||
end | ||
|
||
# | ||
# Size Information Queries | ||
# | ||
|
||
@[Metadata(label: "Database sizes", category: CATEGORY_SIZE_INFORMATION)] | ||
struct DatabaseSize < Query | ||
::CB::QueryMenu.embed_sql("#{__DIR__}/sql/size_information_database_size.sql") | ||
end | ||
|
||
@[Metadata(label: "Table sizes", category: CATEGORY_SIZE_INFORMATION)] | ||
struct TableSize < Query | ||
::CB::QueryMenu.embed_sql("#{__DIR__}/sql/size_information_table_size.sql") | ||
end | ||
end |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,89 @@ | ||
require "base64" | ||
|
||
module CB::QueryMenu | ||
# Metadata annoation for a query. | ||
# | ||
# A `Query` must have a `label` and `category` field defined using this | ||
# annotation. | ||
annotation Metadata; end | ||
|
||
# Category for a query, this is used for grouping and order queries in the | ||
# query menu. | ||
struct Category | ||
# The name of the category. | ||
getter name : String | ||
|
||
# The order that the category appears in the query menu. | ||
getter order : Int8 | ||
|
||
def initialize(@name = "", @order = -1); end | ||
end | ||
|
||
# Query Categories. | ||
CATEGORY_CACHE = Category.new name: "Cache", order: 1 | ||
CATEGORY_CONNECTION_MANAGEMENT = Category.new name: "Connection Management", order: 4 | ||
CATEGORY_EXTENSIONS = Category.new name: "Extensions", order: 7 | ||
CATEGORY_INDEXES = Category.new name: "Indexes", order: 5 | ||
CATEGORY_LOCKS = Category.new name: "Locks", order: 6 | ||
CATEGORY_QUERY_PERFORMANCE = Category.new name: "Query Performance", order: 3 | ||
CATEGORY_SIZE_INFORMATION = Category.new name: "Size Information", order: 2 | ||
|
||
@[Metadata(label: "", category: Category.new)] | ||
abstract struct Query | ||
getter dirname : String | ||
|
||
def initialize(@dirname); end | ||
|
||
def path | ||
File.join(dirname, sql_filename) | ||
end | ||
|
||
# Write the query to file. | ||
def write | ||
File.open(path, "w") { |file| file << Base64.decode_string(sql) } | ||
end | ||
|
||
def self.all | ||
{{ | ||
Query.subclasses.map do |query| | ||
ann = query.annotation(Metadata) | ||
raise "#{query} is missing Metadata annotation" unless ann | ||
query | ||
end | ||
}} | ||
end | ||
|
||
# The category of the query. This value is defined by setting the `category` | ||
# field in the `Metadata` annotation. | ||
def category : Category | ||
{% if @type.annotation(Metadata)[:category] %} | ||
{{@type.annotation(Metadata)[:category]}} | ||
{% else %} | ||
{{raise "#{@type} must have a category."}} | ||
{% end %} | ||
end | ||
|
||
# The label of the query. This value is define by setting the `label` field | ||
# in the `Metadata` annotation. | ||
def label : String | ||
{% if @type.annotation(Metadata)[:label] %} | ||
{{ @type.annotation(Metadata)[:label] }} | ||
{% else %} | ||
{{raise "#{@type} must have a label."}} | ||
{% end %} | ||
end | ||
|
||
abstract def sql | ||
abstract def sql_filename | ||
end | ||
|
||
macro embed_sql(path) | ||
def sql | ||
{{ run("../../tools/embed_base64.cr", path).stringify }} | ||
end | ||
|
||
def sql_filename | ||
File.basename {{path}} | ||
end | ||
end | ||
end |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,32 @@ | ||
require "ecr" | ||
require "file_utils" | ||
|
||
require "./query" | ||
|
||
module CB::QueryMenu | ||
class Menu | ||
private property queries : Hash(String, Array(Query)) = Hash(String, Array(Query)).new([] of Query) | ||
private property path : String = "" | ||
|
||
def render(cluster : CB::Model::Cluster) : String | ||
temp_dir = "/tmp/crunchy/cli/#{cluster.name}-#{cluster.id}-queries" | ||
FileUtils.mkdir_p(temp_dir) unless File.exists? temp_dir | ||
|
||
# Aggregate all queries and group them by category in alphabetical order. | ||
@queries = Query.all.map(&.new(temp_dir)) | ||
.sort_by!(&.category.order) | ||
.group_by(&.category.name) | ||
|
||
# Write the queries to the filesystem. | ||
@queries.each_value { |queries| queries.each(&.write) } | ||
|
||
# Render the menu file. | ||
@path = File.join(temp_dir, "menu.psql") | ||
query_menu = File.open(@path, mode: "w") do |menu| | ||
menu << ECR.render __DIR__ + "/menu.psql.ecr" | ||
end | ||
|
||
"\\set menu '\\\\i #{query_menu.path} '" | ||
end | ||
end | ||
end |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,54 @@ | ||
SELECT | ||
cache_rates.schemaname, | ||
sizes.name AS "Table Name", | ||
cache_rates.ratio AS "Cache Hit Ratio", | ||
indexes.ratio AS "Index Hit Ratio", | ||
CASE WHEN total_reads.cache_reads > 0 THEN ROUND((cache_rates.cache_reads/total_reads.cache_reads * 100), 2) ELSE 0 END AS "Read Percentage", | ||
CASE WHEN rowcount.estimate = -1 THEN 0 ELSE rowcount.estimate END AS "Row Count", | ||
CASE WHEN size = 8192 THEN '0 bytes' ELSE pg_size_pretty(size) END AS "Size" | ||
FROM ( | ||
SELECT | ||
n.nspname AS schemaname, | ||
c.relname AS name, | ||
pg_table_size(c.oid) AS size | ||
FROM pg_class c | ||
LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) | ||
WHERE n.nspname NOT IN ('pg_catalog', 'information_schema') | ||
AND n.nspname !~ '^pg_toast' | ||
AND c.relkind='r' | ||
) AS sizes | ||
INNER JOIN ( | ||
SELECT | ||
schemaname, | ||
relname, | ||
(sum(heap_blks_hit) / nullif(sum(heap_blks_hit) + sum(heap_blks_read), 0) * 100)::int AS ratio, | ||
sum(heap_blks_read) AS cache_reads | ||
FROM pg_statio_user_tables | ||
GROUP BY relname, schemaname) AS cache_rates ON sizes.name = cache_rates.relname | ||
AND sizes.schemaname = cache_rates.schemaname | ||
INNER JOIN ( | ||
SELECT sum(heap_blks_read) AS cache_reads | ||
FROM pg_statio_user_tables | ||
) AS total_reads ON 1 = 1 | ||
LEFT JOIN ( | ||
SELECT | ||
schemaname, | ||
relname, | ||
(sum(idx_blks_hit) / nullif(sum(idx_blks_hit + idx_blks_read),0) * 100)::int AS ratio | ||
FROM pg_statio_user_indexes | ||
GROUP BY schemaname,relname | ||
) AS indexes ON sizes.name = indexes.relname | ||
AND sizes.schemaname = indexes.schemaname | ||
LEFT JOIN ( | ||
SELECT | ||
reltuples AS estimate, | ||
c.relname AS name, | ||
n.nspname AS schemaname | ||
FROM pg_class c | ||
LEFT JOIN pg_namespace n ON (n.oid = c.relnamespace) | ||
WHERE n.nspname NOT IN ('pg_catalog', 'information_schema') | ||
AND n.nspname !~ '^pg_toast' | ||
AND c.relkind='r' | ||
) AS rowcount ON sizes.name = rowcount.name | ||
AND sizes.schemaname = rowcount.schemaname | ||
ORDER BY size DESC |
8 changes: 8 additions & 0 deletions
8
src/cb/query_menu/sql/connection_management_count_by_state.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,8 @@ | ||
SELECT | ||
usename AS user_name, | ||
state, | ||
count(*) AS connection_count | ||
FROM pg_stat_activity | ||
WHERE usename NOT IN ('crunchy_replication', 'crunchy_superuser') | ||
GROUP BY usename, state | ||
ORDER BY 3 DESC; |
8 changes: 8 additions & 0 deletions
8
src/cb/query_menu/sql/connection_management_count_by_user_and_application.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,8 @@ | ||
SELECT | ||
usename as user_name, | ||
application_name, | ||
count(*) as connection_count | ||
FROM pg_stat_activity | ||
WHERE usename NOT IN ('crunchy_replication', 'crunchy_superuser') | ||
GROUP BY usename, application_name | ||
ORDER BY 3 DESC; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1 @@ | ||
SELECT * FROM pg_available_extensions |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1 @@ | ||
SELECT * FROM pg_extension; |
Oops, something went wrong.