From 253cf1867d95cf1ef2e0d2c4fc16d8b32b2daacb Mon Sep 17 00:00:00 2001 From: Shane Borden Date: Thu, 18 Sep 2025 09:49:11 -0500 Subject: [PATCH 1/3] feat: add new scripts --- ...postgres_alloy_columnar_engine_queries.sql | 342 ++++++++++++++++++ .../postgres_index_check_usage_frequency.sql | 273 ++++++++++++++ postgres/postgres_index_information_query.sql | 32 -- postgres/postgres_object_sizes.sql | 120 ++++++ ...ostgres_vacuum_activity_estimate_stats.sql | 2 +- 5 files changed, 736 insertions(+), 33 deletions(-) create mode 100644 postgres/postgres_alloy_columnar_engine_queries.sql create mode 100644 postgres/postgres_index_check_usage_frequency.sql delete mode 100644 postgres/postgres_index_information_query.sql create mode 100644 postgres/postgres_object_sizes.sql diff --git a/postgres/postgres_alloy_columnar_engine_queries.sql b/postgres/postgres_alloy_columnar_engine_queries.sql new file mode 100644 index 0000000..f17f60e --- /dev/null +++ b/postgres/postgres_alloy_columnar_engine_queries.sql @@ -0,0 +1,342 @@ +-- Copyright 2025 shaneborden +-- +-- Licensed under the Apache License, Version 2.0 (the "License"); +-- you may not use this file except in compliance with the License. +-- You may obtain a copy of the License at +-- +-- https://www.apache.org/licenses/LICENSE-2.0 +-- +-- Unless required by applicable law or agreed to in writing, software +-- distributed under the License is distributed on an "AS IS" BASIS, +-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. +-- See the License for the specific language governing permissions and +-- limitations under the License. + +/* Helpful Links +https://cloud.google.com/alloydb/docs/columnar-engine/manage-content-recommendations +https://medium.com/google-cloud/alloydbs-columnar-store-how-to-preserve-it-during-failovers-and-restarts-141a8466772 */ + +/* determine columnar engine settings */ +select name,setting,boot_val,reset_val from pg_settings where name like '%google_columnar_engine%' order by 1; + +/* Set a population policy */ +SELECT google_columnar_engine_add_policy('RECOMMEND_AND_POPULATE_COLUMNS','IMMEDIATE',0,'HOURS'); +--IMMEDIATE - runs immediately one time. When you use this value, specify 0 and 'HOURS' for the duration and time_unit parameters. +--AFTER - runs once when the duration time_unit amount of time passes +--EVERY - runs repeatedly every duration time_unit amount of time + +/* Execute a recommendation */ +SELECT google_columnar_engine_run_recommendation(102400,'PERFORMANCE_OPTIMAL'); + +/* check from psql if columnar is enabled */ +postgres=# show google_columnar_engine.enabled; + google_columnar_engine.enabled +-------------------------------- + off + + /* To show columnar messages in cloud logging */ +textPayload=~"population_jobs.cc|Invalidating columnar|population.cc|columnar" + +/* To Force a SEQ Scan for invalid blocks; this is the default now; Use this for debugging only */ +set session google_columnar_engine.rowstore_scan_mode to 1; + +/* To show the refresh threshold (based on invalid blocks vs total blocks) */ +show google_columnar_engine.refresh_threshold_percentage; + +/* To show the number of DML operations on base table required before the refresh_threshold_percentage kicks in */ +show google_columnar_engine.refresh_threshold_scan_count; + +/* to force a columnar scan; generally isnt needed, this is for testing / debugging only */ +set session google_columnar_engine.force_columnar_mode to true; + +/* other GUC to influence CE costing, this is for testing / debugging only */ +set session enable_cache_aware_costing = true +set session google_columnar_engine.bump_columnar_scan_cost = false + +/* to force columnar using pg_hint_plan */ +/*+ ColumnarScan(xxx) */ + +/* To manually run the job: */ +SELECT google_columnar_engine_recommend(); + +/* To view the list of recommended columns: */ +SELECT * FROM g_columnar_recommended_columns; +SELECT database_name, schema_name, relation_name, column_name FROM g_columnar_recommended_columns; + +/* To add a table */ +SELECT google_columnar_engine_add('t1'); +select google_columnar_engine_add(relation => 'public.t1', in_background => TRUE); + +/* To add a table with a subset of columns */ +SELECT google_columnar_engine_add('public.t1', 'a,b,c,f,'); + +/* To remove a table */ +SELECT google_columnar_engine_drop('t1'); +SELECT google_columnar_engine_drop('public.t1'); + +/* To disable columnar for a query in a session */ +set session google_columnar_engine.enable_columnar_scan TO 'off'; + +/* to Refresh a table */ +select google_columnar_engine_refresh('public.t1'); + +select google_columnar_engine_refresh(relation => 'public.t1', in_background => TRUE); + +/* to check columar jobs */ +select * from g_columnar_jobs; + +/* To view the list of recommended column detail: */ +SELECT + crc.database_name as database_name, + crc.schema_name AS schema_name, + crc.relation_name AS table_name, + pi.inhparent::regclass, + crc.column_name, + crc.column_format, + crc.compression_level, + crc.estimated_size_in_bytes +FROM public.g_columnar_recommended_columns_internal /* g_columnar_recommended_columns */ crc +JOIN pg_stat_all_tables ps + ON ps.schemaname::text = crc.schema_name + AND ps.relname::text = crc.relation_name +JOIN pg_class pc + ON ps.relid = pc.oid +LEFT JOIN pg_catalog.pg_inherits pi + ON ps.relid = pi.inhrelid +ORDER BY 1,2,4 NULLS LAST; + +/* to display table name without column detail */ +SELECT + crc.database_name as database_name, + crc.schema_name AS schema_name, + crc.relation_name AS table_name, + pi.inhparent::regclass, + crc.column_format, + crc.compression_level, + SUM(crc.estimated_size_in_bytes) as total_bytes, + pg_size_pretty(SUM(crc.estimated_size_in_bytes)) as pretty_total_size +FROM g_columnar_recommended_columns crc +JOIN pg_stat_all_tables ps + ON ps.schemaname::text = crc.schema_name + AND ps.relname::text = crc.relation_name +JOIN pg_class pc + ON ps.relid = pc.oid +LEFT JOIN pg_catalog.pg_inherits pi + ON ps.relid = pi.inhrelid +GROUP BY crc.database_name, crc.schema_name, crc.relation_name, pi.inhparent::regclass,crc.column_format,crc.compression_level +ORDER BY 1,2,4 NULLS LAST; + + +/* List of items in the column store */ +SELECT + database_name, + schema_name, + relation_name, + column_name, + column_type, + status, + size_in_bytes, + last_accessed_time, + num_times_accessed +FROM + g_columnar_columns; + +SELECT + * +FROM + g_columnar_columns; + +SELECT + * +FROM + g_columnar_relations +ORDER BY + relation_name; + + +/* To see current status of items in columnstore */ +SELECT + schema_name, + relation_name, + status, + swap_status, + sum(end_block - start_block) ttl_block, + sum(invalid_block_count) invalid_block, + CASE WHEN sum(end_block - start_block) > 0 THEN + round(100 * sum(invalid_block_count) / sum(end_block - start_block), 1) + ELSE 0.0 + END AS invalid_block_perc, + pg_size_pretty(sum(size)) ttl_size, + pg_size_pretty(sum(cached_size_bytes)) ttl_cached_size +FROM + g_columnar_units +WHERE + g_columnar_units.database_name = current_database() + and g_columnar_units.relation_name like '%' +GROUP BY + schema_name, + relation_name, + status, + swap_status +ORDER BY + relation_name; + +/* Check utilization of columnar memory */ +SELECT + memory_name, + memory_total / 1024 / 1024 memory_total_MB, + memory_available / 1024 / 1024 memory_available_MB, + memory_available_percentage, + pg_size_pretty(google_columnar_engine_storage_cache_used()*1024*1024) AS cc_storage_cache_used_mb, + pg_size_pretty(google_columnar_engine_storage_cache_available()*1024*1024) AS cc_storage_cache_avail_mb, + pg_size_pretty((google_columnar_engine_storage_cache_available() - google_columnar_engine_storage_cache_used())*1024*1024) as cc_storage_cache_free_mb +FROM + g_columnar_memory_usage; + +/* Check non default "google" postgres params */ +SELECT + s.name AS "Parameter", + pg_catalog.current_setting(s.name) AS "Value" +FROM + pg_catalog.pg_settings s +WHERE + 1=1 + --AND s.source <> 'default' + --AND s.setting IS DISTINCT FROM s.boot_val + AND lower(s.name) LIKE '%google%' +ORDER BY + 1; + +/* To see Columnar engine column Swap-out */ +SELECT + memory_name, + pg_size_pretty(memory_total) AS cc_allocated, + pg_size_pretty(memory_total - memory_available) AS cc_consumed, + pg_size_pretty(memory_available) cc_available, + --google_columnar_engine_storage_cache_total() as cc_storage_cache_avail_mb, /* Future function */ + google_columnar_engine_storage_cache_used() AS cc_storage_cache_used_mb, + google_columnar_engine_storage_cache_available() AS cc_storage_cache_avail_mb, + CASE WHEN google_columnar_engine_storage_cache_used() > 0 THEN + 'Swapped-out Column(s)' + ELSE + NULL + END AS "SwapOut", + ( + SELECT + CONCAT_WS('-', STRING_AGG(DISTINCT g_columnar_units.relation_name, '/'), STATUS, swap_status) + FROM + g_columnar_units + GROUP BY + status, + swap_status) AS current_obj +FROM + g_columnar_memory_usage +WHERE + memory_name = 'main_pool'; + + +/* To populate many tables manually */ +do +$$ +declare + f record; + gResult numeric; + begin_timestamp timestamp; + age_text text; +begin + for f in SELECT + n.nspname as schemaname, + c.oid::regclass::text AS table_name, + c.oid as oid, + pi.inhparent::regclass::text AS top_table_name, + pg_total_relation_size(c.oid) as size, + pg_size_pretty(pg_total_relation_size(c.oid)) as pretty_size + FROM pg_class c + JOIN pg_namespace n on c.relnamespace = n.oid + LEFT JOIN pg_inherits pi on c.oid = pi.inhrelid + WHERE c.relkind IN ('r', 't', 'm') + AND (n.nspname NOT IN('pg_toast') AND n.nspname LIKE '%') + --AND (c.oid::regclass::text LIKE '%' AND pi.inhparent::regclass::text LIKE '%') + AND (c.oid::regclass::text LIKE 'table_name%' AND pi.inhparent::regclass::text LIKE 'table_partiton_name%') + ORDER BY 2 NULLS LAST + loop + BEGIN + SELECT clock_timestamp() into begin_timestamp; + --SELECT google_columnar_engine_add(f.oid,'[comma separated column list]') into gResult; /* us this if there are specific cols */ + SELECT google_columnar_engine_add(f.oid) into gResult; + SELECT age(clock_timestamp(),begin_timestamp)::text into age_text; + raise notice ' % % % % % %', f.top_table_name, f.table_name, 'google_columnar_engine_add result: ', gResult, ' time: ', age_text; + EXCEPTION WHEN OTHERS THEN + raise notice ' % % % %', f.top_table_name, f.table_name, 'exception result', gResult; + END; + end loop; +end; +$$; + + +/* To refresh many tables manually */ +do +$$ +declare + f record; + gResult numeric; +begin + for f in SELECT + n.nspname as schemaname, + c.oid::regclass::text AS table_name, + c.oid as oid, + pi.inhparent::regclass::text AS top_table_name, + pg_total_relation_size(c.oid) as size, + pg_size_pretty(pg_total_relation_size(c.oid)) as pretty_size + FROM pg_class c + JOIN pg_namespace n on c.relnamespace = n.oid + LEFT JOIN pg_inherits pi on c.oid = pi.inhrelid + WHERE c.relkind IN ('r', 't', 'm') + AND (n.nspname NOT IN('pg_toast') AND n.nspname LIKE '%') + --AND (c.oid::regclass::text LIKE '%' AND pi.inhparent::regclass::text LIKE '%') + AND (c.oid::regclass::text LIKE 'table_name%' AND pi.inhparent::regclass::text LIKE 'table_partiton_name%') + ORDER BY 2 NULLS LAST + loop + BEGIN + SELECT google_columnar_engine_refresh(f.oid) into gResult; + raise notice ' % % % %', f.top_table_name, f.table_name, 'google_columnar_engine_refresh result: ', gResult; + EXCEPTION WHEN OTHERS THEN + raise notice ' % % % %', f.top_table_name, f.table_name, 'exception result', gResult; + END; + end loop; +end; +$$; + +/* To drop many tables manually */ +do +$$ +declare + f record; + gResult numeric; +begin + for f in SELECT + n.nspname as schemaname, + c.oid::regclass::text AS table_name, + c.oid as oid, + pi.inhparent::regclass::text AS top_table_name, + pg_total_relation_size(c.oid) as size, + pg_size_pretty(pg_total_relation_size(c.oid)) as pretty_size + FROM pg_class c + JOIN pg_namespace n on c.relnamespace = n.oid + LEFT JOIN pg_inherits pi on c.oid = pi.inhrelid + JOIN g_columnar_units ce on (ce.schema_name = n.nspname and ce.relation_name = c.oid::regclass::text) + WHERE c.relkind IN ('r', 't', 'm') + AND (n.nspname NOT IN('pg_toast') AND n.nspname LIKE '%') + --AND (c.oid::regclass::text LIKE '%' AND pi.inhparent::regclass::text LIKE '%') + AND (c.oid::regclass::text LIKE 'table_name%' AND pi.inhparent::regclass::text LIKE 'table_partiton_name%') + ORDER BY 2 NULLS LAST + loop + BEGIN + SELECT google_columnar_engine_drop(f.oid) into gResult; + raise notice ' % % % %', f.top_table_name, f.table_name, 'google_columnar_engine_add result: ', gResult; + EXCEPTION WHEN OTHERS THEN + raise notice ' % % % %', f.top_table_name, f.table_name, 'exception result', gResult; + END; + end loop; +end; +$$; \ No newline at end of file diff --git a/postgres/postgres_index_check_usage_frequency.sql b/postgres/postgres_index_check_usage_frequency.sql new file mode 100644 index 0000000..e5fb43f --- /dev/null +++ b/postgres/postgres_index_check_usage_frequency.sql @@ -0,0 +1,273 @@ +/* + https://wiki.postgresql.org/wiki/Index_Maintenance + https://bucardo.org/check_postgres/ +*/ + +/* indexdes supporting pk constraints */ +\prompt 'Enter schema_name: ' vSchemaName +SELECT + n.nspname schema_name, + c.conname constraint_name, + c.contype constraint_type, + i.relname index_name, + t.relname table_name +FROM + pg_constraint c + JOIN pg_namespace n ON (c.connamespace = n.oid + AND n.nspname = :'vSchemaName') + JOIN pg_class i ON (c.conindid = i.oid) + JOIN pg_class t ON (c.conrelid = t.oid) +WHERE + c.contype = 'p'; + +/* Index Information Query */ +\prompt 'Enter schema_name: ' vSchemaName +SELECT + pg_class.relname, + pg_size_pretty(pg_class.reltuples::bigint) AS rows_in_bytes, + pg_class.reltuples AS num_rows, + COUNT(*) AS total_indexes, + COUNT(*) FILTER ( WHERE indisunique) AS unique_indexes, + COUNT(*) FILTER ( WHERE indnatts = 1 ) AS single_column_indexes, + COUNT(*) FILTER ( WHERE indnatts IS DISTINCT FROM 1 ) AS multi_column_indexes +FROM + pg_namespace + LEFT JOIN pg_class ON pg_namespace.oid = pg_class.relnamespace + LEFT JOIN pg_index ON pg_class.oid = pg_index.indrelid +WHERE + pg_namespace.nspname = :'vSchemaName' AND + pg_class.relkind = 'r' +GROUP BY pg_class.relname, pg_class.reltuples +ORDER BY pg.namespace.nspname, pg_class.reltuples DESC; + +/* Index Usage Information */ +\prompt 'Enter schema_name: ' vSchemaName +SELECT + t.schemaname, + t.tablename, + c.reltuples::bigint AS num_rows, + pg_size_pretty(pg_relation_size(c.oid)) AS table_size, + psai.indexrelname AS index_name, + pg_size_pretty(pg_relation_size(i.indexrelid)) AS index_size, + CASE WHEN i.indisunique THEN 'Y' ELSE 'N' END AS "unique", + psai.idx_scan AS number_of_scans, + psai.idx_tup_read AS tuples_read, + psai.idx_tup_fetch AS tuples_fetched +FROM + pg_tables t + LEFT JOIN pg_class c ON t.tablename = c.relname + LEFT JOIN pg_index i ON c.oid = i.indrelid + LEFT JOIN pg_stat_all_indexes psai ON i.indexrelid = psai.indexrelid +WHERE + t.schemaname NOT IN ('pg_catalog', 'information_schema','partman') + AND t.schemaname LIKE ('%') +ORDER BY 1, 2; + + +/* Duplicate Indexes w/o relname */ +SELECT pg_size_pretty(sum(pg_relation_size(idx))::bigint) as size, + (array_agg(idx))[1] as idx1, (array_agg(idx))[2] as idx2, + (array_agg(idx))[3] as idx3, (array_agg(idx))[4] as idx4 +FROM ( + SELECT indexrelid::regclass as idx, (indrelid::text ||E'\n'|| indclass::text ||E'\n'|| indkey::text ||E'\n'|| + coalesce(indexprs::text,'')||E'\n' || coalesce(indpred::text,'')) as key + FROM pg_index) sub +GROUP BY key HAVING count(*)>1 +ORDER BY sum(pg_relation_size(idx)) DESC; + +/* Duplicate Indexes w/ relname */ +SELECT + n.nspname AS schema, + c.relname AS relname, + sum(pg_relation_size(idx))::bigint AS size, + pg_size_pretty(sum(pg_relation_size(idx))::bigint) AS pretty_size, + (array_agg(idx))[1] AS idx1, + (array_agg(idx))[2] AS idx2, + (array_agg(idx))[3] AS idx3, + (array_agg(idx))[4] AS idx4, + (array_agg(idx))[5] AS idx5, + (array_agg(idx))[6] AS idx6, + (array_agg(idx))[7] AS idx7, + (array_agg(idx))[8] AS idx8, + (array_agg(idx))[9] AS idx9, + (array_agg(idx))[10] AS idx10 +FROM ( + SELECT + i.indrelid, + i.indexrelid::regclass AS idx, + (i.indrelid::text || E'\n' || indclass::text || E'\n' || indkey::text || E'\n' || coalesce(indexprs::text, '') || E'\n' || SUBSTRING(pi.indexdef FROM (POSITION('ON' IN pi.indexdef)))) as key + --(indrelid::text || E'\n' || indclass::text || E'\n' || indkey::text || E'\n' || coalesce(indexprs::text, '') || E'\n' || coalesce(indpred::text, '')) AS key + FROM + pg_index i + JOIN pg_class c ON (i.indexrelid = c.oid) + JOIN pg_indexes pi ON (pi.indexname = c.relname)) sub + JOIN pg_class c ON (c.oid = sub.indrelid) + JOIN pg_namespace n ON (c.relnamespace = n.oid) +GROUP BY + n.nspname, + relname, + key +HAVING + count(*) > 1 +ORDER BY + sum(pg_relation_size(idx)) DESC; + + +/* + https://github.com/dataegret/pg-utils/blob/master/sql/low_used_indexes.sql +*/ + +SELECT pg_stat_user_indexes.schemaname || '.' || pg_stat_user_indexes.relname tablemane + , pg_stat_user_indexes.indexrelname + , pg_stat_user_indexes.idx_scan + , psut.write_activity + , psut.seq_scan + , psut.n_live_tup + , pg_size_pretty (pg_relation_size (pg_index.indexrelid::regclass)) as size + from pg_stat_user_indexes + join pg_index + ON pg_stat_user_indexes.indexrelid = pg_index.indexrelid + join (select pg_stat_user_tables.relid + , pg_stat_user_tables.seq_scan + , pg_stat_user_tables.n_live_tup + , ( coalesce (pg_stat_user_tables.n_tup_ins, 0) + + coalesce (pg_stat_user_tables.n_tup_upd, 0) + - coalesce (pg_stat_user_tables.n_tup_hot_upd, 0) + + coalesce (pg_stat_user_tables.n_tup_del, 0) + ) as write_activity + from pg_stat_user_tables) psut + on pg_stat_user_indexes.relid = psut.relid + where pg_index.indisunique is false + and pg_stat_user_indexes.idx_scan::float / (psut.write_activity + 1)::float < 0.01 + and psut.write_activity > case when pg_is_in_recovery () then -1 else 10000 end + order by 4 desc, 1, 2; + +with indexes as ( + select * from pg_stat_user_indexes +) +select table_name, +pg_size_pretty(table_size) as table_size, +index_name, +pg_size_pretty(index_size) as index_size, +idx_scan as index_scans, +round((free_space*100/index_size)::numeric, 1) as waste_percent, +pg_size_pretty(free_space) as waste +from ( + select (case when schemaname = 'public' then format('%I', p.relname) else format('%I.%I', schemaname, p.relname) end) as table_name, + indexrelname as index_name, + (select (case when avg_leaf_density = 'NaN' then 0 + else greatest(ceil(index_size * (1 - avg_leaf_density / (coalesce((SELECT (regexp_matches(reloptions::text, E'.*fillfactor=(\\d+).*'))[1]),'90')::real)))::bigint, 0) end) + from pgstatindex(p.indexrelid::regclass::text) + ) as free_space, + pg_relation_size(p.indexrelid) as index_size, + pg_relation_size(p.relid) as table_size, + idx_scan + from indexes p + join pg_class c on p.indexrelid = c.oid + join pg_index i on i.indexrelid = p.indexrelid + where pg_get_indexdef(p.indexrelid) like '%USING btree%' and + i.indisvalid and (c.relpersistence = 'p' or not pg_is_in_recovery()) + --put your index name/mask here + -- and indexrelname = 'transactions_p01_user_id_idx' +) t +order by free_space desc +limit 100; + + +/* Find Unused Indexes */ +WITH table_scans as ( + SELECT relid, + tables.idx_scan + tables.seq_scan as all_scans, + ( tables.n_tup_ins + tables.n_tup_upd + tables.n_tup_del ) as writes, + pg_relation_size(relid) as table_size + FROM pg_stat_all_tables as tables + WHERE schemaname not in ('pg_toast','pg_catalog','partman') +), +all_writes as ( + SELECT sum(writes) as total_writes + FROM table_scans +), +indexes as ( + SELECT idx_stat.relid, idx_stat.indexrelid, + idx_stat.schemaname, idx_stat.relname as tablename, + idx_stat.indexrelname as indexname, + idx_stat.idx_scan, + pg_relation_size(idx_stat.indexrelid) as index_bytes, + indexdef ~* 'USING btree' AS idx_is_btree + FROM pg_stat_user_indexes as idx_stat + JOIN pg_index + USING (indexrelid) + JOIN pg_indexes as indexes + ON idx_stat.schemaname = indexes.schemaname + AND idx_stat.relname = indexes.tablename + AND idx_stat.indexrelname = indexes.indexname + WHERE pg_index.indisunique = FALSE +), +index_ratios AS ( +SELECT schemaname, tablename, indexname, + idx_scan, all_scans, + round(( CASE WHEN all_scans = 0 THEN 0.0::NUMERIC + ELSE idx_scan::NUMERIC/all_scans * 100 END),2) as index_scan_pct, + writes, + round((CASE WHEN writes = 0 THEN idx_scan::NUMERIC ELSE idx_scan::NUMERIC/writes END),2) + as scans_per_write, + pg_size_pretty(index_bytes) as index_size_pretty, + pg_size_pretty(table_size) as table_size, + idx_is_btree, + index_bytes as index_size_bytes + FROM indexes + JOIN table_scans + USING (relid) +), +index_groups AS ( +SELECT 'Never Used Indexes' as reason, *, 1 as grp +FROM index_ratios +WHERE + idx_scan = 0 + and idx_is_btree +UNION ALL +SELECT 'Low Scans, High Writes' as reason, *, 2 as grp +FROM index_ratios +WHERE + scans_per_write <= 1 + and index_scan_pct < 10 + and idx_scan > 0 + and writes > 100 + and idx_is_btree +UNION ALL +SELECT 'Seldom Used Large Indexes' as reason, *, 3 as grp +FROM index_ratios +WHERE + index_scan_pct < 5 + and scans_per_write > 1 + and idx_scan > 0 + and idx_is_btree + and index_size_bytes > 100000000 +UNION ALL +SELECT 'High-Write Large Non-Btree' as reason, index_ratios.*, 4 as grp +FROM index_ratios, all_writes +WHERE + ( writes::NUMERIC / ( total_writes + 1 ) ) > 0.02 + AND NOT idx_is_btree + AND index_size_bytes > 100000000 +ORDER BY grp, index_size_bytes DESC ) +SELECT reason, schemaname, tablename, indexname, + index_scan_pct, scans_per_write, index_size_pretty,index_size_bytes, table_size +FROM index_groups +WHERE tablename like '%' +ORDER BY reason, index_size_bytes,table_size; + + +/* Index Cache Hit Ratio */ +SELECT +relname, +indexrelname, +sum(idx_blks_read) as idx_read, +sum(idx_blks_hit) as idx_hit, +ROUND((sum(idx_blks_hit) - sum(idx_blks_read)) / sum(idx_blks_hit),4) as ratio +FROM pg_statio_user_indexes +WHERE (idx_blks_read > 0 and idx_blks_hit > 0) +--AND relname like '%transaction%' AND indexrelname like '%user%' +GROUP BY +relname, +indexrelname; diff --git a/postgres/postgres_index_information_query.sql b/postgres/postgres_index_information_query.sql deleted file mode 100644 index ee282b4..0000000 --- a/postgres/postgres_index_information_query.sql +++ /dev/null @@ -1,32 +0,0 @@ --- Copyright 2024 shaneborden --- --- Licensed under the Apache License, Version 2.0 (the "License"); --- you may not use this file except in compliance with the License. --- You may obtain a copy of the License at --- --- https://www.apache.org/licenses/LICENSE-2.0 --- --- Unless required by applicable law or agreed to in writing, software --- distributed under the License is distributed on an "AS IS" BASIS, --- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. --- See the License for the specific language governing permissions and --- limitations under the License. - -\prompt 'Enter schema_name: ' vSchemaName -SELECT - pg_class.relname, - pg_size_pretty(pg_class.reltuples::bigint) AS rows_in_bytes, - pg_class.reltuples AS num_rows, - COUNT(*) AS total_indexes, - COUNT(*) FILTER ( WHERE indisunique) AS unique_indexes, - COUNT(*) FILTER ( WHERE indnatts = 1 ) AS single_column_indexes, - COUNT(*) FILTER ( WHERE indnatts IS DISTINCT FROM 1 ) AS multi_column_indexes -FROM - pg_namespace - LEFT JOIN pg_class ON pg_namespace.oid = pg_class.relnamespace - LEFT JOIN pg_index ON pg_class.oid = pg_index.indrelid -WHERE - pg_namespace.nspname = :'vSchemaName' AND - pg_class.relkind = 'r' -GROUP BY pg_class.relname, pg_class.reltuples -ORDER BY pg.namespace.nspname, pg_class.reltuples DESC; diff --git a/postgres/postgres_object_sizes.sql b/postgres/postgres_object_sizes.sql new file mode 100644 index 0000000..c57c486 --- /dev/null +++ b/postgres/postgres_object_sizes.sql @@ -0,0 +1,120 @@ +-- Copyright 2025 shaneborden +-- +-- Licensed under the Apache License, Version 2.0 (the "License"); +-- you may not use this file except in compliance with the License. +-- You may obtain a copy of the License at +-- +-- https://www.apache.org/licenses/LICENSE-2.0 +-- +-- Unless required by applicable law or agreed to in writing, software +-- distributed under the License is distributed on an "AS IS" BASIS, +-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. +-- See the License for the specific language governing permissions and +-- limitations under the License. + +/* Table Sizes */ +SELECT +n.nspname as schemaname, +c.oid::regclass::text AS table_name, +pi.inhparent::regclass::text AS top_table_name, +pg_total_relation_size(c.oid) as size, +pg_size_pretty(pg_total_relation_size(c.oid)) as pretty_size +FROM pg_class c +JOIN pg_namespace n on c.relnamespace = n.oid +LEFT JOIN pg_inherits pi on c.oid = pi.inhrelid +WHERE c.relkind IN ('r', 't', 'm') +AND (n.nspname NOT IN('pg_toast') AND n.nspname LIKE '%') +AND (c.oid::regclass::text LIKE '%' and pi.inhparent::regclass::text LIKE '%') +ORDER BY 2 NULLS LAST; + +SELECT + *, + pg_size_pretty(table_bytes) AS table, + pg_size_pretty(toast_bytes) AS toast, + pg_size_pretty(index_bytes) AS index, + pg_size_pretty(total_bytes) AS total +FROM ( + SELECT + *, total_bytes - index_bytes - COALESCE(toast_bytes, 0) AS table_bytes + FROM ( + SELECT + c.oid, + n.nspname AS table_schema, + c.relname AS table_name, + c.reltuples AS row_estimate, + pct.relname AS toast_table_name, + pg_total_relation_size(c.oid) AS total_bytes, + pg_indexes_size(c.oid) AS index_bytes, + pg_total_relation_size(c.reltoastrelid) AS toast_bytes + FROM + pg_class c + JOIN pg_class pct ON (c.reltoastrelid = pct.oid) + LEFT JOIN pg_namespace n ON n.oid = c.relnamespace + WHERE c.relkind = 'r' + ) a +) a +WHERE table_schema like '%' +AND table_name like '%' +AND total_bytes > 0 +ORDER BY table_name DESC; + +/* Index Sizes */ +SELECT +n.nspname as schemaname, +pgi.tablename as tablename, +c.oid::regclass::text AS index_name, +pi.inhparent::regclass::text AS top_index_name, +pg_total_relation_size(c.oid) as size, +pg_size_pretty(pg_total_relation_size(c.oid)) as pretty_size +FROM pg_class c +JOIN pg_namespace n on c.relnamespace = n.oid +JOIN pg_indexes pgi on pgi.indexname = c.oid::regclass::text and pgi.schemaname = n.nspname +LEFT JOIN pg_inherits pi on c.oid = pi.inhrelid +WHERE c.relkind IN ('i') +AND (n.nspname NOT IN('pg_toast') AND n.nspname LIKE '%') +AND (c.oid::regclass::text LIKE '%' and pi.inhparent::regclass::text LIKE '%') +ORDER BY 4 NULLS LAST; + +/* Temp Table Size */ +SELECT + n.nspname as SchemaName + ,c.relname as RelationName + ,CASE c.relkind + WHEN 'r' THEN 'table' + WHEN 'v' THEN 'view' + WHEN 'i' THEN 'index' + WHEN 'S' THEN 'sequence' + WHEN 's' THEN 'special' + END as RelationType + ,pg_catalog.pg_get_userbyid(c.relowner) as RelationOwner + ,pg_size_pretty(pg_relation_size(n.nspname ||'.'|| c.relname)) as RelationSize +FROM pg_catalog.pg_class c +LEFT JOIN pg_catalog.pg_namespace n + ON n.oid = c.relnamespace +WHERE c.relkind IN ('r','s') +AND (n.nspname !~ '^pg_toast' and nspname like 'pg_temp%') +ORDER BY pg_relation_size(n.nspname ||'.'|| c.relname) DESC; + +/* String Columns + live tuples + table size*/ +SELECT + c.table_catalog, + c.table_schema, + c.table_name, + c.column_name, + c.data_type, + c.character_maximum_length, + st.n_live_tup, + pg_size_pretty(pg_total_relation_size(pc.oid)) as pretty_size +FROM + information_schema.columns c + JOIN pg_stat_all_tables st ON (st.schemaname = c.table_schema AND st.relname = c.table_name) + JOIN pg_class pc ON (pc.relname = c.table_name) + JOIN pg_namespace n ON (pc.relnamespace = n.oid AND n.nspname = c.table_schema) +WHERE + table_schema NOT IN ('dbms_alert', 'dbms_assert', 'dbms_output', 'dbms_pipe', 'dbms_random', 'dbms_utility', 'information_schema', 'oracle', 'pg_catalog', 'pg_toast', 'plunit', 'plvchr', 'plvdate', 'plvlex', 'plvstr', 'plvsubst', 'utl_file') + AND data_type NOT IN ('ARRAY', 'anyarray', 'bigint', 'boolean', 'bytea', 'double precision', 'inet', 'integer', 'interval', 'numeric', 'oid', 'pg_dependencies', 'pg_lsn', 'pg_ndistinct', 'pg_node_tree', 'real', 'regclass', 'regproc', 'regtype', 'smallint', 'timestamp with time zone', 'timestamp without time zone', 'xid') + and c.table_catalog = current_database() +ORDER BY + 1, + 2, + 3; \ No newline at end of file diff --git a/postgres/postgres_vacuum_activity_estimate_stats.sql b/postgres/postgres_vacuum_activity_estimate_stats.sql index e86fc2f..3dc152c 100644 --- a/postgres/postgres_vacuum_activity_estimate_stats.sql +++ b/postgres/postgres_vacuum_activity_estimate_stats.sql @@ -25,7 +25,7 @@ FROM WHERE reloptions is NOT null) SELECT --to_char(now(), 'YYYY-MM-DD HH:MI'), - s.schemaname ||'.'|| s.relname as relname, + current_database() ||'.'|| s.schemaname ||'.'|| s.relname as relname, n_live_tup live_tup, n_dead_tup dead_dup, n_tup_hot_upd hot_upd, From 17e1725a899b5b7383e290e54b656b459f43cabc Mon Sep 17 00:00:00 2001 From: Shane Borden Date: Thu, 18 Sep 2025 10:37:31 -0500 Subject: [PATCH 2/3] update make process --- Makefile | 107 ++++++++++++++++++++++++++++++++++------- site/index.html | 2 +- site/sitemap.xml.gz | Bin 127 -> 127 bytes tools/install-hatch.sh | 68 ++++++++++++++++++++++++++ 4 files changed, 158 insertions(+), 19 deletions(-) create mode 100644 tools/install-hatch.sh diff --git a/Makefile b/Makefile index 34c012b..7361d3b 100644 --- a/Makefile +++ b/Makefile @@ -1,11 +1,34 @@ +SHELL := /bin/bash + +# ----------------------------------------------------------------------------- +# Display Formatting and Colors +# ----------------------------------------------------------------------------- +BLUE := $(shell printf "\033[1;34m") +GREEN := $(shell printf "\033[1;32m") +RED := $(shell printf "\033[1;31m") +YELLOW := $(shell printf "\033[1;33m") +NC := $(shell printf "\033[0m") +INFO := $(shell printf "$(BLUE)ℹ$(NC)") +OK := $(shell printf "$(GREEN)✓$(NC)") +WARN := $(shell printf "$(YELLOW)⚠$(NC)") +ERROR := $(shell printf "$(RED)✖$(NC)") + +# ============================================================================= +# Configuration and Environment Variables +# ============================================================================= .DEFAULT_GOAL:=help .ONESHELL: -VENV_EXISTS=$(shell python3 -c "if __import__('pathlib').Path('.venv/bin/activate').exists(): print('yes')") -VERSION := $(shell grep -m 1 current_version .bumpversion.cfg | tr -s ' ' | tr -d '"' | tr -d "'" | cut -d' ' -f3) -BUILD_DIR=dist -COLLECTOR_PACKAGE=sql-scripts -BASE_DIR=$(shell pwd) - +.EXPORT_ALL_VARIABLES: +MAKEFLAGS += --no-print-directory + +USING_NPM = $(shell python3 -c "if __import__('pathlib').Path('package-lock.json').exists(): print('yes')") +ENV_PREFIX =.venv/bin/ +VENV_EXISTS = $(shell python3 -c "if __import__('pathlib').Path('.venv/bin/activate').exists(): print('yes')") +NODE_MODULES_EXISTS = $(shell python3 -c "if __import__('pathlib').Path('node_modules').exists(): print('yes')") +BUILD_DIR =dist +COLLECTOR_PACKAGE =sql-scripts +BASE_DIR =$(shell pwd) + .EXPORT_ALL_VARIABLES: ifndef VERBOSE @@ -15,15 +38,46 @@ endif REPO_INFO ?= $(shell git config --get remote.origin.url) COMMIT_SHA ?= git-$(shell git rev-parse --short HEAD) +# ============================================================================= +# Help and Documentation +# ============================================================================= + help: ## Display this help @awk 'BEGIN {FS = ":.*##"; printf "\nUsage:\n make \033[36m\033[0m\n"} /^[a-zA-Z0-9_-]+:.*?##/ { printf " \033[36m%-15s\033[0m %s\n", $$1, $$2 } /^##@/ { printf "\n\033[1m%s\033[0m\n", substr($$0, 5) } ' $(MAKEFILE_LIST) -.PHONY: install +# ============================================================================= +# Developer Utils +# ============================================================================= +install-pipx: ## Install pipx + @python3 -m pip install --upgrade --user pipx + +install-hatch: ## Install Hatch, UV, and Ruff + @sh ./tools/install-hatch.sh + +configure-hatch: ## Configure Hatch defaults + @hatch config set dirs.env.virtual .direnv + @hatch config set dirs.env.pip-compile .direnv + +upgrade-hatch: ## Update Hatch, UV, and Ruff + @hatch self update + install: ## Install the project in dev mode. - @if [ "$(VENV_EXISTS)" ]; then source .venv/bin/activate; fi - @if [ ! "$(VENV_EXISTS)" ]; then python3 -m venv .venv && source .venv/bin/activate; fi - .venv/bin/pip install -U wheel setuptools cython pip mypy sqlfluff && .venv/bin/pip install -U -r requirements.txt -r requirements-docs.txt - @echo "=> Build environment installed successfully. ** If you want to re-install or update, 'make install'" + @if [ "$(VENV_EXISTS)" ]; then echo "=> Removing existing virtual environment"; $(MAKE) destroy-venv; fi + @$(MAKE) clean + @if ! hatch --version > /dev/null; then echo '=> Installing `hatch`'; $(MAKE) install-hatch ; fi + @echo "=> Creating Python environments..." + @$(MAKE) configure-hatch + @hatch env create local + @echo "=> Install complete! Note: If you want to re-install re-run 'make install'" + # .venv/bin/pip install -U wheel setuptools cython pip mypy sqlfluff && .venv/bin/pip install -U -r requirements.txt -r requirements-docs.txt + +.PHONY: upgrade +upgrade: ## Upgrade all dependencies to the latest stable versions + @echo "=> Updating all dependencies" + @echo "=> Python Dependencies Updated" + @hatch run lint:pre-commit autoupdate + @echo "=> Updated Pre-commit" + @$(MAKE) install .PHONY: clean clean: ## Cleanup temporary build artifacts @@ -38,6 +92,21 @@ clean: ## Cleanup temporary build a @find . -name '.ipynb_checkpoints' -exec rm -rf {} + >/dev/null 2>&1 @echo "${OK} Working directory cleaned" +deep-clean: clean destroy-venv destroy-node_modules ## Clean everything up + @hatch python remove all + @echo "=> Hatch environments pruned and python installations trimmed" + @uv cache clean + @echo "=> UV Cache cleaned successfully" + +destroy-venv: ## Destroy the virtual environment + @hatch env prune + @hatch env remove lint + @rm -Rf .venv + @rm -Rf .direnv + +destroy-node_modules: ## Destroy the node environment + @rm -rf node_modules .astro + .PHONY: clean-sqlscripts clean-sqlscripts: @echo "=> Cleaning previous build artifacts for sql scripts..." @@ -94,6 +163,14 @@ package-sqlscripts: .PHONY: build build: build-sqlscripts ## Build and package the collectors +.PHONY: pre-release +pre-release: ## bump the version and create the release tag + make docs + make clean + hatch run local:bump2version $(increment) + head .bumpversion.cfg | grep ^current_version + make build + ############### # docs # @@ -123,10 +200,4 @@ docs: ## generate HTML documentation and serve it to the browser ./.venv/bin/mkdocs build ./.venv/bin/mkdocs serve -.PHONY: pre-release -pre-release: ## bump the version and create the release tag - make gen-docs - make clean - .venv/bin/bump2version $(increment) - head .bumpversion.cfg | grep ^current_version - make build + diff --git a/site/index.html b/site/index.html index 9031a24..1632382 100644 --- a/site/index.html +++ b/site/index.html @@ -206,5 +206,5 @@ diff --git a/site/sitemap.xml.gz b/site/sitemap.xml.gz index 045f25149c4ccdc1f08422843f4ea47daf2020a6..c2e8d7e396a634fdc4f88937d3af8d563a9b8e41 100644 GIT binary patch delta 13 Ucmb=gXP58h;ArqZJ(0Zv039v_W&i*H delta 13 Ucmb=gXP58h;AptOHIcmn035>vDgXcg diff --git a/tools/install-hatch.sh b/tools/install-hatch.sh new file mode 100644 index 0000000..77e3028 --- /dev/null +++ b/tools/install-hatch.sh @@ -0,0 +1,68 @@ +#!/usr/bin/env bash +# Copyright 2025 shane-borden + +# Licensed under the Apache License, Version 2.0 (the "License"); +# you may not use this file except in compliance with the License. +# You may obtain a copy of the License at + +# https://www.apache.org/licenses/LICENSE-2.0 + +# Unless required by applicable law or agreed to in writing, software +# distributed under the License is distributed on an "AS IS" BASIS, +# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. +# See the License for the specific language governing permissions and +# limitations under the License. +# --- Constants --- +BASE_URL="https://github.com/pypa/hatch/releases/latest/download" +EXTRACT_CMD="tar -xzf" + +# --- Handle Optional Installation Directory --- +INSTALL_DIR="$1" # Default: current directory +if [ -n "$INSTALL_DIR" ]; then + if [ ! -d "$INSTALL_DIR" ]; then # Check if directory exists + INSTALL_DIR="$HOME/.local/bin" + echo "Error: Invalid install directory '$INSTALL_DIR'" + exit 1 + fi + INSTALL_DIR=$(realpath "$INSTALL_DIR") # Get absolute path +fi + +# --- Determine Platform --- +PLATFORM=$(uname -s) +MACHINE=$(uname -m) +FILE_EXT="tar.gz" + +if [ "$PLATFORM" = "Darwin" ]; then + PLATFORM_NAME="apple-darwin" +elif [ "$PLATFORM" = "Linux" ]; then + PLATFORM_NAME="unknown-linux-gnu" + if [ "$MACHINE" = "aarch64" ]; then + MACHINE="aarch64" + fi +elif [ "$PLATFORM" = "Windows" ]; then + PLATFORM_NAME="pc-windows-msvc" + FILE_EXT="zip" + EXTRACT_CMD="unzip" +else + echo "Unsupported platform: $PLATFORM" + exit 1 +fi + +# --- Construct File Name and URL --- +FILENAME="hatch-$MACHINE-$PLATFORM_NAME.$FILE_EXT" +URL="$BASE_URL/$FILENAME" + +# --- Download and Extract --- +echo "Downloading Hatch binary: $FILENAME" +curl -L -o "$FILENAME" "$URL" + +echo "Extracting to '$INSTALL_DIR'..." +$EXTRACT_CMD "$FILENAME" -C "$INSTALL_DIR" # Extract to install directory +rm "$FILENAME" # Remove archive + +HATCH_BINARY="$INSTALL_DIR/hatch" # Path to the extracted binary +if [ -x "$HATCH_BINARY" ]; then + echo "Hatch binary successfully installed at '$HATCH_BINARY'" +else + echo "Error: Hatch binary not found or not executable." +fi From 5bc4da1e03800dac992dd9c7400240869042d346 Mon Sep 17 00:00:00 2001 From: Shane Borden Date: Thu, 18 Sep 2025 10:40:23 -0500 Subject: [PATCH 3/3] Revert "update make process" This reverts commit 17e1725a899b5b7383e290e54b656b459f43cabc. --- Makefile | 107 +++++++---------------------------------- site/index.html | 2 +- site/sitemap.xml.gz | Bin 127 -> 127 bytes tools/install-hatch.sh | 68 -------------------------- 4 files changed, 19 insertions(+), 158 deletions(-) delete mode 100644 tools/install-hatch.sh diff --git a/Makefile b/Makefile index 7361d3b..34c012b 100644 --- a/Makefile +++ b/Makefile @@ -1,34 +1,11 @@ -SHELL := /bin/bash - -# ----------------------------------------------------------------------------- -# Display Formatting and Colors -# ----------------------------------------------------------------------------- -BLUE := $(shell printf "\033[1;34m") -GREEN := $(shell printf "\033[1;32m") -RED := $(shell printf "\033[1;31m") -YELLOW := $(shell printf "\033[1;33m") -NC := $(shell printf "\033[0m") -INFO := $(shell printf "$(BLUE)ℹ$(NC)") -OK := $(shell printf "$(GREEN)✓$(NC)") -WARN := $(shell printf "$(YELLOW)⚠$(NC)") -ERROR := $(shell printf "$(RED)✖$(NC)") - -# ============================================================================= -# Configuration and Environment Variables -# ============================================================================= .DEFAULT_GOAL:=help .ONESHELL: -.EXPORT_ALL_VARIABLES: -MAKEFLAGS += --no-print-directory - -USING_NPM = $(shell python3 -c "if __import__('pathlib').Path('package-lock.json').exists(): print('yes')") -ENV_PREFIX =.venv/bin/ -VENV_EXISTS = $(shell python3 -c "if __import__('pathlib').Path('.venv/bin/activate').exists(): print('yes')") -NODE_MODULES_EXISTS = $(shell python3 -c "if __import__('pathlib').Path('node_modules').exists(): print('yes')") -BUILD_DIR =dist -COLLECTOR_PACKAGE =sql-scripts -BASE_DIR =$(shell pwd) - +VENV_EXISTS=$(shell python3 -c "if __import__('pathlib').Path('.venv/bin/activate').exists(): print('yes')") +VERSION := $(shell grep -m 1 current_version .bumpversion.cfg | tr -s ' ' | tr -d '"' | tr -d "'" | cut -d' ' -f3) +BUILD_DIR=dist +COLLECTOR_PACKAGE=sql-scripts +BASE_DIR=$(shell pwd) + .EXPORT_ALL_VARIABLES: ifndef VERBOSE @@ -38,46 +15,15 @@ endif REPO_INFO ?= $(shell git config --get remote.origin.url) COMMIT_SHA ?= git-$(shell git rev-parse --short HEAD) -# ============================================================================= -# Help and Documentation -# ============================================================================= - help: ## Display this help @awk 'BEGIN {FS = ":.*##"; printf "\nUsage:\n make \033[36m\033[0m\n"} /^[a-zA-Z0-9_-]+:.*?##/ { printf " \033[36m%-15s\033[0m %s\n", $$1, $$2 } /^##@/ { printf "\n\033[1m%s\033[0m\n", substr($$0, 5) } ' $(MAKEFILE_LIST) -# ============================================================================= -# Developer Utils -# ============================================================================= -install-pipx: ## Install pipx - @python3 -m pip install --upgrade --user pipx - -install-hatch: ## Install Hatch, UV, and Ruff - @sh ./tools/install-hatch.sh - -configure-hatch: ## Configure Hatch defaults - @hatch config set dirs.env.virtual .direnv - @hatch config set dirs.env.pip-compile .direnv - -upgrade-hatch: ## Update Hatch, UV, and Ruff - @hatch self update - +.PHONY: install install: ## Install the project in dev mode. - @if [ "$(VENV_EXISTS)" ]; then echo "=> Removing existing virtual environment"; $(MAKE) destroy-venv; fi - @$(MAKE) clean - @if ! hatch --version > /dev/null; then echo '=> Installing `hatch`'; $(MAKE) install-hatch ; fi - @echo "=> Creating Python environments..." - @$(MAKE) configure-hatch - @hatch env create local - @echo "=> Install complete! Note: If you want to re-install re-run 'make install'" - # .venv/bin/pip install -U wheel setuptools cython pip mypy sqlfluff && .venv/bin/pip install -U -r requirements.txt -r requirements-docs.txt - -.PHONY: upgrade -upgrade: ## Upgrade all dependencies to the latest stable versions - @echo "=> Updating all dependencies" - @echo "=> Python Dependencies Updated" - @hatch run lint:pre-commit autoupdate - @echo "=> Updated Pre-commit" - @$(MAKE) install + @if [ "$(VENV_EXISTS)" ]; then source .venv/bin/activate; fi + @if [ ! "$(VENV_EXISTS)" ]; then python3 -m venv .venv && source .venv/bin/activate; fi + .venv/bin/pip install -U wheel setuptools cython pip mypy sqlfluff && .venv/bin/pip install -U -r requirements.txt -r requirements-docs.txt + @echo "=> Build environment installed successfully. ** If you want to re-install or update, 'make install'" .PHONY: clean clean: ## Cleanup temporary build artifacts @@ -92,21 +38,6 @@ clean: ## Cleanup temporary build a @find . -name '.ipynb_checkpoints' -exec rm -rf {} + >/dev/null 2>&1 @echo "${OK} Working directory cleaned" -deep-clean: clean destroy-venv destroy-node_modules ## Clean everything up - @hatch python remove all - @echo "=> Hatch environments pruned and python installations trimmed" - @uv cache clean - @echo "=> UV Cache cleaned successfully" - -destroy-venv: ## Destroy the virtual environment - @hatch env prune - @hatch env remove lint - @rm -Rf .venv - @rm -Rf .direnv - -destroy-node_modules: ## Destroy the node environment - @rm -rf node_modules .astro - .PHONY: clean-sqlscripts clean-sqlscripts: @echo "=> Cleaning previous build artifacts for sql scripts..." @@ -163,14 +94,6 @@ package-sqlscripts: .PHONY: build build: build-sqlscripts ## Build and package the collectors -.PHONY: pre-release -pre-release: ## bump the version and create the release tag - make docs - make clean - hatch run local:bump2version $(increment) - head .bumpversion.cfg | grep ^current_version - make build - ############### # docs # @@ -200,4 +123,10 @@ docs: ## generate HTML documentation and serve it to the browser ./.venv/bin/mkdocs build ./.venv/bin/mkdocs serve - +.PHONY: pre-release +pre-release: ## bump the version and create the release tag + make gen-docs + make clean + .venv/bin/bump2version $(increment) + head .bumpversion.cfg | grep ^current_version + make build diff --git a/site/index.html b/site/index.html index 1632382..9031a24 100644 --- a/site/index.html +++ b/site/index.html @@ -206,5 +206,5 @@ diff --git a/site/sitemap.xml.gz b/site/sitemap.xml.gz index c2e8d7e396a634fdc4f88937d3af8d563a9b8e41..045f25149c4ccdc1f08422843f4ea47daf2020a6 100644 GIT binary patch delta 13 Ucmb=gXP58h;AptOHIcmn035>vDgXcg delta 13 Ucmb=gXP58h;ArqZJ(0Zv039v_W&i*H diff --git a/tools/install-hatch.sh b/tools/install-hatch.sh deleted file mode 100644 index 77e3028..0000000 --- a/tools/install-hatch.sh +++ /dev/null @@ -1,68 +0,0 @@ -#!/usr/bin/env bash -# Copyright 2025 shane-borden - -# Licensed under the Apache License, Version 2.0 (the "License"); -# you may not use this file except in compliance with the License. -# You may obtain a copy of the License at - -# https://www.apache.org/licenses/LICENSE-2.0 - -# Unless required by applicable law or agreed to in writing, software -# distributed under the License is distributed on an "AS IS" BASIS, -# WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. -# See the License for the specific language governing permissions and -# limitations under the License. -# --- Constants --- -BASE_URL="https://github.com/pypa/hatch/releases/latest/download" -EXTRACT_CMD="tar -xzf" - -# --- Handle Optional Installation Directory --- -INSTALL_DIR="$1" # Default: current directory -if [ -n "$INSTALL_DIR" ]; then - if [ ! -d "$INSTALL_DIR" ]; then # Check if directory exists - INSTALL_DIR="$HOME/.local/bin" - echo "Error: Invalid install directory '$INSTALL_DIR'" - exit 1 - fi - INSTALL_DIR=$(realpath "$INSTALL_DIR") # Get absolute path -fi - -# --- Determine Platform --- -PLATFORM=$(uname -s) -MACHINE=$(uname -m) -FILE_EXT="tar.gz" - -if [ "$PLATFORM" = "Darwin" ]; then - PLATFORM_NAME="apple-darwin" -elif [ "$PLATFORM" = "Linux" ]; then - PLATFORM_NAME="unknown-linux-gnu" - if [ "$MACHINE" = "aarch64" ]; then - MACHINE="aarch64" - fi -elif [ "$PLATFORM" = "Windows" ]; then - PLATFORM_NAME="pc-windows-msvc" - FILE_EXT="zip" - EXTRACT_CMD="unzip" -else - echo "Unsupported platform: $PLATFORM" - exit 1 -fi - -# --- Construct File Name and URL --- -FILENAME="hatch-$MACHINE-$PLATFORM_NAME.$FILE_EXT" -URL="$BASE_URL/$FILENAME" - -# --- Download and Extract --- -echo "Downloading Hatch binary: $FILENAME" -curl -L -o "$FILENAME" "$URL" - -echo "Extracting to '$INSTALL_DIR'..." -$EXTRACT_CMD "$FILENAME" -C "$INSTALL_DIR" # Extract to install directory -rm "$FILENAME" # Remove archive - -HATCH_BINARY="$INSTALL_DIR/hatch" # Path to the extracted binary -if [ -x "$HATCH_BINARY" ]; then - echo "Hatch binary successfully installed at '$HATCH_BINARY'" -else - echo "Error: Hatch binary not found or not executable." -fi