├── Check-Skew-OS-Method ├── README.md ├── fn_skew_detail_view.sql └── fn_skew_summary_view.sql ├── Distribution-Policy-SQL-Script ├── README.md ├── create_ddl.sql └── distribution-policy.sql ├── Distribution-Policy-Shell-Script ├── README.md └── get_distribution_policy.sh ├── Gpperform-Maintenance-Script ├── README.md ├── environment_parameters.env └── gpperfmon_maintenance.sh ├── Last-Used-Table-and-Analyze ├── Last-Used-Table-and-Analyze.sql └── README.md ├── README.md └── gpdb-check-health ├── README.md ├── bin ├── dcacheck.sh ├── environment_parameters.env ├── run_all.sh ├── run_database_info.sh ├── run_db_session_activity.sh └── run_general_info.sh └── sql ├── .DS_Store ├── database-config-history.sql ├── database-crash-recovery-check.sql ├── database-create-log-collection-view.sql ├── database-create-skew-function.sql ├── database-fatal-error-panic-occurrence.sql ├── database-get-skew-info.sql ├── database-hostname.sql ├── database-list.sql ├── database-lock-info.sql ├── database-longest-conn.sql ├── database-longest-query.sql ├── database-master-mirroring.sql ├── database-orphan-info.sql ├── database-parameter-list.sql ├── database-processing-skew.sql ├── database-relation-bloat.sql ├── database-relation-list.sql ├── database-relation-lock-info.sql ├── database-relation-size.sql ├── database-rq-info.sql ├── database-seg-config.sql ├── database-segments-orphan-locks.sql ├── database-session-activity.sql ├── database-transaction-age.sql ├── database-transaction-lock-info.sql └── database-transaction-relation-age.sql /Check-Skew-OS-Method/README.md: -------------------------------------------------------------------------------- 1 | # Purpose 2 | 3 | In this approach the view looks at the file sizes for each table for each segment. It then will output only the tables that have at least one segment with more than 20% more bytes than expected. 4 | 5 | Two variation of the same script have been described below one that gives you a quick summary and other one detailed information of the OS file size distribution. 6 | 7 | There are drawbacks using the above method ( i.e calculating the data skew using the OS file size ) , the major one being table bloat. 8 | 9 | DML operation on the table doesn't release space back to OS, So the calculation above takes into consideration the size occupied by table bloat. 10 | 11 | Please check the article on what is table bloat & the article on how to remove bloat. 12 | 13 | # Execution 14 | 15 | + Execute the function to create the external table and the view. 16 | 17 | ``` 18 | SELECT fn_create_db_files(); 19 | ``` 20 | 21 | + Now use the view to obtain the information 22 | 23 | ``` 24 | SELECT * FROM vw_file_skew ORDER BY 3 DESC LIMIT 10; 25 | ``` 26 | 27 | + To use the second function use 28 | 29 | ``` 30 | select * from public.fn_get_skew() LIMIT 10; 31 | ``` 32 | -------------------------------------------------------------------------------- /Check-Skew-OS-Method/fn_skew_detail_view.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION public.fn_get_skew(out schema_name varchar, 2 | out table_name varchar, 3 | out pTableName varchar, 4 | out owner_name varchar, 5 | out total_size_GB numeric(15,2), 6 | out seg_min_size_GB numeric(15,2), 7 | out seg_max_size_GB numeric(15,2), 8 | out seg_avg_size_GB numeric(15,2), 9 | out seg_gap_min_max_percent numeric(6,2), 10 | out seg_gap_min_max_GB numeric(15,2), 11 | out nb_empty_seg int) RETURNS SETOF record AS 12 | $$ 13 | DECLARE 14 | v_function_name text := 'fn_get_skew'; 15 | v_location int; 16 | v_sql text; 17 | v_db_oid text; 18 | v_num_segments numeric; 19 | v_skew_amount numeric; 20 | v_res record; 21 | BEGIN 22 | v_location := 1000; 23 | SELECT oid INTO v_db_oid 24 | FROM pg_database 25 | WHERE datname = current_database(); 26 | 27 | v_location := 2200; 28 | v_sql := 'DROP EXTERNAL TABLE IF EXISTS public.db_files_ext'; 29 | 30 | v_location := 2300; 31 | EXECUTE v_sql; 32 | 33 | v_location := 3000; 34 | v_sql := 'CREATE EXTERNAL WEB TABLE public.db_files_ext ' || 35 | '(segment_id int, relfilenode text, filename text, ' || 36 | 'size numeric) ' || 37 | 'execute E''ls -l $GP_SEG_DATADIR/base/' || v_db_oid || 38 | ' | ' || 39 | 'grep gpadmin | ' || 40 | E'awk {''''print ENVIRON["GP_SEGMENT_ID"] "\\t" $9 "\\t" ' || 41 | 'ENVIRON["GP_SEG_DATADIR"] "/' || v_db_oid || 42 | E'/" $9 "\\t" $5''''}'' on all ' || 'format ''text'''; 43 | 44 | v_location := 3100; 45 | EXECUTE v_sql; 46 | 47 | v_location := 4000; 48 | for v_res in ( 49 | select sub.vschema_name, 50 | sub.vtable_name, 51 | sub.vowner_name, 52 | (sum(sub.size)/(1024^3))::numeric(15,2) AS vtotal_size_GB, 53 | --Size on segments 54 | (min(sub.size)/(1024^3))::numeric(15,2) as vseg_min_size_GB, 55 | (max(sub.size)/(1024^3))::numeric(15,2) as vseg_max_size_GB, 56 | (avg(sub.size)/(1024^3))::numeric(15,2) as vseg_avg_size_GB, 57 | --Percentage of gap between smaller segment and bigger segment 58 | (100*(max(sub.size) - min(sub.size))/greatest(max(sub.size),1))::numeric(6,2) as vseg_gap_min_max_percent, 59 | ((max(sub.size) - min(sub.size))/(1024^3))::numeric(15,2) as vseg_gap_min_max_GB, 60 | count(sub.size) filter (where sub.size = 0) as vnb_empty_seg 61 | from ( 62 | SELECT n.nspname AS vschema_name, 63 | c.relname AS vtable_name, 64 | db.segment_id, 65 | sum(db.size) AS size, 66 | pg_catalog.pg_get_userbyid(c.relowner) as vowner_name 67 | FROM ONLY public.db_files_ext db 68 | JOIN pg_class c ON split_part(db.relfilenode, '.'::text, 1) = c.relfilenode::text 69 | JOIN pg_namespace n ON c.relnamespace = n.oid 70 | WHERE c.relkind = 'r'::"char" 71 | and n.nspname not in ('pg_catalog','information_schema','gp_toolkit') 72 | and not n.nspname like 'pg_temp%' 73 | GROUP BY n.nspname, c.relname, db.segment_id,c.relowner 74 | ) sub 75 | group by 1,2,3 76 | --Extract only table bigger than 1 GB 77 | -- and with a skew greater than 20% 78 | having sum(sub.size)/(1024^3) > 1 79 | and (100*(max(sub.size) - min(sub.size))/greatest(max(sub.size),1))::numeric(6,2) > 20 80 | order by 1,2,3 81 | limit 100 ) loop 82 | schema_name = v_res.vschema_name; 83 | table_name = v_res.vtable_name; 84 | owner_name = v_res.vowner_name; 85 | total_size_GB = v_res.vtotal_size_GB; 86 | seg_min_size_GB = v_res.vseg_min_size_GB; 87 | seg_max_size_GB = v_res.vseg_max_size_GB; 88 | seg_avg_size_GB = v_res.vseg_avg_size_GB; 89 | seg_gap_min_max_percent = v_res.vseg_gap_min_max_percent; 90 | seg_gap_min_max_GB = v_res.vseg_gap_min_max_GB; 91 | nb_empty_seg = v_res.vnb_empty_seg; 92 | return next; 93 | end loop; 94 | 95 | v_location := 4100; 96 | v_sql := 'DROP EXTERNAL TABLE IF EXISTS public.db_files_ext'; 97 | 98 | v_location := 4200; 99 | EXECUTE v_sql; 100 | 101 | return; 102 | EXCEPTION 103 | WHEN OTHERS THEN 104 | RAISE EXCEPTION '(%:%:%)', v_function_name, v_location, sqlerrm; 105 | END; 106 | $$ 107 | language plpgsql; 108 | -------------------------------------------------------------------------------- /Check-Skew-OS-Method/fn_skew_summary_view.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION fn_create_db_files() RETURNS void AS 2 | $$ 3 | DECLARE 4 | v_function_name text := 'fn_create_db_files'; 5 | v_location int; 6 | v_sql text; 7 | v_db_oid text; 8 | v_num_segments numeric; 9 | v_skew_amount numeric; 10 | BEGIN 11 | v_location := 1000; 12 | SELECT oid INTO v_db_oid 13 | FROM pg_database 14 | WHERE datname = current_database(); 15 | 16 | v_location := 2000; 17 | v_sql := 'DROP VIEW IF EXISTS vw_file_skew'; 18 | 19 | v_location := 2100; 20 | EXECUTE v_sql; 21 | 22 | v_location := 2200; 23 | v_sql := 'DROP EXTERNAL TABLE IF EXISTS db_files'; 24 | 25 | v_location := 2300; 26 | EXECUTE v_sql; 27 | 28 | v_location := 3000; 29 | v_sql := 'CREATE EXTERNAL WEB TABLE db_files ' || 30 | '(segment_id int, relfilenode text, filename text, ' || 31 | 'size numeric) ' || 32 | 'execute E''ls -l $GP_SEG_DATADIR/base/' || v_db_oid || 33 | ' | ' || 34 | 'grep gpadmin | ' || 35 | E'awk {''''print ENVIRON["GP_SEGMENT_ID"] "\\t" $9 "\\t" ' || 36 | 'ENVIRON["GP_SEG_DATADIR"] "/' || v_db_oid || 37 | E'/" $9 "\\t" $5''''}'' on all ' || 'format ''text'''; 38 | 39 | v_location := 3100; 40 | EXECUTE v_sql; 41 | 42 | v_location := 4000; 43 | SELECT count(*) INTO v_num_segments 44 | FROM gp_segment_configuration 45 | WHERE preferred_role = 'p' 46 | AND content >= 0; 47 | 48 | v_location := 4100; 49 | v_skew_amount := 1.2*(1/v_num_segments); 50 | 51 | v_location := 4200; 52 | v_sql := 'CREATE OR REPLACE VIEW vw_file_skew AS ' || 53 | 'SELECT schema_name, ' || 54 | 'table_name, ' || 55 | 'owner, ' || 56 | 'max(size)/sum(size) as largest_segment_percentage, ' || 57 | 'sum(size) as total_size ' || 58 | 'FROM ( ' || 59 | 'SELECT n.nspname AS schema_name, ' || 60 | ' c.relname AS table_name, ' || 61 | ' sum(db.size) as size, ' || 62 | ' pg_catalog.pg_get_userbyid(c.relowner) as owner' || 63 | ' FROM db_files db ' || 64 | ' JOIN pg_class c ON ' || 65 | ' split_part(db.relfilenode, ''.'', 1) = c.relfilenode::text ' || 66 | ' JOIN pg_namespace n ON c.relnamespace = n.oid ' || 67 | ' WHERE c.relkind = ''r'' ' || 68 | ' GROUP BY n.nspname, c.relname, db.segment_id,c.relowner ' || 69 | ') as sub ' || 70 | 'GROUP BY schema_name, table_name, owner ' || 71 | 'HAVING sum(size) > 0 and max(size)/sum(size) > ' || 72 | v_skew_amount::text || ' ' || 73 | 'ORDER BY largest_segment_percentage DESC, schema_name, ' || 74 | 'table_name'; 75 | 76 | v_location := 4300; 77 | EXECUTE v_sql; 78 | 79 | EXCEPTION 80 | WHEN OTHERS THEN 81 | RAISE EXCEPTION '(%:%:%)', v_function_name, v_location, sqlerrm; 82 | END; 83 | $$ 84 | language plpgsql; 85 | -------------------------------------------------------------------------------- /Distribution-Policy-SQL-Script/README.md: -------------------------------------------------------------------------------- 1 | # Goal 2 | 3 | The distribution policy on any Pivotal Greenplum Database can be easily found with "\d " , or can be retrieved from gp_distribution_policy table and matching with pg_attributes, but there is no direct SQL query that is available which can be queried to obtain distribution policy on each table from catalog tables. 4 | 5 | In this document we will create a function that can help you create a simple SQL to retrieve information of the tables distribution policy. 6 | 7 | # Execution 8 | 9 | + Create the ddl on the database 10 | 11 | ``` 12 | psql -d -f create_ddl.sql 13 | ``` 14 | 15 | + Execute the query to extract the information 16 | 17 | ``` 18 | psql -d -f distribution-policy.sql 19 | ``` 20 | -------------------------------------------------------------------------------- /Distribution-Policy-SQL-Script/create_ddl.sql: -------------------------------------------------------------------------------- 1 | -- Create "commacat" functions 2 | 3 | CREATE or replace FUNCTION commacat(acc text, instr text) RETURNS text AS $$ 4 | BEGIN 5 | IF acc IS NULL OR acc = '' THEN 6 | RETURN instr; 7 | ELSE 8 | RETURN acc || ',' || instr; 9 | END IF; 10 | END; 11 | $$ LANGUAGE plpgsql 12 | ; 13 | 14 | -- Create "textcat_all" Aggregate 15 | 16 | CREATE AGGREGATE textcat_all( 17 | basetype = text, 18 | sfunc = commacat,stype = text, 19 | initcond = '' 20 | ); 21 | 22 | -------------------------------------------------------------------------------- /Distribution-Policy-SQL-Script/distribution-policy.sql: -------------------------------------------------------------------------------- 1 | select nspname||'.'||relname as "Table Name", 2 | textcat_all(attname) as " Distribution Policy" 3 | from pg_attribute 4 | join (SELECT pg_class.oid,nspname,relname,unnest(attrnums) as col 5 | from gp_distribution_policy 6 | join pg_class on localoid=oid 7 | join pg_namespace nsp on relnamespace=nsp.oid) def on def.col=attnum and oid=attrelid group by 1 8 | union 9 | select nspname||'.'||relname as "Table Name", 10 | 'Random' as " Distribution Policy" 11 | from pg_class c 12 | join pg_namespace n on n.oid=c.relnamespace 13 | join gp_distribution_policy d on d.localoid=c.oid 14 | and d.attrnums is NULL; 15 | -------------------------------------------------------------------------------- /Distribution-Policy-Shell-Script/README.md: -------------------------------------------------------------------------------- 1 | # Goal 2 | 3 | Is to provide a simple shell scripts to help administrator identify the distribution policy of the tables in the database. 4 | 5 | # Execution 6 | 7 | Use the below steps to execute the query 8 | 9 | ``` 10 | /bin/sh get_distribution_policy.sh 11 | ``` 12 | -------------------------------------------------------------------------------- /Distribution-Policy-Shell-Script/get_distribution_policy.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | # 3 | # get_distribution_policy.sh 4 | # pivotal - 2014 5 | # 6 | # 7 | # 8 | 9 | # Function : To extract all the user tables. 10 | 11 | extract_table() { 12 | 13 | # echo "INFO - Extracting all the table names, schema name and oid's" 14 | # echo 15 | 16 | psql -d $PGDATABASE -p $PGPORT -Atc "SELECT 17 | a.oid , nspname , relname 18 | FROM pg_class a , pg_namespace b 19 | WHERE 20 | relkind='r' 21 | AND b.oid=a.relnamespace 22 | AND relname not in (select partitiontablename from pg_partitions) 23 | AND relnamespace in ( select oid from pg_namespace 24 | where nspname not in ('gp_toolkit','pg_toast','pg_aoseg','information_schema','pg_catalog') and nspname not like 'pg_temp%') order by 3" > $extract_table 25 | } 26 | 27 | 28 | # Function : To extract all the distribution policy. 29 | 30 | ext_parent_tb_dist_plcy() { 31 | 32 | # echo "INFO - Extracting the distribution policy for the collected table " 33 | # echo 34 | 35 | cat $extract_table | while read line 36 | do 37 | export i=`echo $line | cut -d'|' -f1` 38 | export j=`echo $line | cut -d'|' -f2` 39 | export k=`echo $line | cut -d'|' -f3` 40 | psql -d $PGDATABASE -p $PGPORT -xtc "SELECT localoid , attrnums 41 | FROM gp_distribution_policy 42 | where localoid=($i)" | tr -d '{}' | tr -d '|' | grep -v row > $ext_tab_parent_dist_info 43 | 44 | export table_oid=`grep localoid $ext_tab_parent_dist_info | awk '{print $2}'` 45 | export table_dist_col=`grep attrnums $ext_tab_parent_dist_info | awk '{print $2}'` 46 | if [ "$table_dist_col" = "" ]; 47 | then 48 | echo $j " " $k " Random">> $random_info 49 | else 50 | psql -d $PGDATABASE -p $PGPORT -Atc "SELECT attname 51 | FROM pg_attribute 52 | WHERE attrelid in ($table_oid) and attnum in ($table_dist_col)" | awk '{ printf $1 ","}' | sed s/.$// > $ext_tab_parent_dist_col_info 53 | 54 | echo $j " " $k " " `cat $ext_tab_parent_dist_col_info` >> $non_random_info 55 | fi 56 | done 57 | 58 | } 59 | 60 | # Function : To Print all the all the user tables. 61 | 62 | print_table_distribution() { 63 | 64 | # echo "INFO - Priniting the distribution policy of the table in the database " $PGDATABASE 65 | # echo 66 | echo "----| Table Name - With Random Distribution Policy |----" 67 | echo 68 | 69 | awk 'BEGIN { printf "%-30s %-30s %s\n", "SCHEMA-NAME","TABLE-NAME","DISTRIBUTION-POLICY" 70 | printf "%-30s %-30s %s\n", "-----------","----------","-------------------" } 71 | { printf "%-30s %-30s %s\n", $1, $2 , $3 }' $random_info 72 | 73 | echo 74 | echo "----| Table Name - With Distribution Policy |----" 75 | echo 76 | 77 | awk 'BEGIN { printf "%-30s %-30s %s\n", "SCHEMA-NAME","TABLE-NAME","DISTRIBUTION-POLICY" 78 | printf "%-30s %-30s %s\n", "-----------","----------","-------------------" } 79 | { printf "%-30s %-30s %s\n", $1, $2 , $3 }' $non_random_info 80 | } 81 | 82 | # Main program starts here 83 | 84 | # Checking the parameter passed 85 | 86 | echo 87 | echo "INFO - Checking the parameter passed for the script: " $0 88 | echo 89 | 90 | if [ $# -lt 2 ] 91 | then 92 | 93 | echo "ERR - Script cannot execute since one / more parameters is missing" 94 | echo "ERR - Usage: $0 { Please provide us the database name & port number }" 95 | echo "INFO - Example to run is /bin/sh get_distribution_policy.sh template1 5432" 96 | echo 97 | 98 | exit 1 99 | 100 | fi 101 | 102 | # Acception of the parameters 103 | 104 | # echo "INFO - Passing the parameters passed to variables " 105 | # echo 106 | 107 | export PGDATABASE=$1 108 | export PGPORT=$2 109 | export extract_table=/tmp/extract_table 110 | export ext_tab_parent_dist_info=/tmp/ext_tab_parent_dist_info 111 | export ext_tab_parent_dist_col_info=/tmp/ext_tab_parent_dist_col_info 112 | export random_info=/tmp/random_info 113 | export non_random_info=/tmp/non_random_info 114 | export junkfile=/tmp/junkfile 115 | 116 | # Remove old temporary files. 117 | 118 | # echo "INFO - Removing the old / temporary files from previous run, if any" 119 | # echo 120 | 121 | if (test -f $extract_table ) 122 | then 123 | rm -r $extract_table > $junkfile 2>> $junkfile 124 | fi 125 | 126 | if (test -f $ext_tab_parent_dist_info) 127 | then 128 | rm -r $ext_tab_parent_dist_info > $junkfile 2>> $junkfile 129 | fi 130 | 131 | if (test -f $ext_tab_parent_dist_col_info) 132 | then 133 | rm -r $ext_tab_parent_dist_col_info > $junkfile 2>> $junkfile 134 | fi 135 | 136 | if (test -f $random_info) 137 | then 138 | rm -r $random_info > $junkfile 2>> $junkfile 139 | fi 140 | 141 | if (test -f $non_random_info) 142 | then 143 | rm -r $non_random_info > $junkfile 2>> $junkfile 144 | fi 145 | 146 | 147 | # Calling the Function to confirm the script execution 148 | 149 | extract_table 150 | ext_parent_tb_dist_plcy 151 | print_table_distribution 152 | -------------------------------------------------------------------------------- /Gpperform-Maintenance-Script/README.md: -------------------------------------------------------------------------------- 1 | # Goal 2 | 3 | Is to provide a simple shell scripts to help administrator schedule a maintenance task to drop historical partition on gpperfom database greater than specific retention period (This script takes in months as retention period). 4 | 5 | This script might be needed to control the size of the gpperfmon database or to eliminate the historical data that is not needed anymore. 6 | 7 | # Execution 8 | 9 | + Copy the two files (provided as attachment in this documents) "environment_parameters.env" & "gpperfmon_maintenance.sh" to any directory of your choice ( both should be on the same directory like) 10 | 11 | ``` 12 | gpadmin:Fullrack@mdw $ pwd 13 | /data1/gpadmin 14 | gpadmin:Fullrack@mdw $ ls -ltr 15 | total 56 16 | -rw------- 1 gpadmin gpadmin 7485 Aug 21 02:18 gpperfmon_maintenance.sh 17 | -rw------- 1 gpadmin gpadmin 127 Aug 21 02:29 environment_parameters.env 18 | ``` 19 | 20 | + open the "environment_parameters.env" and edit the parameters that reflects to your database environment. 21 | + Run the shell script using 22 | 23 | ``` 24 | /bin/sh gpperfmon_maintenance.sh 25 | -------------------------------------------------------------------------------- /Gpperform-Maintenance-Script/environment_parameters.env: -------------------------------------------------------------------------------- 1 | gphome:/usr/local/greenplum-db-4.2.6.3 2 | pgdatabase:gpperfmon 3 | pgport:5432 4 | master_data_directory:/data/master/gpseg-1 5 | retention:3 -------------------------------------------------------------------------------- /Gpperform-Maintenance-Script/gpperfmon_maintenance.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | # 3 | # gpperfmon_maintenance.sh 4 | # pivital - 2014 5 | # 6 | # 7 | # 8 | 9 | # Function : To extract the history partition name which is less than retention period. 10 | 11 | extract_partition_information() { 12 | 13 | echo "INFO - Extracting information of partition older than retention period: "$Retention" Months" 14 | echo 15 | 16 | psql -d $PGDATABASE -p $PGPORT -c "SELECT 17 | schemaname||'.'||tablename as \"Parent Table\", 18 | partitionschemaname||'.'||partitiontablename as \"Partition Name\", 19 | age(substring(partitionrangestart from 2 for 19)::timestamp) \"Partition Age\", 20 | substring(partitionrangestart from 2 for 19)::timestamp as \"Partition Start\", 21 | substring(partitionrangeend from 2 for 19)::timestamp as \"Partition End\", 22 | partitionrank as \"Parition Rank\", 23 | (select pg_size_pretty(pg_total_relation_size(b.partitiontablename)) from pg_partitions b where p.partitiontablename=b.partitiontablename ) as \"Partition Size\" 24 | FROM 25 | pg_partitions p 26 | WHERE 27 | partitionrangestart < current_timestamp::timestamp without time zone - interval '${Retention} months' 28 | and tablename like '%history' 29 | ORDER BY 3 desc;" 30 | } 31 | 32 | # Function : To extract the sql to drop those older partition, but it ignores if that is the only partition of the table. 33 | 34 | generate_sql_to_drop() { 35 | 36 | echo "INFO - Generating SQL to drop partiton older than retention period: "$Retention" Months" 37 | echo 38 | 39 | psql -d $PGDATABASE -p $PGPORT -Atc "SELECT 40 | 'ALTER TABLE ' ||schemaname||'.'||tablename || ' DROP PARTITION FOR (RANK(' || partitionrank|| '));' 41 | FROM 42 | pg_partitions 43 | WHERE 44 | partitionrangestart < current_timestamp::timestamp without time zone - interval '${Retention} months' 45 | and tablename in ( select a.tablename from pg_partitions a where a.tablename like '%history' group by a.tablename having count(*) > 1 ) 46 | ORDER BY partitionrank desc; " > $sql_file 47 | } 48 | 49 | # Function : To drop the partition. 50 | 51 | execute_drop_sql() { 52 | 53 | echo "INFO - Excecuting the sql file generated to drop the partition with retention older than: " $Retention" Months" 54 | echo 55 | 56 | psql -d $PGDATABASE -p $PGPORT -ef $sql_file > $drop_output 57 | 58 | } 59 | 60 | # Function : To extract the history partition name after executing the drop. 61 | 62 | extract_partition_info_after_drop() { 63 | 64 | echo "INFO - Extracting information of partition after dropping the partition more than the retention period: "$Retention" Months" 65 | echo 66 | echo "MESG - If any partition left after drop, the partition could be the last partition of the table" 67 | echo "MESG - Drop script ignore the last partition , to avoid the below error \"cannot drop partition for rank 1 of relation \"\" -- only one remains\" " 68 | echo 69 | 70 | psql -d $PGDATABASE -p $PGPORT -c "SELECT 71 | schemaname||'.'||tablename as \"Parent Table\", 72 | partitionschemaname||'.'||partitiontablename as \"Partition Name\", 73 | age(substring(partitionrangestart from 2 for 19)::timestamp) \"Partition Age\", 74 | substring(partitionrangestart from 2 for 19)::timestamp as \"Partition Start\", 75 | substring(partitionrangeend from 2 for 19)::timestamp as \"Partition End\" 76 | FROM 77 | pg_partitions p 78 | WHERE 79 | partitionrangestart < current_timestamp::timestamp without time zone - interval '${Retention} months' 80 | and tablename like '%history' 81 | ORDER BY 3 desc;" 82 | } 83 | 84 | # Main program starts here 85 | 86 | # Script and log directories 87 | 88 | echo "INFO - Generating the directories name / location where the output logs will saved / stored" 89 | echo 90 | 91 | export script=$0 92 | export script_basename=`basename $script` 93 | export script_dir=`dirname $script` 94 | cd $script_dir 95 | export script_dir=`pwd` 96 | export install_dir=`dirname $script_dir` 97 | export logdir=$script_dir/log 98 | export tmpdir=$script_dir/tmp 99 | export fixdir=$script_dir/fix 100 | 101 | # Creating tmp / log directory 102 | 103 | echo "INFO - Creating the directories which will be used for storing logs / temp files ( if not available ) " 104 | echo 105 | 106 | mkdir -p $script_dir/log 107 | mkdir -p $script_dir/tmp 108 | mkdir -p $script_dir/fix 109 | 110 | # Reading the parameter file to set the environment 111 | 112 | echo "INFO - Reading the parameter file to set the environment" 113 | echo 114 | 115 | export paramfile=$script_dir/environment_parameters.env 116 | export GPHOME=`grep -i gphome $paramfile | grep -v grep | cut -d: -f2` 117 | source $GPHOME/greenplum_path.sh 118 | export PGDATABASE=`grep -i pgdatabase $paramfile | grep -v grep | cut -d: -f2` 119 | export PGPORT=`grep -i pgport $paramfile | grep -v grep | cut -d: -f2` 120 | export MASTER_DATA_DIRECTORY=`grep -i master_data_directory $paramfile | grep -v grep | cut -d: -f2` 121 | export Retention=`grep -i retention $paramfile | grep -v grep | cut -d: -f2` 122 | 123 | # Script and log filenames 124 | 125 | echo "INFO - Generating filenames needed for output logs" 126 | echo 127 | 128 | export logfile=${logdir}/${script_basename}.${PGDATABASE}.${PGPORT}.log 129 | export oldlog1=${logdir}/${script_basename}.${PGDATABASE}.${PGPORT}.log.1 130 | export oldlog2=${logdir}/${script_basename}.${PGDATABASE}.${PGPORT}.log.2 131 | export junkfile=${tmpdir}/${script_basename}.${PGDATABASE}.${PGPORT}.junk 132 | export sql_file=${fixdir}/${script_basename}.${PGDATABASE}.${PGPORT}.dropping_older_partition.sql 133 | export drop_output=${tmpdir}/${script_basename}.${PGDATABASE}.${PGPORT}.drop_output.tmp 134 | 135 | # Save old log files 136 | 137 | echo "INFO - Checking / archiving the old log files from previous run" 138 | echo 139 | 140 | if (test -f $oldlog1 ) 141 | then 142 | mv -f $oldlog1 $oldlog2 > $junkfile 2>> $junkfile 143 | fi 144 | 145 | if (test -f $logfile ) 146 | then 147 | mv -f $logfile $oldlog1 > $junkfile 2>> $junkfile 148 | fi 149 | 150 | # Remove old temporary files. 151 | 152 | echo "INFO - Removing the old / temporary files from previous run, if any" 153 | echo 154 | 155 | if (test -f $extract_table ) 156 | then 157 | rm -r $sql_file > $junkfile 2>> $junkfile 158 | fi 159 | 160 | # Direct messages to logfile 161 | 162 | echo "INFO - All the log / output messages are being moved to logfile: " $logfile 163 | echo "INFO - Please use a different session to view the progress / logfile: " $logfile 164 | echo "INFO - Do not press ctrl + c or kill the session unless its needed , allow the program to complete" 165 | echo 166 | 167 | exec > $logfile 2>> $logfile 168 | 169 | # Printing the message on the environment that will be used by this script 170 | 171 | echo "INFO - Program succesfully started" 172 | echo "INFO - Program started at" `date` 173 | echo 174 | echo "--------------------------------------------------------------------------------------------------------------------------------------------------------------------" 175 | echo 176 | echo "MESG - GreenPlum Database Cluster Environment: " 177 | echo 178 | echo " INFO - Software Location:" $GPHOME 179 | echo " INFO - Database:" $PGDATABASE 180 | echo " INFO - Port:" $PGPORT 181 | echo " INFO - Master Data Directory:" $MASTER_DATA_DIRECTORY 182 | echo " INFO - Retention:"$Retention" Months" 183 | echo 184 | echo "MESG - The script logs name / location" 185 | echo 186 | echo " INFO - Logfile Destination:" $logdir 187 | echo " INFO - Logfile Name:" $logfile 188 | echo 189 | echo "--------------------------------------------------------------------------------------------------------------------------------------------------------------------" 190 | echo 191 | 192 | 193 | # Calling the Function to confirm the script execution 194 | 195 | extract_partition_information 196 | generate_sql_to_drop 197 | execute_drop_sql 198 | extract_partition_info_after_drop 199 | 200 | # Program ending messages. 201 | 202 | echo "INFO - Progam succesfully completed" 203 | echo "INFO - Program ended at" `date` 204 | echo -------------------------------------------------------------------------------- /Last-Used-Table-and-Analyze/Last-Used-Table-and-Analyze.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION fn_ident_table_last_change() RETURNS void AS 2 | $$ 3 | DECLARE 4 | v_function_name text := 'fn_ident_table_last_change'; 5 | v_location int; 6 | v_sql text; 7 | v_db_oid text; 8 | BEGIN 9 | v_location := 1000; 10 | SELECT oid INTO v_db_oid 11 | FROM pg_database 12 | WHERE datname = current_database(); 13 | 14 | v_location := 2000; 15 | v_sql := 'DROP VIEW IF EXISTS v_ident_table_last_change cascade'; 16 | 17 | v_location := 2100; 18 | EXECUTE v_sql; 19 | 20 | v_location := 2200; 21 | v_sql := 'DROP EXTERNAL TABLE IF EXISTS ext_db_files_last_change'; 22 | 23 | v_location := 2300; 24 | EXECUTE v_sql; 25 | 26 | v_location := 3000; 27 | v_sql := 'CREATE EXTERNAL WEB TABLE ext_db_files_last_change ' || 28 | '( ' || 29 | ' segment_id INTEGER, ' || 30 | ' relfilenode TEXT, ' || 31 | ' filename TEXT, ' || 32 | ' size NUMERIC, ' || 33 | ' last_timestamp_change timestamp ' || 34 | ') ' || 35 | 'EXECUTE E''find $GP_SEG_DATADIR/base/' || v_db_oid || 36 | E' -type f -printf "$GP_SEGMENT_ID|%f|%h/%f|%s|%TY-%Tm-%Td %TX\n" 2> /dev/null || true'' ON ALL ' || 37 | E'FORMAT ''text'' (delimiter ''|'' null E''\N'' escape E''\\'''')'; 38 | 39 | v_location := 3100; 40 | EXECUTE v_sql; 41 | 42 | v_location := 4000; 43 | v_sql := 'CREATE OR replace VIEW v_ident_table_last_change ' || 44 | 'AS ' || 45 | ' WITH last_change ' || 46 | ' AS (SELECT Split_part(relfilenode, ''.'' :: text, 1) AS table_relfilenode, ' || 47 | ' SUM(SIZE) AS SIZE, ' || 48 | ' Max(last_timestamp_change) AS ' || 49 | ' max_last_timestamp_change ' || 50 | ' FROM ext_db_files_last_change ' || 51 | ' WHERE relfilenode NOT IN ( ''PG_VERSION'', ''pg_internal.init'' ) ' || 52 | ' GROUP BY 1) ' || 53 | ' SELECT (n.nspname ||''.''|| tab.relname ) AS relation_name, ' || 54 | ' T.relpages, ' || 55 | ' T.reltuples, ' || 56 | ' T.max_last_timestamp_change, ' || 57 | ' pslo.statime AS last_analyze_timestamp,' || 58 | ' tab.relhassubclass AS flag_is_partitioned, ' || 59 | ' CASE ' || 60 | ' WHEN tab.relhassubclass = FALSE THEN max_last_timestamp_change ' || 61 | ' ELSE Greatest(Max(max_last_timestamp_change) ' || 62 | ' over ( ' || 63 | ' PARTITION BY CASE WHEN tab.relhassubclass = TRUE ' || 64 | ' THEN ' || 65 | ' n.nspname ' || 66 | ' ELSE ' || 67 | ' part.schemaname END, CASE WHEN tab.relhassubclass = ' || 68 | ' TRUE THEN ' || 69 | ' tab.relname ELSE ' || 70 | ' part.tablename END ), max_last_timestamp_change) ' || 71 | ' END AS global_max_last_timestamp_change, ' || 72 | ' CASE ' || 73 | ' WHEN tab.relhassubclass = FALSE THEN sum_size_table ' || 74 | ' ELSE SUM(sum_size_table) ' || 75 | ' over ( ' || 76 | ' PARTITION BY CASE WHEN tab.relhassubclass = TRUE THEN ' || 77 | ' n.nspname ELSE ' || 78 | ' part.schemaname END, CASE WHEN tab.relhassubclass = TRUE THEN ' || 79 | ' tab.relname ELSE ' || 80 | ' part.tablename END ) ' || 81 | ' END AS global_sum_size_table, ' || 82 | ' T.sum_size_table, ' || 83 | ' tab.relkind AS relkind, ' || 84 | ' tab.relstorage, ' || 85 | ' CASE ' || 86 | ' WHEN tab.relhassubclass = TRUE THEN n.nspname ' || 87 | ' ELSE part.schemaname ' || 88 | ' END AS part_master_schema, ' || 89 | ' CASE ' || 90 | ' WHEN tab.relhassubclass = TRUE THEN tab.relname ' || 91 | ' ELSE part.tablename ' || 92 | ' END AS part_master_table ' || 93 | ' FROM (SELECT Coalesce(aoseg.relid, aovisi.relid, toast.oid, c.oid) AS oid, ' || 94 | ' SUM(c.relpages) AS ' || 95 | ' relpages ' || 96 | ' , ' || 97 | ' SUM(c.reltuples) ' || 98 | ' AS reltuples, ' || 99 | ' Max(last_change.max_last_timestamp_change) AS ' || 100 | ' max_last_timestamp_change, ' || 101 | ' SUM(last_change.SIZE) AS ' || 102 | ' sum_size_table ' || 103 | ' FROM last_change ' || 104 | ' inner join pg_class c ' || 105 | ' ON last_change.table_relfilenode = c.relfilenode ' || 106 | ' left outer join pg_appendonly aoseg ' || 107 | ' ON aoseg.segrelid = c.oid ' || 108 | ' left outer join pg_appendonly aovisi ' || 109 | ' ON aovisi.visimaprelid = c.oid ' || 110 | ' left outer join pg_class toast ' || 111 | ' ON c.oid = toast.reltoastrelid ' || 112 | ' GROUP BY 1) T ' || 113 | ' inner join pg_class tab ' || 114 | ' ON T.oid = tab.oid ' || 115 | ' left join pg_stat_last_operation pslo' || 116 | ' ON pslo.objid = T.oid ' || 117 | ' AND pslo.staactionname = ''ANALYZE''' || 118 | ' inner join pg_namespace n ' || 119 | ' ON tab.relnamespace = n.oid ' || 120 | ' AND n.nspname NOT IN ( ''information_schema'', ''pg_catalog'', ' || 121 | ' ''pg_toast'' ' || 122 | ' ) ' || 123 | ' left outer join pg_partitions part ' || 124 | ' ON n.nspname = part.partitionschemaname ' || 125 | ' AND tab.relname = part.partitiontablename'; 126 | 127 | v_location := 4100; 128 | EXECUTE v_sql; 129 | 130 | EXCEPTION 131 | WHEN OTHERS THEN 132 | RAISE EXCEPTION '(%:%:%)', v_function_name, v_location, sqlerrm; 133 | 134 | END; 135 | $$ 136 | language plpgsql; 137 | -------------------------------------------------------------------------------- /Last-Used-Table-and-Analyze/README.md: -------------------------------------------------------------------------------- 1 | # Purpose 2 | 3 | Often time the DBA has concerns like 4 | 5 | + When was the table / index etc was was last used or touched. 6 | + If there is a need for analyzing the table. 7 | + Or if there is any data added to the table so that the relation can be analyzed 8 | + Which partition table has the data added and which partition table need a analyze. 9 | 10 | # Execution 11 | 12 | + Execute the function to create the external table and the view. 13 | 14 | ``` 15 | select fn_ident_table_last_change(); 16 | ``` 17 | 18 | + Now use the view to obtain the information 19 | 20 | ``` 21 | select * from v_ident_table_last_change; 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | Some General adminsitration tools for greenplum database server -------------------------------------------------------------------------------- /gpdb-check-health/README.md: -------------------------------------------------------------------------------- 1 | # Goal 2 | 3 | This has some general health check of the database scripts. 4 | 5 | # Execution 6 | 7 | + Update the file "environment_parameters.env" with the environment of your database 8 | 9 | + Execute the script either running one by one or run run_all.sh to run all the scripts 10 | 11 | ``` 12 | ./run_all.sh 13 | ``` 14 | 15 | + health check on server not yet implemented , its TODO item .. 16 | -------------------------------------------------------------------------------- /gpdb-check-health/bin/dcacheck.sh: -------------------------------------------------------------------------------- 1 | 2 | # Function : Checking if the server is a DCA / DCA Version / Firmware Version 3 | 4 | check_if_dca() { 5 | 6 | echo "INFO - Checking if GPDB is run on a DCA / Non-DCA" 7 | echo 8 | 9 | if (test -f /etc/gpdb-appliance-version) 10 | then 11 | echo "DCA Version: " `cat /etc/gpdb-appliance-version` > $collect_dcainfo 12 | else 13 | echo "This is a software-only install , ignoring the DCA check " > $collect_dcainfo 14 | fi 15 | } -------------------------------------------------------------------------------- /gpdb-check-health/bin/environment_parameters.env: -------------------------------------------------------------------------------- 1 | gphome:/usr/local/greenplum-db 2 | pgdatabase:flightdata 3 | pgport:4281 4 | master_data_directory:/data/master/fai_4281-1 -------------------------------------------------------------------------------- /gpdb-check-health/bin/run_all.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | # 3 | # run_database_info.sh 4 | # pivotal - 2014 5 | # 6 | 7 | # Main program starts here 8 | 9 | # Script and log directories 10 | 11 | echo "INFO - Generating the directories name / location where the output logs will saved / stored" 12 | 13 | export script=$0 14 | export script_basename=`basename $script` 15 | export script_dir=`dirname $script`/.. 16 | cd $script_dir 17 | export script_dir=`pwd` 18 | export install_dir=`dirname $script_dir` 19 | export logdir=$script_dir/log 20 | export tmpdir=$script_dir/tmp 21 | export fixdir=$script_dir/fix 22 | export sqldir=$script_dir/sql 23 | export rptdir=$script_dir/rpt 24 | 25 | echo "INFO - Program ( ${script_basename} ) succesfully started at" `date` 26 | 27 | # Creating tmp / log directory 28 | 29 | echo "INFO - Creating the directories which will be used for storing logs / temp files ( if not available ) " 30 | 31 | mkdir -p $script_dir/log 32 | mkdir -p $script_dir/tmp 33 | mkdir -p $script_dir/rpt 34 | 35 | # Reading the parameter file to set the environment 36 | 37 | echo "INFO - Reading the parameter file to set the environment" 38 | 39 | export paramfile=$script_dir/bin/environment_parameters.env 40 | export GPHOME=`grep -i ^gphome $paramfile | grep -v grep | cut -d: -f2` 41 | source $GPHOME/greenplum_path.sh 42 | export PGDATABASE=`grep -i ^pgdatabase $paramfile | grep -v grep | cut -d: -f2` 43 | export PGPORT=`grep -i ^pgport $paramfile | grep -v grep | cut -d: -f2` 44 | export MASTER_DATA_DIRECTORY=`grep -i ^master_data_directory $paramfile | grep -v grep | cut -d: -f2` 45 | 46 | # Creating the logfiles that is needed for this script. 47 | 48 | echo "INFO - Generating filenames needed for output logs" 49 | 50 | export log_all=${logdir}/all_check_greenplum.out 51 | export generate_report_general_info_rpt=${logdir}/generate_report_general_info.rpt 52 | export generate_report_db_session_activity_rpt=${logdir}/generate_report_db_session_activity.rpt 53 | export generate_report_database_info_rpt=${logdir}/generate_report_database_info.rpt 54 | 55 | # Calling the dependant scripts to gather the checks of the cluster.. 56 | 57 | echo "INFO - Calling the dependant scripts to gather the checks of the cluster" 58 | 59 | echo -e "\n \t \t \t \t \t X----- Report generated at: " `date` "-----X \n \n" > $log_all 60 | 61 | echo "INFO - Calling script for general information on the cluster" 62 | 63 | /bin/sh $script_dir/bin/run_general_info.sh $log_all 64 | 65 | cat $generate_report_general_info_rpt >> $log_all 66 | 67 | echo "INFO - Calling script for session activity on the cluster" 68 | 69 | /bin/sh $script_dir/bin/run_db_session_activity.sh 70 | cat $generate_report_db_session_activity_rpt >> $log_all 71 | 72 | echo "INFO - Calling script for database activity on the cluster" 73 | 74 | /bin/sh $script_dir/bin/run_database_info.sh 75 | cat $generate_report_database_info_rpt >> $log_all 76 | 77 | echo -e "\n \t \t \t \t \t X----- Report completed at: " `date` "-----X \n \n" >> $log_all 78 | 79 | # Program ending messages. 80 | 81 | echo "INFO - Program ( ${script_basename} ) succesfully completed at" `date` 82 | echo "INFO - Program ( ${script_basename} ) report file available at" $log_all -------------------------------------------------------------------------------- /gpdb-check-health/bin/run_database_info.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | # 3 | # run_database_info.sh 4 | # pivotal - 2014 5 | # 6 | 7 | # Function : To gather genertic database information. 8 | 9 | generic_db_info() { 10 | 11 | echo "INFO - Generating the report on the list of database" 12 | 13 | $GPHOME/bin/psql -d $PGDATABASE -p $PGPORT -f $sqldir/database-list.sql | egrep -v "rows\)|row\)" > $collect_dblist 14 | 15 | } 16 | 17 | # Function : To collect relevant information with specific to database . 18 | 19 | db_info() { 20 | 21 | # The below line gathers all the relations with reference to specific type. 22 | 23 | echo "INFO - Generating the report specific to database" 24 | 25 | $GPHOME/bin/psql -d $PGDATABASE -p $PGPORT -Atc "select datname from pg_database where datallowconn='t' and datname not in ('template1','template0','postgres') order by 1" | while read line 26 | do 27 | echo "INFO - Generating the report for relation information in the database" $line 28 | $GPHOME/bin/psql -d $line -p $PGPORT -Atf $sqldir/database-relation-list.sql > $collect_db_relation_info 29 | echo -e "\n --------------------------------- " >> $collect_dbrpt_relation_info 30 | echo -e " DATABASE:" $line >> $collect_dbrpt_relation_info 31 | echo -e " --------------------------------- \n" >> $collect_dbrpt_relation_info 32 | echo -e " ==> Relation count in the database \n" >> $collect_dbrpt_relation_info 33 | echo " Relation Information | Result " >> $collect_dbrpt_relation_info 34 | echo "------------------------------------------------------+----------------------------------" >> $collect_dbrpt_relation_info 35 | echo "Relation - Heap | " ` grep heap $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 36 | echo "Relation - Index | " ` grep index $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 37 | echo "Relation - Append Only (Row) | " ` grep appendobjrow $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 38 | echo "Relation - Append Only (Column) | " ` grep appendobjcolumn $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 39 | echo "Relation - Append Only (AO Table) | " ` grep appendtab $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 40 | echo "Relation - Append Only (AO Table Index) | " ` grep appendindx $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 41 | echo "Relation - Toast Table | " ` grep toast $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 42 | echo "Relation - Toast Table Index | " ` grep tostindx $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 43 | echo "Relation - Partition Table | " ` grep partition $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 44 | echo "Relation - External Table | " ` grep external $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 45 | echo "Relation - View | " ` grep view $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 46 | echo "Relation - Composite Type | " ` grep composite $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 47 | echo "Relation - Sequence | " ` grep sequence $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 48 | echo "Relation - Index (on top of AO table) | " ` grep AOblkdir $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 49 | echo "Constraint - Primary | " ` grep pkconst $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 50 | echo "Constraint - Unique | " ` grep ukconst $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 51 | echo "Constraint - Foriegn | " ` grep fkconst $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 52 | echo "Constraint - Check | " ` grep ckconst $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 53 | echo "Functions | " ` grep proc $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 54 | echo "Triggers | " ` grep trigger $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 55 | echo "Schema | " ` grep namespace $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 56 | echo "Temp Schema | " ` grep temp $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 57 | echo "Are Orphan temp shema available on Master | " ` grep orphanmasttmp $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 58 | echo "Are Orphan temp shema available on Segments | " ` grep orphansegtmp $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 59 | echo "Relations with random distribution | " ` grep randomly $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 60 | echo "Relations with distribution policy | " ` grep distributed $collect_db_relation_info | cut -d'|' -f2 ` >> $collect_dbrpt_relation_info 61 | 62 | # The below line gathers the database transaction age to avoid wraparounds. 63 | 64 | echo -e "\n ==> Database transaction age > 150000000 (TOP 10) \n" >> $collect_dbrpt_relation_info 65 | 66 | $GPHOME/bin/psql -d $line -p $PGPORT -f $sqldir/database-transaction-age.sql| egrep -v "rows\)|row\)" > $collect_db_trans_age_info 67 | 68 | if [ `sed '/^$/d;s/[[:blank:]]//g' $collect_db_trans_age_info | wc -l` -gt 2 ] 69 | then 70 | cat $collect_db_trans_age_info >> $collect_dbrpt_relation_info 71 | else 72 | echo -e "No segments has the database transaction age greater than 150000000 for this database \n" >> $collect_dbrpt_relation_info 73 | fi 74 | 75 | # The below line gathers the relation transaction age. 76 | 77 | echo -e " ==> Relation transaction age > 150000000 (TOP 10) \n" >> $collect_dbrpt_relation_info 78 | 79 | $GPHOME/bin/psql -d $line -p $PGPORT -f $sqldir/database-transaction-relation-age.sql| egrep -v "rows\)|row\)" > $collect_relation_trans_age_info 80 | 81 | if [ `sed '/^$/d;s/[[:blank:]]//g' $collect_relation_trans_age_info | wc -l` -gt 2 ] 82 | then 83 | cat $collect_relation_trans_age_info >> $collect_dbrpt_relation_info 84 | else 85 | echo -e "No segments has the relation transaction age greater than 150000000 for this database \n" >> $collect_dbrpt_relation_info 86 | fi 87 | 88 | # The below line bloat information of the relation in the database. 89 | 90 | echo -e " ==> Identifying relations that has bloat on the database" >> $collect_dbrpt_relation_info 91 | echo -e " ==> NOTE: The query needs upto date statistics (analyze) for the relations \n" >> $collect_dbrpt_relation_info 92 | 93 | $GPHOME/bin/psql -d $line -p $PGPORT -f $sqldir/database-relation-bloat.sql | egrep -v "rows\)|row\)" > $collect_db_relation_bloat 94 | 95 | if [ `sed '/^$/d;s/[[:blank:]]//g' $collect_db_relation_bloat | wc -l` -gt 2 ] 96 | then 97 | cat $collect_db_relation_bloat >> $collect_dbrpt_relation_info 98 | else 99 | echo -e "No relation with bloat detected on this database \n" >> $collect_dbrpt_relation_info 100 | fi 101 | 102 | # The below line gathers the database skew information. 103 | 104 | echo -e " ==> Database skew information (The values are in bytes)." >> $collect_dbrpt_relation_info 105 | echo -e " ==> NOTE: This approach check for file sizes for each table for each segment, " >> $collect_dbrpt_relation_info 106 | echo -e " ==> It then will output only the tables that have at least one segment with more than 20% more byte" >> $collect_dbrpt_relation_info 107 | 108 | $GPHOME/bin/psql -d $line -p $PGPORT -f $sqldir/database-create-skew-function.sql > $junkfile 2>&1 109 | $GPHOME/bin/psql -d $line -p $PGPORT -f $sqldir/database-get-skew-info.sql | egrep -v "rows\)|row\)" > $collect_db_skew 110 | 111 | if [ `sed '/^$/d;s/[[:blank:]]//g' $collect_db_skew | wc -l` -gt 2 ] 112 | then 113 | echo -e " ==> HINT: largest_segment_percentage is calculated using max(size)/sum(size) for the relation i.e sum(size) = size of the relation on all segments," >> $collect_dbrpt_relation_info 114 | echo -e " ==> max(size) = max size on a single segment ( if it has multiple files like xxx.1, xxx.2,.... then it adds them up.) \n" >> $collect_dbrpt_relation_info 115 | cat $collect_db_skew >> $collect_dbrpt_relation_info 116 | else 117 | echo -e "\n No database skew found for any relation \n" >> $collect_dbrpt_relation_info 118 | fi 119 | 120 | # The below line gathers all the relations and sorts the objects with highest size. 121 | 122 | echo -e " ==> Relation size in the database - Index inclusive (TOP 10) \n" >> $collect_dbrpt_relation_info 123 | 124 | $GPHOME/bin/psql -d $line -p $PGPORT -f $sqldir/database-relation-size.sql | egrep -v "rows\)|row\)" > $collect_db_relation_size 125 | 126 | cat $collect_db_relation_size >> $collect_dbrpt_relation_info 127 | 128 | done 129 | } 130 | 131 | # Function : To gather GUC that is currently being set in the database. 132 | 133 | db_parameter_info() { 134 | 135 | echo "INFO - Generating the report on the parameter values of the cluster" 136 | 137 | $GPHOME/bin/psql -d $PGDATABASE -p $PGPORT -f $sqldir/database-parameter-list.sql | egrep -v "rows\)|row\)" > $collect_guc_value 138 | 139 | } 140 | 141 | # Function : Collect all the information generated above to a single report file. 142 | 143 | generate_report_general_info() { 144 | 145 | echo "INFO - Generating the report for the program: " $script_basename 146 | 147 | echo -e "\n \t \t \t \t \t \t GREENPLUM DATABASE WIDE INFORMATION" > $generate_report_database_info 148 | echo -e "\t \t \t \t \t \t -----------------------------------------\n " >> $generate_report_database_info 149 | echo -e " --> Information of the database in the greenplum cluster \n" >> $generate_report_database_info 150 | cat $collect_dblist >> $generate_report_database_info 151 | echo -e " --> Information with specific to database" >> $generate_report_database_info 152 | cat $collect_dbrpt_relation_info >> $generate_report_database_info 153 | echo -e " --> The values of GUC in the cluster" >> $generate_report_database_info 154 | echo -e " --> NOTE: 1. The column \"parameter value\" is trimmed to 30 characters" >> $generate_report_database_info 155 | echo -e " --> 2. The column \"parameter desc\" is trimmed to 100 characters \n" >> $generate_report_database_info 156 | cat $collect_guc_value >> $generate_report_database_info 157 | 158 | } 159 | 160 | 161 | # Main program starts here 162 | 163 | # Script and log directories 164 | 165 | echo "INFO - Generating the directories name / location where the output logs will saved / stored" 166 | 167 | export script=$0 168 | export script_basename=`basename $script` 169 | export script_dir=`dirname $script`/.. 170 | cd $script_dir 171 | export script_dir=`pwd` 172 | export install_dir=`dirname $script_dir` 173 | export logdir=$script_dir/log 174 | export tmpdir=$script_dir/tmp 175 | export fixdir=$script_dir/fix 176 | export sqldir=$script_dir/sql 177 | export rptdir=$script_dir/rpt 178 | 179 | echo "INFO - Program ( ${script_basename} ) succesfully started at" `date` 180 | 181 | # Creating tmp / log directory 182 | 183 | echo "INFO - Creating the directories which will be used for storing logs / temp files ( if not available ) " 184 | 185 | mkdir -p $script_dir/log 186 | mkdir -p $script_dir/tmp 187 | mkdir -p $script_dir/rpt 188 | 189 | # Reading the parameter file to set the environment 190 | 191 | echo "INFO - Reading the parameter file to set the environment" 192 | 193 | export paramfile=$script_dir/bin/environment_parameters.env 194 | export GPHOME=`grep -i ^gphome $paramfile | grep -v grep | cut -d: -f2` 195 | source $GPHOME/greenplum_path.sh 196 | export PGDATABASE=`grep -i ^pgdatabase $paramfile | grep -v grep | cut -d: -f2` 197 | export PGPORT=`grep -i ^pgport $paramfile | grep -v grep | cut -d: -f2` 198 | export MASTER_DATA_DIRECTORY=`grep -i ^master_data_directory $paramfile | grep -v grep | cut -d: -f2` 199 | 200 | # Creating the logfiles that is needed for this script. 201 | 202 | echo "INFO - Generating filenames needed for output logs" 203 | 204 | export collect_dblist=${tmpdir}/${script_basename}.dblist.tmp 205 | export collect_db_trans_age_info=${tmpdir}/${script_basename}.dbage.tmp 206 | export collect_relation_trans_age_info=${tmpdir}/${script_basename}.relationage.tmp 207 | export collect_db_relation_bloat=${tmpdir}/${script_basename}.dbrelationbloat.tmp 208 | export collect_db_relation_info=${tmpdir}/${script_basename}.dbrelationcount.tmp 209 | export collect_db_relation_size=${tmpdir}/${script_basename}.dbrelationsize.tmp 210 | export collect_dbrpt_relation_info=${tmpdir}/${script_basename}.dbrelationcountreport.tmp 211 | export collect_guc_value=${tmpdir}/${script_basename}.gucvalue.tmp 212 | export collect_db_skew=${tmpdir}/${script_basename}.dbskew.tmp 213 | export junkfile=${tmpdir}/${script_basename}.junk 214 | export generate_report_database_info=${logdir}/generate_report_database_info.rpt 215 | export old_generate_report_database_info_1=${logdir}/generate_report_database_info.rpt.1 216 | export old_generate_report_database_info_2=${logdir}/generate_report_database_info.rpt.2 217 | 218 | # Save old log files 219 | 220 | echo "INFO - Checking / archiving the old log files from previous run" 221 | 222 | if (test -f $old_generate_report_database_info_1 ) 223 | then 224 | mv -f $old_generate_report_database_info_1 $old_generate_report_database_info_2 > $junkfile 2>> $junkfile 225 | fi 226 | 227 | if (test -f $generate_report_general_info ) 228 | then 229 | mv -f $generate_report_general_info $old_generate_report_database_info_1 > $junkfile 2>> $junkfile 230 | fi 231 | 232 | if (test -f $collect_dbrpt_relation_info ) 233 | then 234 | rm -rf $collect_dbrpt_relation_info > $junkfile 2>> $junkfile 235 | fi 236 | 237 | # Calling the Function to confirm the script execution 238 | 239 | generic_db_info 240 | db_info 241 | db_parameter_info 242 | generate_report_general_info 243 | 244 | # Program ending messages. 245 | 246 | echo "INFO - Program ( ${script_basename} ) succesfully completed at" `date` 247 | echo "INFO - Program ( ${script_basename} ) report file available at" $generate_report_database_info -------------------------------------------------------------------------------- /gpdb-check-health/bin/run_db_session_activity.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | # 3 | # run_db_session_activity.sh 4 | # pivotal - 2014 5 | # 6 | 7 | # Function : To gather the version of the postgres / greenplum 8 | 9 | session_info() { 10 | 11 | echo "INFO - Generating report on the session activity in the database" 12 | 13 | $GPHOME/bin/psql -d $PGDATABASE -p $PGPORT -Atf $sqldir/database-session-activity.sql > $collect_session_info 14 | echo " Database Session Activty | Result " > $collect_session_info_rpt 15 | echo "-------------------------------------------------------------+----------------------------------" >> $collect_session_info_rpt 16 | echo "Total connection in the greenplum cluster : " ` grep connection $collect_session_info | cut -d'|' -f2 ` >> $collect_session_info_rpt 17 | echo "Total active statements in the cluster : " ` grep active $collect_session_info | cut -d'|' -f2 ` >> $collect_session_info_rpt 18 | echo "Total idle statements in the cluster : " ` grep idle $collect_session_info | cut -d'|' -f2 ` >> $collect_session_info_rpt 19 | echo "Total waiting statements in the cluster (waiting on master) : " ` grep waiting $collect_session_info | cut -d'|' -f2 ` >> $collect_session_info_rpt 20 | echo "Total orphan process in the cluster (no session on master) : " ` grep orphan $collect_session_info | cut -d'|' -f2 ` >> $collect_session_info_rpt 21 | 22 | } 23 | 24 | # Function : To gather orphan process information . 25 | 26 | check_orphan_info() { 27 | 28 | echo "INFO - Generating the report of process and checking if the total segments = total sessions " 29 | 30 | $GPHOME/bin/psql -d $PGDATABASE -p $PGPORT -f $sqldir/database-orphan-info.sql | egrep -v "rows\)|row\)" > $collect_orphan_info 31 | 32 | } 33 | 34 | 35 | # Function : To gather longest connected session in the database. 36 | 37 | check_longest_conn() { 38 | 39 | echo "INFO - Generating the report for top 10 longest connected sessions in the database " 40 | 41 | $GPHOME/bin/psql -d $PGDATABASE -p $PGPORT -f $sqldir/database-longest-conn.sql | egrep -v "rows\)|row\)" > $collect_longest_connected_session 42 | 43 | } 44 | # Function : To gather longest running query in the database. 45 | 46 | check_longest_query() { 47 | 48 | echo "INFO - Generating the report for top 10 longest running query in the database " 49 | 50 | $GPHOME/bin/psql -d $PGDATABASE -p $PGPORT -f $sqldir/database-longest-query.sql | egrep -v "rows\)|row\)" > $collect_longest_query 51 | 52 | } 53 | 54 | # Function : To gather database lock information. 55 | 56 | check_dblocks() { 57 | 58 | echo "INFO - Generating a report of database lock if any" 59 | 60 | $GPHOME/bin/psql -d $PGDATABASE -p $PGPORT -f $sqldir/database-lock-info.sql | egrep -v "rows\)|row\)" > $collect_dblock_info 61 | 62 | } 63 | 64 | # Function : To gather database lock for locktype relation . 65 | 66 | check_relation_dblocks() { 67 | 68 | echo "INFO - Generating the report of database lock with locktype = Relation " 69 | 70 | $GPHOME/bin/psql -d $PGDATABASE -p $PGPORT -f $sqldir/database-relation-lock-info.sql | egrep -v "rows\)|row\)" > $collect_relation_dblock_info 71 | 72 | } 73 | 74 | 75 | # Function : To gather database lock for locktype transaction . 76 | 77 | check_transaction_dblocks() { 78 | 79 | echo "INFO - Generating the report of database lock with locktype = Transaction " 80 | 81 | $GPHOME/bin/psql -d $PGDATABASE -p $PGPORT -f $sqldir/database-transaction-lock-info.sql | egrep -v "rows\)|row\)" > $collect_transaction_dblock_info 82 | 83 | } 84 | 85 | # Function : To gather resource queue information . 86 | 87 | check_rq_info() { 88 | 89 | echo "INFO - Generating the report of resource queue usage or if locktype = resource queue" 90 | 91 | $GPHOME/bin/psql -d $PGDATABASE -p $PGPORT -f $sqldir/database-rq-info.sql | egrep -v "rows\)|row\)" > $collect_rq_info 92 | 93 | } 94 | 95 | # Function : To gather orphan process lock information . 96 | 97 | check_orphan_lock_info() { 98 | 99 | echo "INFO - Generating the report of locks if its related to orphan process" 100 | 101 | $GPHOME/bin/psql -d $PGDATABASE -p $PGPORT -f $sqldir/database-segments-orphan-locks.sql | egrep -v "rows\)|row\)" > $collect_orphan_lock_info 102 | 103 | } 104 | 105 | # Function : To gather Workfile / Spill File / Processing skew information . 106 | 107 | check_processing_spillfiles() { 108 | 109 | echo "INFO - Generating the report on Workfile / Spill File / Processing skew information" 110 | 111 | $GPHOME/bin/psql -d $PGDATABASE -p $PGPORT -f $sqldir/database-processing-skew.sql | egrep -v "rows\)|row\)" > $collect_processing_skew 112 | 113 | } 114 | 115 | # Function : To generate the hostfile of the server. 116 | 117 | get_hostname_info() { 118 | 119 | echo "INFO - Generating the hostfile of active segments" 120 | 121 | $GPHOME/bin/psql -d $PGDATABASE -p $PGPORT -Atf $sqldir/database-hostname.sql | egrep -v "rows\)|row\)" > $collect_hostname_info 122 | 123 | } 124 | 125 | # Function : To generate the hostfile of the server. 126 | 127 | check_vacuum_running_seg() { 128 | 129 | echo "INFO - Generating the report of running VACUUM process" 130 | 131 | $GPHOME/bin/gpssh -f $collect_hostname_info "ps aux|head -1;ps aux |grep -i vacuum | grep -v grep" > $collect_vacuum_info 132 | cat $collect_vacuum_info | sed 's/\[//g' | awk '{print $1}' | uniq -c | while read line 133 | do 134 | export cnt=`echo $line | awk '{print $1}'` 135 | export hst=`echo $line | awk '{print $2}'` 136 | if [ $cnt -gt 2 ] 137 | then 138 | cat $collect_vacuum_info | grep ${hst} 139 | fi 140 | done > $collect_vacuum_info_rpt 141 | 142 | } 143 | 144 | generate_report_general_info() { 145 | 146 | echo "INFO - Generating the report for the program: " $script_basename 147 | 148 | echo -e "\n \t \t \t \t \t \t SESSION INFORMATION ON THE CLUSTER" > $generate_report_db_session_activity 149 | echo -e "\t \t \t \t \t \t ---------------------------------------- \n " >> $generate_report_db_session_activity 150 | echo -e " --> Session activity on the greeplum cluster \n" >> $generate_report_db_session_activity 151 | cat $collect_session_info_rpt >> $generate_report_db_session_activity 152 | echo -e "\n --> Information on the process and if its a orphan session in the greenplum cluster" >> $generate_report_db_session_activity 153 | if [ `sed '/^$/d;s/[[:blank:]]//g' $collect_orphan_info | wc -l` -gt 2 ] 154 | then 155 | echo -e " --> NOTE: From the below report total segments = total sessions, if not then the session is orphan or missing on one more segments " >> $generate_report_db_session_activity 156 | echo -e " --> HINT: If total segments <> total sessions, check gp_segment_id under pg_locks where mppsessionid = < the session ID without suffix con > " >> $generate_report_db_session_activity 157 | echo -e " --> KNOWN ISSUE: If there is a backup/restore (especially gp_dump/gp_restore) running, then to take of the parallel feature each " >> $generate_report_db_session_activity 158 | echo -e " --> segments connects independently and issue COPY FROM/TO, so they are not Orphan Process as well \n" >> $generate_report_db_session_activity 159 | cat $collect_orphan_info >> $generate_report_db_session_activity 160 | else 161 | echo -e "\nNo information of any orphan sessions in the greenplum cluster \n" >> $generate_report_db_session_activity 162 | fi 163 | echo -e " --> Information on IDLE session and when was it last activated on greenplum cluster (TOP 10) \n" >> $generate_report_db_session_activity 164 | if [ `sed '/^$/d;s/[[:blank:]]//g' $collect_longest_connected_session | wc -l` -gt 2 ] 165 | then 166 | cat $collect_longest_connected_session >> $generate_report_db_session_activity 167 | else 168 | echo -e "No information of any IDLE connection in the greenplum cluster \n" >> $generate_report_db_session_activity 169 | fi 170 | echo -e " --> Information of longest running query on greenplum cluster (TOP 10) " >> $generate_report_db_session_activity 171 | if [ `sed '/^$/d;s/[[:blank:]]//g' $collect_longest_query | wc -l` -gt 2 ] 172 | then 173 | echo -e " --> NOTE: Query is trimed to 100 characters \n" >> $generate_report_db_session_activity 174 | cat $collect_longest_query >> $generate_report_db_session_activity 175 | else 176 | echo -e "\nNo information of any query running in the greenplum cluster \n" >> $generate_report_db_session_activity 177 | fi 178 | echo -e " --> Information of locks in the greenplum cluster. \n" >> $generate_report_db_session_activity 179 | if [ `sed '/^$/d;s/[[:blank:]]//g' $collect_dblock_info | wc -l` -gt 2 ] 180 | then 181 | cat $collect_dblock_info >> $generate_report_db_session_activity 182 | else 183 | echo -e "No information of any database lock in the greenplum cluster \n" >> $generate_report_db_session_activity 184 | fi 185 | echo -e " --> Information on blocker/holder in the database with locktype = Relation (These are Master process)" >> $generate_report_db_session_activity 186 | if [ `sed '/^$/d;s/[[:blank:]]//g' $collect_relation_dblock_info | wc -l` -gt 2 ] 187 | then 188 | echo -e " --> NOTE: Do check the orphan lock sections in the report ( if available ) , if the below sessionID are on waiters list \n" >> $generate_report_db_session_activity 189 | cat $collect_relation_dblock_info >> $generate_report_db_session_activity 190 | else 191 | echo -e "\nNo information on blocker/holder in the database with locktype = Relation \n" >> $generate_report_db_session_activity 192 | fi 193 | echo -e " --> Information on blocker/holder in the database with locktype = Transaction (These are Master process)" >> $generate_report_db_session_activity 194 | if [ `sed '/^$/d;s/[[:blank:]]//g' $collect_transaction_dblock_info | wc -l` -gt 2 ] 195 | then 196 | echo -e " --> NOTE: Do check the orphan lock sections in the report ( if available ) , if the below sessionID are on waiters list \n" >> $generate_report_db_session_activity 197 | cat $collect_transaction_dblock_info >> $generate_report_db_session_activity 198 | else 199 | echo -e "\nNo information on blocker/holder in the database with locktype = Transaction \n" >> $generate_report_db_session_activity 200 | fi 201 | echo -e " --> Information on resource queue usage or if locktype = resource queue \n" >> $generate_report_db_session_activity 202 | cat $collect_rq_info >> $generate_report_db_session_activity 203 | echo -e " --> Information on orphan locks ( i.e locks held by a segments process ) \n" >> $generate_report_db_session_activity 204 | if [ `sed '/^$/d;s/[[:blank:]]//g' $collect_orphan_lock_info | wc -l` -gt 2 ] 205 | then 206 | cat $collect_orphan_lock_info >> $generate_report_db_session_activity 207 | else 208 | echo -e "No information for orphan locks that is currently blocking current running queries\n" >> $generate_report_db_session_activity 209 | fi 210 | echo -e " --> Information on workfile / spill files / processing skew information \n" >> $generate_report_db_session_activity 211 | if [ `sed '/^$/d;s/[[:blank:]]//g' $collect_processing_skew | wc -l` -gt 2 ] 212 | then 213 | cat $collect_processing_skew >> $generate_report_db_session_activity 214 | else 215 | echo -e "No information for spill files generated or any processing skew\n" >> $generate_report_db_session_activity 216 | fi 217 | echo -e " --> Information of the vacuum process running on the segments \n" >> $generate_report_db_session_activity 218 | if [ `sed '/^$/d;s/[[:blank:]]//g' $collect_vacuum_info_rpt | wc -l` -gt 1 ] 219 | then 220 | cat $collect_vacuum_info_rpt >> $generate_report_db_session_activity 221 | else 222 | echo -e "No information of any vacuum process running on the segments\n" >> $generate_report_db_session_activity 223 | fi 224 | } 225 | 226 | # Main program starts here 227 | 228 | # Script and log directories 229 | 230 | echo "INFO - Generating the directories name / location where the output logs will saved / stored" 231 | 232 | export script=$0 233 | export script_basename=`basename $script` 234 | export script_dir=`dirname $script`/.. 235 | cd $script_dir 236 | export script_dir=`pwd` 237 | export install_dir=`dirname $script_dir` 238 | export logdir=$script_dir/log 239 | export tmpdir=$script_dir/tmp 240 | export fixdir=$script_dir/fix 241 | export sqldir=$script_dir/sql 242 | export rptdir=$script_dir/rpt 243 | 244 | echo "INFO - Program ( ${script_basename} ) succesfully started at" `date` 245 | 246 | # Creating tmp / log directory 247 | 248 | echo "INFO - Creating the directories which will be used for storing logs / temp files ( if not available ) " 249 | 250 | mkdir -p $script_dir/log 251 | mkdir -p $script_dir/tmp 252 | mkdir -p $script_dir/rpt 253 | 254 | # Reading the parameter file to set the environment 255 | 256 | echo "INFO - Reading the parameter file to set the environment" 257 | 258 | export paramfile=$script_dir/bin/environment_parameters.env 259 | export GPHOME=`grep -i ^gphome $paramfile | grep -v grep | cut -d: -f2` 260 | source $GPHOME/greenplum_path.sh 261 | export PGDATABASE=`grep -i ^pgdatabase $paramfile | grep -v grep | cut -d: -f2` 262 | export PGPORT=`grep -i ^pgport $paramfile | grep -v grep | cut -d: -f2` 263 | export MASTER_DATA_DIRECTORY=`grep -i ^master_data_directory $paramfile | grep -v grep | cut -d: -f2` 264 | 265 | # Creating the logfiles that is needed for this script. 266 | 267 | echo "INFO - Generating filenames needed for output logs" 268 | 269 | export collect_session_info=${tmpdir}/${script_basename}.sessioninfo.tmp 270 | export collect_session_info_rpt=${tmpdir}/${script_basename}.sessioninforpt.tmp 271 | export collect_dblock_info=${tmpdir}/${script_basename}.dblock.tmp 272 | export collect_longest_connected_session=${tmpdir}/${script_basename}.longestconn.tmp 273 | export collect_longest_query=${tmpdir}/${script_basename}.longestquery.tmp 274 | export collect_relation_dblock_info=${tmpdir}/${script_basename}.relationdblock.tmp 275 | export collect_transaction_dblock_info=${tmpdir}/${script_basename}.transactiondblock.tmp 276 | export collect_rq_info=${tmpdir}/${script_basename}.rqinfo.tmp 277 | export collect_orphan_info=${tmpdir}/${script_basename}.orphan.tmp 278 | export collect_orphan_lock_info=${tmpdir}/${script_basename}.orphanlock.tmp 279 | export collect_hostname_info=${tmpdir}/${script_basename}.hostfile.tmp 280 | export collect_vacuum_info=${tmpdir}/${script_basename}.vacuum.tmp 281 | export collect_vacuum_info_rpt=${tmpdir}/${script_basename}.vacuumrpt.tmp 282 | export collect_processing_skew=${tmpdir}/${script_basename}.processingskew.tmp 283 | export junkfile=${tmpdir}/${script_basename}.junk 284 | export generate_report_db_session_activity=${logdir}/generate_report_db_session_activity.rpt 285 | export old_generate_report_db_session_activity_1=${logdir}/generate_report_db_session_activity.rpt.1 286 | export old_generate_report_db_session_activity_2=${logdir}/generate_report_db_session_activity.rpt.2 287 | 288 | # Save old log files 289 | 290 | echo "INFO - Checking / archiving the old log files from previous run" 291 | 292 | if (test -f $old_generate_report_db_session_activity_1 ) 293 | then 294 | mv -f $old_generate_report_db_session_activity_1 $old_generate_report_db_session_activity_2 > $junkfile 2>> $junkfile 295 | fi 296 | 297 | if (test -f $generate_report_general_info ) 298 | then 299 | mv -f $generate_report_general_info $old_generate_report_db_session_activity_1 > $junkfile 2>> $junkfile 300 | fi 301 | 302 | # Calling the Function to confirm the script execution 303 | 304 | session_info 305 | check_orphan_info 306 | check_longest_conn 307 | check_longest_query 308 | check_dblocks 309 | check_relation_dblocks 310 | check_transaction_dblocks 311 | check_rq_info 312 | check_orphan_lock_info 313 | check_processing_spillfiles 314 | get_hostname_info 315 | check_vacuum_running_seg 316 | generate_report_general_info 317 | 318 | # Program ending messages. 319 | 320 | echo "INFO - Program ( ${script_basename} ) succesfully completed at" `date` 321 | echo "INFO - Program ( ${script_basename} ) report file available at" $generate_report_db_session_activity -------------------------------------------------------------------------------- /gpdb-check-health/bin/run_general_info.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | # 3 | # run_general_info.sh 4 | # pivotal - 2014 5 | # 6 | 7 | # Function : To gather the version of the postgres / greenplum 8 | 9 | version_info() { 10 | 11 | echo "INFO - Getting the version of Postgres / Greenplum / DCA" 12 | 13 | export postgresversion=`$GPHOME/bin/postgres --version| cut -d' ' -f4` 14 | export greenplumversion=`$GPHOME/bin/postgres --gp-version| cut -d' ' -f4` 15 | if (test -f /etc/gpdb-appliance-version) 16 | then 17 | export dcaversion=`cat /etc/gpdb-appliance-version` 18 | else 19 | export dcaversion="N/A" 20 | fi 21 | awk 'BEGIN { printf "%-24s %-30s %-33s %-20s \n", "", "Postgres" ,"Greenplum","DCA" 22 | printf "%-20s %-30s %-30s %-20s \n", "","----------------","----------------","----------------" 23 | printf "%-24s %-30s %-31s %-20s \n", "Version","'$postgresversion'","'$greenplumversion'","'$dcaversion'"}' 2>&1 > $collect_version 24 | 25 | } 26 | 27 | 28 | # Function : To gather information on the segment configuration and the cluster status. 29 | 30 | seg_config_info() { 31 | 32 | echo "INFO - Generating the information on the segment configuration and the cluster status" 33 | 34 | $GPHOME/bin/psql -d $PGDATABASE -p $PGPORT -Atf $sqldir/database-seg-config.sql > $collect_seg_configuration 35 | echo " Cluster configuration | Result " > $collect_segrpt_configuration 36 | echo "----------------------------------------+----------------------------------" >> $collect_segrpt_configuration 37 | echo "Uptime of the greenplum database | " ` grep uptime $collect_seg_configuration | cut -d'|' -f2 ` >> $collect_segrpt_configuration 38 | echo "Total segments in the cluster | " ` grep totalcount $collect_seg_configuration | cut -d'|' -f2 ` >> $collect_segrpt_configuration 39 | echo "Total primary segments in the cluster | " ` grep primary $collect_seg_configuration | cut -d'|' -f2 ` >> $collect_segrpt_configuration 40 | echo "Total mirror segments in the cluster | " ` grep mirror $collect_seg_configuration | cut -d'|' -f2 ` >> $collect_segrpt_configuration 41 | echo "Is master standby configured | " ` grep standby $collect_seg_configuration | cut -d'|' -f2 ` >> $collect_segrpt_configuration 42 | echo "Total segments hosts in the cluster | " ` grep seghost $collect_seg_configuration | cut -d'|' -f2 ` >> $collect_segrpt_configuration 43 | echo "Total master hosts in the cluster | " ` grep masterhost $collect_seg_configuration | cut -d'|' -f2 ` >> $collect_segrpt_configuration 44 | echo "Total segments down in the cluster | " ` grep down $collect_seg_configuration | cut -d'|' -f2 ` >> $collect_segrpt_configuration 45 | echo "Total segments not in preferred role | " ` grep preferred $collect_seg_configuration | cut -d'|' -f2 ` >> $collect_segrpt_configuration 46 | echo "Total segments in sync mode | " ` grep ^sync $collect_seg_configuration | cut -d'|' -f2 ` >> $collect_segrpt_configuration 47 | echo "Total segments in changetracking mode | " ` grep changetracking $collect_seg_configuration | cut -d'|' -f2 ` >> $collect_segrpt_configuration 48 | echo "Total segments in resync mode | " ` grep resync $collect_seg_configuration | cut -d'|' -f2 ` >> $collect_segrpt_configuration 49 | echo "Total roles/users in the cluster | " ` grep role $collect_seg_configuration | cut -d'|' -f2 ` >> $collect_segrpt_configuration 50 | echo "Total roles/users with superuser access | " ` grep superuser $collect_seg_configuration | cut -d'|' -f2 ` >> $collect_segrpt_configuration 51 | 52 | } 53 | 54 | # Function : To gather grenplum coniguration history on last time they were down. 55 | 56 | seg_config_hist() { 57 | 58 | echo "INFO - Generating the report on when the segments was marked down last" 59 | 60 | $GPHOME/bin/psql -d $PGDATABASE -p $PGPORT -f $sqldir/database-config-history.sql | egrep -v "rows\)|row\)" > $collect_config_history 61 | 62 | } 63 | 64 | # Function : To gather master / standby master status. 65 | 66 | master_stndby_info() { 67 | 68 | echo "INFO - Generating the report on master / standby master status" 69 | 70 | $GPHOME/bin/gpstate -f > $collect_master_standby 71 | 72 | } 73 | 74 | # Function : Collect FATAL / PANIC / ERROR messages on the database logs. 75 | 76 | get_error_info() { 77 | 78 | echo "INFO - Generating the report to gather FATAL/PANIC/ERROR messages in the cluster in the last 3 days (Might take time based on the size of the log file)" 79 | 80 | $GPHOME/bin/psql -d $PGDATABASE -p $PGPORT -f $sqldir/database-create-log-collection-view.sql > $junkfile 2>&1 81 | $GPHOME/bin/psql -d $PGDATABASE -p $PGPORT -f $sqldir/database-fatal-error-panic-occurrence.sql | egrep -v "rows\)|row\)" > $collect_fatal_panic_error 82 | 83 | } 84 | 85 | # Function : To gather top 10 FATAL messages in the greenplum cluster. 86 | 87 | fatal_occurrence() { 88 | 89 | echo "INFO - Generating the report to gather FATAL messages in the cluster" 90 | 91 | head -2 $collect_fatal_panic_error > $collect_fatal ; grep FATAL $collect_fatal_panic_error | head -10 >> $collect_fatal 92 | 93 | } 94 | 95 | # Function : To gather top 10 PANIC messages in the greenplum cluster. 96 | 97 | panic_occurrence() { 98 | 99 | echo "INFO - Generating the report to gather PANIC messages in the cluster" 100 | 101 | head -2 $collect_fatal_panic_error > $collect_panic ; grep PANIC $collect_fatal_panic_error | head -10 >> $collect_panic 102 | 103 | } 104 | 105 | # Function : To gather top 10 ERROR messages in the greenplum cluster. 106 | 107 | error_in_db_occurrence() { 108 | 109 | echo "INFO - Generating the report to gather ERROR messages in the cluster" 110 | 111 | head -2 $collect_fatal_panic_error > $collect_error_in_db ; grep ERROR $collect_fatal_panic_error | head -10 >> $collect_error_in_db 112 | 113 | } 114 | 115 | # Function : To gather information if master lost connection with segments. 116 | 117 | crash_recovery_occurrence() { 118 | 119 | echo "INFO - Generating the report if master lost connection with segments in the last 2 days (Might take time based on the size of the log file) " 120 | 121 | $GPHOME/bin/psql -d $PGDATABASE -p $PGPORT -f $sqldir/database-crash-recovery-check.sql | egrep -v "rows\)|row\)" > $collect_crash_recovery_info 122 | 123 | } 124 | 125 | # Function : Collect all the information generated above to a single report file. 126 | 127 | generate_report_general_info() { 128 | 129 | echo "INFO - Generating the report for the program: " $script_basename 130 | 131 | echo -e "\t \t \t \t \t \t GENERAL INFORMATION ON THE CLUSTER" > $generate_report_general_info 132 | echo -e "\t \t \t \t \t \t ----------------------------------------\n " >> $generate_report_general_info 133 | echo -e " --> Version of the greenplum cluster \n" >> $generate_report_general_info 134 | cat $collect_version >> $generate_report_general_info 135 | echo -e "\n --> Information of the cluster configuration in the greenplum cluster \n" >> $generate_report_general_info 136 | cat $collect_segrpt_configuration >> $generate_report_general_info 137 | echo -e "\n --> Information of when the segments in cluster configuration was marked down (Last 10 entries)" >> $generate_report_general_info 138 | if [ `sed '/^$/d;s/[[:blank:]]//g' $collect_config_history | wc -l` -gt 2 ] 139 | then 140 | echo -e " --> NOTE: The below shown information is the time when the coniguration history table was updated, so not the exact start time" >> $generate_report_general_info 141 | echo -e " --> HINT: 1. If role=p , then FTS Probe process running on master marked the primary segment down after it couldn't communicate" >> $generate_report_general_info 142 | echo -e " --> so check the logs of master (with search similar to \"grep FTS | grep dbid= | head -10\") for start time and then check primary logs " >> $generate_report_general_info 143 | echo -e " --> 2. If role=m , then Primary segments of the content marked it down after it couldn't reach mirror" >> $generate_report_general_info 144 | echo -e " --> so check the logs of primary segment (with search similar \"grep \"mirror transition\" | head -10\") for start time and then check mirror logs \n " >> $generate_report_general_info 145 | cat $collect_config_history >> $generate_report_general_info 146 | else 147 | echo -e "\nNo information on the configuration history of any segments marked down \n" >> $generate_report_general_info 148 | fi 149 | echo -e " --> Master / Standby master sync status \n" >> $generate_report_general_info 150 | cat $collect_master_standby >> $generate_report_general_info 151 | echo -e " \n --> Information of top occurrence FATAL messages in the greenplum cluster in the last 3 days (Top 10)" >> $generate_report_general_info 152 | echo -e " --> PLEASE NOTE: This information depends on the availability of the master logs at location" $MASTER_DATA_DIRECTORY "\n" >> $generate_report_general_info 153 | if [ `sed '/^$/d;s/[[:blank:]]//g' $collect_fatal | wc -l` -gt 2 ] 154 | then 155 | cat $collect_fatal >> $generate_report_general_info 156 | else 157 | echo -e "No information on the master log of any occurrence of FATAL message" >> $generate_report_general_info 158 | fi 159 | echo -e " \n--> Information of top occurrence PANIC messages in the greenplum cluster in the last 3 days (Top 10)" >> $generate_report_general_info 160 | echo -e " --> PLEASE NOTE: This information depends on the availability of the master logs at location" $MASTER_DATA_DIRECTORY/pg_log "\n" >> $generate_report_general_info 161 | if [ `sed '/^$/d;s/[[:blank:]]//g' $collect_panic | wc -l` -gt 2 ] 162 | then 163 | cat $collect_panic >> $generate_report_general_info 164 | else 165 | echo -e "No information on the master log of any occurrence of PANIC message" >> $generate_report_general_info 166 | fi 167 | echo -e " \n--> Information of top occurrence ERROR messages in the greenplum cluster in the last 3 days (Top 10)" >> $generate_report_general_info 168 | echo -e " --> PLEASE NOTE: This information depends on the availability of the master logs at location" $MASTER_DATA_DIRECTORY/pg_log "\n" >> $generate_report_general_info 169 | if [ `sed '/^$/d;s/[[:blank:]]//g' $collect_error_in_db | wc -l` -gt 2 ] 170 | then 171 | cat $collect_error_in_db >> $generate_report_general_info 172 | else 173 | echo -e "No information on the master log of any occurrence of ERROR message" >> $generate_report_general_info 174 | fi 175 | echo -e " \n--> Information of when the master lost connection to the segments aka segment crashed in the last 2 days from master logs" >> $generate_report_general_info 176 | echo -e " --> PLEASE NOTE: This information depends on the availability of the master logs at location" $MASTER_DATA_DIRECTORY/pg_log >> $generate_report_general_info 177 | if [ `sed '/^$/d;s/[[:blank:]]//g' $collect_crash_recovery_info | wc -l` -gt 8 ] 178 | then 179 | echo -e " --> NOTE: The information in the messages column is limited to 100 characters \n" >> $generate_report_general_info 180 | cat $collect_crash_recovery_info >> $generate_report_general_info 181 | else 182 | echo -e "\nNo information on the master log of master losing connection with segments \n" >> $generate_report_general_info 183 | fi 184 | } 185 | 186 | # Main program starts here 187 | 188 | # Script and log directories 189 | 190 | echo "INFO - Generating the directories name / location where the output logs will saved / stored" 191 | 192 | export script=$0 193 | export script_basename=`basename $script` 194 | export script_dir=`dirname $script`/.. 195 | cd $script_dir 196 | export script_dir=`pwd` 197 | export install_dir=`dirname $script_dir` 198 | export logdir=$script_dir/log 199 | export tmpdir=$script_dir/tmp 200 | export fixdir=$script_dir/fix 201 | export sqldir=$script_dir/sql 202 | export rptdir=$script_dir/rpt 203 | 204 | echo "INFO - Program ( ${script_basename} ) succesfully started at" `date` 205 | 206 | # Creating tmp / log directory 207 | 208 | echo "INFO - Creating the directories which will be used for storing logs / temp files (if not available)" 209 | 210 | mkdir -p $script_dir/log 211 | mkdir -p $script_dir/tmp 212 | mkdir -p $script_dir/rpt 213 | 214 | # Reading the parameter file to set the environment 215 | 216 | echo "INFO - Reading the parameter file to set the environment" 217 | 218 | export paramfile=$script_dir/bin/environment_parameters.env 219 | export GPHOME=`grep -i ^gphome $paramfile | grep -v grep | cut -d: -f2` 220 | source $GPHOME/greenplum_path.sh 221 | export PGDATABASE=`grep -i ^pgdatabase $paramfile | grep -v grep | cut -d: -f2` 222 | export PGPORT=`grep -i ^pgport $paramfile | grep -v grep | cut -d: -f2` 223 | export MASTER_DATA_DIRECTORY=`grep -i ^master_data_directory $paramfile | grep -v grep | cut -d: -f2` 224 | 225 | # Creating the logfiles that is needed for this script. 226 | 227 | echo "INFO - Generating filenames needed for output logs" 228 | 229 | export collect_dblist=${tmpdir}/${script_basename}.dblist.tmp 230 | export collect_version=${tmpdir}/${script_basename}.version.tmp 231 | export collect_seg_configuration=${tmpdir}/${script_basename}.config.tmp 232 | export collect_segrpt_configuration=${tmpdir}/${script_basename}.configrpt.tmp 233 | export collect_config_history=${tmpdir}/${script_basename}.confighistory.tmp 234 | export collect_fatal=${tmpdir}/${script_basename}.fatal.tmp 235 | export collect_panic=${tmpdir}/${script_basename}.panic.tmp 236 | export collect_crash_recovery_info=${tmpdir}/${script_basename}.crashrecovery.tmp 237 | export collect_error_in_db=${tmpdir}/${script_basename}.errorindb.tmp 238 | export collect_master_standby=${tmpdir}/${script_basename}.masterstndby.tmp 239 | export collect_fatal_panic_error=${tmpdir}/${script_basename}.fatalpanicerror.tmp 240 | export junkfile=${tmpdir}/${script_basename}.junk 241 | export generate_report_general_info=${logdir}/generate_report_general_info.rpt 242 | export old_generate_report_general_info_1=${logdir}/generate_report_general_info.rpt.1 243 | export old_generate_report_general_info_2=${logdir}/generate_report_general_info.rpt.2 244 | 245 | # Save old log files 246 | 247 | echo "INFO - Checking / archiving the old log files from previous run" 248 | 249 | if (test -f $old_generate_report_general_info_1 ) 250 | then 251 | mv -f $old_generate_report_general_info_1 $old_generate_report_general_info_2 > $junkfile 2>> $junkfile 252 | fi 253 | 254 | if (test -f $generate_report_general_info ) 255 | then 256 | mv -f $generate_report_general_info $old_generate_report_general_info_1 > $junkfile 2>> $junkfile 257 | fi 258 | 259 | # Calling the Function to confirm the script execution 260 | 261 | version_info 262 | seg_config_info 263 | seg_config_hist 264 | master_stndby_info 265 | get_error_info 266 | fatal_occurrence 267 | panic_occurrence 268 | error_in_db_occurrence 269 | crash_recovery_occurrence 270 | generate_report_general_info 271 | 272 | # Program ending messages. 273 | 274 | echo "INFO - Program ( ${script_basename} ) succesfully completed at" `date` 275 | echo "INFO - Program ( ${script_basename} ) report file available at" $generate_report_general_info -------------------------------------------------------------------------------- /gpdb-check-health/sql/.DS_Store: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/faisaltheparttimecoder/Greenplum/ca9ed34fd07069b84ee6ec42331917935e3e67d6/gpdb-check-health/sql/.DS_Store -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-config-history.sql: -------------------------------------------------------------------------------- 1 | select h.time "Time", 2 | h.dbid||':'||content||':'||hostname||':'||port||':'||preferred_role "dbid:content:hostname:port:role", 3 | "desc" "Description" 4 | from gp_configuration_history h, gp_segment_configuration c 5 | where "desc" like '%DOWN%' 6 | and c.dbid=h.dbid 7 | order by time desc limit 10; -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-crash-recovery-check.sql: -------------------------------------------------------------------------------- 1 | \echo Start time of the message 2 | \echo 3 | select logtime "Time", 4 | substring(logmessage from 1 for 100) "Message" 5 | from check_greenplum.gp_log_database_all 6 | where (logmessage like '%Lost connection to one or more segments - fault detector checking for segment failures%' 7 | or logmessage like '%Dispatcher encountered connection error%') 8 | and logtime between now() - interval '2 days' and now() 9 | and logmessage not like '%gp_toolkit.gp_log_database%' 10 | order by logtime 11 | limit 5; 12 | 13 | \echo Ending time of the message 14 | \echo 15 | select logtime "Time", 16 | substring(logmessage from 1 for 100) "Message" 17 | from check_greenplum.gp_log_database_all 18 | where (logmessage like '%Lost connection to one or more segments - fault detector checking for segment failures%' 19 | or logmessage like '%Dispatcher encountered connection error%') 20 | and logtime between now() - interval '2 days' and now() 21 | and logmessage not like '%gp_toolkit.gp_log_database%' 22 | order by logtime 23 | limit 5; -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-create-log-collection-view.sql: -------------------------------------------------------------------------------- 1 | CREATE SCHEMA check_greenplum; 2 | 3 | CREATE OR REPLACE VIEW check_greenplum.gp_log_database_all AS SELECT gp_log_system.logtime, 4 | gp_log_system.loguser, 5 | gp_log_system.logdatabase, 6 | gp_log_system.logpid, 7 | gp_log_system.logthread, 8 | gp_log_system.loghost, 9 | gp_log_system.logport, 10 | gp_log_system.logsessiontime, 11 | gp_log_system.logtransaction, 12 | gp_log_system.logsession, 13 | gp_log_system.logcmdcount, 14 | gp_log_system.logsegment, 15 | gp_log_system.logslice, 16 | gp_log_system.logdistxact, 17 | gp_log_system.loglocalxact, 18 | gp_log_system.logsubxact, 19 | gp_log_system.logseverity, 20 | gp_log_system.logstate, 21 | gp_log_system.logmessage, 22 | gp_log_system.logdetail, 23 | gp_log_system.loghint, 24 | gp_log_system.logquery, 25 | gp_log_system.logquerypos, 26 | gp_log_system.logcontext, 27 | gp_log_system.logdebug, 28 | gp_log_system.logcursorpos, 29 | gp_log_system.logfunction, 30 | gp_log_system.logfile, 31 | gp_log_system.logline, 32 | gp_log_system.logstack 33 | FROM gp_toolkit.gp_log_system; -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-create-skew-function.sql: -------------------------------------------------------------------------------- 1 | CREATE SCHEMA check_greenplum; 2 | 3 | CREATE OR REPLACE FUNCTION check_greenplum.fn_create_db_files_skew() RETURNS void AS 4 | $$ 5 | DECLARE 6 | v_function_name text := 'fn_create_db_files_skew'; 7 | v_location int; 8 | v_sql text; 9 | v_db_oid text; 10 | v_num_segments numeric; 11 | v_skew_amount numeric; 12 | BEGIN 13 | v_location := 1000; 14 | SELECT oid INTO v_db_oid 15 | FROM pg_database 16 | WHERE datname = current_database(); 17 | 18 | v_location := 2000; 19 | v_sql := 'DROP VIEW IF EXISTS check_greenplum.vw_file_skew'; 20 | 21 | v_location := 2100; 22 | EXECUTE v_sql; 23 | 24 | v_location := 2200; 25 | v_sql := 'DROP EXTERNAL TABLE IF EXISTS check_greenplum.db_files_skew'; 26 | 27 | v_location := 2300; 28 | EXECUTE v_sql; 29 | 30 | v_location := 3000; 31 | v_sql := 'CREATE EXTERNAL WEB TABLE check_greenplum.db_files_skew ' || 32 | '(segment_id int, relfilenode text, filename text, ' || 33 | 'size numeric) ' || 34 | 'execute E''ls -l $GP_SEG_DATADIR/base/' || v_db_oid || 35 | ' | ' || 36 | 'grep gpadmin | ' || 37 | E'awk {''''print ENVIRON["GP_SEGMENT_ID"] "\\t" $9 "\\t" ' || 38 | 'ENVIRON["GP_SEG_DATADIR"] "/' || v_db_oid || 39 | E'/" $9 "\\t" $5''''}'' on all ' || 'format ''text'''; 40 | 41 | v_location := 3100; 42 | EXECUTE v_sql; 43 | 44 | v_location := 4000; 45 | SELECT count(*) INTO v_num_segments 46 | FROM gp_segment_configuration 47 | WHERE preferred_role = 'p' 48 | AND content >= 0; 49 | 50 | v_location := 4100; 51 | v_skew_amount := 1.2*(1/v_num_segments); 52 | 53 | v_location := 4200; 54 | v_sql := 'CREATE OR REPLACE VIEW check_greenplum.vw_file_skew AS ' || 55 | 'SELECT schema_name, ' || 56 | 'table_name, ' || 57 | 'max(size)/sum(size) as largest_segment_percentage, ' || 58 | 'sum(size) as total_size ' || 59 | 'FROM ( ' || 60 | 'SELECT n.nspname AS schema_name, ' || 61 | ' c.relname AS table_name, ' || 62 | ' sum(db.size) as size ' || 63 | ' FROM check_greenplum.db_files_skew db ' || 64 | ' JOIN pg_class c ON ' || 65 | ' split_part(db.relfilenode, ''.'', 1) = c.relfilenode ' || 66 | ' JOIN pg_namespace n ON c.relnamespace = n.oid ' || 67 | ' WHERE c.relkind = ''r'' ' || 68 | ' GROUP BY n.nspname, c.relname, db.segment_id ' || 69 | ') as sub ' || 70 | 'GROUP BY schema_name, table_name ' || 71 | 'HAVING sum(size) > 0 and max(size)/sum(size) > ' || 72 | v_skew_amount::text || ' ' || 73 | 'ORDER BY largest_segment_percentage DESC, schema_name, ' || 74 | 'table_name'; 75 | 76 | v_location := 4300; 77 | EXECUTE v_sql; 78 | 79 | END; 80 | $$ 81 | language plpgsql; 82 | 83 | 84 | SELECT check_greenplum.fn_create_db_files_skew(); -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-fatal-error-panic-occurrence.sql: -------------------------------------------------------------------------------- 1 | SELECT logseverity "Severity", 2 | logdatabase "Database name", 3 | substring(logmessage from 1 for 80) "Message", 4 | count(*) "# of occurance" 5 | FROM check_greenplum.gp_log_database_all 6 | WHERE logseverity in ('ERROR','FATAL','PANIC') 7 | AND logtime between now() - interval '3 days' and now() 8 | AND logmessage not like '%check_greenplum%' 9 | GROUP BY logseverity,logdatabase,logmessage 10 | ORDER BY 4 DESC ; -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-get-skew-info.sql: -------------------------------------------------------------------------------- 1 | SELECT * FROM check_greenplum.vw_file_skew ORDER BY 3 DESC; -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-hostname.sql: -------------------------------------------------------------------------------- 1 | select distinct hostname 2 | from gp_segment_configuration 3 | where role='p'; -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-list.sql: -------------------------------------------------------------------------------- 1 | select 2 | d.oid "Database OID", 3 | d.datname "Database Name", 4 | r.rolname "Database Owner", 5 | pg_catalog.pg_encoding_to_char(d.encoding) as "Database Encoding", 6 | d.datallowconn "Connections Allowed", 7 | d.datconnlimit "Connection Limit", 8 | pg_size_pretty(pg_database_size(d.datname)) "Database Size" 9 | from 10 | pg_catalog.pg_database d , pg_catalog.pg_roles r 11 | where 12 | d.datdba=r.oid 13 | order by 2 ; 14 | -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-lock-info.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | (select datname from pg_database where oid=a.database) AS "Database Name", 3 | a.locktype AS "Lock Type", 4 | a.relation::regclass AS "Relation Name", 5 | (select rsqname from pg_resqueue where oid=a.objid) AS "Resource Queue", 6 | count(*) AS "Total Waiters" 7 | FROM pg_locks a 8 | WHERE a.granted='f' 9 | GROUP BY 1,2,3,4 10 | ; -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-longest-conn.sql: -------------------------------------------------------------------------------- 1 | select now()-query_start AS "Time - Last Activated", 2 | now()-backend_start AS "Time - When Connected", 3 | datname as "Database name", 4 | usename as "Username", 5 | procpid as "PID", 6 | sess_id as "Session ID", 7 | substring(current_query from 1 for 100) AS "Query" 8 | from pg_stat_activity 9 | where procpid not in (select pg_backend_pid()) 10 | and current_query like '' 11 | order by 1 desc 12 | limit 10; 13 | 14 | -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-longest-query.sql: -------------------------------------------------------------------------------- 1 | select now()-query_start AS "Running Time", 2 | datname as "Database name", 3 | usename as "Username", 4 | procpid as "PID", 5 | sess_id as "Session ID", 6 | substring(current_query from 1 for 100) AS "Query" 7 | from pg_stat_activity 8 | where procpid not in (select pg_backend_pid()) 9 | and current_query not like '' 10 | order by 1 desc 11 | limit 10; 12 | -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-master-mirroring.sql: -------------------------------------------------------------------------------- 1 | select * from gp_master_mirroring ; -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-orphan-info.sql: -------------------------------------------------------------------------------- 1 | select 2 | 'con'|| a.mppsessionid AS "Session ID", 3 | b.total_seg as "Total Segments", 4 | count(a.*) AS "Total Sessions" 5 | from 6 | (select distinct mppsessionid,gp_segment_id 7 | from pg_locks 8 | where mppsessionid not in (select sess_id from pg_stat_activity where procpid!=pg_backend_pid() OR current_query!='' OR waiting='t') 9 | and mppsessionid != 0 10 | ) a, 11 | (select count(*) as total_seg 12 | from gp_segment_configuration 13 | where role='p' 14 | ) b 15 | group by 1,2 16 | having count(a.*) < b.total_seg 17 | order by 3; -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-parameter-list.sql: -------------------------------------------------------------------------------- 1 | SELECT name "Parameter Name", 2 | substring(setting from 1 for 30) "Parameter Value", 3 | substring(short_desc from 1 for 100) "Parameter Desc" 4 | FROM pg_settings 5 | order by 1; -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-processing-skew.sql: -------------------------------------------------------------------------------- 1 | SELECT datname "Database Name", 2 | procpid "Process ID", 3 | sess_id "Session ID", 4 | sum(size)/1024::float "Total Spill Size(KB)", 5 | sum(numfiles) "Total Spill Files" 6 | FROM gp_toolkit.gp_workfile_usage_per_query 7 | WHERE sess_id not in (select sess_id from pg_stat_activity where procpid=pg_backend_pid()) 8 | GROUP BY 1,2,3 9 | ORDER BY 4 DESC; -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-relation-bloat.sql: -------------------------------------------------------------------------------- 1 | SELECT bdirelid "Relation OID", 2 | bdinspname ||'.'|| bdirelname "Relation Name", 3 | bdirelpages "Allocated Pages", 4 | bdiexppages "Pages Needed", 5 | bdidiag "Message" 6 | FROM gp_toolkit.gp_bloat_diag; 7 | 8 | 9 | 10 | -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-relation-list.sql: -------------------------------------------------------------------------------- 1 | select 'toast|' ||count(*) 2 | from pg_class where relname like 'pg_toast%' and relkind='t' and relstorage='h' 3 | union 4 | select 'tostindx|' ||count(*) 5 | from pg_class where relname like 'pg_toast%index' and relkind='i' and relstorage='h' 6 | union 7 | select 'view|' ||count(*) 8 | from pg_class where relkind='v' and relstorage='v' 9 | union 10 | select 'composite|' ||count(*) 11 | from pg_class where relkind='c' and relstorage='v' 12 | union 13 | select 'external|' ||count(*) 14 | from pg_class where relkind='r' and relstorage='x' 15 | union 16 | select 'heap|' ||count(*) 17 | from pg_class where relkind='r' and relstorage='h' and relname not in (select partitiontablename from pg_partitions) 18 | union 19 | select 'partition|' ||count(*) 20 | from pg_class where relkind='r' and relstorage='h' and relname in (select partitiontablename from pg_partitions) 21 | union 22 | select 'appendindx|' ||count(*) 23 | from pg_class where relname like 'pg_ao%index' and relkind='i' and relstorage='h' 24 | union 25 | select 'appendtab|' ||count(*) 26 | from pg_class where relkind='o' and relstorage='h' 27 | union 28 | select 'appendobjrow|' ||count(*) 29 | from pg_class where relkind='r' and relstorage='a' and oid in ( select relid from pg_appendonly where columnstore='f') 30 | union 31 | select 'appendobjcolumn|' ||count(*) 32 | from pg_class where relkind='r' and relstorage='c' and oid in ( select relid from pg_appendonly where columnstore='t') 33 | union 34 | select 'sequence|' ||count(*) 35 | from pg_class where relkind='S' and relstorage='h' 36 | union 37 | select 'index|' ||count(*) 38 | from pg_class where relkind='i' and relstorage='h' and relname not like 'pg_toast%' and relname not like 'pg_ao%' 39 | union 40 | select 'AOblkdir|' ||count(*) 41 | from pg_class where relkind='b' and relstorage='h' and relname ~ 'pg_ao' 42 | ; 43 | select 'proc|'||count(*) 44 | from pg_proc 45 | ; 46 | select 'trigger|'||count(*) 47 | from pg_trigger 48 | ; 49 | select 'ckconst|'|| count(*) 50 | from pg_constraint where contype='c' 51 | union 52 | select 'pkconst|'|| count(*) 53 | from pg_constraint where contype='p' 54 | union 55 | select 'fkconst|'|| count(*) 56 | from pg_constraint where contype='f' 57 | union 58 | select 'ukconst|'|| count(*) 59 | from pg_constraint where contype='u' 60 | ; 61 | select 'randomly|'||count(*) 62 | from gp_distribution_policy where attrnums is NULL 63 | union 64 | select 'distributed|'||count(*) 65 | from gp_distribution_policy where attrnums is NOT NULL 66 | ; 67 | select 'namespace|'||count(*) 68 | from pg_namespace 69 | union 70 | select 'temp|'||count(*) 71 | from pg_namespace where nspname like 'pg_temp%' 72 | union 73 | select 'orphanmasttmp|' || case count(*) when 0 then 'no' else 'yes' end 74 | from (select nspname from pg_namespace where nspname like 'pg_temp%' except select 'pg_temp_' || sess_id::varchar from pg_stat_activity) as foo 75 | union 76 | select 'orphansegtmp|' || case count(*) when 0 then 'no' else 'yes' end 77 | from (select nspname from gp_dist_random('pg_namespace') where nspname like 'pg_temp%' except select 'pg_temp_' || sess_id::varchar from pg_stat_activity) as foo 78 | ; -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-relation-lock-info.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | l.locktype AS "Blocker locktype", 3 | d.datname AS "Database", 4 | l.relation::regclass AS "Blocking Table", 5 | a.usename AS "Blocking user", 6 | l.pid AS "Blocker pid", 7 | l.mppsessionid AS "Blockers SessionID", 8 | l.mode AS "Blockers lockmode", 9 | now()-a.query_start AS "Blocked duration", 10 | substring(a.current_query from 1 for 40) AS "Blocker Query" 11 | FROM 12 | pg_locks l, 13 | pg_stat_activity a, 14 | pg_database d 15 | WHERE l.pid=a.procpid 16 | AND l.database=d.oid 17 | AND l.granted = true 18 | AND relation in ( select relation from pg_locks where granted='f') 19 | ORDER BY 3; -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-relation-size.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | nspname ||'.'|| relname "Relation Name", 3 | nspname "Schema Name", 4 | case relkind when 'r' then 'Table' 5 | when 'i' then 'Index' 6 | when 'S' then 'Sequence' 7 | when 't' then 'Toast Table' 8 | when 'v' then 'View' 9 | when 'c' then 'Composite Type' 10 | when 'o' then 'Append-only Tables' 11 | when 's' then 'Special' 12 | end "Object Type", 13 | pg_size_pretty(pg_total_relation_size(a.oid)) AS "size" 14 | FROM 15 | pg_class a , pg_namespace b 16 | WHERE 17 | b.oid = a.relnamespace 18 | and nspname NOT IN ('pg_catalog', 'information_schema') 19 | and a.relkind!='i' 20 | and b.nspname !~ '^pg_toast' 21 | ORDER BY pg_total_relation_size(a.oid) DESC 22 | LIMIT 10; -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-rq-info.sql: -------------------------------------------------------------------------------- 1 | select 2 | rsqname as "RQname", 3 | rsqcountlimit as "RQActivestmt-Limit", 4 | rsqcountvalue as "RQActivestmt-Current", 5 | rsqcostlimit as "RQCost-Limit", 6 | rsqcostvalue as "RQCost-Current", 7 | rsqmemorylimit::integer as "RQMemory-Limit", 8 | rsqmemoryvalue::integer "RQMemory-Current", 9 | rsqholders as "RQHolders", 10 | rsqwaiters as "RQWaiters" 11 | from gp_toolkit.gp_resqueue_status; -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-seg-config.sql: -------------------------------------------------------------------------------- 1 | select 'uptime|' || now() - pg_postmaster_start_time() 2 | union 3 | select 'totalcount|' || count(*) 4 | from gp_segment_configuration 5 | union 6 | select 'seghost|' || count(distinct hostname) 7 | from gp_segment_configuration 8 | where content<>'-1' 9 | union 10 | select 'masterhost|' || count(distinct hostname) 11 | from gp_segment_configuration 12 | where content='-1' 13 | union 14 | select 'primary|' || count(*) 15 | from gp_segment_configuration 16 | where role='p' and content<>'-1' 17 | union 18 | select 'mirror|' || count(*) 19 | from gp_segment_configuration 20 | where role='m' and content<>'-1' 21 | union 22 | select 'standby|' || case count(*) when 1 then 'no' else 'yes' end 23 | from gp_segment_configuration 24 | where content='-1' 25 | union 26 | select 'down|' || count(*) 27 | from gp_segment_configuration 28 | where status='d' 29 | union 30 | select 'preferred|' || count(*) 31 | from gp_segment_configuration 32 | where role<>preferred_role 33 | union 34 | select 'sync|' || count(*) 35 | from gp_segment_configuration 36 | where mode='s' 37 | union 38 | select 'changetracking|' || count(*) 39 | from gp_segment_configuration 40 | where mode='c' 41 | union 42 | select 'resync|' || count(*) 43 | from gp_segment_configuration 44 | where mode='r' 45 | union 46 | select 'role|' || count(*) 47 | from pg_roles 48 | union 49 | select 'superuser|' || count(*) 50 | from pg_roles 51 | where rolsuper='t'; 52 | -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-segments-orphan-locks.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | w.relation::regclass AS "Table", 3 | w.mode AS "Waiters Mode", 4 | w.pid AS "Waiters PID", 5 | w.mppsessionid AS "Waiters SessionID", 6 | b.mode AS "Blockers Mode", 7 | b.pid AS "Blockers PID", 8 | b.mppsessionid AS "Blockers SessionID", 9 | (select 'Hostname: ' || c.hostname ||' Content: '|| c.content || ' Port: ' || port from gp_segment_configuration c where c.content=b.gp_segment_id and role='p') AS "Blocking Segment" 10 | FROM pg_catalog.pg_locks AS w, pg_catalog.pg_locks AS b 11 | Where ((w."database" = b."database" AND w.relation = b.relation) 12 | OR w.transactionid = b.transaction) 13 | AND w.granted='f' 14 | AND b.granted='t' 15 | AND w.mppsessionid <> b.mppsessionid 16 | AND w.mppsessionid in (SELECT l.mppsessionid FROM pg_locks l WHERE l.granted = true AND relation in ( select relation from pg_locks where granted='f')) 17 | AND w.gp_segment_id = b.gp_segment_id 18 | ORDER BY 1; -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-session-activity.sql: -------------------------------------------------------------------------------- 1 | select 'connection|' || count(*) 2 | from pg_stat_activity where procpid not in ( select pg_backend_pid() ) 3 | union 4 | select 'active|' || count(*) 5 | from pg_stat_activity 6 | where current_query<>'' and procpid not in ( select pg_backend_pid() ) 7 | union 8 | select 'idle|' || count(*) 9 | from pg_stat_activity 10 | where current_query='' 11 | union 12 | select 'waiting|' || count(*) 13 | from pg_stat_activity 14 | where waiting='t' 15 | union 16 | select 'orphan|'|| count(DISTINCT connection) 17 | from (select 18 | hostname , 19 | port , 20 | pl.gp_segment_id as segment , 21 | 'con'||mppsessionid as connection , 22 | relation::oid::regclass , granted 23 | from 24 | pg_locks pl , 25 | gp_segment_configuration gsc 26 | where 27 | pl.gp_segment_id=gsc.content 28 | and gsc.role='p' 29 | and mppsessionid not in (select sess_id from pg_stat_activity ) 30 | ) as q1 31 | ; -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-transaction-age.sql: -------------------------------------------------------------------------------- 1 | SELECT 'Hostname: '|| hostname ||' Content: '|| Content || ' Port: ' || port "Segment Information", 2 | datname "Database name", 3 | age(datfrozenxid) "Transaction age" 4 | FROM pg_database d , gp_segment_configuration c 5 | WHERE d.gp_segment_id=c.content 6 | AND d.datname=current_database() 7 | AND age(datfrozenxid)>150000000 8 | UNION 9 | SELECT 'Hostname: '|| hostname ||' Content: '|| Content || ' Port: ' || port "Segment Information", 10 | datname "Database name", 11 | age(datfrozenxid) "Transaction age" 12 | FROM gp_dist_random('pg_database') d , gp_segment_configuration c 13 | WHERE d.gp_segment_id=c.content 14 | AND d.datname=current_database() 15 | AND age(datfrozenxid)>150000000 16 | order by 3 desc 17 | LIMIT 10; -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-transaction-lock-info.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | l.locktype AS "Blocker locktype", 3 | l.relation::regclass AS "Blocking Table", 4 | a.usename AS "Blocking user", 5 | l.pid AS "Blocker pid", 6 | l.mppsessionid AS "Blockers SessionID", 7 | l.mode AS "Blockers lockmode", 8 | now()-a.query_start AS "Blocked duration", 9 | substring(a.current_query from 1 for 40) AS "Blocker Query" 10 | FROM 11 | pg_locks l, 12 | pg_locks w, 13 | pg_stat_activity a 14 | WHERE l.pid=a.procpid 15 | AND l.transaction=w.transactionid 16 | AND l.granted = true 17 | AND w.granted = false 18 | AND l.transactionid is not NULL 19 | ORDER BY 3; -------------------------------------------------------------------------------- /gpdb-check-health/sql/database-transaction-relation-age.sql: -------------------------------------------------------------------------------- 1 | SELECT 'Hostname: '|| hostname ||' Content: '|| Content || ' Port: ' || port "Segment Information", 2 | n.nspname||'.'|| r.relname "Relation Name", 3 | age(r.relfrozenxid) "Relation Age" 4 | FROM pg_class r, gp_segment_configuration c , pg_namespace n 5 | WHERE r.relkind ='r' 6 | AND r.relstorage != 'x' 7 | AND age(r.relfrozenxid)>150000000 8 | AND r.gp_segment_id=c.content 9 | AND n.oid=r.relnamespace 10 | union 11 | SELECT 'Hostname: '|| hostname ||' Content: '|| Content || ' Port: ' || port "Segment Information", 12 | n.nspname||'.'||r.relname "Relation Name", 13 | age(r.relfrozenxid) "Relation Age" 14 | FROM gp_dist_random('pg_class') r, gp_segment_configuration c , pg_namespace n 15 | WHERE r.relkind ='r' 16 | AND r.relstorage != 'x' 17 | AND age(r.relfrozenxid)>150000000 18 | AND r.gp_segment_id=c.content 19 | AND n.oid=r.relnamespace 20 | ORDER BY 3 DESC 21 | LIMIT 10; 22 | --------------------------------------------------------------------------------