mirror of
https://github.com/sosedoff/pgweb.git
synced 2024-12-13 15:35:28 +03:00
Add context menu to display database tables stats (#639)
* Add context menu to display database tables stats * Move table stats implementation into client
This commit is contained in:
parent
06212b4c34
commit
5b2d4e4454
@ -497,6 +497,12 @@ func GetTableConstraints(c *gin.Context) {
|
||||
serveResult(c, res, err)
|
||||
}
|
||||
|
||||
// GetTablesStats renders data sizes and estimated rows for all tables in the database
|
||||
func GetTablesStats(c *gin.Context) {
|
||||
res, err := DB(c).TablesStats()
|
||||
serveResult(c, res, err)
|
||||
}
|
||||
|
||||
// HandleQuery runs the database query
|
||||
func HandleQuery(query string, c *gin.Context) {
|
||||
metrics.IncrementQueriesCount()
|
||||
|
@ -43,6 +43,7 @@ func SetupRoutes(router *gin.Engine) {
|
||||
api.GET("/tables/:table/info", GetTableInfo)
|
||||
api.GET("/tables/:table/indexes", GetTableIndexes)
|
||||
api.GET("/tables/:table/constraints", GetTableConstraints)
|
||||
api.GET("/tables_stats", GetTablesStats)
|
||||
api.GET("/functions/:id", GetFunction)
|
||||
api.GET("/query", RunQuery)
|
||||
api.POST("/query", RunQuery)
|
||||
|
@ -335,6 +335,10 @@ func (client *Client) TableConstraints(table string) (*Result, error) {
|
||||
return res, err
|
||||
}
|
||||
|
||||
func (client *Client) TablesStats() (*Result, error) {
|
||||
return client.query(statements.TablesStats)
|
||||
}
|
||||
|
||||
// Returns all active queriers on the server
|
||||
func (client *Client) Activity() (*Result, error) {
|
||||
if client.serverType == cockroachType {
|
||||
|
@ -641,6 +641,25 @@ func testReadOnlyMode(t *testing.T) {
|
||||
assert.NoError(t, err)
|
||||
}
|
||||
|
||||
func testTablesStats(t *testing.T) {
|
||||
columns := []string{
|
||||
"schema_name",
|
||||
"table_name",
|
||||
"total_size",
|
||||
"data_size",
|
||||
"index_size",
|
||||
"estimated_rows_count",
|
||||
"estimated_rows",
|
||||
"index_to_data_ratio",
|
||||
"indexes_count",
|
||||
"columns_count",
|
||||
}
|
||||
|
||||
result, err := testClient.TablesStats()
|
||||
assert.NoError(t, err)
|
||||
assert.Equal(t, columns, result.Columns)
|
||||
}
|
||||
|
||||
func TestAll(t *testing.T) {
|
||||
if onWindows() {
|
||||
t.Log("Unit testing on Windows platform is not supported.")
|
||||
@ -678,6 +697,7 @@ func TestAll(t *testing.T) {
|
||||
testHistory(t)
|
||||
testReadOnlyMode(t)
|
||||
testDumpExport(t)
|
||||
testTablesStats(t)
|
||||
|
||||
teardownClient()
|
||||
teardown(t, true)
|
||||
|
@ -41,6 +41,9 @@ var (
|
||||
//go:embed sql/objects.sql
|
||||
Objects string
|
||||
|
||||
//go:embed sql/tables_stats.sql
|
||||
TablesStats string
|
||||
|
||||
//go:embed sql/function.sql
|
||||
Function string
|
||||
|
||||
|
44
pkg/statements/sql/tables_stats.sql
Normal file
44
pkg/statements/sql/tables_stats.sql
Normal file
@ -0,0 +1,44 @@
|
||||
WITH columns_counts AS (
|
||||
SELECT table_schema, table_name, COUNT(1) AS num
|
||||
FROM information_schema.columns
|
||||
GROUP BY table_schema, table_name
|
||||
),
|
||||
indexes_counts AS (
|
||||
SELECT schemaname, tablename, COUNT(1) AS num
|
||||
FROM pg_indexes
|
||||
GROUP BY schemaname, tablename
|
||||
)
|
||||
SELECT
|
||||
tables.schemaname AS schema_name,
|
||||
tables.relname AS table_name,
|
||||
pg_size_pretty(pg_total_relation_size(tables.relid)) AS total_size,
|
||||
pg_size_pretty(pg_relation_size(tables.relid)) AS data_size,
|
||||
pg_size_pretty(pg_indexes_size(tables.relid)) AS index_size,
|
||||
pg_class.reltuples AS estimated_rows_count,
|
||||
CASE
|
||||
WHEN pg_class.reltuples >= 0 AND pg_class.reltuples < 1000
|
||||
THEN pg_class.reltuples::text
|
||||
WHEN pg_class.reltuples >= 1000 AND pg_class.reltuples < 1000000
|
||||
THEN ROUND((pg_class.reltuples / 1000))::text || 'K'
|
||||
WHEN pg_class.reltuples >= 1000000
|
||||
THEN ROUND(pg_class.reltuples / 1000000)::text || 'M'
|
||||
END AS estimated_rows,
|
||||
CASE
|
||||
WHEN pg_class.reltuples > 1000
|
||||
THEN ROUND(pg_indexes_size(tables.relid)::numeric / pg_relation_size(tables.relid), 2)
|
||||
END AS index_to_data_ratio,
|
||||
indexes_counts.num AS indexes_count,
|
||||
columns_counts.num AS columns_count
|
||||
FROM
|
||||
pg_catalog.pg_statio_user_tables AS tables
|
||||
LEFT JOIN pg_class
|
||||
ON pg_class.oid = tables.relid
|
||||
LEFT JOIN indexes_counts
|
||||
ON indexes_counts.schemaname = tables.schemaname
|
||||
AND indexes_counts.tablename = tables.relname
|
||||
LEFT JOIN columns_counts
|
||||
ON columns_counts.table_schema = tables.schemaname
|
||||
AND columns_counts.table_name = tables.relname
|
||||
ORDER BY
|
||||
pg_total_relation_size(tables.relid) DESC,
|
||||
pg_relation_size(tables.relid) DESC
|
@ -310,6 +310,7 @@
|
||||
</div>
|
||||
<div id="current_database_context_menu">
|
||||
<ul class="dropdown-menu" role="menu">
|
||||
<li><a href="#" data-action="show_tables_stats">Show Tables Stats</a></li>
|
||||
<li><a href="#" data-action="export">Export SQL dump</a></li>
|
||||
</ul>
|
||||
</div>
|
||||
|
@ -99,6 +99,7 @@ function getTableRows(table, opts, cb) { apiCall("get", "/tables/" + table
|
||||
function getTableStructure(table, opts, cb) { apiCall("get", "/tables/" + table, opts, cb); }
|
||||
function getTableIndexes(table, cb) { apiCall("get", "/tables/" + table + "/indexes", {}, cb); }
|
||||
function getTableConstraints(table, cb) { apiCall("get", "/tables/" + table + "/constraints", {}, cb); }
|
||||
function getTablesStats(cb) { apiCall("get", "/tables_stats", {}, cb); }
|
||||
function getFunction(id, cb) { apiCall("get", "/functions/" + id, {}, cb); }
|
||||
function getHistory(cb) { apiCall("get", "/history", {}, cb); }
|
||||
function getBookmarks(cb) { apiCall("get", "/bookmarks", {}, cb); }
|
||||
@ -619,6 +620,17 @@ function showPaginatedTableContent() {
|
||||
showTableContent(sortColumn, sortOrder);
|
||||
}
|
||||
|
||||
function showTablesStats() {
|
||||
getTablesStats(function(data) {
|
||||
buildTable(data);
|
||||
|
||||
setCurrentTab("table_structure");
|
||||
$("#input").hide();
|
||||
$("#body").prop("class", "full");
|
||||
$("#results").addClass("no-crop");
|
||||
});
|
||||
}
|
||||
|
||||
function showTableStructure() {
|
||||
var name = getCurrentObject().name;
|
||||
|
||||
@ -1193,6 +1205,9 @@ function bindCurrentDatabaseMenu() {
|
||||
var menuItem = $(e.target);
|
||||
|
||||
switch(menuItem.data("action")) {
|
||||
case "show_tables_stats":
|
||||
showTablesStats();
|
||||
break;
|
||||
case "export":
|
||||
openInNewWindow("api/export");
|
||||
break;
|
||||
|
Loading…
Reference in New Issue
Block a user