├── LICENSE ├── README.md ├── age ├── README.txt ├── vacuum_high_age.pl ├── vacuum_high_age_5.pl └── vacuum_high_age_otherdb.sh ├── analyze ├── README.txt ├── analyze_for_daily.pl ├── analyze_root.pl ├── analyze_root_for_schema.pl └── ao_state │ ├── check_ao_state.sql │ ├── check_ao_state_gp7.sql │ └── create_state_table.sql ├── check_panic ├── README.txt └── check_panic.pl ├── clean_log ├── README.txt └── clean_log.pl ├── cmd_on_segdir ├── README.txt └── run_on_all_segdir.pl ├── drop_pg_temp ├── README.txt └── drop_pg_temp.sh ├── gp_healthcheck ├── README.txt ├── aobloat │ ├── check_ao_bloat.sql │ └── check_ao_bloat_gp7.sql ├── gp_check_size.pl ├── gp_healthcheck.pl ├── gp_healthcheck.py ├── gpsize │ ├── load_files_size.sql │ ├── load_files_size_cbdb.sql │ ├── load_files_size_v6.sql │ └── load_files_size_v7.sql └── skew │ ├── skewcheck_func.sql │ ├── skewcheck_func_gp6.sql │ └── skewcheck_func_gp7.sql ├── gpsize ├── README.txt ├── gp_partitiontable_size.sql ├── gp_partitiontable_size_gp7.sql ├── gpsize.sql ├── gpsize_v6.sql ├── load_files_size.sql ├── load_files_size_v6.sql └── load_files_size_v7.sql ├── gpssh-exkeys_gp6 ├── README.txt ├── gpssh-exkeys_gp6.sh └── sshpass ├── killsession ├── README.txt ├── gp_kill_idle.sh └── gp_kill_idle_gp6.sh ├── lock ├── README.txt ├── v_check_lock_tables.sql ├── v_check_lock_tables_6.sql └── v_check_lock_tables_gp7.sql ├── perl_template ├── perl_fork_test.pl └── perl_template.pl ├── pg_catalog ├── README.txt ├── catalog_monitor.pl ├── vacuum_analyze.sh └── vacuum_analyze_mproc.sh ├── show_privilege_view ├── README.txt ├── show_privelege_info.sql └── view_for_table_privilege.sql ├── skew ├── README.txt ├── skewcheck_func.sql ├── skewcheck_func_gp6.sql └── skewcheck_func_gp7.sql └── vacuum ├── README.txt ├── aobloat ├── check_ao_bloat.sql └── check_ao_bloat_gp7.sql ├── gp_reclaim_space.pl └── gp_vacuum_script.pl /README.md: -------------------------------------------------------------------------------- 1 | # gp_simpletools 2 | Some simple tools for greenplum db, tools developed include function, shell, perl etc. 3 | -------------------------------------------------------------------------------- /age/README.txt: -------------------------------------------------------------------------------- 1 | INFORMATION: 2 | Find out age>300,000,000, use vacuum freeze. 3 | 4 | vacuum_high_age_otherdb.sh: 5 | For database: gpperfmon, postgres, template1, template0 6 | 7 | vacuum_high_age.pl: 8 | Use for GP4.3.x.x 9 | Find out age>300,000,000 (Limit 8000), use vacuum freeze. Program have 3 parallel jobs. 10 | Usage: 11 | perl vacuum_high_age.pl dbname duration(hours) log_dir 12 | Program will exit when run time larger than duration(hours) 13 | Example: 14 | perl vacuum_high_age.pl testdb 2 /home/gpadmin/gpAdminLogs 15 | 16 | vacuum_high_age_5.pl: 17 | Use for GP5.x.x / GP6.x.x 18 | Find out age>300,000,000 (Limit 9000), use vacuum freeze. Program have 3 parallel jobs. 19 | Usage: 20 | perl vacuum_high_age_5.pl dbname duration(hours) log_dir 21 | Program will exit when run time larger than duration(hours) 22 | Example: 23 | perl vacuum_high_age_5.pl testdb 2 /home/gpadmin/gpAdminLogs 24 | 25 | 26 | -------------------------------------------------------------------------------- /age/vacuum_high_age.pl: -------------------------------------------------------------------------------- 1 | #!/usr/bin/perl 2 | use strict; 3 | use Time::Local; 4 | use POSIX ":sys_wait_h"; 5 | use POSIX; 6 | open(STDERR, ">&STDOUT"); 7 | $| = 1; 8 | 9 | ############################################################################################################################### 10 | #GPDB vacuum high age table. 11 | #Command line: perl vacuum_high_age.pl dbname duration(hours) log_dir 12 | #Sample: perl vacuum_high_age.pl gsdc 2 2/home/gpadmin/gpAdminLogs/ 13 | ############################################################################################################################### 14 | 15 | if ($#ARGV != 2 ) { 16 | print "Argument number Error\nExample:\nperl $0 dbname duration(hours) log_dir\n" ; 17 | exit (1) ; 18 | } 19 | my $hostname = "localhost"; 20 | my $port = "5432"; 21 | my $username = "gpadmin"; 22 | my $password = ""; 23 | my $concurrency = 3; 24 | my $database = $ARGV[0]; 25 | my $duration=$ARGV[1]; ##Program running durations(hours). If running exceed this duration, program exit 0 26 | my $log_dir=$ARGV[2]; 27 | my $AGE_LEVEL="300000000"; 28 | 29 | my $fh_log; 30 | 31 | 32 | sub set_env 33 | { 34 | $ENV{"PGHOST"}=$hostname; 35 | $ENV{"PGPORT"}=$port; 36 | $ENV{"PGDATABASE"}=$database; 37 | $ENV{"PGUSER"}=$username; 38 | $ENV{"PGPASSWORD"}=$password; 39 | 40 | `source /usr/local/greenplum-db/greenplum_path.sh`; 41 | 42 | return 0; 43 | } 44 | 45 | 46 | sub getCurrentDatetime 47 | { 48 | my ($sec,$min,$hour,$mday,$mon,$year,$wday,$yday,$isdst) = localtime(time()); 49 | my $current = ""; 50 | 51 | $year += 1900; 52 | $mon = sprintf("%02d", $mon + 1); 53 | $mday = sprintf("%02d", $mday); 54 | $hour = sprintf("%02d", $hour); 55 | $min = sprintf("%02d", $min); 56 | $sec = sprintf("%02d", $sec); 57 | $current = "${year}${mon}${mday}_${hour}${min}${sec}"; 58 | 59 | return $current; 60 | } 61 | 62 | sub getCurrentDate 63 | { 64 | my ($sec,$min,$hour,$mday,$mon,$year,$wday,$yday,$isdst) = localtime(time()); 65 | my $current = ""; 66 | 67 | $year += 1900; 68 | $mon = sprintf("%02d", $mon + 1); 69 | $mday = sprintf("%02d", $mday); 70 | $current = "${year}${mon}${mday}"; 71 | 72 | return $current; 73 | } 74 | 75 | sub showTime 76 | { 77 | my ($sec,$min,$hour,$mday,$mon,$year,$wday,$yday,$isdst) = localtime(time()); 78 | my $current = ""; 79 | 80 | $year += 1900; 81 | $mon = sprintf("%02d", $mon + 1); 82 | $mday = sprintf("%02d", $mday); 83 | $hour = sprintf("%02d", $hour); 84 | $min = sprintf("%02d", $min); 85 | $sec = sprintf("%02d", $sec); 86 | 87 | $current = "${year}-${mon}-${mday} ${hour}:${min}:${sec}"; 88 | 89 | return $current; 90 | 91 | } 92 | 93 | sub trim { 94 | my @out = @_; 95 | for (@out) { 96 | s/^\s+//; 97 | s/\s+$//; 98 | } 99 | return wantarray ? @out : $out[0]; 100 | } 101 | 102 | sub lower { 103 | my @out =@_; 104 | for (@out) { 105 | tr/[A-Z]/[a-z]/; 106 | } 107 | return wantarray ? @out : $out[0]; 108 | } 109 | 110 | 111 | 112 | sub get_tablelist{ 113 | my @target_tablelist; 114 | my @tmp_tablelist; 115 | my $ret; 116 | my $sql; 117 | 118 | ###Prepare high age tableinfo 119 | $sql = qq{ 120 | drop table if exists tmp_class_age; 121 | create table tmp_class_age as 122 | select oid as reloid,relname,age(relfrozenxid)::bigint as age_int,gp_segment_id as segid from gp_dist_random('pg_class') 123 | where relkind='r' and relstorage!='x' and age(relfrozenxid)>$AGE_LEVEL and relhassubclass=true 124 | distributed randomly; 125 | 126 | insert into tmp_class_age 127 | select oid as reloid,relname,age(relfrozenxid)::bigint as age_int,gp_segment_id from pg_class 128 | where relkind='r' and relstorage!='x' and age(relfrozenxid)>$AGE_LEVEL and relhassubclass=true; 129 | 130 | insert into tmp_class_age 131 | select oid as reloid,relname,age(relfrozenxid)::bigint as age_int,gp_segment_id as segid from gp_dist_random('pg_class') 132 | where relkind='r' and relstorage!='x' and age(relfrozenxid)>$AGE_LEVEL and relhassubclass=false and relname not like '%_1_prt_%'; 133 | 134 | insert into tmp_class_age 135 | select oid as reloid,relname,age(relfrozenxid)::bigint as age_int,gp_segment_id from pg_class 136 | where relkind='r' and relstorage!='x' and age(relfrozenxid)>$AGE_LEVEL and relhassubclass=false and relname not like '%_1_prt_%'; 137 | }; 138 | print $fh_log "[INFO]psql -A -X -t -c [".$sql."]\n"; 139 | `psql -A -X -t -c "$sql"` ; 140 | $ret=$?; 141 | if($ret) { 142 | print $fh_log "[ERROR]Get partition tablelist error [".$sql."]\n"; 143 | return -1; 144 | } 145 | 146 | ###Get high age table list 147 | $sql = qq{ 148 | select 'VACUUM FREEZE '||c.nspname||'.'||b.relname||';' from 149 | (select reloid,relname,age_int,row_number() over(partition by reloid,relname order by age_int desc) rn from tmp_class_age) a 150 | inner join pg_class b on a.reloid=b.oid and a.rn=1 151 | inner join pg_namespace c on b.relnamespace=c.oid 152 | order by age_int desc limit 8000 153 | }; 154 | print $fh_log "[INFO]psql -A -X -t -c [".$sql."]\n"; 155 | @tmp_tablelist=`psql -A -X -t -c "$sql"` ; 156 | $ret=$?; 157 | if($ret) { 158 | print $fh_log "[ERROR]Get partition tablelist error [".$sql."]\n"; 159 | return -1; 160 | } 161 | push @target_tablelist,@tmp_tablelist; 162 | 163 | ###Prepare high age tableinfo 164 | $sql = qq{ 165 | drop table if exists tmp_class_age; 166 | create table tmp_class_age as 167 | select oid as reloid,relname,age(relfrozenxid)::bigint as age_int,gp_segment_id as segid from gp_dist_random('pg_class') 168 | where relkind='r' and relstorage!='x' and age(relfrozenxid)>$AGE_LEVEL and relhassubclass=false and relname like '%_1_prt_%' 169 | distributed randomly; 170 | 171 | insert into tmp_class_age 172 | select oid as reloid,relname,age(relfrozenxid)::bigint as age_int,gp_segment_id from pg_class 173 | where relkind='r' and relstorage!='x' and age(relfrozenxid)>$AGE_LEVEL and relhassubclass=false and relname like '%_1_prt_%'; 174 | }; 175 | print $fh_log "[INFO]psql -A -X -t -c [".$sql."]\n"; 176 | `psql -A -X -t -c "$sql"` ; 177 | $ret=$?; 178 | if($ret) { 179 | print $fh_log "[ERROR]Get partition tablelist error [".$sql."]\n"; 180 | return -1; 181 | } 182 | 183 | ###Get high age table list 184 | $sql = qq{ 185 | select 'VACUUM FREEZE '||c.nspname||'.'||b.relname||';' from 186 | (select reloid,relname,age_int,row_number() over(partition by reloid,relname order by age_int desc) rn from tmp_class_age) a 187 | inner join pg_class b on a.reloid=b.oid and a.rn=1 188 | inner join pg_namespace c on b.relnamespace=c.oid 189 | order by age_int desc limit 8000 190 | }; 191 | print $fh_log "[INFO]psql -A -X -t -c [".$sql."]\n"; 192 | @tmp_tablelist=`psql -A -X -t -c "$sql"` ; 193 | $ret=$?; 194 | if($ret) { 195 | print $fh_log "[ERROR]Get partition tablelist error [".$sql."]\n"; 196 | return -1; 197 | } 198 | push @target_tablelist,@tmp_tablelist; 199 | 200 | return 0,@target_tablelist; 201 | } 202 | 203 | 204 | sub main{ 205 | #my $pid; 206 | #my $childpid; 207 | #my @childgrp; 208 | #my $icalc; 209 | #my $each_run; 210 | #my $itotal; 211 | my $sql; 212 | my $ret; 213 | my @target_tablelist; 214 | my $starttime; 215 | my $nowtime; 216 | my $t_interval; 217 | 218 | set_env(); 219 | 220 | my $logday=getCurrentDate(); 221 | my $logfile=open($fh_log, '>>', $log_dir."/vacuum_high_age_$logday.log"); 222 | unless ($logfile){ 223 | print "[ERROR]:Cound not open logfile ".$log_dir."/vacuum_high_age_$logday.log\n"; 224 | exit -1; 225 | } 226 | print $fh_log "[INFO]:Start time:".showTime()."\n"; 227 | $starttime=time(); 228 | 229 | ($ret,@target_tablelist) = get_tablelist(); 230 | if ( $ret ) { 231 | print $fh_log "[ERROR]Get high age table list error!\n"; 232 | return -1; 233 | } 234 | 235 | my $num_proc = 0; 236 | my $num_finish = 0; 237 | my $pid; 238 | #my $childpid; 239 | my $icalc; 240 | my $mainpid=$$; 241 | my $itotal=$#target_tablelist+1; 242 | print $fh_log "[INFO]Total count [".$itotal."]\n"; 243 | 244 | #if ($itotal%$concurrency==0) { 245 | # $each_run=$itotal/$concurrency; 246 | #} else { 247 | # $each_run=int($itotal/$concurrency)+1; 248 | #} 249 | 250 | ## == get the child signal,if the child process exit, then the $num_proc will reduce 1== 251 | $SIG{CHLD} = \&handler; 252 | 253 | sub handler { 254 | my $c_pid; 255 | 256 | $c_pid=$$; 257 | #print "current pid=".$c_pid."=\n"; 258 | if ($c_pid==$mainpid) { 259 | #print "I'm main, received a child process exit signal\n"; 260 | while ( waitpid(-1, WNOHANG) > 0 ) { 261 | $num_proc--; 262 | print "Retrieve a child process. num_proc=$num_proc=\n"; 263 | $num_finish++; 264 | } 265 | } 266 | return 0; 267 | } 268 | ## == get the child signal,if the child process exit, then the $num_proc will reduce 1== 269 | 270 | for ($icalc=0; $icalc<$itotal; $icalc++){ 271 | 272 | $nowtime=time(); 273 | $t_interval=$nowtime-$starttime; 274 | print $fh_log "[INFO]t_interval:[".$t_interval."]\n"; 275 | if ($t_interval>$duration*3600) { 276 | print $fh_log "[INFO]Time is up\n"; 277 | last; 278 | } 279 | 280 | $pid=fork(); 281 | if(!(defined ($pid))) { 282 | print $fh_log "[ERROR]Can not fork a child process $! \n"; 283 | exit(-1); 284 | } 285 | #$childpid=$$; 286 | 287 | if ($pid==0) { 288 | #Child process 289 | my $it; 290 | my $irun; 291 | my $sql; 292 | my $nowtime; 293 | my $t_interval; 294 | 295 | chomp($target_tablelist[$icalc]); 296 | $sql = qq{$target_tablelist[$icalc]}; 297 | print $fh_log "[INFO][SQL]=[$sql]\n"; 298 | 299 | my $tmp_result=`psql -A -X -t -c "$sql"` ; 300 | $ret=$?; 301 | if ( $ret ){ 302 | print $fh_log "[ERROR]VACUUM error: [".$sql."]\nerrmsg: [".$tmp_result."]\n"; 303 | } 304 | 305 | exit(0); 306 | } else { 307 | #Parent process 308 | $num_proc++; 309 | if ($num_finish%10 == 0) { 310 | print "Child process count [".$num_proc."], finish count[".$num_finish."/".$itotal."]\n"; 311 | } 312 | do { 313 | sleep(1); 314 | } until ( $num_proc < $concurrency ); 315 | } 316 | } 317 | 318 | if ( $num_finish<$itotal ) { 319 | my $unfinish = $itotal-$num_finish; 320 | print $fh_log "[INFO]:Waiting for ".$unfinish." unfinished child processes\n"; 321 | } 322 | #waiting for all child finished; 323 | my $ichd=0; 324 | do { 325 | while ( ($ichd=waitpid(-1, WNOHANG)) > 0 ) { $num_finish++; } 326 | sleep(1); 327 | } until ( $ichd < 0 ); 328 | 329 | return 0; 330 | } 331 | 332 | my $ret = main(); 333 | print $fh_log "[INFO]:Finish time:".showTime()."\n"; 334 | close $fh_log; 335 | exit($ret); 336 | 337 | -------------------------------------------------------------------------------- /age/vacuum_high_age_otherdb.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | source /usr/local/greenplum-db/greenplum_path.sh 4 | 5 | AGE_LEVEL=300000000 6 | DATETIME=`date +%Y-%m-%d\ %H:%M:%S` 7 | echo "Start time: " ${DATETIME} 8 | 9 | echo "Checking another database " 10 | psql -d postgres -a <${AGE_LEVEL} and datname in ('postgres','template1','gpperfmon') 15 | distributed randomly; 16 | 17 | insert into tmp_db_age select datname,datfrozenxid,age(datfrozenxid) from pg_database 18 | where age(datfrozenxid)>${AGE_LEVEL} and datname in ('postgres','template1','gpperfmon'); 19 | 20 | copy ( 21 | select 'vacuumdb '||datname||';' from tmp_db_age group by 1 22 | ) to '/tmp/.age_vacuumdb.sh'; 23 | 24 | EOF 25 | 26 | sh /tmp/.age_vacuumdb.sh 27 | 28 | echo "Checking template0 " 29 | psql -d postgres -a <${AGE_LEVEL} and datname in ('template0') 34 | distributed randomly; 35 | 36 | insert into tmp_t0_age select datname,datfrozenxid,age(datfrozenxid) from pg_database 37 | where age(datfrozenxid)>${AGE_LEVEL} and datname in ('template0'); 38 | 39 | copy ( 40 | select 'set allow_system_table_mods=DML;update pg_database set datallowconn=true where datname=''template0'';' 41 | from tmp_t0_age group by 1 42 | ) to '/tmp/.upd_template0.sql'; 43 | 44 | copy ( 45 | select 'vacuum freeze;set allow_system_table_mods=DML;update pg_database set datallowconn=false where datname=''template0'';' 46 | from tmp_t0_age group by 1 47 | ) to '/tmp/.va_template0.sql'; 48 | 49 | copy ( 50 | select 'PGOPTIONS=''-c gp_session_role=utility'' psql -h '||hostname||' -p '||port||' -d postgres -af /tmp/.upd_template0.sql' 51 | from gp_segment_configuration where role='p' 52 | ) to '/tmp/.upd_t0_per_ins.sh'; 53 | 54 | copy ( 55 | select 'PGOPTIONS=''-c gp_session_role=utility'' psql -h '||hostname||' -p '||port||' -d template0 -af /tmp/.va_template0.sql' 56 | from gp_segment_configuration where role='p' 57 | ) to '/tmp/.va_t0_per_ins.sh'; 58 | 59 | EOF 60 | 61 | CHK_T0=`cat /tmp/.upd_template0.sql |wc -l` 62 | if [ $CHK_T0 -eq "1" ]; 63 | then 64 | sh /tmp/.upd_t0_per_ins.sh 65 | sh /tmp/.va_t0_per_ins.sh 66 | fi 67 | 68 | 69 | DATETIME=`date +%Y-%m-%d\ %H:%M:%S` 70 | echo "Finish time: " ${DATETIME} 71 | 72 | 73 | -------------------------------------------------------------------------------- /analyze/README.txt: -------------------------------------------------------------------------------- 1 | ------------------------- 2 | ao_state: 3 | 4 | Function install: 5 | psql -d dbname -af ./ao_state/check_ao_state.sql 6 | 7 | Example: 8 | select * from get_AOtable_state_list('(''schemaname1'',''schemaname2'')'); 9 | select * from get_AOtable_state_list(); 10 | 11 | Information: 12 | Use this function to check AO table states. (Not for heap table) 13 | If data in AOtable is changed (include: insert,update,delete,alter table reorganize), modcount will be changed. 14 | 15 | 16 | Create state table: 17 | psql -d dbname -af ./ao_state/create_state_table.sql 18 | Table check_ao_state is used to record each AOtable's modcount. 19 | 20 | 21 | ------------------------- 22 | analyze_for_daily.pl 23 | 24 | Example: 25 | perl analyze_for_daily.pl dbname schemaname concurrency 26 | 27 | Information: 28 | If schemaname=ALL, scan all schema in database for analyze 29 | You can specified mutli schema , for example: perl analyze_for_daily.pl dbname public,dw,ods 10 30 | This program skip rootpartition analyze. It will analyze all heap table, and AOtable is changed in schema. 31 | This program can be setting in crontab, running every day. 32 | 33 | 34 | analyze_root_for_schema.pl (Old version) 35 | 36 | 37 | analyze_root.pl 38 | 39 | Example: 40 | perl analyze_root.pl dbname schema concurrency 41 | 42 | Information: 43 | If schemaname=ALL, scan all schema in database for analyze 44 | You can specified mutli schema. 45 | For example: perl analyze_root.pl dbname ALL 10 46 | perl analyze_root.pl dbname public,dw,ods 10 47 | This program only analyze rootpartition tables. 48 | This program can be setting in crontab, running weekly or monthly. 49 | 50 | 51 | 52 | -------------------------------------------------------------------------------- /analyze/analyze_for_daily.pl: -------------------------------------------------------------------------------- 1 | #!/usr/bin/perl 2 | use POSIX qw(strftime); 3 | use strict; 4 | use Time::Local; 5 | use POSIX ":sys_wait_h"; 6 | use POSIX; 7 | open(STDERR, ">&STDOUT"); 8 | 9 | 10 | if ($#ARGV != 2 ) { 11 | print "Argument number Error\nExample:\nperl $0 dbname schemaname concurrency\nIf schemaname=ALL, all schema will be analyzed!\n" ; 12 | exit (1) ; 13 | } 14 | 15 | my ($hostname,$port,$username,$password,$database ); 16 | $database=$ARGV[0]; 17 | $username=`whoami`; 18 | chomp($username); 19 | my $inputschema=$ARGV[1]; 20 | my $currdatetime=getCurrDateTime(); 21 | my $concurrency=$ARGV[2]; 22 | 23 | my $num_proc = 0; 24 | my $num_finish = 0; 25 | my $mainpid=$$; 26 | 27 | 28 | my $exclude_schema=qq{ 29 | 'gp_toolkit' 30 | ,'ngpaatmpdata' 31 | ,'pg_toast' 32 | ,'pg_bitmapindex' 33 | ,'pg_catalog' 34 | ,'public' 35 | ,'information_schema' 36 | ,'gpexpand' 37 | ,'pg_aoseg' 38 | ,'oracompat' 39 | ,'monitor_old' 40 | ,'tmp_gpexport_copy' 41 | ,'stage' 42 | ,'tmp_job' 43 | ,'tmp' 44 | ,'monitor' 45 | ,'monitor_old' 46 | ,'workfile' 47 | ,'session_state' 48 | }; 49 | 50 | 51 | 52 | sub set_env 53 | { 54 | $ENV{"PGHOST"}="localhost"; 55 | #$ENV{"PGPORT"}="5432"; 56 | $ENV{"PGDATABASE"}=$database; 57 | $ENV{"PGUSER"}=$username; 58 | $ENV{"PGPASSWORD"}=""; 59 | 60 | return 0; 61 | } 62 | 63 | sub getCurrDateTime{ 64 | my ($sec,$min,$hour,$mday,$mon,$year,$wday,$yday,$isdst) = localtime(time()-86400); 65 | $year += 1900; 66 | $mon = sprintf("%02d", $mon + 1); 67 | $mday = sprintf("%02d", $mday); 68 | $hour = sprintf("%02d", $hour); 69 | $min = sprintf("%02d", $min); 70 | $sec = sprintf("%02d", $sec); 71 | return "${year}${mon}${mday}${hour}${min}${sec}"; 72 | } 73 | 74 | sub get_schema 75 | { 76 | my $tmpsss; 77 | my $curr_schema; 78 | my $sql; 79 | my $ret; 80 | 81 | if ($inputschema eq "ALL") { 82 | $sql = qq{ select string_agg(''''||nspname||'''',',' ) from pg_namespace 83 | where nspname not like 'pg%' and nspname not like 'gp%' and 84 | nspname not in ($exclude_schema); }; 85 | $tmpsss=`psql -A -X -t -c "$sql" 2>/dev/null` ; 86 | $ret=$?>>8; 87 | if($ret) { 88 | print "psql get all schema error\n"; 89 | exit -1; 90 | } 91 | chomp($tmpsss); 92 | $curr_schema = "($tmpsss)"; 93 | 94 | } else { 95 | $tmpsss = $inputschema; 96 | $tmpsss =~ s/,/\',\'/g; 97 | $curr_schema = "('$tmpsss')"; 98 | 99 | } 100 | 101 | print "analyze schema [".$curr_schema."]\n"; 102 | return $curr_schema; 103 | 104 | } 105 | 106 | sub getWeekday{ 107 | 108 | my ($sec,$min,$hour,$dd,$mm,$yyyy,$wday,$yday,$isdst) = localtime(time()); 109 | $yyyy += 1900; 110 | $mm = sprintf("%02d", $mm + 1); 111 | $dd = sprintf("%02d", $dd); 112 | 113 | my $epoch_seconds=timelocal(0,0,0,$dd,$mm-1,$yyyy); 114 | my $weekDay= strftime("%u",localtime($epoch_seconds)); 115 | 116 | return $weekDay; 117 | } 118 | 119 | sub get_tablelist{ 120 | my ($curr_schema)=@_; 121 | my @target_tablelist; 122 | my @tmp_tablelist; 123 | my $ret; 124 | my $sql; 125 | my $tmp_schemastr; 126 | 127 | $tmp_schemastr = $curr_schema; 128 | $tmp_schemastr =~ s/\'/\'\'/g; 129 | print "tmp_schemastr[".$tmp_schemastr."]\n"; 130 | 131 | 132 | ###Heap table list 133 | $sql = qq{ select 'analyze '||aa.nspname||'.'||bb.relname||';' 134 | from pg_namespace aa inner join pg_class bb on aa.oid=bb.relnamespace 135 | left join pg_stat_last_operation o on bb.oid=o.objid and o.staactionname='ANALYZE' 136 | where aa.nspname in ${curr_schema} and bb.relkind='r' and bb.relstorage='h' and bb.relhassubclass=false 137 | and ((o.statime is null) or ((o.statime is not null) and (now() - o.statime > interval '3 day'))); 138 | }; 139 | @tmp_tablelist=`psql -A -X -t -c "$sql"`; 140 | $ret=$?; 141 | if($ret) { 142 | print "Get heap table list error =$sql=\n"; 143 | return -1; 144 | } 145 | push @target_tablelist,@tmp_tablelist; 146 | 147 | 148 | ###AO table list 149 | $sql = qq{ drop table if exists analyze_target_list_${currdatetime}; 150 | create table analyze_target_list_${currdatetime} (like check_ao_state); 151 | 152 | insert into analyze_target_list_${currdatetime} 153 | select *,current_timestamp from get_AOtable_state_list('${tmp_schemastr}') a; 154 | 155 | create temp table ao_analyze_stat_temp ( 156 | reloid bigint, 157 | schemaname text, 158 | tablename text, 159 | statime timestamp without time zone 160 | ) distributed by (reloid); 161 | 162 | insert into ao_analyze_stat_temp 163 | select objid,schemaname,objname,statime from pg_stat_operations op 164 | inner join ( 165 | select reloid,last_checktime,row_number() over(partition by reloid order by last_checktime desc) rn 166 | from check_ao_state 167 | ) aost 168 | on op.objid=aost.reloid 169 | where op.actionname='ANALYZE' and aost.rn=1 and op.statime>=aost.last_checktime; 170 | 171 | select 'analyze '||schemaname||'.'||tablename||';' from 172 | ( 173 | select a.reloid,a.schemaname,a.tablename 174 | from check_ao_state a,analyze_target_list_${currdatetime} b 175 | where a.reloid=b.reloid and a.modcount<>b.modcount 176 | union all 177 | select b.reloid,b.schemaname,b.tablename 178 | from analyze_target_list_${currdatetime} b 179 | where b.reloid not in (select reloid from check_ao_state) 180 | ) t1 181 | where t1.reloid not in (select reloid from ao_analyze_stat_temp); 182 | }; 183 | print "psql -A -X -t -q -c \"$sql\" \n"; 184 | @tmp_tablelist=`psql -A -X -t -q -c "$sql" 2>/dev/null`; ####Use -q :run quietly (no messages, only query output) 185 | $ret=$?; 186 | if($ret) { 187 | print "Get AO table list error =$sql=\n"; 188 | return -1; 189 | } 190 | push @target_tablelist,@tmp_tablelist; 191 | 192 | return 0,@target_tablelist; 193 | } 194 | 195 | sub run_after_analyze{ 196 | my ($curr_schema)=@_; 197 | my $sql; 198 | my $ret; 199 | my $tmp_schemastr; 200 | 201 | ${tmp_schemastr} = ${curr_schema}; 202 | ${tmp_schemastr} =~ s/\'/\'\'/g; 203 | print "tmp_schemastr[".$tmp_schemastr."]\n"; 204 | 205 | $sql = qq{ delete from check_ao_state a 206 | using analyze_target_list_${currdatetime} b where a.reloid=b.reloid; 207 | delete from check_ao_state a 208 | where reloid not in (select oid from pg_class); 209 | 210 | insert into check_ao_state 211 | select reloid,schemaname,tablename,modcount,current_timestamp from analyze_target_list_${currdatetime} a; 212 | 213 | drop table if exists analyze_target_list_${currdatetime}; 214 | }; 215 | print "psql -A -X -t -c \"$sql\" \n"; 216 | `psql -A -X -t -c "$sql"` ; 217 | $ret=$?; 218 | if($ret) { 219 | print "psql refresh AO table state error =$sql=\n"; 220 | return -1; 221 | } 222 | 223 | $sql = qq{ vacuum analyze check_ao_state; }; 224 | `psql -A -X -t -c "$sql"` ; 225 | $ret=$?; 226 | if($ret) { 227 | print "vacuum analyze check_ao_state error\n"; 228 | return -1; 229 | } 230 | 231 | return 0; 232 | } 233 | 234 | 235 | 236 | ## == get the child signal,if the child process exit, then the $num_proc will reduce 1== 237 | $SIG{CHLD} = \&handler; 238 | 239 | sub handler { 240 | my $c_pid; 241 | 242 | $c_pid=$$; 243 | if ($c_pid==$mainpid) { 244 | if ($num_proc==0) { return 0; } 245 | while ( waitpid(-1, WNOHANG) > 0 ) { 246 | $num_proc--; 247 | $num_finish++; 248 | } 249 | } 250 | return 0; 251 | } 252 | ## == get the child signal,if the child process exit, then the $num_proc will reduce 1== 253 | 254 | 255 | 256 | sub main{ 257 | my $pid; 258 | my $icalc; 259 | my $itotal; 260 | my $sql; 261 | my $ret; 262 | my @target_tablelist; 263 | my $childpid; 264 | 265 | 266 | set_env(); 267 | my $analyze_schema = get_schema(); 268 | print $analyze_schema."\n"; 269 | ($ret,@target_tablelist) = get_tablelist($analyze_schema); 270 | if ( $ret ) { 271 | print "Get table list for analyze error!\n"; 272 | return -1; 273 | } 274 | 275 | $itotal=$#target_tablelist+1; 276 | print "Total count [".$itotal."]\n"; 277 | 278 | for ($icalc=0; $icalc<$itotal;$icalc++){ 279 | 280 | $pid=fork(); 281 | if(!(defined ($pid))) { 282 | print "Can not fork a child process!!!\n$!\n"; 283 | exit(-1); 284 | } 285 | $childpid=$$; 286 | 287 | if ($pid==0) { 288 | #Child process 289 | my $it; 290 | my $irun; 291 | my $sql; 292 | 293 | chomp($target_tablelist[$icalc]); 294 | $sql = $target_tablelist[$icalc]; 295 | print "[SQL]=[$sql]\n"; 296 | 297 | my $tmp_result=`psql -A -X -t -c "$sql" 2>&1` ; 298 | $ret=$?; 299 | if ( $ret ){ 300 | print "Analyze error: ".$sql."\n".$tmp_result; 301 | } 302 | 303 | exit(0); 304 | } else { 305 | #Parent process 306 | $num_proc++; 307 | if ($num_finish%10 == 0) { 308 | print "Child process count [".$num_proc."], finish count[".$num_finish."/".$itotal."]\n"; 309 | } 310 | do { 311 | sleep(1); 312 | } until ( $num_proc < $concurrency ); 313 | } 314 | } 315 | 316 | print "waiting for all child finished!\n"; 317 | my $ichd=0; 318 | do { 319 | while ( ($ichd=waitpid(-1, WNOHANG)) > 0 ) { $num_finish++; } 320 | sleep(3); 321 | } until ( $ichd < 0 ); 322 | 323 | 324 | run_after_analyze($analyze_schema); 325 | 326 | return 0; 327 | } 328 | 329 | 330 | 331 | 332 | my $ret = main(); 333 | exit($ret); 334 | 335 | 336 | -------------------------------------------------------------------------------- /analyze/analyze_root.pl: -------------------------------------------------------------------------------- 1 | #!/usr/bin/perl 2 | use strict; 3 | use Time::Local; 4 | use File::Basename; 5 | use warnings; 6 | use POSIX ":sys_wait_h"; 7 | use POSIX; 8 | open(STDERR, ">&STDOUT"); 9 | 10 | if ($#ARGV != 2 ) { 11 | print "Argument number Error\nExample:\nperl $0 dbname schema concurrency\n" ; 12 | exit (1) ; 13 | } 14 | 15 | my ($hostname,$port,$username,$password,$database ); 16 | $database=$ARGV[0]; 17 | $username=`whoami`; 18 | chomp($username); 19 | my $inputschema=$ARGV[1]; 20 | my $concurrency=$ARGV[2]; 21 | 22 | my $num_proc = 0; 23 | my $num_finish = 0; 24 | my $mainpid=$$; 25 | 26 | 27 | my $exclude_schema=qq{ 28 | 'gp_toolkit' 29 | ,'ngpaatmpdata' 30 | ,'pg_toast' 31 | ,'pg_bitmapindex' 32 | ,'pg_catalog' 33 | ,'public' 34 | ,'information_schema' 35 | ,'gpexpand' 36 | ,'pg_aoseg' 37 | ,'oracompat' 38 | ,'monitor_old' 39 | ,'tmp_gpexport_copy' 40 | ,'stage' 41 | ,'tmp_job' 42 | ,'tmp' 43 | ,'monitor' 44 | ,'monitor_old' 45 | ,'workfile' 46 | ,'session_state' 47 | }; 48 | 49 | 50 | sub set_env 51 | { 52 | $ENV{"PGHOST"}="localhost"; 53 | #$ENV{"PGPORT"}="5432"; 54 | $ENV{"PGDATABASE"}=$database; 55 | $ENV{"PGUSER"}=$username; 56 | $ENV{"PGPASSWORD"}=""; 57 | 58 | return 0; 59 | } 60 | 61 | 62 | sub get_schema 63 | { 64 | my $tmpsss; 65 | my $curr_schema; 66 | my $sql; 67 | my $ret; 68 | 69 | if ($inputschema eq "ALL") { 70 | $sql = qq{ select string_agg(''''||nspname||'''',',' ) from pg_namespace 71 | where nspname not like 'pg%' and nspname not like 'gp%' and 72 | nspname not in ($exclude_schema); }; 73 | $tmpsss=`psql -A -X -t -c "$sql" 2>/dev/null` ; 74 | $ret=$?>>8; 75 | if($ret) { 76 | print "psql get all schema error\n"; 77 | exit -1; 78 | } 79 | chomp($tmpsss); 80 | $curr_schema = "($tmpsss)"; 81 | 82 | } else { 83 | $tmpsss = $inputschema; 84 | $tmpsss =~ s/,/\',\'/g; 85 | $curr_schema = "('$tmpsss')"; 86 | 87 | } 88 | 89 | print "analyze schema [".$curr_schema."]\n"; 90 | return $curr_schema; 91 | 92 | } 93 | 94 | 95 | sub get_tablelist{ 96 | my ($curr_schema)=@_; 97 | my @tmp_tablelist; 98 | my $ret; 99 | my $sql; 100 | 101 | ###root partition 102 | $sql = qq{ select 'analyze rootpartition '||aa.nspname||'.'||bb.relname||';' 103 | from pg_namespace aa,pg_class bb 104 | where aa.oid=bb.relnamespace and aa.nspname in ${curr_schema} 105 | and bb.relkind='r' and bb.relstorage!='x' and bb.relhassubclass=true; }; 106 | print "psql -A -X -t -c \"$sql\" \n"; 107 | @tmp_tablelist=`psql -A -X -t -c "$sql"`; 108 | $ret=$? >> 8; 109 | if($ret) { 110 | print "Get rootpartition error \n"; 111 | return -1; 112 | } 113 | 114 | return 0,@tmp_tablelist; 115 | } 116 | 117 | 118 | ## == get the child signal,if the child process exit, then the $num_proc will reduce 1== 119 | $SIG{CHLD} = \&handler; 120 | 121 | sub handler { 122 | my $c_pid; 123 | 124 | $c_pid=$$; 125 | if ($c_pid==$mainpid) { 126 | if ($num_proc==0) { return 0; } 127 | while ( waitpid(-1, WNOHANG) > 0 ) { 128 | $num_proc--; 129 | $num_finish++; 130 | } 131 | } 132 | return 0; 133 | } 134 | ## == get the child signal,if the child process exit, then the $num_proc will reduce 1== 135 | 136 | 137 | ############################################################################################ 138 | ########################################Main funcion######################################## 139 | ############################################################################################ 140 | sub main{ 141 | my $pid; 142 | my $icalc; 143 | my $itotal; 144 | my $sql; 145 | my $ret; 146 | my @target_tablelist; 147 | my $childpid; 148 | 149 | 150 | set_env(); 151 | 152 | my $analyze_schema = get_schema(); 153 | print $analyze_schema."\n"; 154 | ($ret,@target_tablelist) = get_tablelist($analyze_schema); 155 | if ( $ret ) { 156 | print "Get table list for analyze error!\n"; 157 | return -1; 158 | } 159 | 160 | $itotal=$#target_tablelist+1; 161 | print "Total count [".$itotal."]\n"; 162 | 163 | for ($icalc=0; $icalc<$itotal;$icalc++){ 164 | 165 | $pid=fork(); 166 | if(!(defined ($pid))) { 167 | print "Can not fork a child process!!!\n$!\n"; 168 | exit(-1); 169 | } 170 | $childpid=$$; 171 | 172 | if ($pid==0) { 173 | #Child process 174 | my $it; 175 | my $irun; 176 | my $sql; 177 | my $where_str; 178 | 179 | chomp($target_tablelist[$icalc]); 180 | $sql = $target_tablelist[$icalc]; 181 | print "[SQL]=[$sql]\n"; 182 | 183 | my $tmp_result=`psql -A -X -t -c "$sql" 2>&1` ; 184 | $ret=$?; 185 | if ( $ret ){ 186 | print "Analyze error: ".$tmp_result."\n"; 187 | } 188 | 189 | exit(0); 190 | } else { 191 | #Parent process 192 | $num_proc++; 193 | if ($num_finish%10 == 0) { 194 | print "Child process count [".$num_proc."], finish count[".$num_finish."/".$itotal."]\n"; 195 | } 196 | do { 197 | sleep(1); 198 | } until ( $num_proc < $concurrency ); 199 | } 200 | } 201 | 202 | print "waiting for all child finished!\n"; 203 | my $ichd=0; 204 | do { 205 | while ( ($ichd=waitpid(-1, WNOHANG)) > 0 ) { $num_finish++; } 206 | sleep(3); 207 | } until ( $ichd < 0 ); 208 | 209 | return 0; 210 | } 211 | 212 | 213 | 214 | my $ret = main(); 215 | exit($ret); 216 | 217 | 218 | -------------------------------------------------------------------------------- /analyze/analyze_root_for_schema.pl: -------------------------------------------------------------------------------- 1 | #!/usr/bin/perl 2 | use strict; 3 | use Time::Local; 4 | use File::Basename; 5 | use warnings; 6 | use Switch; 7 | use POSIX ":sys_wait_h"; 8 | use POSIX; 9 | open(STDERR, ">&STDOUT"); 10 | 11 | if ($#ARGV != 2 ) { 12 | print "Argument number Error\nExample:\nperl $0 dbname schema concurrency\n" ; 13 | exit (1) ; 14 | } 15 | 16 | my $database = $ARGV[0]; 17 | my $schemaname = $ARGV[1]; 18 | my $concurrency = $ARGV[2]; 19 | 20 | 21 | sub set_env 22 | { 23 | $ENV{"PGHOST"}="localhost"; 24 | $ENV{"PGDATABASE"}=$database; 25 | $ENV{"PGUSER"}="gpadmin"; 26 | $ENV{"PGPASSWORD"}="gpadmin"; 27 | 28 | return 0; 29 | } 30 | 31 | sub get_tablelist{ 32 | my $curr_schema; 33 | my @tmp_tablelist; 34 | my $ret; 35 | my $sql; 36 | 37 | ###root partition 38 | if ( $schemaname eq "ALL" ) { 39 | $sql = qq{ select 'analyze rootpartition '||aa.nspname||'.'||bb.relname||';' 40 | from pg_namespace aa,pg_class bb 41 | where aa.oid=bb.relnamespace and aa.nspname not like 'pg%' and aa.nspname not like 'gp%' 42 | and bb.relkind='r' and bb.relstorage!='x' 43 | and bb.relhassubclass=true; }; 44 | print "psql -A -X -t -c \"$sql\" \n"; 45 | @tmp_tablelist=`psql -A -X -t -c "$sql"`; 46 | $ret=$? >> 8; 47 | if($ret) { 48 | print "psql ALL rootpartition error \n"; 49 | return -1; 50 | } 51 | } else { 52 | my $tmpsss=$schemaname; 53 | $tmpsss =~ s/,/\',\'/g; 54 | $curr_schema = "('$tmpsss')"; 55 | $sql = qq{ select 'analyze rootpartition '||aa.nspname||'.'||bb.relname||';' 56 | from pg_namespace aa,pg_class bb 57 | where aa.oid=bb.relnamespace and aa.nspname in ${curr_schema} 58 | and bb.relkind='r' and bb.relstorage!='x' 59 | and bb.relhassubclass=true; }; 60 | print "psql -A -X -t -c \"$sql\" \n"; 61 | @tmp_tablelist=`psql -A -X -t -c "$sql"` ; 62 | $ret=$? >> 8; 63 | if($ret) { 64 | print "psql rootpartition error \n"; 65 | return -1; 66 | } 67 | } 68 | 69 | return 0,@tmp_tablelist; 70 | } 71 | 72 | 73 | 74 | ############################################################################################ 75 | ########################################Main funcion######################################## 76 | ############################################################################################ 77 | my $num_proc = 0; 78 | my $num_finish = 0; 79 | my $pid; 80 | my $childpid; 81 | my $mainpid=$$; 82 | 83 | my $icalc; 84 | my $itotal; 85 | my $sql; 86 | my $ret; 87 | my @target_tablelist; 88 | 89 | 90 | set_env(); 91 | 92 | ($ret,@target_tablelist) = get_tablelist(); 93 | if ( $ret ) { 94 | print "Get table list for analyze error!\n"; 95 | exit -1; 96 | } 97 | 98 | $itotal=$#target_tablelist+1; 99 | print "Total count [".$itotal."]\n"; 100 | 101 | 102 | 103 | 104 | ## == get the child signal,if the child process exit, then the $num_proc will reduce 1== 105 | $SIG{CHLD} = \&handler; 106 | 107 | sub handler { 108 | my $c_pid; 109 | 110 | $c_pid=$$; 111 | if ($c_pid==$mainpid) { 112 | while ( waitpid(-1, WNOHANG) > 0 ) { 113 | $num_proc--; 114 | $num_finish++; 115 | } 116 | } 117 | return 0; 118 | } 119 | ## == get the child signal,if the child process exit, then the $num_proc will reduce 1== 120 | 121 | 122 | 123 | for ($icalc=0; $icalc<$itotal;$icalc++){ 124 | 125 | $pid=fork(); 126 | if(!(defined ($pid))) { 127 | print "Can not fork a child process!!!\n$!\n"; 128 | exit(-1); 129 | } 130 | #$childpid=$$; 131 | 132 | if ($pid==0) { 133 | #Child process 134 | my $it; 135 | my $irun; 136 | my $sql; 137 | my $where_str; 138 | 139 | chomp($target_tablelist[$icalc]); 140 | $sql = $target_tablelist[$icalc]; 141 | print "[SQL]=[$sql]\n"; 142 | 143 | my $tmp_result=`psql -A -X -t -c "$sql" 2>&1` ; 144 | $ret=$?; 145 | if ( $ret ){ 146 | print "Analyze error: ".$tmp_result."\n"; 147 | } 148 | 149 | exit(0); 150 | } else { 151 | #Parent process 152 | $num_proc++; 153 | if ($num_finish%10 == 0) { 154 | print "Child process count [".$num_proc."], finish count[".$num_finish."/".$itotal."]\n"; 155 | } 156 | do { 157 | sleep(1); 158 | } until ( $num_proc < $concurrency ); 159 | } 160 | } 161 | 162 | 163 | #waiting for all child finished; 164 | my $ichd=0; 165 | do { 166 | while ( ($ichd=waitpid(-1, WNOHANG)) > 0 ) { $num_finish++; } 167 | sleep(3); 168 | } until ( $ichd < 0 ); 169 | 170 | 171 | exit 0; 172 | -------------------------------------------------------------------------------- /analyze/ao_state/check_ao_state.sql: -------------------------------------------------------------------------------- 1 | CREATE TYPE type_AOtable_state as (reloid bigint,schemaname text,tablename text,modcount bigint); 2 | 3 | CREATE OR REPLACE FUNCTION get_AOtable_state_list(in_schemaname text) 4 | RETURNS SETOF type_AOtable_state AS 5 | $$ 6 | declare 7 | v_record type_AOtable_state%rowtype; 8 | i_oid bigint; 9 | v_schema text; 10 | v_table text; 11 | v_tuple text; 12 | v_sql text; 13 | v_sql2 text; 14 | BEGIN 15 | 16 | v_sql2 := ' 17 | SELECT ALL_DATA_TABLES.oid,ALL_DATA_TABLES.schemaname, ALL_DATA_TABLES.tablename, OUTER_PG_CLASS.relname as tupletable FROM ( 18 | SELECT ALLTABLES.oid, ALLTABLES.schemaname, ALLTABLES.tablename FROM 19 | 20 | (SELECT c.oid, n.nspname AS schemaname, c.relname AS tablename FROM pg_class c, pg_namespace n 21 | WHERE n.oid = c.relnamespace) as ALLTABLES, 22 | 23 | (SELECT n.nspname AS schemaname, c.relname AS tablename 24 | FROM pg_class c LEFT JOIN pg_namespace n ON n.oid = c.relnamespace 25 | LEFT JOIN pg_tablespace t ON t.oid = c.reltablespace 26 | WHERE c.relkind = ''r''::char AND c.oid > 16384 AND (c.relnamespace > 16384 or n.nspname = ''public'') 27 | EXCEPT 28 | ((SELECT x.schemaname, x.partitiontablename FROM 29 | (SELECT distinct schemaname, tablename, partitiontablename, partitionlevel FROM pg_partitions) as X, 30 | (SELECT schemaname, tablename maxtable, max(partitionlevel) maxlevel FROM pg_partitions group by (tablename, schemaname)) as Y 31 | WHERE x.schemaname = y.schemaname and x.tablename = Y.maxtable and x.partitionlevel != Y.maxlevel) 32 | UNION (SELECT distinct schemaname, tablename FROM pg_partitions))) as DATATABLES 33 | 34 | WHERE ALLTABLES.schemaname = DATATABLES.schemaname and ALLTABLES.tablename = DATATABLES.tablename 35 | AND ALLTABLES.oid not in (select reloid from pg_exttable) AND ALLTABLES.schemaname NOT LIKE ''pg_temp_%'' 36 | ) as ALL_DATA_TABLES, pg_appendonly, pg_class OUTER_PG_CLASS 37 | WHERE ALL_DATA_TABLES.oid = pg_appendonly.relid 38 | AND OUTER_PG_CLASS.oid = pg_appendonly.segrelid 39 | AND pg_appendonly.columnstore = ''f'' 40 | AND ALL_DATA_TABLES.schemaname in '||in_schemaname||' 41 | 42 | UNION ALL 43 | 44 | SELECT ALL_DATA_TABLES.oid,ALL_DATA_TABLES.schemaname, ALL_DATA_TABLES.tablename, OUTER_PG_CLASS.relname as tupletable FROM ( 45 | SELECT ALLTABLES.oid, ALLTABLES.schemaname, ALLTABLES.tablename FROM 46 | 47 | (SELECT c.oid, n.nspname AS schemaname, c.relname AS tablename FROM pg_class c, pg_namespace n 48 | WHERE n.oid = c.relnamespace) as ALLTABLES, 49 | 50 | (SELECT n.nspname AS schemaname, c.relname AS tablename 51 | FROM pg_class c LEFT JOIN pg_namespace n ON n.oid = c.relnamespace 52 | LEFT JOIN pg_tablespace t ON t.oid = c.reltablespace 53 | WHERE c.relkind = ''r''::char AND c.oid > 16384 AND (c.relnamespace > 16384 or n.nspname = ''public'') 54 | EXCEPT 55 | ((SELECT x.schemaname, x.partitiontablename FROM 56 | (SELECT distinct schemaname, tablename, partitiontablename, partitionlevel FROM pg_partitions) as X, 57 | (SELECT schemaname, tablename maxtable, max(partitionlevel) maxlevel FROM pg_partitions group by (tablename, schemaname)) as Y 58 | WHERE x.schemaname = y.schemaname and x.tablename = Y.maxtable and x.partitionlevel != Y.maxlevel) 59 | UNION (SELECT distinct schemaname, tablename FROM pg_partitions))) as DATATABLES 60 | 61 | WHERE ALLTABLES.schemaname = DATATABLES.schemaname and ALLTABLES.tablename = DATATABLES.tablename 62 | AND ALLTABLES.oid not in (select reloid from pg_exttable) AND ALLTABLES.schemaname NOT LIKE ''pg_temp_%'' 63 | ) as ALL_DATA_TABLES, pg_appendonly, pg_class OUTER_PG_CLASS 64 | WHERE ALL_DATA_TABLES.oid = pg_appendonly.relid 65 | AND OUTER_PG_CLASS.oid = pg_appendonly.segrelid 66 | AND pg_appendonly.columnstore = ''t'' 67 | AND ALL_DATA_TABLES.schemaname in '||in_schemaname; 68 | 69 | for i_oid,v_schema,v_table,v_tuple in 70 | execute v_sql2 71 | loop 72 | v_record.reloid := i_oid; 73 | v_record.schemaname := v_schema; 74 | v_record.tablename := v_table; 75 | 76 | BEGIN 77 | v_sql := 'select coalesce(sum(modcount::bigint), 0) from pg_aoseg.'||v_tuple; 78 | --raise info 'sql=%=',v_sql; 79 | execute v_sql into v_record.modcount; 80 | EXCEPTION WHEN undefined_table THEN 81 | raise info 'WARNING: pg_aoseg.% does not exist, skipped!',v_tuple; 82 | continue; 83 | END; 84 | 85 | return next v_record; 86 | end loop; 87 | return; 88 | 89 | END; 90 | $$ 91 | LANGUAGE plpgsql; 92 | 93 | 94 | 95 | CREATE OR REPLACE FUNCTION get_AOtable_state_list() 96 | RETURNS SETOF type_AOtable_state AS 97 | $$ 98 | declare 99 | v_record type_AOtable_state%rowtype; 100 | i_oid bigint; 101 | v_schema text; 102 | v_table text; 103 | v_tuple text; 104 | v_sql text; 105 | BEGIN 106 | 107 | for i_oid,v_schema,v_table,v_tuple in 108 | SELECT ALL_DATA_TABLES.oid,ALL_DATA_TABLES.schemaname, ALL_DATA_TABLES.tablename, OUTER_PG_CLASS.relname as tupletable FROM ( 109 | SELECT ALLTABLES.oid, ALLTABLES.schemaname, ALLTABLES.tablename FROM 110 | 111 | (SELECT c.oid, n.nspname AS schemaname, c.relname AS tablename FROM pg_class c, pg_namespace n 112 | WHERE n.oid = c.relnamespace) as ALLTABLES, 113 | 114 | (SELECT n.nspname AS schemaname, c.relname AS tablename 115 | FROM pg_class c LEFT JOIN pg_namespace n ON n.oid = c.relnamespace 116 | LEFT JOIN pg_tablespace t ON t.oid = c.reltablespace 117 | WHERE c.relkind = 'r'::char AND c.oid > 16384 AND (c.relnamespace > 16384 or n.nspname = 'public') 118 | EXCEPT 119 | ((SELECT x.schemaname, x.partitiontablename FROM 120 | (SELECT distinct schemaname, tablename, partitiontablename, partitionlevel FROM pg_partitions) as X, 121 | (SELECT schemaname, tablename maxtable, max(partitionlevel) maxlevel FROM pg_partitions group by (tablename, schemaname)) as Y 122 | WHERE x.schemaname = y.schemaname and x.tablename = Y.maxtable and x.partitionlevel != Y.maxlevel) 123 | UNION (SELECT distinct schemaname, tablename FROM pg_partitions))) as DATATABLES 124 | 125 | WHERE ALLTABLES.schemaname = DATATABLES.schemaname and ALLTABLES.tablename = DATATABLES.tablename 126 | AND ALLTABLES.oid not in (select reloid from pg_exttable) AND ALLTABLES.schemaname NOT LIKE 'pg_temp_%' 127 | ) as ALL_DATA_TABLES, pg_appendonly, pg_class OUTER_PG_CLASS 128 | WHERE ALL_DATA_TABLES.oid = pg_appendonly.relid 129 | AND OUTER_PG_CLASS.oid = pg_appendonly.segrelid 130 | AND pg_appendonly.columnstore = 'f' 131 | 132 | UNION ALL 133 | 134 | SELECT ALL_DATA_TABLES.oid,ALL_DATA_TABLES.schemaname, ALL_DATA_TABLES.tablename, OUTER_PG_CLASS.relname as tupletable FROM ( 135 | SELECT ALLTABLES.oid, ALLTABLES.schemaname, ALLTABLES.tablename FROM 136 | 137 | (SELECT c.oid, n.nspname AS schemaname, c.relname AS tablename FROM pg_class c, pg_namespace n 138 | WHERE n.oid = c.relnamespace) as ALLTABLES, 139 | 140 | (SELECT n.nspname AS schemaname, c.relname AS tablename 141 | FROM pg_class c LEFT JOIN pg_namespace n ON n.oid = c.relnamespace 142 | LEFT JOIN pg_tablespace t ON t.oid = c.reltablespace 143 | WHERE c.relkind = 'r'::char AND c.oid > 16384 AND (c.relnamespace > 16384 or n.nspname = 'public') 144 | EXCEPT 145 | ((SELECT x.schemaname, x.partitiontablename FROM 146 | (SELECT distinct schemaname, tablename, partitiontablename, partitionlevel FROM pg_partitions) as X, 147 | (SELECT schemaname, tablename maxtable, max(partitionlevel) maxlevel FROM pg_partitions group by (tablename, schemaname)) as Y 148 | WHERE x.schemaname = y.schemaname and x.tablename = Y.maxtable and x.partitionlevel != Y.maxlevel) 149 | UNION (SELECT distinct schemaname, tablename FROM pg_partitions))) as DATATABLES 150 | 151 | WHERE ALLTABLES.schemaname = DATATABLES.schemaname and ALLTABLES.tablename = DATATABLES.tablename 152 | AND ALLTABLES.oid not in (select reloid from pg_exttable) AND ALLTABLES.schemaname NOT LIKE 'pg_temp_%' 153 | ) as ALL_DATA_TABLES, pg_appendonly, pg_class OUTER_PG_CLASS 154 | WHERE ALL_DATA_TABLES.oid = pg_appendonly.relid 155 | AND OUTER_PG_CLASS.oid = pg_appendonly.segrelid 156 | AND pg_appendonly.columnstore = 't' 157 | 158 | loop 159 | v_record.reloid := i_oid; 160 | v_record.schemaname := v_schema; 161 | v_record.tablename := v_table; 162 | 163 | BEGIN 164 | v_sql := 'select coalesce(sum(modcount::bigint), 0) from pg_aoseg.'||v_tuple; 165 | --raise info 'sql=%=',v_sql; 166 | execute v_sql into v_record.modcount; 167 | EXCEPTION WHEN undefined_table THEN 168 | raise info 'WARNING: pg_aoseg.% does not exist, skipped!',v_tuple; 169 | continue; 170 | END; 171 | 172 | return next v_record; 173 | end loop; 174 | return; 175 | 176 | END; 177 | $$ 178 | LANGUAGE plpgsql; -------------------------------------------------------------------------------- /analyze/ao_state/check_ao_state_gp7.sql: -------------------------------------------------------------------------------- 1 | CREATE TYPE type_AOtable_state as (reloid bigint,schemaname text,tablename text,modcount bigint); 2 | 3 | CREATE OR REPLACE FUNCTION get_AOtable_state_list(in_schemaname text) 4 | RETURNS SETOF type_AOtable_state AS 5 | $$ 6 | declare 7 | v_record type_AOtable_state%rowtype; 8 | i_oid bigint; 9 | v_schema text; 10 | v_table text; 11 | v_tuple text; 12 | v_sql text; 13 | v_sql2 text; 14 | BEGIN 15 | 16 | v_sql2 := ' 17 | select rel.oid,nsp.nspname,rel.relname,aoseg.relname 18 | from pg_class rel,pg_namespace nsp,pg_appendonly ao,pg_class aoseg 19 | where rel.relnamespace=nsp.oid and rel.oid=ao.relid and aoseg.oid=ao.segrelid and rel.relhassubclass=false 20 | and rel.oid > 16384 AND (rel.relnamespace > 16384 or nsp.nspname = ''public'') 21 | and rel.relkind = ''r'' and rel.relam in (3434,3435) 22 | and nsp.nspname not like ''pg_%'' and nsp.nspname not like ''gp_%'' 23 | and nsp.nspname in '||in_schemaname; 24 | 25 | for i_oid,v_schema,v_table,v_tuple in 26 | execute v_sql2 27 | loop 28 | v_record.reloid := i_oid; 29 | v_record.schemaname := v_schema; 30 | v_record.tablename := v_table; 31 | 32 | BEGIN 33 | v_sql := 'select coalesce(sum(modcount::bigint), 0) from pg_aoseg.'||v_tuple; 34 | --raise info 'sql=%=',v_sql; 35 | execute v_sql into v_record.modcount; 36 | EXCEPTION WHEN undefined_table THEN 37 | raise info 'WARNING: pg_aoseg.% does not exist, skipped!',v_tuple; 38 | continue; 39 | END; 40 | 41 | return next v_record; 42 | end loop; 43 | return; 44 | 45 | END; 46 | $$ 47 | LANGUAGE plpgsql; 48 | 49 | 50 | 51 | CREATE OR REPLACE FUNCTION get_AOtable_state_list() 52 | RETURNS SETOF type_AOtable_state AS 53 | $$ 54 | declare 55 | v_record type_AOtable_state%rowtype; 56 | i_oid bigint; 57 | v_schema text; 58 | v_table text; 59 | v_tuple text; 60 | v_sql text; 61 | BEGIN 62 | 63 | for i_oid,v_schema,v_table,v_tuple in 64 | select rel.oid,nsp.nspname,rel.relname,aoseg.relname 65 | from pg_class rel,pg_namespace nsp,pg_appendonly ao,pg_class aoseg 66 | where rel.relnamespace=nsp.oid and rel.oid=ao.relid and aoseg.oid=ao.segrelid and rel.relhassubclass=false 67 | and rel.oid > 16384 AND (rel.relnamespace > 16384 or nsp.nspname = 'public') 68 | and rel.relkind = 'r' and rel.relam in (3434,3435) 69 | and nsp.nspname not like 'pg_%' and nsp.nspname not like 'gp_%' 70 | 71 | loop 72 | v_record.reloid := i_oid; 73 | v_record.schemaname := v_schema; 74 | v_record.tablename := v_table; 75 | 76 | BEGIN 77 | v_sql := 'select coalesce(sum(modcount::bigint), 0) from pg_aoseg.'||v_tuple; 78 | --raise info 'sql=%=',v_sql; 79 | execute v_sql into v_record.modcount; 80 | EXCEPTION WHEN undefined_table THEN 81 | raise info 'WARNING: pg_aoseg.% does not exist, skipped!',v_tuple; 82 | continue; 83 | END; 84 | 85 | return next v_record; 86 | end loop; 87 | return; 88 | 89 | END; 90 | $$ 91 | LANGUAGE plpgsql; -------------------------------------------------------------------------------- /analyze/ao_state/create_state_table.sql: -------------------------------------------------------------------------------- 1 | create table check_ao_state ( 2 | reloid bigint, 3 | schemaname text, 4 | tablename text, 5 | modcount bigint, 6 | last_checktime timestamp without time zone 7 | ) distributed by (reloid); 8 | 9 | -------------------------------------------------------------------------------- /check_panic/README.txt: -------------------------------------------------------------------------------- 1 | Information: 2 | Use for check PANIC in pg_log on all segments. 3 | Program log will write to $HOME/gpAdminLogs/check_panic.pl_YYYYMMDD.log 4 | 5 | Usage: 6 | perl check_panic.pl -d testdb --check_date 2020-01-01 7 | perl check_panic.pl --help 8 | 9 | 10 | 11 | -------------------------------------------------------------------------------- /clean_log/README.txt: -------------------------------------------------------------------------------- 1 | clean_log.pl: 2 | 3 | Usage: 4 | perl clean_log.pl 5 | 6 | Information: 7 | In this script, there are tow parameter: 8 | my $RM_INVERVAL=30; 9 | my $GZIP_INVERVAL=5; 10 | 11 | RM_INVERVAL: Remove the log files before xx days 12 | GZIP_INVERVAL: Use gzip to compress the log files before xx days 13 | 14 | You can replace this two parameters under your requirement. 15 | 16 | 17 | -------------------------------------------------------------------------------- /clean_log/clean_log.pl: -------------------------------------------------------------------------------- 1 | #!/usr/bin/perl 2 | use strict; 3 | 4 | my $RM_INVERVAL=30; 5 | my $GZIP_INVERVAL=5; 6 | my ($gphome,$path,$ld_library_path,$pythonpath,$pythonhome,$openssl_conf,$master_data_directory); 7 | my $fh_log; 8 | 9 | sub getCurrentDate 10 | { 11 | my ($sec,$min,$hour,$mday,$mon,$year,$wday,$yday,$isdst) = localtime(time()); 12 | my $current = ""; 13 | 14 | $year += 1900; 15 | $mon = sprintf("%02d", $mon + 1); 16 | $mday = sprintf("%02d", $mday); 17 | $current = "${year}${mon}${mday}"; 18 | 19 | return $current; 20 | } 21 | 22 | sub showTime 23 | { 24 | my ($sec,$min,$hour,$mday,$mon,$year,$wday,$yday,$isdst) = localtime(time()); 25 | my $current = ""; 26 | 27 | $year += 1900; 28 | $mon = sprintf("%02d", $mon + 1); 29 | $mday = sprintf("%02d", $mday); 30 | $hour = sprintf("%02d", $hour); 31 | $min = sprintf("%02d", $min); 32 | $sec = sprintf("%02d", $sec); 33 | 34 | $current = "${year}-${mon}-${mday} ${hour}:${min}:${sec}"; 35 | 36 | return $current; 37 | } 38 | 39 | sub initLog{ 40 | my $logday=getCurrentDate(); 41 | my $logfile=open($fh_log, '>>', "$ENV{HOME}/gpAdminLogs/clean_log_$logday.log"); 42 | unless ($logfile){ 43 | print "[ERROR]:Cound not open logfile $ENV{HOME}/gpAdminLogs/clean_log_$logday.log\n"; 44 | exit -1; 45 | } 46 | } 47 | 48 | sub info{ 49 | my ($printmsg)=@_; 50 | print $fh_log "[".showTime()." INFO] ".$printmsg; 51 | return 0; 52 | } 53 | 54 | sub error{ 55 | my ($printmsg)=@_; 56 | print $fh_log "[".showTime()." ERROR] ".$printmsg; 57 | return 0; 58 | } 59 | 60 | 61 | sub gpenv { 62 | my @sysenv=`source ~/.bashrc;env`; 63 | my %config_params; 64 | foreach (@sysenv) { 65 | chomp; 66 | my @tmp=split /=/,$_; 67 | $config_params{$tmp[0]}=$tmp[1]; 68 | } 69 | $gphome=$config_params{"GPHOME"}; 70 | $path=$config_params{"PATH"}; 71 | $ld_library_path=$config_params{"LD_LIBRARY_PATH"}; 72 | $pythonpath=$config_params{"PYTHONPATH"}; 73 | $pythonhome=$config_params{"PYTHONHOME"}; 74 | $openssl_conf=$config_params{"OPENSSL_CONF"}; 75 | $master_data_directory=$config_params{"MASTER_DATA_DIRECTORY"}; 76 | 77 | $ENV{"GPHOME"}=$gphome; 78 | $ENV{"PATH"}=$path; 79 | $ENV{"LD_LIBRARY_PATH"}=$ld_library_path; 80 | $ENV{"PYTHONPATH"}=$pythonpath; 81 | $ENV{"PYTHONHOME"}=$pythonhome; 82 | $ENV{"OPENSSL_CONF"}=$openssl_conf; 83 | $ENV{"MASTER_DATA_DIRECTORY"}=$master_data_directory; 84 | 85 | return(0); 86 | } 87 | 88 | 89 | sub main{ 90 | my $gziplist; 91 | my $rmlist; 92 | 93 | gpenv(); 94 | initLog(); 95 | 96 | info("------gpAdminLogs rm list------\n"); 97 | $rmlist = `gpssh -f ~/allhosts "find /home/gpadmin/gpAdminLogs/ -mtime +${RM_INVERVAL} -name '*.log*' -exec ls -l {} \\;"`; 98 | info("$rmlist"); 99 | `gpssh -f ~/allhosts "find /home/gpadmin/gpAdminLogs/ -mtime +${RM_INVERVAL} -name '*.log*' -exec rm -f {} \\;"`; 100 | info("------gpAdminLogs gzip list------\n"); 101 | $gziplist = `gpssh -f ~/allhosts "find /home/gpadmin/gpAdminLogs/ -mtime +${GZIP_INVERVAL} -name '*.log' -exec ls -l {} \\;"`; 102 | info("$gziplist"); 103 | `gpssh -f ~/allhosts "find /home/gpadmin/gpAdminLogs/ -mtime +${GZIP_INVERVAL} -name '*.log' -exec gzip -f {} \\;"`; 104 | 105 | info("------Master pg_log rm list------\n"); 106 | $rmlist = `gpssh -f ~/allmasters "find ${master_data_directory}/pg_log -mtime +${RM_INVERVAL} -name '*.csv*' -exec ls -l {} \\;"`; 107 | info("$rmlist"); 108 | `gpssh -f ~/allmasters "find ${master_data_directory}/pg_log -mtime +${RM_INVERVAL} -name '*.csv*' -exec rm -f {} \\;"`; 109 | info("------Master pg_log gzip list------\n"); 110 | $gziplist = `gpssh -f ~/allmasters "find ${master_data_directory}/pg_log -mtime +${GZIP_INVERVAL} -name '*.csv' -exec ls -l {} \\;"`; 111 | info("$gziplist"); 112 | `gpssh -f ~/allmasters "find ${master_data_directory}/pg_log -mtime +${GZIP_INVERVAL} -name '*.csv' -exec gzip -f {} \\;"`; 113 | 114 | info("------Segment pg_log rm list------\n"); 115 | $rmlist = `gpssh -f ~/allsegs "find /data*/primary/gpseg*/pg_log -mtime +${RM_INVERVAL} -name '*.csv*' -exec ls -l {} \\;"`; 116 | info("$rmlist"); 117 | `gpssh -f ~/allsegs "find /data*/primary/gpseg*/pg_log -mtime +${RM_INVERVAL} -name '*.csv*' -exec rm -f {} \\;"`; 118 | $rmlist = `gpssh -f ~/allsegs "find /data*/mirror/gpseg*/pg_log -mtime +${RM_INVERVAL} -name '*.csv*' -exec ls -l {} \\;"`; 119 | info("$rmlist"); 120 | `gpssh -f ~/allsegs "find /data*/mirror/gpseg*/pg_log -mtime +${RM_INVERVAL} -name '*.csv*' -exec rm -f {} \\;"`; 121 | info("------Segment pg_log gzip list------\n"); 122 | $gziplist = `gpssh -f ~/allsegs "find /data*/primary/gpseg*/pg_log -mtime +${GZIP_INVERVAL} -name '*.csv' -exec ls -l {} \\;"`; 123 | info("$gziplist"); 124 | `gpssh -f ~/allsegs "find /data*/primary/gpseg*/pg_log -mtime +${GZIP_INVERVAL} -name '*.csv' -exec gzip -f {} \\;"`; 125 | $gziplist = `gpssh -f ~/allsegs "find /data*/mirror/gpseg*/pg_log -mtime +${GZIP_INVERVAL} -name '*.csv' -exec ls -l {} \\;"`; 126 | info("$gziplist"); 127 | `gpssh -f ~/allsegs "find /data*/mirror/gpseg*/pg_log -mtime +${GZIP_INVERVAL} -name '*.csv' -exec gzip -f {} \\;"`; 128 | 129 | close $fh_log; 130 | 131 | } 132 | 133 | main(); 134 | -------------------------------------------------------------------------------- /cmd_on_segdir/README.txt: -------------------------------------------------------------------------------- 1 | Usage: Run command and shell in all segment instance directories, include master and all segment instances 2 | 3 | Example: 4 | perl run_on_all_segdir.pl "echo \"hello\"" 5 | perl run_on_all_segdir.pl "grep gpadmin pg_hba.conf |awk '{print \\\$4}'" 6 | 7 | Information: 8 | Because the script should connect to GP to load all the segment info, Script should run on GP starting or GP master starting status. 9 | 10 | -------------------------------------------------------------------------------- /cmd_on_segdir/run_on_all_segdir.pl: -------------------------------------------------------------------------------- 1 | #!/usr/bin/perl 2 | use strict; 3 | use Time::Local; 4 | use Switch; 5 | 6 | if ($#ARGV != 0 ) { 7 | print "Argument number Error\nExample:\nperl $0 run_command\n" ; 8 | exit (1) ; 9 | } 10 | 11 | my $run_cmd = $ARGV[0]; 12 | 13 | 14 | sub getCurrentDateTime 15 | { 16 | my ($sec,$min,$hour,$mday,$mon,$year,$wday,$yday,$isdst) = localtime(time()); 17 | my $current = ""; 18 | 19 | $year += 1900; 20 | $mon = sprintf("%02d", $mon + 1); 21 | $mday = sprintf("%02d", $mday); 22 | $hour = sprintf("%02d", $hour); 23 | $min = sprintf("%02d", $min); 24 | $sec = sprintf("%02d", $sec); 25 | $current = "${year}${mon}${mday}${hour}${min}${sec}"; 26 | 27 | return $current; 28 | } 29 | 30 | 31 | sub get_gpver { 32 | my @tmpstr; 33 | my @tmpver; 34 | my $sql = qq{select version();}; 35 | my $sver=`PGOPTIONS='-c gp_session_role=utility' psql -A -X -t -c "$sql" -d postgres` ; 36 | my $ret=$?; 37 | if($ret) { 38 | print "Get GP version error!\n"; 39 | exit 1; 40 | } 41 | chomp($sver); 42 | @tmpstr = split / /,$sver; 43 | print $tmpstr[4]."\n"; 44 | @tmpver = split /\./,$tmpstr[4]; 45 | print $tmpver[0]."\n"; 46 | 47 | return $tmpver[0]; 48 | } 49 | 50 | 51 | 52 | 53 | sub get_seg_dir { 54 | #0 all instances 55 | #1 master 56 | #2 gpseg0 57 | my ($iflag) = @_; 58 | my $sql; 59 | my $gpver=get_gpver(); 60 | 61 | switch ($iflag) { 62 | case 0 { 63 | if ($gpver>=6) { 64 | $sql =qq{ 65 | SELECT conf.hostname||','||conf.datadir 66 | FROM gp_segment_configuration conf 67 | ORDER BY conf.dbid; 68 | }; 69 | } else { 70 | $sql =qq{ 71 | SELECT conf.hostname||','||pgfse.fselocation 72 | FROM pg_filespace_entry pgfse, gp_segment_configuration conf 73 | WHERE pgfse.fsefsoid=3052 AND conf.dbid=pgfse.fsedbid 74 | ORDER BY conf.dbid; 75 | }; 76 | } 77 | } 78 | case 1 { 79 | if ($gpver>=6) { 80 | $sql =qq{ 81 | SELECT conf.hostname||','||conf.datadir 82 | FROM gp_segment_configuration conf 83 | WHERE conf.content=-1 AND conf.dbid=1; 84 | }; 85 | } else { 86 | $sql =qq{ 87 | SELECT conf.hostname||','||pgfse.fselocation 88 | FROM pg_filespace_entry pgfse, gp_segment_configuration conf 89 | WHERE pgfse.fsefsoid=3052 AND conf.dbid=pgfse.fsedbid 90 | AND conf.content=-1 AND conf.dbid=1; 91 | }; 92 | } 93 | } 94 | case 2 { 95 | if ($gpver>=6) { 96 | $sql =qq{ 97 | SELECT conf.hostname||','||conf.datadir 98 | FROM gp_segment_configuration conf 99 | WHERE conf.content=0 AND conf.dbid=2; 100 | }; 101 | } else { 102 | $sql =qq{ 103 | SELECT conf.hostname||','||pgfse.fselocation 104 | FROM pg_filespace_entry pgfse, gp_segment_configuration conf 105 | WHERE pgfse.fsefsoid=3052 AND conf.dbid=pgfse.fsedbid 106 | AND conf.content=0 AND conf.dbid=2; 107 | }; 108 | } 109 | } 110 | } 111 | 112 | print "PGOPTIONS='-c gp_session_role=utility' psql -A -X -t -c \"$sql\" -d postgres\n"; 113 | my @tmplist=`PGOPTIONS='-c gp_session_role=utility' psql -A -X -t -c "$sql" -d postgres` ; 114 | my $ret=$?; 115 | if($ret) { 116 | my $sInfo="psql error =$sql="; 117 | return(1,$sInfo); 118 | } 119 | 120 | return(0,@tmplist); 121 | 122 | } 123 | 124 | 125 | sub run_on_segdir{ 126 | my @cmdstr; 127 | my @seg_dir_list; 128 | my $ret; 129 | my $cmd; 130 | my $mychoice; 131 | my $checkresult; 132 | 133 | #get segment list 134 | ($ret,@seg_dir_list)=get_seg_dir(0); 135 | if ($ret) { return $ret; } 136 | #print @seg_dir_list; 137 | 138 | #Confirmation info 139 | @cmdstr=split /,/,$seg_dir_list[0]; 140 | chomp($cmdstr[0]); 141 | chomp($cmdstr[1]); 142 | $cmd=qq{ssh $cmdstr[0] "cd $cmdstr[1]; $run_cmd"}; 143 | while (1==1) { 144 | print "Please Confirm Command: \n$cmd\n(Yy/Nn)\n"; 145 | $mychoice=; 146 | chomp($mychoice); 147 | #print "My option is <".$mytmp.">\n"; 148 | if ( $mychoice eq "y" || $mychoice eq "Y" ) {last;} 149 | elsif ( $mychoice eq "n" || $mychoice eq "N" ) {exit 0;} 150 | } 151 | 152 | my $jj; 153 | for ($jj=0;$jj<$#seg_dir_list+1;$jj++) { 154 | @cmdstr=split /,/,$seg_dir_list[$jj]; 155 | chomp($cmdstr[0]); 156 | chomp($cmdstr[1]); 157 | $cmd=qq{ssh $cmdstr[0] "cd $cmdstr[1]; $run_cmd" 2>&1}; 158 | print "cmd[".$cmd."]\n"; 159 | $checkresult=`$cmd`; 160 | print $checkresult; 161 | } 162 | 163 | return 0; 164 | } 165 | 166 | 167 | 168 | ############################################################################################ 169 | ########################################Main funcion######################################## 170 | ############################################################################################ 171 | sub main{ 172 | my $ret; 173 | 174 | $ret=run_on_segdir(); 175 | return($ret); 176 | } 177 | 178 | my $ret = main(); 179 | exit($ret); 180 | 181 | 182 | -------------------------------------------------------------------------------- /drop_pg_temp/README.txt: -------------------------------------------------------------------------------- 1 | INFORMATION: 2 | Drop all the useless schema named pg_temp_xxxxx in GPDB. 3 | 4 | Usage: 5 | sh drop_pg_temp.sh 6 | 7 | 8 | -------------------------------------------------------------------------------- /drop_pg_temp/drop_pg_temp.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | source /usr/local/greenplum-db/greenplum_path.sh 4 | 5 | LEAKED_SCHEMA_QUERY=" 6 | SELECT 'DROP SCHEMA IF EXISTS '||schema||' CASCADE;' FROM ( 7 | SELECT distinct nspname as schema 8 | FROM ( 9 | SELECT nspname, replace(nspname, 'pg_temp_','')::int as sess_id 10 | FROM gp_dist_random('pg_namespace') 11 | WHERE nspname ~ '^pg_temp_[0-9]+' 12 | UNION ALL 13 | SELECT nspname, replace(nspname, 'pg_toast_temp_','')::int as sess_id 14 | FROM gp_dist_random('pg_namespace') 15 | WHERE nspname ~ '^pg_toast_temp_[0-9]+' 16 | ) n LEFT OUTER JOIN pg_stat_activity x using (sess_id) 17 | WHERE x.sess_id is null 18 | UNION 19 | SELECT nspname as schema 20 | FROM ( 21 | SELECT nspname, replace(nspname, 'pg_temp_','')::int as sess_id 22 | FROM pg_namespace 23 | WHERE nspname ~ '^pg_temp_[0-9]+' 24 | UNION ALL 25 | SELECT nspname, replace(nspname, 'pg_toast_temp_','')::int as sess_id 26 | FROM pg_namespace 27 | WHERE nspname ~ '^pg_toast_temp_[0-9]+' 28 | ) n LEFT OUTER JOIN pg_stat_activity x using (sess_id) 29 | WHERE x.sess_id is null 30 | ) foo; 31 | " 32 | 33 | psql postgres -Atc "select datname from pg_database where datname != 'template0'" | while read a; do echo "check for ${a}";psql -Atc "${LEAKED_SCHEMA_QUERY}" ${a} | psql -a ${a}; done 34 | 35 | 36 | -------------------------------------------------------------------------------- /gp_healthcheck/README.txt: -------------------------------------------------------------------------------- 1 | Greenplum Database Health Check Tool (gp_healthcheck) 2 | 3 | gp_healthcheck is a comprehensive health check tool for Greenplum Database, designed to analyze database status, storage usage, performance bottlenecks, bloat, skew, and long-running transactions. It helps database administrators (DBAs) quickly identify potential issues and ensure database stability. 4 | 5 | Features 6 | 7 | Supports Greenplum 4.3, 5, 6, and 7, with the following checks: 8 | 9 | 1. Cluster-Level Checks 10 | - Database status: Detects down nodes. 11 | - Cluster size: Reports segment count and distribution. 12 | - Disk space usage: Monitors disk utilization across nodes. 13 | - Database size: Lists storage usage per database. 14 | - Age: Checks datfrozenxid to prevent transaction ID wraparound. 15 | 16 | 2. Active Sessions & Transactions 17 | - Long-running queries: Identifies SQL running for more than 24 hours. 18 | - Idle in transactions: Detects uncommitted idle in transactions exceeding 24 hours. 19 | 20 | 3. Database Internal Health Checks 21 | - System tables: Analyzes key system tables, size, and bloat. 22 | - Database objects statistics: 23 | - Schema size 24 | - Tablespace size 25 | - Top 50 largest heap tables 26 | - Top 50 largest AO tables 27 | - Top 100 largest partitioned tables 28 | - Skew detection: Measures data distribution imbalance across segments. 29 | - Bloat detection: Identifies excessive bloat in AO tables. 30 | - Default subpartition check: Ensures proper partition design. 31 | 32 | 33 | ------------------------- 34 | Installation: 35 | 36 | 1. Verify plpythonu is created 37 | SELECT * FROM pg_language WHERE lanname = 'plpythonu'; 38 | CREATE LANGUAGE IF NOT EXISTS plpythonu; --GP4.3, 5, 6 39 | CREATE LANGUAGE IF NOT EXISTS plpython3u; --GP7 40 | 41 | 2. Install SQL functions 42 | For different Greenplum versions: 43 | 44 | AO Table Bloat Check 45 | psql -d dbname -af ./aobloat/check_ao_bloat.sql # GP4.3, GP5, GP6 46 | psql -d dbname -af ./aobloat/check_ao_bloat_gp7.sql # GP7 47 | 48 | Table Skew Check 49 | psql dbname -af ./skew/skewcheck_func.sql # GP4.3, GP5 50 | psql dbname -af ./skew/skewcheck_func_gp6.sql # GP6 51 | psql dbname -af ./skew/skewcheck_func_gp7.sql # GP7 52 | 53 | Storage Usage Check 54 | psql dbname -af ./gpsize/load_files_size.sql # GP4.3, GP5 55 | psql dbname -af ./gpsize/load_files_size_v6.sql # GP6 56 | psql dbname -af ./gpsize/load_files_size_v7.sql # GP7 57 | psql dbname -af ./gpsize/load_files_size_cbdb.sql # CloudBerryDB 58 | 59 | 60 | ------------------------- 61 | Usage: 62 | 63 | 1. Check one database 64 | perl gp_healthcheck.pl --dbname testdb --jobs 3 65 | 66 | 2. Check Specific Schema 67 | perl gp_healthcheck.pl --dbname testdb --include-schema public --include-schema analytics 68 | 69 | 3. Check All Databases in GP cluster 70 | perl gp_healthcheck.pl --alldb --jobs 3 71 | 72 | 4. Check All Databases in GP cluster, and auto create UDF if it is not exists in DB. 73 | perl gp_healthcheck.pl --alldb --jobs 3 --create-udf /home/gpadmin/gpshell 74 | 75 | 5. Custom Log Directory 76 | perl gp_healthcheck.pl --alldb --log-dir /tmp/logs 77 | 78 | 6. Help 79 | perl gp_healthcheck.pl --help 80 | perl gp_healthcheck.pl -? 81 | 82 | 83 | ------------------------- 84 | Options: 85 | --hostname | -h 86 | Master hostname or master host IP. Default: localhost 87 | 88 | --port | -p 89 | GP Master port number, Default: 5432 90 | 91 | --dbname | -d 92 | Database name. If not specified, uses the value specified by the environment variable PGDATABASE, even if PGDATABASE is not specified, return error. 93 | 94 | --username | -u 95 | The super user of GPDB. Default: gpadmin 96 | 97 | --password | -pw 98 | The password of GP user. Default: no password 99 | 100 | --help | -? 101 | Show the help message. 102 | 103 | --alldb | -A 104 | Check all database in GP cluster. 105 | 106 | --log-dir | -l 107 | The directory to write the log file. Default: ~/gpAdminLogs. 108 | 109 | --jobs 110 | The number of parallel jobs to check skew, bloat and default partition. Default value: 2 111 | 112 | --include-schema 113 | Check (include: skew, bloat) only specified schema(s). --include-schema can be specified multiple times. 114 | 115 | --include-schema-file 116 | A file containing a list of schema to be included in healthcheck. 117 | 118 | --skip-without-udf 119 | If skew,bloat,dbsize functions is not created in DB, then skip these checking. Default is false. 120 | 121 | --create-udf 122 | If skew,bloat,dbsize functions is not created in DB, automatic create them. UDF directory must be specified. 123 | 124 | 125 | 126 | 127 | -------------------------------------------------------------------------------- /gp_healthcheck/aobloat/check_ao_bloat.sql: -------------------------------------------------------------------------------- 1 | CREATE TYPE type_AOtable_bloat as (reloid bigint,schemaname text,tablename text,percent_hidden float,bloat float); 2 | 3 | 4 | CREATE OR REPLACE FUNCTION check_AOtable_bloat() 5 | RETURNS SETOF type_AOtable_bloat AS 6 | $$ 7 | declare 8 | v_record type_AOtable_bloat%rowtype; 9 | i_oid bigint; 10 | v_schema text; 11 | v_table text; 12 | v_sql text; 13 | v_hidden bigint; 14 | v_total bigint; 15 | BEGIN 16 | set statement_timeout='24h'; 17 | 18 | BEGIN 19 | v_sql := 'drop table if exists ao_aovisimap_hidden; 20 | create temp table ao_aovisimap_hidden as 21 | select rel.oid reloid,nsp.nspname,rel.relname,rel.gp_segment_id segid, 22 | (gp_toolkit.__gp_aovisimap_hidden_typed(rel.oid)::record).* 23 | FROM gp_dist_random(''pg_class'') rel, pg_namespace nsp 24 | where nsp.oid=rel.relnamespace and rel.relkind=''r'' and rel.relstorage in (''a'',''c'')'; 25 | execute v_sql; 26 | EXCEPTION WHEN undefined_table THEN 27 | raise info 'Any relation oid not found because of a concurrent drop operation, skipped!'; 28 | return; 29 | END; 30 | 31 | v_sql := 'select reloid,nspname,relname,sum(hidden) hidden_tupcount,sum(total) total_tupcount from ao_aovisimap_hidden group by 1,2,3'; 32 | for i_oid,v_schema,v_table,v_hidden,v_total in 33 | execute v_sql 34 | loop 35 | v_record.reloid := i_oid; 36 | v_record.schemaname := v_schema; 37 | v_record.tablename := v_table; 38 | 39 | IF v_total > 0 THEN 40 | v_record.percent_hidden := (100 * v_hidden / v_total::numeric)::numeric(5,2); 41 | ELSE 42 | v_record.percent_hidden := 0::numeric(5,2); 43 | END IF; 44 | v_record.bloat := 100 / (100.1-v_record.percent_hidden); 45 | 46 | return next v_record; 47 | end loop; 48 | return; 49 | 50 | END; 51 | $$ 52 | LANGUAGE plpgsql; 53 | 54 | 55 | 56 | ----old function, in_schemaname format: '(''schema1'',''schema2'',''schema3'')' 57 | CREATE OR REPLACE FUNCTION check_AOtable_bloat(in_schemaname text) 58 | RETURNS SETOF type_AOtable_bloat AS 59 | $$ 60 | declare 61 | v_record type_AOtable_bloat%rowtype; 62 | i_oid bigint; 63 | v_schema text; 64 | v_table text; 65 | v_sql text; 66 | v_hidden bigint; 67 | v_total bigint; 68 | BEGIN 69 | set statement_timeout='24h'; 70 | 71 | BEGIN 72 | v_sql := 'drop table if exists ao_aovisimap_hidden; 73 | create temp table ao_aovisimap_hidden as 74 | select rel.oid reloid,nsp.nspname,rel.relname,rel.gp_segment_id segid, 75 | (gp_toolkit.__gp_aovisimap_hidden_typed(rel.oid)::record).* 76 | FROM gp_dist_random(''pg_class'') rel, pg_namespace nsp 77 | where nsp.oid=rel.relnamespace and rel.relkind=''r'' and rel.relstorage in (''a'',''c'') 78 | and nsp.nspname in '||in_schemaname; 79 | execute v_sql; 80 | EXCEPTION WHEN undefined_table THEN 81 | raise info 'Any relation oid not found because of a concurrent drop operation, skipped!'; 82 | return; 83 | END; 84 | 85 | v_sql := 'select reloid,nspname,relname,sum(hidden) hidden_tupcount,sum(total) total_tupcount from ao_aovisimap_hidden group by 1,2,3'; 86 | for i_oid,v_schema,v_table,v_hidden,v_total in 87 | execute v_sql 88 | loop 89 | v_record.reloid := i_oid; 90 | v_record.schemaname := v_schema; 91 | v_record.tablename := v_table; 92 | 93 | IF v_total > 0 THEN 94 | v_record.percent_hidden := (100 * v_hidden / v_total::numeric)::numeric(5,2); 95 | ELSE 96 | v_record.percent_hidden := 0::numeric(5,2); 97 | END IF; 98 | v_record.bloat := 100 / (100.1-v_record.percent_hidden); 99 | 100 | return next v_record; 101 | end loop; 102 | return; 103 | 104 | END; 105 | $$ 106 | LANGUAGE plpgsql; 107 | 108 | 109 | 110 | ----new new new function, in_schemaname format: 'schema1,schema2,schema3' 111 | CREATE OR REPLACE FUNCTION AOtable_bloatcheck(in_schemaname text) 112 | RETURNS SETOF type_AOtable_bloat AS 113 | $$ 114 | declare 115 | v_record type_AOtable_bloat%rowtype; 116 | i_oid bigint; 117 | v_schema text; 118 | v_table text; 119 | v_sql text; 120 | schema_array text[]; 121 | v_schemastr text; 122 | i int; 123 | v_hidden bigint; 124 | v_total bigint; 125 | BEGIN 126 | schema_array := string_to_array(in_schemaname,','); 127 | --raise info '%,%',array_lower(schema_array,1),array_upper(schema_array,1); 128 | v_schemastr := '('; 129 | i := 1; 130 | while i <= array_upper(schema_array,1) loop 131 | --raise info '%',schema_array[i]; 132 | if i 0 THEN 164 | v_record.percent_hidden := (100 * v_hidden / v_total::numeric)::numeric(5,2); 165 | ELSE 166 | v_record.percent_hidden := 0::numeric(5,2); 167 | END IF; 168 | v_record.bloat := 100 / (100.1-v_record.percent_hidden); 169 | 170 | return next v_record; 171 | end loop; 172 | return; 173 | 174 | END; 175 | $$ 176 | LANGUAGE plpgsql; 177 | 178 | 179 | ----new new new function, all schema 180 | CREATE OR REPLACE FUNCTION AOtable_bloatcheck() 181 | RETURNS SETOF type_AOtable_bloat AS 182 | $$ 183 | declare 184 | v_record type_AOtable_bloat%rowtype; 185 | i_oid bigint; 186 | v_schema text; 187 | v_table text; 188 | v_sql text; 189 | schema_array text[]; 190 | v_schemastr text; 191 | i int; 192 | v_hidden bigint; 193 | v_total bigint; 194 | BEGIN 195 | BEGIN 196 | v_sql := 'drop table if exists ao_aovisimap_hidden; 197 | create temp table ao_aovisimap_hidden as 198 | select rel.oid reloid,nsp.nspname,rel.relname,rel.gp_segment_id segid, 199 | (gp_toolkit.__gp_aovisimap_hidden_typed(rel.oid)::record).* 200 | FROM gp_dist_random(''pg_class'') rel, pg_namespace nsp 201 | where nsp.oid=rel.relnamespace and rel.relkind=''r'' and rel.relstorage in (''a'',''c'')'; 202 | execute v_sql; 203 | EXCEPTION WHEN undefined_table THEN 204 | raise info 'Any relation oid not found because of a concurrent drop operation, skipped!'; 205 | return; 206 | END; 207 | 208 | v_sql := 'select reloid,nspname,relname,sum(hidden) hidden_tupcount,sum(total) total_tupcount from ao_aovisimap_hidden group by 1,2,3'; 209 | for i_oid,v_schema,v_table,v_hidden,v_total in 210 | execute v_sql 211 | loop 212 | v_record.reloid := i_oid; 213 | v_record.schemaname := v_schema; 214 | v_record.tablename := v_table; 215 | 216 | IF v_total > 0 THEN 217 | v_record.percent_hidden := (100 * v_hidden / v_total::numeric)::numeric(5,2); 218 | ELSE 219 | v_record.percent_hidden := 0::numeric(5,2); 220 | END IF; 221 | v_record.bloat := 100 / (100.1-v_record.percent_hidden); 222 | 223 | return next v_record; 224 | end loop; 225 | return; 226 | 227 | END; 228 | $$ 229 | LANGUAGE plpgsql; 230 | 231 | -------------------------------------------------------------------------------- /gp_healthcheck/aobloat/check_ao_bloat_gp7.sql: -------------------------------------------------------------------------------- 1 | CREATE TYPE type_AOtable_bloat as (reloid bigint,schemaname text,tablename text,percent_hidden float,bloat float); 2 | 3 | 4 | ----new new new function, in_schemaname format: 'schema1,schema2,schema3' 5 | CREATE OR REPLACE FUNCTION AOtable_bloatcheck(in_schemaname text) 6 | RETURNS SETOF type_AOtable_bloat AS 7 | $$ 8 | declare 9 | v_record type_AOtable_bloat%rowtype; 10 | i_oid bigint; 11 | v_schema text; 12 | v_table text; 13 | v_sql text; 14 | schema_array text[]; 15 | v_schemastr text; 16 | i int; 17 | v_hidden bigint; 18 | v_total bigint; 19 | BEGIN 20 | schema_array := string_to_array(in_schemaname,','); 21 | --raise info '%,%',array_lower(schema_array,1),array_upper(schema_array,1); 22 | v_schemastr := '('; 23 | i := 1; 24 | while i <= array_upper(schema_array,1) loop 25 | --raise info '%',schema_array[i]; 26 | if i 0 THEN 58 | v_record.percent_hidden := (100 * v_hidden / v_total::numeric)::numeric(5,2); 59 | ELSE 60 | v_record.percent_hidden := 0::numeric(5,2); 61 | END IF; 62 | v_record.bloat := 100 / (100.1-v_record.percent_hidden); 63 | 64 | return next v_record; 65 | end loop; 66 | return; 67 | 68 | END; 69 | $$ 70 | LANGUAGE plpgsql; 71 | 72 | 73 | ----new new new function, all schema 74 | CREATE OR REPLACE FUNCTION AOtable_bloatcheck() 75 | RETURNS SETOF type_AOtable_bloat AS 76 | $$ 77 | declare 78 | v_record type_AOtable_bloat%rowtype; 79 | i_oid bigint; 80 | v_schema text; 81 | v_table text; 82 | v_sql text; 83 | schema_array text[]; 84 | v_schemastr text; 85 | i int; 86 | v_hidden bigint; 87 | v_total bigint; 88 | BEGIN 89 | BEGIN 90 | v_sql := 'drop table if exists ao_aovisimap_hidden; 91 | create temp table ao_aovisimap_hidden as 92 | select rel.oid reloid,nsp.nspname,rel.relname,rel.gp_segment_id segid, 93 | (gp_toolkit.__gp_aovisimap_hidden_typed(rel.oid)::record).* 94 | FROM gp_dist_random(''pg_class'') rel, pg_namespace nsp 95 | where nsp.oid=rel.relnamespace and rel.relkind=''r'' and rel.relam in (3434,3435)'; 96 | execute v_sql; 97 | EXCEPTION WHEN undefined_table THEN 98 | raise info 'Any relation oid not found because of a concurrent drop operation, skipped!'; 99 | return; 100 | END; 101 | 102 | v_sql := 'select reloid,nspname,relname,sum(hidden) hidden_tupcount,sum(total) total_tupcount from ao_aovisimap_hidden group by 1,2,3'; 103 | for i_oid,v_schema,v_table,v_hidden,v_total in 104 | execute v_sql 105 | loop 106 | v_record.reloid := i_oid; 107 | v_record.schemaname := v_schema; 108 | v_record.tablename := v_table; 109 | 110 | IF v_total > 0 THEN 111 | v_record.percent_hidden := (100 * v_hidden / v_total::numeric)::numeric(5,2); 112 | ELSE 113 | v_record.percent_hidden := 0::numeric(5,2); 114 | END IF; 115 | v_record.bloat := 100 / (100.1-v_record.percent_hidden); 116 | 117 | return next v_record; 118 | end loop; 119 | return; 120 | 121 | END; 122 | $$ 123 | LANGUAGE plpgsql; 124 | 125 | -------------------------------------------------------------------------------- /gp_healthcheck/gpsize/load_files_size.sql: -------------------------------------------------------------------------------- 1 | drop table if exists public.gp_seg_size_ora cascade; 2 | create table public.gp_seg_size_ora 3 | ( 4 | acl text 5 | ,num int 6 | ,sysuser text 7 | ,sysgroup text 8 | ,size numeric 9 | ,modtime timestamp 10 | ,filename text 11 | )distributed randomly; 12 | 13 | drop table if exists public.gp_seg_table_size cascade; 14 | create table public.gp_seg_table_size 15 | ( 16 | hostname text 17 | ,oid oid 18 | ,relnamespace oid 19 | ,relname name 20 | ,reltablespace oid 21 | ,relfilenode oid 22 | ,size numeric 23 | ,relfilecount int 24 | ,max_modtime timestamp 25 | ) distributed randomly; 26 | 27 | 28 | CREATE LANGUAGE plpythonu; 29 | 30 | 31 | DROP FUNCTION IF EXISTS public.hostname(); 32 | CREATE or replace FUNCTION public.hostname() RETURNS 33 | text 34 | as $$ 35 | import socket 36 | return socket.gethostname() 37 | $$ LANGUAGE plpythonu; 38 | 39 | 40 | 41 | DROP FUNCTION IF EXISTS public.load_files_size(); 42 | CREATE or REPLACE FUNCTION public.load_files_size() RETURNS text 43 | as $$ 44 | import subprocess 45 | 46 | rows = plpy.execute("select current_database() dbname, current_setting('port') portno;") 47 | (dbname, portno) = (rows[0]["dbname"], rows[0]["portno"]) 48 | rows = plpy.execute("select '/tmp/fs_'||current_setting('gp_dbid')||'.dat' as filename;") 49 | filename = rows[0]["filename"] 50 | 51 | def run_psql_utility(v_sql): 52 | psql_cmd = """PGOPTIONS='-c gp_session_role=utility' psql -v ON_ERROR_STOP=1 -d %s -p %s -A -X -t -c \"%s\" """ % (dbname, portno, v_sql) 53 | #plpy.info(psql_cmd) 54 | p = subprocess.Popen(psql_cmd,shell=True, stdout=subprocess.PIPE, stderr=subprocess.PIPE, stdin=subprocess.PIPE) 55 | p_stdout = p.stdout.read() 56 | p_stderr = p.stderr.read() 57 | p.wait() 58 | if p.returncode != 0: 59 | plpy.error(p_stderr) 60 | 61 | rows = plpy.execute("select 'export LANG=en_US.utf8;ls -l --time-style=''+%Y-%m-%d_%H:%M:%S'' '||current_setting('data_directory')||'/base/'||c.oid||'> /tmp/fs_'||current_setting('gp_dbid')||'.dat ; ' as cmd1 from pg_database c where c.datname=current_database();") 62 | cmd1 = rows[0]["cmd1"] 63 | rows = plpy.execute("select string_agg('ls -l --time-style=''+%Y-%m-%d_%H:%M:%S'' ' ||case when current_setting('gp_dbid')::int=c.db_id_1 then trim(c.location_1) when current_setting('gp_dbid')::int=c.db_id_2 then trim(c.location_2) end ||'/*/'||(SELECT oid from pg_database where datname=current_database())||' >> /tmp/fs_'||current_setting('gp_dbid')||'.dat',' ; ') as cmd2 from gp_persistent_filespace_node c;") 64 | cmd2 = rows[0]["cmd2"] 65 | if cmd2 is None: 66 | ls_cmd = cmd1 67 | else: 68 | ls_cmd = cmd1+cmd2 69 | #plpy.info(ls_cmd) 70 | p = subprocess.Popen(ls_cmd,shell=True, stdout=subprocess.PIPE, stderr=subprocess.PIPE, stdin=subprocess.PIPE) 71 | p_stdout = p.stdout.read() 72 | p_stderr = p.stderr.read() 73 | p.wait() 74 | if p.returncode != 0: 75 | plpy.notice(p_stderr) 76 | 77 | sed_cmd = "sed -i 's/[ ]\{1,\}/|/g;/?/d;/^total/d;/^\//d;/^$/d' "+filename 78 | #plpy.info(sed_cmd) 79 | p = subprocess.Popen(sed_cmd,shell=True, stdout=subprocess.PIPE, stderr=subprocess.PIPE, stdin=subprocess.PIPE) 80 | p_stdout = p.stdout.read() 81 | p_stderr = p.stderr.read() 82 | p.wait() 83 | if p.returncode != 0: 84 | plpy.error(p_stderr) 85 | 86 | copy_sql = "copy public.gp_seg_size_ora from '"+filename+"' delimiter '|';" 87 | run_psql_utility(copy_sql) 88 | 89 | insert_sql = "insert into public.gp_seg_table_size (select hostname(),a.oid,a.relnamespace,a.relname,a.reltablespace,a.relfilenode,b.size,b.relfilecount,b.max_modtime from pg_class a join (select split_part(filename,'.',1) as relfilenode,sum(size) size,count(*) relfilecount,max(modtime) max_modtime from gp_seg_size_ora group by 1) b on a.relfilenode::text=b.relfilenode);" 90 | run_psql_utility(insert_sql) 91 | 92 | return "OK" 93 | $$ LANGUAGE plpythonu; 94 | 95 | 96 | --truncate gp_seg_size_ora; 97 | --truncate gp_seg_table_size; 98 | --select gp_segment_id,public.load_files_size() from gp_dist_random('gp_id'); 99 | 100 | 101 | -------------------------------------------------------------------------------- /gp_healthcheck/gpsize/load_files_size_cbdb.sql: -------------------------------------------------------------------------------- 1 | drop table if exists public.gp_seg_size_ora cascade; 2 | create table public.gp_seg_size_ora 3 | ( 4 | acl text 5 | ,num int 6 | ,sysuser text 7 | ,sysgroup text 8 | ,size numeric 9 | ,modtime timestamp 10 | ,filename text 11 | )distributed randomly; 12 | 13 | drop table if exists public.gp_seg_table_size cascade; 14 | create table public.gp_seg_table_size 15 | ( 16 | hostname text 17 | ,oid oid 18 | ,relnamespace oid 19 | ,relname name 20 | ,reltablespace oid 21 | ,relfilenode oid 22 | ,size numeric 23 | ,relfilecount int 24 | ,max_modtime timestamp 25 | ) distributed randomly; 26 | 27 | 28 | CREATE LANGUAGE plpython3u; 29 | 30 | 31 | DROP FUNCTION IF EXISTS public.hostname(); 32 | CREATE or replace FUNCTION public.hostname() RETURNS 33 | text 34 | as $$ 35 | import socket 36 | return socket.gethostname() 37 | $$ LANGUAGE plpython3u; 38 | 39 | 40 | 41 | 42 | DROP FUNCTION IF EXISTS public.load_files_size(); 43 | CREATE or REPLACE FUNCTION public.load_files_size() RETURNS text 44 | as $$ 45 | import subprocess 46 | 47 | rows = plpy.execute("select current_database() dbname, current_setting('port') portno;") 48 | (dbname, portno) = (rows[0]["dbname"], rows[0]["portno"]) 49 | rows = plpy.execute("select '/tmp/fs_'||current_setting('gp_dbid')||'.dat' as filename;") 50 | filename = rows[0]["filename"] 51 | 52 | def run_psql_utility(v_sql): 53 | psql_cmd = """PGOPTIONS='-c gp_role=utility' psql -v ON_ERROR_STOP=1 -d %s -p %s -A -X -t -c \"%s\" """ % (dbname, portno, v_sql) 54 | #plpy.info(psql_cmd) 55 | p = subprocess.Popen(psql_cmd,shell=True, stdout=subprocess.PIPE, stderr=subprocess.PIPE, stdin=subprocess.PIPE) 56 | p_stdout = p.stdout.read() 57 | p_stderr = p.stderr.read() 58 | p.wait() 59 | if p.returncode != 0: 60 | plpy.error(p_stderr) 61 | 62 | rows = plpy.execute("select 'export LANG=en_US.utf8;ls -l --time-style=''+%Y-%m-%d_%H:%M:%S'' '||current_setting('data_directory')||'/base/'||c.oid||'> /tmp/fs_'||current_setting('gp_dbid')||'.dat ; ' as cmd1 from pg_database c where c.datname=current_database();") 63 | cmd1 = rows[0]["cmd1"] 64 | rows = plpy.execute("select string_agg('export LANG=en_US.utf8;ls -l --time-style=''+%Y-%m-%d_%H:%M:%S'' ' ||pg_tablespace_location(oid)||'/'||current_setting('gp_dbid')||'/*/'||(SELECT oid from pg_database where datname=current_database())||' >> /tmp/fs_'||current_setting('gp_dbid')||'.dat',' ; ') as cmd2 from pg_tablespace where oid not in (1663,1664);") 65 | cmd2 = rows[0]["cmd2"] 66 | if cmd2 is None: 67 | ls_cmd = cmd1 68 | else: 69 | ls_cmd = cmd1+cmd2 70 | #plpy.info(ls_cmd) 71 | p = subprocess.Popen(ls_cmd,shell=True, stdout=subprocess.PIPE, stderr=subprocess.PIPE, stdin=subprocess.PIPE) 72 | p_stdout = p.stdout.read() 73 | p_stderr = p.stderr.read() 74 | p.wait() 75 | if p.returncode != 0: 76 | plpy.notice(p_stderr) 77 | 78 | #sed_cmd = "sed -i 's/[ ]\{1,\}/|/g;/?/d;/^total/d;/^\//d;/^$/d' "+filename 79 | sed_cmd = "sed -i 's/[ ]\{1,\}/|/g;/?/d;/^total/d;/^总用量/d;/^\//d;/^$/d' "+filename 80 | #plpy.info(sed_cmd) 81 | p = subprocess.Popen(sed_cmd,shell=True, stdout=subprocess.PIPE, stderr=subprocess.PIPE, stdin=subprocess.PIPE) 82 | p_stdout = p.stdout.read() 83 | p_stderr = p.stderr.read() 84 | p.wait() 85 | if p.returncode != 0: 86 | plpy.error(p_stderr) 87 | 88 | copy_sql = "copy public.gp_seg_size_ora from '"+filename+"' delimiter '|' SEGMENT REJECT LIMIT 10 ROWS;" 89 | run_psql_utility(copy_sql) 90 | 91 | insert_sql = "insert into public.gp_seg_table_size (select hostname(),a.oid,a.relnamespace,a.relname,a.reltablespace,a.relfilenode,b.size,b.relfilecount,b.max_modtime from pg_class a join (select split_part(filename,'.',1) as relfilenode,sum(size) size,count(*) relfilecount,max(modtime) max_modtime from gp_seg_size_ora group by 1) b on a.relfilenode::text=b.relfilenode);" 92 | run_psql_utility(insert_sql) 93 | 94 | return "OK" 95 | $$ LANGUAGE plpython3u; 96 | 97 | 98 | --truncate gp_seg_size_ora; 99 | --truncate gp_seg_table_size; 100 | --select gp_segment_id,public.load_files_size() from gp_dist_random('gp_id'); 101 | 102 | 103 | 104 | 105 | -------------------------------------------------------------------------------- /gp_healthcheck/gpsize/load_files_size_v6.sql: -------------------------------------------------------------------------------- 1 | drop table if exists public.gp_seg_size_ora cascade; 2 | create table public.gp_seg_size_ora 3 | ( 4 | acl text 5 | ,num int 6 | ,sysuser text 7 | ,sysgroup text 8 | ,size numeric 9 | ,modtime timestamp 10 | ,filename text 11 | )distributed randomly; 12 | 13 | drop table if exists public.gp_seg_table_size cascade; 14 | create table public.gp_seg_table_size 15 | ( 16 | hostname text 17 | ,oid oid 18 | ,relnamespace oid 19 | ,relname name 20 | ,reltablespace oid 21 | ,relfilenode oid 22 | ,size numeric 23 | ,relfilecount int 24 | ,max_modtime timestamp 25 | ) distributed randomly; 26 | 27 | 28 | CREATE LANGUAGE plpythonu; 29 | 30 | 31 | DROP FUNCTION IF EXISTS public.hostname(); 32 | CREATE or replace FUNCTION public.hostname() RETURNS 33 | text 34 | as $$ 35 | import socket 36 | return socket.gethostname() 37 | $$ LANGUAGE plpythonu; 38 | 39 | 40 | 41 | 42 | DROP FUNCTION IF EXISTS public.load_files_size(); 43 | CREATE or REPLACE FUNCTION public.load_files_size() RETURNS text 44 | as $$ 45 | import subprocess 46 | 47 | rows = plpy.execute("select current_database() dbname, current_setting('port') portno;") 48 | (dbname, portno) = (rows[0]["dbname"], rows[0]["portno"]) 49 | rows = plpy.execute("select '/tmp/fs_'||current_setting('gp_dbid')||'.dat' as filename;") 50 | filename = rows[0]["filename"] 51 | 52 | def run_psql_utility(v_sql): 53 | psql_cmd = """PGOPTIONS='-c gp_session_role=utility' psql -v ON_ERROR_STOP=1 -d %s -p %s -A -X -t -c \"%s\" """ % (dbname, portno, v_sql) 54 | #plpy.info(psql_cmd) 55 | p = subprocess.Popen(psql_cmd,shell=True, stdout=subprocess.PIPE, stderr=subprocess.PIPE, stdin=subprocess.PIPE) 56 | p_stdout = p.stdout.read() 57 | p_stderr = p.stderr.read() 58 | p.wait() 59 | if p.returncode != 0: 60 | plpy.error(p_stderr) 61 | 62 | rows = plpy.execute("select 'export LANG=en_US.utf8;ls -l --time-style=''+%Y-%m-%d_%H:%M:%S'' '||current_setting('data_directory')||'/base/'||c.oid||'> /tmp/fs_'||current_setting('gp_dbid')||'.dat ; ' as cmd1 from pg_database c where c.datname=current_database();") 63 | cmd1 = rows[0]["cmd1"] 64 | rows = plpy.execute("select string_agg('ls -l --time-style=''+%Y-%m-%d_%H:%M:%S'' ' ||pg_tablespace_location(oid)||'/'||current_setting('gp_dbid')||'/*/'||(SELECT oid from pg_database where datname=current_database())||' >> /tmp/fs_'||current_setting('gp_dbid')||'.dat',' ; ') as cmd2 from pg_tablespace where oid not in (1663,1664);") 65 | cmd2 = rows[0]["cmd2"] 66 | if cmd2 is None: 67 | ls_cmd = cmd1 68 | else: 69 | ls_cmd = cmd1+cmd2 70 | #plpy.info(ls_cmd) 71 | p = subprocess.Popen(ls_cmd,shell=True, stdout=subprocess.PIPE, stderr=subprocess.PIPE, stdin=subprocess.PIPE) 72 | p_stdout = p.stdout.read() 73 | p_stderr = p.stderr.read() 74 | p.wait() 75 | if p.returncode != 0: 76 | plpy.notice(p_stderr) 77 | 78 | sed_cmd = "sed -i 's/[ ]\{1,\}/|/g;/?/d;/^total/d;/^\//d;/^$/d' "+filename 79 | #plpy.info(sed_cmd) 80 | p = subprocess.Popen(sed_cmd,shell=True, stdout=subprocess.PIPE, stderr=subprocess.PIPE, stdin=subprocess.PIPE) 81 | p_stdout = p.stdout.read() 82 | p_stderr = p.stderr.read() 83 | p.wait() 84 | if p.returncode != 0: 85 | plpy.error(p_stderr) 86 | 87 | copy_sql = "copy public.gp_seg_size_ora from '"+filename+"' delimiter '|';" 88 | run_psql_utility(copy_sql) 89 | 90 | insert_sql = "insert into public.gp_seg_table_size (select hostname(),a.oid,a.relnamespace,a.relname,a.reltablespace,a.relfilenode,b.size,b.relfilecount,b.max_modtime from pg_class a join (select split_part(filename,'.',1) as relfilenode,sum(size) size,count(*) relfilecount,max(modtime) max_modtime from gp_seg_size_ora group by 1) b on a.relfilenode::text=b.relfilenode);" 91 | run_psql_utility(insert_sql) 92 | 93 | return "OK" 94 | $$ LANGUAGE plpythonu; 95 | 96 | 97 | --truncate gp_seg_size_ora; 98 | --truncate gp_seg_table_size; 99 | --select gp_segment_id,public.load_files_size() from gp_dist_random('gp_id'); 100 | 101 | 102 | 103 | 104 | -------------------------------------------------------------------------------- /gp_healthcheck/gpsize/load_files_size_v7.sql: -------------------------------------------------------------------------------- 1 | drop table if exists public.gp_seg_size_ora cascade; 2 | create table public.gp_seg_size_ora 3 | ( 4 | acl text 5 | ,num int 6 | ,sysuser text 7 | ,sysgroup text 8 | ,size numeric 9 | ,modtime timestamp 10 | ,filename text 11 | )distributed randomly; 12 | 13 | drop table if exists public.gp_seg_table_size cascade; 14 | create table public.gp_seg_table_size 15 | ( 16 | hostname text 17 | ,oid oid 18 | ,relnamespace oid 19 | ,relname name 20 | ,reltablespace oid 21 | ,relfilenode oid 22 | ,size numeric 23 | ,relfilecount int 24 | ,max_modtime timestamp 25 | ) distributed randomly; 26 | 27 | 28 | CREATE LANGUAGE plpython3u; 29 | 30 | 31 | DROP FUNCTION IF EXISTS public.hostname(); 32 | CREATE or replace FUNCTION public.hostname() RETURNS 33 | text 34 | as $$ 35 | import socket 36 | return socket.gethostname() 37 | $$ LANGUAGE plpython3u; 38 | 39 | 40 | 41 | 42 | DROP FUNCTION IF EXISTS public.load_files_size(); 43 | CREATE or REPLACE FUNCTION public.load_files_size() RETURNS text 44 | as $$ 45 | import subprocess 46 | 47 | rows = plpy.execute("select current_database() dbname, current_setting('port') portno;") 48 | (dbname, portno) = (rows[0]["dbname"], rows[0]["portno"]) 49 | rows = plpy.execute("select '/tmp/fs_'||current_setting('gp_dbid')||'.dat' as filename;") 50 | filename = rows[0]["filename"] 51 | 52 | def run_psql_utility(v_sql): 53 | psql_cmd = """PGOPTIONS='-c gp_session_role=utility' psql -v ON_ERROR_STOP=1 -d %s -p %s -A -X -t -c \"%s\" """ % (dbname, portno, v_sql) 54 | #plpy.info(psql_cmd) 55 | p = subprocess.Popen(psql_cmd,shell=True, stdout=subprocess.PIPE, stderr=subprocess.PIPE, stdin=subprocess.PIPE) 56 | p_stdout = p.stdout.read() 57 | p_stderr = p.stderr.read() 58 | p.wait() 59 | if p.returncode != 0: 60 | plpy.error(p_stderr) 61 | 62 | rows = plpy.execute("select 'export LANG=en_US.utf8;ls -l --time-style=''+%Y-%m-%d_%H:%M:%S'' '||current_setting('data_directory')||'/base/'||c.oid||'> /tmp/fs_'||current_setting('gp_dbid')||'.dat ; ' as cmd1 from pg_database c where c.datname=current_database();") 63 | cmd1 = rows[0]["cmd1"] 64 | rows = plpy.execute("select string_agg('ls -l --time-style=''+%Y-%m-%d_%H:%M:%S'' ' ||pg_tablespace_location(oid)||'/'||current_setting('gp_dbid')||'/*/'||(SELECT oid from pg_database where datname=current_database())||' >> /tmp/fs_'||current_setting('gp_dbid')||'.dat',' ; ') as cmd2 from pg_tablespace where oid not in (1663,1664);") 65 | cmd2 = rows[0]["cmd2"] 66 | if cmd2 is None: 67 | ls_cmd = cmd1 68 | else: 69 | ls_cmd = cmd1+cmd2 70 | #plpy.info(ls_cmd) 71 | p = subprocess.Popen(ls_cmd,shell=True, stdout=subprocess.PIPE, stderr=subprocess.PIPE, stdin=subprocess.PIPE) 72 | p_stdout = p.stdout.read() 73 | p_stderr = p.stderr.read() 74 | p.wait() 75 | if p.returncode != 0: 76 | plpy.notice(p_stderr) 77 | 78 | sed_cmd = "sed -i 's/[ ]\{1,\}/|/g;/?/d;/^total/d;/^\//d;/^$/d' "+filename 79 | #plpy.info(sed_cmd) 80 | p = subprocess.Popen(sed_cmd,shell=True, stdout=subprocess.PIPE, stderr=subprocess.PIPE, stdin=subprocess.PIPE) 81 | p_stdout = p.stdout.read() 82 | p_stderr = p.stderr.read() 83 | p.wait() 84 | if p.returncode != 0: 85 | plpy.error(p_stderr) 86 | 87 | copy_sql = "copy public.gp_seg_size_ora from '"+filename+"' delimiter '|';" 88 | run_psql_utility(copy_sql) 89 | 90 | insert_sql = "insert into public.gp_seg_table_size (select hostname(),a.oid,a.relnamespace,a.relname,a.reltablespace,a.relfilenode,b.size,b.relfilecount,b.max_modtime from pg_class a join (select split_part(filename,'.',1) as relfilenode,sum(size) size,count(*) relfilecount,max(modtime) max_modtime from gp_seg_size_ora group by 1) b on a.relfilenode::text=b.relfilenode);" 91 | run_psql_utility(insert_sql) 92 | 93 | return "OK" 94 | $$ LANGUAGE plpython3u; 95 | 96 | 97 | --truncate gp_seg_size_ora; 98 | --truncate gp_seg_table_size; 99 | --select gp_segment_id,public.load_files_size() from gp_dist_random('gp_id'); 100 | 101 | 102 | 103 | 104 | -------------------------------------------------------------------------------- /gp_healthcheck/skew/skewcheck_func.sql: -------------------------------------------------------------------------------- 1 | CREATE TYPE type_skew_resultset as (tablename text,sys_segcount int,data_segcount int,maxsize_segid int,maxsize text,skew numeric(18,2),dk text); 2 | 3 | 4 | 5 | ----s_schema format: 'schema1,schema2,schema3' 6 | CREATE OR REPLACE FUNCTION skewcheck_func(s_schema text) 7 | RETURNS SETOF type_skew_resultset AS 8 | $$ 9 | declare 10 | v_record type_skew_resultset%rowtype; 11 | i_sys_segcount int; 12 | schema_array text[]; 13 | v_schemastr text; 14 | i int; 15 | v_sql text; 16 | 17 | BEGIN 18 | --select * from skewcheck_func('public,dw,ods'); 19 | schema_array := string_to_array(s_schema,','); 20 | --raise info '%,%',array_lower(schema_array,1),array_upper(schema_array,1); 21 | v_schemastr := '('; 22 | i := 1; 23 | while i <= array_upper(schema_array,1) loop 24 | --raise info '%',schema_array[i]; 25 | if i-1 and role='p'; 35 | 36 | drop table if exists skewresult_new2; 37 | create temp table skewresult_new2 ( 38 | tablename varchar(100), 39 | partname varchar(200), 40 | segid int, 41 | cnt bigint 42 | ) distributed randomly; 43 | 44 | v_sql := 'insert into skewresult_new2 45 | select case when position(''_1_prt_'' in nsp.nspname||''.''||rel.relname)>0 then 46 | substr(nsp.nspname||''.''||rel.relname,1,position(''_1_prt_'' in nsp.nspname||''.''||rel.relname)-1) 47 | else nsp.nspname||''.''||rel.relname 48 | end 49 | ,nsp.nspname||''.''||rel.relname 50 | ,rel.gp_segment_id 51 | ,pg_relation_size(E''\"''||nsp.nspname||E''\".\"''||rel.relname||E''\"'') 52 | from gp_dist_random(''pg_class'') rel, pg_namespace nsp 53 | where nsp.oid=rel.relnamespace and rel.relkind=''r'' and relstorage!=''x'' 54 | and nsp.nspname in '||v_schemastr; 55 | execute v_sql; 56 | 57 | drop table if exists skewresult_tmp; 58 | create temp table skewresult_tmp ( 59 | tablename varchar(100), 60 | segid int, 61 | rec_num numeric(30,0) 62 | ) distributed by (tablename); 63 | 64 | insert into skewresult_tmp 65 | select tablename,segid,sum(cnt) as rec_num from skewresult_new2 66 | where tablename in ( 67 | select tablename from skewresult_new2 group by 1 having sum(cnt)>1073741824 68 | ) group by 1,2 having sum(cnt)>0; 69 | 70 | drop table if exists skewresult_tabledk; 71 | create temp table skewresult_tabledk 72 | as 73 | select tablename,string_agg(attname,',' order by attid) dk 74 | from ( 75 | select nsp.nspname||'.'||rel.relname tablename,a.attrnums[attid] attnum,attid,att.attname 76 | from pg_catalog.gp_distribution_policy a, 77 | generate_series(1,50) attid, 78 | pg_attribute att, 79 | pg_class rel, 80 | pg_namespace nsp 81 | where rel.oid=a.localoid and rel.relnamespace=nsp.oid and a.localoid=att.attrelid 82 | and array_upper(a.attrnums,1)>=attid and a.attrnums[attid]=att.attnum 83 | and relname not like '%_1_prt_%' 84 | ) foo 85 | group by 1 86 | distributed randomly; 87 | 88 | drop table if exists tmp_skewresult; 89 | create temp table tmp_skewresult 90 | (tablename text,sys_segcount int,data_segcount int,maxsize_segid int,maxsize bigint,skew numeric(18,2),dk text) 91 | distributed randomly; 92 | 93 | insert into tmp_skewresult 94 | select t1.tablename,i_sys_segcount,t1.segcount,t2.segid max_segid,t2.segsize max_segsize,t3.skew::numeric(18,2),t4.dk 95 | from ( 96 | select tablename,count(*) as segcount from skewresult_tmp 97 | group by 1 having count(*)0.5 126 | ) t3 on t1.tablename=t3.tablename 127 | left join skewresult_tabledk t4 on t1.tablename=t4.tablename 128 | where t2.rn=1; 129 | 130 | 131 | for v_record in 132 | select tablename,sys_segcount,data_segcount,maxsize_segid,pg_size_pretty(maxsize::bigint),skew,dk from tmp_skewresult 133 | order by data_segcount asc,maxsize desc 134 | loop 135 | return next v_record; 136 | end loop; 137 | return; 138 | 139 | END; 140 | $$ 141 | LANGUAGE plpgsql volatile; 142 | -------------------------------------------------------------------------------- /gp_healthcheck/skew/skewcheck_func_gp6.sql: -------------------------------------------------------------------------------- 1 | CREATE TYPE type_skew_resultset as (tablename text,sys_segcount int,data_segcount int,maxsize_segid int,maxsize text,skew numeric(18,2),dk text); 2 | 3 | 4 | 5 | ----s_schema format: 'schema1,schema2,schema3' 6 | CREATE OR REPLACE FUNCTION skewcheck_func(s_schema text) 7 | RETURNS SETOF type_skew_resultset AS 8 | $$ 9 | declare 10 | v_record type_skew_resultset%rowtype; 11 | i_sys_segcount int; 12 | schema_array text[]; 13 | v_schemastr text; 14 | i int; 15 | v_sql text; 16 | 17 | BEGIN 18 | --select * from skewcheck_func('public,dw,ods'); 19 | schema_array := string_to_array(s_schema,','); 20 | --raise info '%,%',array_lower(schema_array,1),array_upper(schema_array,1); 21 | v_schemastr := '('; 22 | i := 1; 23 | while i <= array_upper(schema_array,1) loop 24 | --raise info '%',schema_array[i]; 25 | if i-1 and role='p'; 35 | 36 | drop table if exists skewresult_new2; 37 | create temp table skewresult_new2 ( 38 | tablename varchar(100), 39 | partname varchar(200), 40 | segid int, 41 | cnt bigint 42 | ) distributed randomly; 43 | 44 | v_sql := 'insert into skewresult_new2 45 | select case when position(''_1_prt_'' in nsp.nspname||''.''||rel.relname)>0 then 46 | substr(nsp.nspname||''.''||rel.relname,1,position(''_1_prt_'' in nsp.nspname||''.''||rel.relname)-1) 47 | else nsp.nspname||''.''||rel.relname 48 | end 49 | ,nsp.nspname||''.''||rel.relname 50 | ,rel.gp_segment_id 51 | ,pg_relation_size(E''\"''||nsp.nspname||E''\".\"''||rel.relname||E''\"'') 52 | from gp_dist_random(''pg_class'') rel, pg_namespace nsp 53 | where nsp.oid=rel.relnamespace and rel.relkind=''r'' and relstorage!=''x'' 54 | and nsp.nspname in '||v_schemastr; 55 | execute v_sql; 56 | 57 | drop table if exists skewresult_tmp; 58 | create temp table skewresult_tmp ( 59 | tablename varchar(100), 60 | segid int, 61 | rec_num numeric(30,0) 62 | ) distributed by (tablename); 63 | 64 | insert into skewresult_tmp 65 | select tablename,segid,sum(cnt) as rec_num from skewresult_new2 66 | where tablename in ( 67 | select tablename from skewresult_new2 group by 1 having sum(cnt)>1073741824 68 | ) group by 1,2 having sum(cnt)>0; 69 | 70 | drop table if exists skewresult_tabledk; 71 | create temp table skewresult_tabledk 72 | as 73 | select tablename,string_agg(attname,',' order by attid) dk 74 | from ( 75 | select nsp.nspname||'.'||rel.relname tablename,a.distkey[attid] attnum,attid,att.attname 76 | from pg_catalog.gp_distribution_policy a, 77 | generate_series(0,50) attid, 78 | pg_attribute att, 79 | pg_class rel, 80 | pg_namespace nsp 81 | where rel.oid=a.localoid and rel.relnamespace=nsp.oid and a.localoid=att.attrelid 82 | and array_upper(a.distkey,1)>=attid and a.distkey[attid]=att.attnum 83 | and relname not like '%_1_prt_%' 84 | ) foo 85 | group by 1 86 | distributed randomly; 87 | 88 | drop table if exists tmp_skewresult; 89 | create temp table tmp_skewresult 90 | (tablename text,sys_segcount int,data_segcount int,maxsize_segid int,maxsize bigint,skew numeric(18,2),dk text) 91 | distributed randomly; 92 | 93 | insert into tmp_skewresult 94 | select t1.tablename,i_sys_segcount,t1.segcount,t2.segid max_segid,t2.segsize max_segsize,t3.skew::numeric(18,2),t4.dk 95 | from ( 96 | select tablename,count(*) as segcount from skewresult_tmp 97 | group by 1 having count(*)0.5 126 | ) t3 on t1.tablename=t3.tablename 127 | left join skewresult_tabledk t4 on t1.tablename=t4.tablename 128 | where t2.rn=1; 129 | 130 | 131 | for v_record in 132 | select tablename,sys_segcount,data_segcount,maxsize_segid,pg_size_pretty(maxsize::bigint),skew,dk from tmp_skewresult 133 | order by data_segcount asc,maxsize desc 134 | loop 135 | return next v_record; 136 | end loop; 137 | return; 138 | 139 | END; 140 | $$ 141 | LANGUAGE plpgsql volatile; 142 | 143 | 144 | 145 | CREATE OR REPLACE FUNCTION skewcheck_func() 146 | RETURNS SETOF type_skew_resultset AS 147 | $$ 148 | declare 149 | v_record type_skew_resultset%rowtype; 150 | i_sys_segcount int; 151 | 152 | BEGIN 153 | --select * from skewcheck_func(); 154 | 155 | select count(*) into i_sys_segcount from gp_segment_configuration where content>-1 and role='p'; 156 | 157 | drop table if exists skewresult_new2; 158 | create temp table skewresult_new2 ( 159 | tablename varchar(100), 160 | partname varchar(200), 161 | segid int, 162 | cnt bigint 163 | ) distributed randomly; 164 | insert into skewresult_new2 165 | select case when position('_1_prt_' in nsp.nspname||'.'||rel.relname)>0 then 166 | substr(nsp.nspname||'.'||rel.relname,1,position('_1_prt_' in nsp.nspname||'.'||rel.relname)-1) 167 | else nsp.nspname||'.'||rel.relname 168 | end 169 | ,nsp.nspname||'.'||rel.relname 170 | ,rel.gp_segment_id 171 | ,pg_relation_size(E'\"'||nsp.nspname||E'\".\"'||rel.relname||E'\"') 172 | from gp_dist_random('pg_class') rel, pg_namespace nsp 173 | where nsp.oid=rel.relnamespace and rel.relkind='r' and relstorage!='x' 174 | and nsp.nspname not like 'pg%' and nsp.nspname not like 'gp%'; 175 | 176 | drop table if exists skewresult_tmp; 177 | create temp table skewresult_tmp ( 178 | tablename varchar(100), 179 | segid int, 180 | rec_num numeric(30,0) 181 | ) distributed by (tablename); 182 | 183 | insert into skewresult_tmp 184 | select tablename,segid,sum(cnt) as rec_num from skewresult_new2 185 | where tablename in ( 186 | select tablename from skewresult_new2 group by 1 having sum(cnt)>1073741824 187 | ) group by 1,2 having sum(cnt)>0; 188 | 189 | drop table if exists skewresult_tabledk; 190 | create temp table skewresult_tabledk 191 | as 192 | select tablename,string_agg(attname,',' order by attid) dk 193 | from ( 194 | select nsp.nspname||'.'||rel.relname tablename,a.distkey[attid] attnum,attid,att.attname 195 | from pg_catalog.gp_distribution_policy a, 196 | generate_series(0,50) attid, 197 | pg_attribute att, 198 | pg_class rel, 199 | pg_namespace nsp 200 | where rel.oid=a.localoid and rel.relnamespace=nsp.oid and a.localoid=att.attrelid 201 | and array_upper(a.distkey,1)>=attid and a.distkey[attid]=att.attnum 202 | and relname not like '%_1_prt_%' 203 | ) foo 204 | group by 1 205 | distributed randomly; 206 | 207 | drop table if exists tmp_skewresult; 208 | create temp table tmp_skewresult 209 | (tablename text,sys_segcount int,data_segcount int,maxsize_segid int,maxsize bigint,skew numeric(18,2),dk text) 210 | distributed randomly; 211 | 212 | insert into tmp_skewresult 213 | select t1.tablename,i_sys_segcount,t1.segcount,t2.segid max_segid,t2.segsize max_segsize,t3.skew::numeric(18,2),t4.dk 214 | from ( 215 | select tablename,count(*) as segcount from skewresult_tmp 216 | group by 1 having count(*)0.5 245 | ) t3 on t1.tablename=t3.tablename 246 | left join skewresult_tabledk t4 on t1.tablename=t4.tablename 247 | where t2.rn=1; 248 | 249 | 250 | for v_record in 251 | select tablename,sys_segcount,data_segcount,maxsize_segid,pg_size_pretty(maxsize::bigint),skew,dk from tmp_skewresult 252 | order by data_segcount asc,maxsize desc 253 | loop 254 | return next v_record; 255 | end loop; 256 | return; 257 | 258 | END; 259 | $$ 260 | LANGUAGE plpgsql volatile; 261 | 262 | -------------------------------------------------------------------------------- /gp_healthcheck/skew/skewcheck_func_gp7.sql: -------------------------------------------------------------------------------- 1 | CREATE TYPE type_skew_resultset as (tablename regclass,sys_segcount int,data_segcount int,maxsize_segid int,maxsize text,skew numeric(18,2),dk text); 2 | 3 | 4 | 5 | ----s_schema format: 'schema1,schema2,schema3' 6 | CREATE OR REPLACE FUNCTION skewcheck_func(s_schema text) 7 | RETURNS SETOF type_skew_resultset AS 8 | $$ 9 | declare 10 | v_record type_skew_resultset%rowtype; 11 | i_sys_segcount int; 12 | schema_array text[]; 13 | v_schemastr text; 14 | i int; 15 | v_sql text; 16 | 17 | BEGIN 18 | --select * from skewcheck_func('public,dw,ods'); 19 | schema_array := string_to_array(s_schema,','); 20 | --raise info '%,%',array_lower(schema_array,1),array_upper(schema_array,1); 21 | v_schemastr := '('; 22 | i := 1; 23 | while i <= array_upper(schema_array,1) loop 24 | --raise info '%',schema_array[i]; 25 | if i-1 and role='p'; 35 | 36 | drop table if exists skewresult_new2; 37 | create temp table skewresult_new2 ( 38 | tablename regclass, 39 | partname regclass, 40 | segid int, 41 | cnt bigint 42 | ) distributed by (tablename); 43 | 44 | v_sql := 'insert into skewresult_new2 45 | select case when relispartition then pg_partition_root(rel.oid) 46 | else rel.oid::regclass 47 | end 48 | ,rel.oid::regclass 49 | ,rel.gp_segment_id 50 | ,pg_relation_size(rel.oid) 51 | from gp_dist_random(''pg_class'') rel, pg_namespace nsp 52 | where rel.relnamespace=nsp.oid and rel.relkind=''r'' and nsp.nspname in '||v_schemastr; 53 | execute v_sql; 54 | 55 | drop table if exists skewresult_tmp; 56 | create temp table skewresult_tmp ( 57 | tablename regclass, 58 | segid int, 59 | rec_num numeric(30,0) 60 | ) distributed by (tablename); 61 | 62 | insert into skewresult_tmp 63 | select tablename,segid,sum(cnt) as rec_num from skewresult_new2 64 | where tablename in ( 65 | select tablename from skewresult_new2 group by 1 having sum(cnt)>1073741824 66 | ) group by 1,2 having sum(cnt)>0; 67 | 68 | drop table if exists skewresult_tabledk; 69 | create temp table skewresult_tabledk ( 70 | tablename regclass, 71 | dk text 72 | ) distributed by (tablename); 73 | 74 | v_sql := 'insert into skewresult_tabledk 75 | select tablename,string_agg(attname,'','' order by attid) dk 76 | from ( 77 | select rel.oid::regclass tablename,a.distkey[attid] attnum,attid,att.attname 78 | from pg_catalog.gp_distribution_policy a, 79 | generate_series(0,50) attid, 80 | pg_attribute att, 81 | pg_class rel, 82 | pg_namespace nsp 83 | where rel.relnamespace=nsp.oid and rel.oid=a.localoid and a.localoid=att.attrelid 84 | and array_upper(a.distkey,1)>=attid and a.distkey[attid]=att.attnum and rel.relispartition=false 85 | and nsp.nspname in '||v_schemastr||' 86 | ) foo 87 | group by 1'; 88 | execute v_sql; 89 | 90 | drop table if exists tmp_skewresult; 91 | create temp table tmp_skewresult ( 92 | tablename regclass, 93 | sys_segcount int, 94 | data_segcount int, 95 | maxsize_segid int, 96 | maxsize bigint, 97 | skew numeric(18,2), 98 | dk text 99 | ) distributed by (tablename); 100 | 101 | insert into tmp_skewresult 102 | select t1.tablename,i_sys_segcount,t1.segcount,t2.segid max_segid,t2.segsize max_segsize,t3.skew::numeric(18,2),t4.dk 103 | from ( 104 | select tablename,count(*) as segcount from skewresult_tmp 105 | group by 1 having count(*)0.5 134 | ) t3 on t1.tablename=t3.tablename 135 | left join skewresult_tabledk t4 on t1.tablename=t4.tablename 136 | where t2.rn=1; 137 | 138 | 139 | for v_record in 140 | select tablename,sys_segcount,data_segcount,maxsize_segid,pg_size_pretty(maxsize::bigint),skew,dk from tmp_skewresult 141 | order by data_segcount asc,maxsize desc 142 | loop 143 | return next v_record; 144 | end loop; 145 | return; 146 | 147 | END; 148 | $$ 149 | LANGUAGE plpgsql volatile; 150 | 151 | 152 | 153 | CREATE OR REPLACE FUNCTION skewcheck_func() 154 | RETURNS SETOF type_skew_resultset AS 155 | $$ 156 | declare 157 | v_record type_skew_resultset%rowtype; 158 | i_sys_segcount int; 159 | 160 | BEGIN 161 | --select * from skewcheck_func(); 162 | 163 | select count(*) into i_sys_segcount from gp_segment_configuration where content>-1 and role='p'; 164 | 165 | drop table if exists skewresult_new2; 166 | create temp table skewresult_new2 ( 167 | tablename regclass, 168 | partname regclass, 169 | segid int, 170 | cnt bigint 171 | ) distributed randomly; 172 | 173 | insert into skewresult_new2 174 | select case when relispartition then pg_partition_root(rel.oid) 175 | else rel.oid::regclass 176 | end 177 | ,rel.oid::regclass 178 | ,rel.gp_segment_id 179 | ,pg_relation_size(rel.oid) 180 | from gp_dist_random('pg_class') rel, pg_namespace nsp 181 | where rel.relnamespace=nsp.oid and rel.relkind='r'; 182 | 183 | drop table if exists skewresult_tmp; 184 | create temp table skewresult_tmp ( 185 | tablename varchar(100), 186 | segid int, 187 | rec_num numeric(30,0) 188 | ) distributed by (tablename); 189 | 190 | insert into skewresult_tmp 191 | select tablename,segid,sum(cnt) as rec_num from skewresult_new2 192 | where tablename in ( 193 | select tablename from skewresult_new2 group by 1 having sum(cnt)>1073741824 194 | ) group by 1,2 having sum(cnt)>0; 195 | 196 | drop table if exists skewresult_tabledk; 197 | create temp table skewresult_tabledk 198 | as 199 | select tablename,string_agg(attname,',' order by attid) dk 200 | from ( 201 | select nsp.nspname||'.'||rel.relname tablename,a.distkey[attid] attnum,attid,att.attname 202 | from pg_catalog.gp_distribution_policy a, 203 | generate_series(0,50) attid, 204 | pg_attribute att, 205 | pg_class rel, 206 | pg_namespace nsp 207 | where rel.oid=a.localoid and rel.relnamespace=nsp.oid and a.localoid=att.attrelid 208 | and array_upper(a.distkey,1)>=attid and a.distkey[attid]=att.attnum 209 | and relname not like '%_1_prt_%' 210 | ) foo 211 | group by 1 212 | distributed randomly; 213 | 214 | drop table if exists tmp_skewresult; 215 | create temp table tmp_skewresult 216 | (tablename text,sys_segcount int,data_segcount int,maxsize_segid int,maxsize bigint,skew numeric(18,2),dk text) 217 | distributed randomly; 218 | 219 | insert into tmp_skewresult 220 | select t1.tablename,i_sys_segcount,t1.segcount,t2.segid max_segid,t2.segsize max_segsize,t3.skew::numeric(18,2),t4.dk 221 | from ( 222 | select tablename,count(*) as segcount from skewresult_tmp 223 | group by 1 having count(*)0.5 252 | ) t3 on t1.tablename=t3.tablename 253 | left join skewresult_tabledk t4 on t1.tablename=t4.tablename 254 | where t2.rn=1; 255 | 256 | 257 | for v_record in 258 | select tablename,sys_segcount,data_segcount,maxsize_segid,pg_size_pretty(maxsize::bigint),skew,dk from tmp_skewresult 259 | order by data_segcount asc,maxsize desc 260 | loop 261 | return next v_record; 262 | end loop; 263 | return; 264 | 265 | END; 266 | $$ 267 | LANGUAGE plpgsql volatile; 268 | 269 | -------------------------------------------------------------------------------- /gpsize/README.txt: -------------------------------------------------------------------------------- 1 | Preparation: 2 | Check if plpythonu is created: select * from pg_language; 3 | If not, please create language plpythonu: create language plpythonu; 4 | 5 | Installation: 6 | For GP4.3 and GP5: 7 | psql dbname -af ./gpsize/load_files_size.sql 8 | For GP6: 9 | psql dbname -af ./gpsize/load_files_size_v6.sql 10 | 11 | Information: 12 | This component is used to query all data files on all segment instances. Query result load into table public.gp_seg_size. 13 | Base on public.gp_seg_size, we can calculate schema size, table size, tablespace size, tablespace file numbers. 14 | But not recommend to calculate database size, because of public.gp_seg_size is not include data file size on master instance. 15 | 16 | Usage: 17 | 1, Prepare gpsize data, insert into gp_seg_table_size 18 | truncate gp_seg_size_ora; 19 | truncate gp_seg_table_size; 20 | select gp_segment_id,public.load_files_size() from gp_dist_random('gp_id'); 21 | 22 | 2, Use SQL in gpsize.sql / gpsize_v6.sql, Calculate schema size, tablespace size, large table in DB ... 23 | 24 | 25 | 26 | ------------------- 27 | Calculate partition table size function: public.gp_partitiontable_size(tablename text) 28 | Can not use on none partition table. 29 | 30 | Installation: 31 | psql dbname -af gp_partitiontable_size.sql 32 | 33 | Sample: 34 | select gp_partitiontable_size('schemaname.tablename'); 35 | 36 | 37 | 38 | 39 | -------------------------------------------------------------------------------- /gpsize/gp_partitiontable_size.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION public.gp_partitiontable_size(tablename text) 2 | RETURNS bigint AS 3 | $$ 4 | DECLARE 5 | s_schema name; 6 | s_table name; 7 | i_size bigint; 8 | v_sql text; 9 | BEGIN 10 | select nspname,relname into s_schema,s_table from pg_namespace aa, pg_class bb 11 | where aa.oid=bb.relnamespace and bb.oid=tablename::regclass; 12 | --raise info '%,%',s_schema,s_table; 13 | 14 | v_sql := E'select sum(pg_relation_size(E''\\\"''||partitionschemaname||E''\\\".\\\"''||partitiontablename||E''\\\"''))::bigint 15 | from pg_partitions where schemaname='''||s_schema||''' and tablename='''||s_table||''';'; 16 | --raise info '%', v_sql; 17 | execute v_sql into i_size; 18 | 19 | return i_size; 20 | END; 21 | $$ 22 | LANGUAGE plpgsql volatile; 23 | 24 | 25 | -------------------------------------------------------------------------------- /gpsize/gp_partitiontable_size_gp7.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION public.gp_partitiontable_size(tablename text) 2 | RETURNS bigint AS 3 | $$ 4 | DECLARE 5 | i_size bigint; 6 | BEGIN 7 | SELECT sum(pg_relation_size(partitiontablename))::bigint into i_size FROM ( 8 | SELECT pg_partition_root(c.oid)::regclass AS tablename, 9 | c.oid::regclass AS partitiontablename 10 | FROM pg_class c 11 | WHERE c.relispartition = true and pg_partition_root(c.oid)=tablename::regclass 12 | ) foo; 13 | 14 | return i_size; 15 | END; 16 | $$ 17 | LANGUAGE plpgsql volatile; 18 | 19 | 20 | -------------------------------------------------------------------------------- /gpsize/gpsize.sql: -------------------------------------------------------------------------------- 1 | ----init data file size 2 | truncate gp_seg_size_ora; 3 | truncate gp_seg_table_size; 4 | select gp_segment_id,public.load_files_size() from gp_dist_random('gp_id'); 5 | 6 | 7 | ----schema size 8 | with foo as (select relnamespace,sum(size)::bigint as size from gp_seg_table_size group by 1) 9 | select a.nspname,pg_size_pretty(b.size) 10 | from pg_namespace a,foo b 11 | where a.oid=b.relnamespace and a.nspname not like 'pg_temp%' 12 | order by b.size desc; 13 | 14 | ----tablespace size 15 | select case when spcname is null then 'pg_default' else spcname end as tsname, 16 | pg_size_pretty(tssize) 17 | from ( 18 | select c.spcname,sum(a.size)::bigint tssize 19 | from gp_seg_table_size a 20 | left join pg_tablespace c on a.reltablespace=c.oid 21 | group by 1 22 | ) foo 23 | order by tsname; 24 | 25 | 26 | ----tablespace filenum 27 | select tsname,segfilenum as max_segfilenum 28 | from ( 29 | select case when spcname is null then 'pg_default' else spcname end as tsname, 30 | segfilenum, 31 | row_number() over(partition by spcname order by segfilenum desc) rn 32 | from ( 33 | select c.spcname,a.gp_segment_id segid,sum(relfilecount) segfilenum 34 | from gp_seg_table_size a 35 | left join pg_tablespace c on a.reltablespace=c.oid 36 | group by 1,2 37 | ) foo 38 | ) t1 where rn=1 39 | order by tsname; 40 | 41 | 42 | ----large table top 100 43 | --AO table 44 | select b.nspname||'.'||a.relname as tablename, c.relstorage, pg_size_pretty(sum(a.size)::bigint) as table_size 45 | from gp_seg_table_size a,pg_namespace b,pg_class c where a.relnamespace=b.oid and a.oid=c.oid and c.relstorage in ('a','c') 46 | --and c.relname not like '%_1_prt_%' 47 | group by 1,2 order by sum(a.size) desc limit 100; 48 | 49 | --heap 50 | select b.nspname||'.'||a.relname as tablename, c.relstorage, pg_size_pretty(sum(a.size)::bigint) as table_size 51 | from gp_seg_table_size a,pg_namespace b,pg_class c where a.relnamespace=b.oid and a.oid=c.oid and c.relstorage = 'h' 52 | --and c.relname not like '%_1_prt_%' 53 | group by 1,2 order by sum(a.size) desc limit 100; 54 | 55 | 56 | ----skew check 57 | CREATE TYPE type_skew_resultset as (tablename text,sys_segcount int,data_segcount int,maxsize_segid int,maxsize text,skew numeric(18,2),dk text); 58 | 59 | CREATE OR REPLACE FUNCTION skewcheck_from_fsize() 60 | RETURNS SETOF type_skew_resultset AS 61 | $$ 62 | declare 63 | v_record type_skew_resultset%rowtype; 64 | i_sys_segcount int; 65 | BEGIN 66 | --select * from skewcheck_from_fsize(); 67 | 68 | select count(*) into i_sys_segcount from gp_segment_configuration where content>-1 and role='p'; 69 | 70 | drop table if exists skewresult_new2; 71 | create temp table skewresult_new2 ( 72 | tablename varchar(100), 73 | partname varchar(200), 74 | segid int, 75 | cnt bigint 76 | ) distributed randomly; 77 | 78 | insert into skewresult_new2 79 | select case when position('_1_prt_' in tablename)>0 then 80 | substr(tablename,1,position('_1_prt_' in tablename)-1) 81 | else tablename 82 | end as tablename 83 | ,tablename as partname 84 | ,segid 85 | ,seg_size 86 | from ( 87 | select b.nspname||'.'||a.relname as tablename, a.gp_segment_id segid, sum(a.size)::bigint as seg_size 88 | from gp_seg_table_size a,pg_namespace b,pg_class c where a.relnamespace=b.oid and a.oid=c.oid and c.relstorage = 'h' 89 | and b.nspname not like 'pg%' and b.nspname not like 'gp%' 90 | group by 1,2 91 | ) t1; 92 | 93 | drop table if exists skewresult_tmp; 94 | create temp table skewresult_tmp ( 95 | tablename varchar(100), 96 | segid int, 97 | rec_num numeric(30,0) 98 | ) distributed by (tablename); 99 | 100 | insert into skewresult_tmp 101 | select tablename,segid,sum(cnt) as rec_num from skewresult_new2 102 | where tablename in ( 103 | select tablename from skewresult_new2 group by 1 having sum(cnt)>1073741824 104 | ) group by 1,2 having sum(cnt)>0; 105 | 106 | drop table if exists skewresult_tabledk; 107 | create temp table skewresult_tabledk 108 | as 109 | select tablename,string_agg(attname,',' order by attid) dk 110 | from ( 111 | select nsp.nspname||'.'||rel.relname tablename,a.attrnums[attid] attnum,attid,att.attname 112 | from gp_distribution_policy a, 113 | generate_series(1,50) attid, 114 | pg_attribute att, 115 | pg_class rel, 116 | pg_namespace nsp 117 | where rel.oid=a.localoid and rel.relnamespace=nsp.oid and a.localoid=att.attrelid 118 | and array_upper(a.attrnums,1)>=attid and a.attrnums[attid]=att.attnum 119 | and relname not like '%_1_prt_%' 120 | ) foo 121 | group by 1 122 | distributed randomly; 123 | 124 | drop table if exists tmp_skewresult; 125 | create temp table tmp_skewresult 126 | (tablename text,sys_segcount int,data_segcount int,maxsize_segid int,maxsize bigint,skew numeric(18,2),dk text) 127 | distributed randomly; 128 | 129 | insert into tmp_skewresult 130 | select t1.tablename,i_sys_segcount,t1.segcount,t2.segid max_segid,t2.segsize max_segsize,t3.skew::numeric(18,2),t4.dk 131 | from ( 132 | select tablename,count(*) as segcount from skewresult_tmp 133 | group by 1 having count(*)0.5 162 | ) t3 on t1.tablename=t3.tablename 163 | left join skewresult_tabledk t4 on t1.tablename=t4.tablename 164 | where t2.rn=1; 165 | 166 | 167 | for v_record in 168 | select tablename,sys_segcount,data_segcount,maxsize_segid,pg_size_pretty(maxsize::bigint),skew,dk from tmp_skewresult 169 | order by data_segcount asc,maxsize desc 170 | loop 171 | return next v_record; 172 | end loop; 173 | return; 174 | 175 | END; 176 | $$ 177 | LANGUAGE plpgsql volatile; 178 | 179 | select * from skewcheck_from_fsize(); 180 | 181 | 182 | 183 | 184 | 185 | -------------------------------------------------------------------------------- /gpsize/gpsize_v6.sql: -------------------------------------------------------------------------------- 1 | ----init data file size 2 | truncate gp_seg_size_ora; 3 | truncate gp_seg_table_size; 4 | 5 | select gp_segment_id,public.load_files_size() from gp_dist_random('gp_id'); 6 | 7 | 8 | ----schema size 9 | with foo as (select relnamespace,sum(size)::bigint as size from gp_seg_table_size group by 1) 10 | select a.nspname,pg_size_pretty(b.size) 11 | from pg_namespace a,foo b 12 | where a.oid=b.relnamespace and a.nspname not like 'pg_temp%' 13 | order by b.size desc; 14 | 15 | ----tablespace size 16 | select case when spcname is null then 'pg_default' else spcname end as tsname, 17 | pg_size_pretty(tssize) 18 | from ( 19 | select c.spcname,sum(a.size)::bigint tssize 20 | from gp_seg_table_size a 21 | left join pg_tablespace c on a.reltablespace=c.oid 22 | group by 1 23 | ) foo 24 | order by tsname; 25 | 26 | 27 | ----tablespace filenum 28 | select tsname,segfilenum as max_segfilenum 29 | from ( 30 | select case when spcname is null then 'pg_default' else spcname end as tsname, 31 | segfilenum, 32 | row_number() over(partition by spcname order by segfilenum desc) rn 33 | from ( 34 | select c.spcname,a.gp_segment_id segid,sum(relfilecount) segfilenum 35 | from gp_seg_table_size a 36 | left join pg_tablespace c on a.reltablespace=c.oid 37 | group by 1 38 | ) foo 39 | ) t1 where rn=1 40 | order by tsname; 41 | 42 | 43 | ----large table top 100 44 | --AO table 45 | select b.nspname||'.'||a.relname as tablename, c.relstorage, pg_size_pretty(sum(a.size)::bigint) as table_size 46 | from gp_seg_table_size a,pg_namespace b,pg_class c where a.relnamespace=b.oid and a.oid=c.oid and c.relstorage in ('a','c') 47 | --and c.relname not like '%_1_prt_%' 48 | group by 1,2 order by sum(a.size) desc limit 100; 49 | 50 | --heap 51 | select b.nspname||'.'||a.relname as tablename, c.relstorage, pg_size_pretty(sum(a.size)::bigint) as table_size 52 | from gp_seg_table_size a,pg_namespace b,pg_class c where a.relnamespace=b.oid and a.oid=c.oid and c.relstorage = 'h' 53 | --and c.relname not like '%_1_prt_%' 54 | group by 1,2 order by sum(a.size) desc limit 100; 55 | 56 | 57 | ----skew check 58 | CREATE TYPE type_skew_resultset as (tablename text,sys_segcount int,data_segcount int,maxsize_segid int,maxsize text,skew numeric(18,2),dk text); 59 | 60 | 61 | CREATE OR REPLACE FUNCTION skewcheck_from_fsize() 62 | RETURNS SETOF type_skew_resultset AS 63 | $$ 64 | declare 65 | v_record type_skew_resultset%rowtype; 66 | i_sys_segcount int; 67 | BEGIN 68 | --select * from skewcheck_from_fsize(); 69 | 70 | select count(*) into i_sys_segcount from gp_segment_configuration where content>-1 and role='p'; 71 | 72 | drop table if exists skewresult_new2; 73 | create temp table skewresult_new2 ( 74 | tablename varchar(100), 75 | partname varchar(200), 76 | segid int, 77 | cnt bigint 78 | ) distributed randomly; 79 | 80 | insert into skewresult_new2 81 | select case when position('_1_prt_' in tablename)>0 then 82 | substr(tablename,1,position('_1_prt_' in tablename)-1) 83 | else tablename 84 | end as tablename 85 | ,tablename as partname 86 | ,segid 87 | ,seg_size 88 | from ( 89 | select b.nspname||'.'||a.relname as tablename, a.gp_segment_id segid, sum(a.size)::bigint as seg_size 90 | from gp_seg_table_size a,pg_namespace b,pg_class c where a.relnamespace=b.oid and a.oid=c.oid and c.relstorage = 'h' 91 | and b.nspname not like 'pg%' and b.nspname not like 'gp%' 92 | group by 1,2 93 | ) t1; 94 | 95 | drop table if exists skewresult_tmp; 96 | create temp table skewresult_tmp ( 97 | tablename varchar(100), 98 | segid int, 99 | rec_num numeric(30,0) 100 | ) distributed by (tablename); 101 | 102 | insert into skewresult_tmp 103 | select tablename,segid,sum(cnt) as rec_num from skewresult_new2 104 | where tablename in ( 105 | select tablename from skewresult_new2 group by 1 having sum(cnt)>1073741824 106 | ) group by 1,2 having sum(cnt)>0; 107 | 108 | drop table if exists skewresult_tabledk; 109 | create temp table skewresult_tabledk 110 | as 111 | select tablename,string_agg(attname,',' order by attid) dk 112 | from ( 113 | select nsp.nspname||'.'||rel.relname tablename,a.distkey[attid] attnum,attid,att.attname 114 | from pg_catalog.gp_distribution_policy a, 115 | generate_series(0,50) attid, 116 | pg_attribute att, 117 | pg_class rel, 118 | pg_namespace nsp 119 | where rel.oid=a.localoid and rel.relnamespace=nsp.oid and a.localoid=att.attrelid 120 | and array_upper(a.distkey,1)>=attid and a.distkey[attid]=att.attnum 121 | and relname not like '%_1_prt_%' 122 | ) foo 123 | group by 1 124 | distributed randomly; 125 | 126 | drop table if exists tmp_skewresult; 127 | create temp table tmp_skewresult 128 | (tablename text,sys_segcount int,data_segcount int,maxsize_segid int,maxsize bigint,skew numeric(18,2),dk text) 129 | distributed randomly; 130 | 131 | insert into tmp_skewresult 132 | select t1.tablename,i_sys_segcount,t1.segcount,t2.segid max_segid,t2.segsize max_segsize,t3.skew::numeric(18,2),t4.dk 133 | from ( 134 | select tablename,count(*) as segcount from skewresult_tmp 135 | group by 1 having count(*)0.5 164 | ) t3 on t1.tablename=t3.tablename 165 | left join skewresult_tabledk t4 on t1.tablename=t4.tablename 166 | where t2.rn=1; 167 | 168 | 169 | for v_record in 170 | select tablename,sys_segcount,data_segcount,maxsize_segid,pg_size_pretty(maxsize::bigint),skew,dk from tmp_skewresult 171 | order by data_segcount asc,maxsize desc 172 | loop 173 | return next v_record; 174 | end loop; 175 | return; 176 | 177 | END; 178 | $$ 179 | LANGUAGE plpgsql volatile; 180 | 181 | select * from skewcheck_from_fsize(); 182 | 183 | 184 | 185 | 186 | -------------------------------------------------------------------------------- /gpsize/load_files_size.sql: -------------------------------------------------------------------------------- 1 | drop table if exists public.gp_seg_size_ora cascade; 2 | create table public.gp_seg_size_ora 3 | ( 4 | acl text 5 | ,num int 6 | ,sysuser text 7 | ,sysgroup text 8 | ,size numeric 9 | ,modtime timestamp 10 | ,filename text 11 | )distributed randomly; 12 | 13 | drop table if exists public.gp_seg_table_size cascade; 14 | create table public.gp_seg_table_size 15 | ( 16 | hostname text 17 | ,oid oid 18 | ,relnamespace oid 19 | ,relname name 20 | ,reltablespace oid 21 | ,relfilenode oid 22 | ,size numeric 23 | ,relfilecount int 24 | ,max_modtime timestamp 25 | ) distributed randomly; 26 | 27 | 28 | DROP FUNCTION IF EXISTS public.hostname(); 29 | CREATE or replace FUNCTION public.hostname() RETURNS 30 | text 31 | as $$ 32 | import socket 33 | return socket.gethostname() 34 | $$ LANGUAGE plpythonu; 35 | 36 | 37 | 38 | DROP FUNCTION IF EXISTS public.load_files_size(); 39 | CREATE or REPLACE FUNCTION public.load_files_size() RETURNS text 40 | as $$ 41 | import subprocess 42 | 43 | rows = plpy.execute("select current_database() dbname, current_setting('port') portno;") 44 | (dbname, portno) = (rows[0]["dbname"], rows[0]["portno"]) 45 | rows = plpy.execute("select '/tmp/fs_'||current_setting('gp_dbid')||'.dat' as filename;") 46 | filename = rows[0]["filename"] 47 | 48 | def run_psql_utility(v_sql): 49 | psql_cmd = """PGOPTIONS='-c gp_session_role=utility' psql -v ON_ERROR_STOP=1 -d %s -p %s -A -X -t -c \"%s\" """ % (dbname, portno, v_sql) 50 | #plpy.info(psql_cmd) 51 | p = subprocess.Popen(psql_cmd,shell=True, stdout=subprocess.PIPE, stderr=subprocess.PIPE, stdin=subprocess.PIPE) 52 | p_stdout = p.stdout.read() 53 | p_stderr = p.stderr.read() 54 | p.wait() 55 | if p.returncode != 0: 56 | plpy.error(p_stderr) 57 | 58 | rows = plpy.execute("select 'export LANG=en_US.utf8;ls -l --time-style=''+%Y-%m-%d_%H:%M:%S'' '||current_setting('data_directory')||'/base/'||c.oid||'> /tmp/fs_'||current_setting('gp_dbid')||'.dat ; ' as cmd1 from pg_database c where c.datname=current_database();") 59 | cmd1 = rows[0]["cmd1"] 60 | rows = plpy.execute("select string_agg('ls -l --time-style=''+%Y-%m-%d_%H:%M:%S'' ' ||case when current_setting('gp_dbid')::int=c.db_id_1 then trim(c.location_1) when current_setting('gp_dbid')::int=c.db_id_2 then trim(c.location_2) end ||'/*/'||(SELECT oid from pg_database where datname=current_database())||' >> /tmp/fs_'||current_setting('gp_dbid')||'.dat',' ; ') as cmd2 from gp_persistent_filespace_node c;") 61 | cmd2 = rows[0]["cmd2"] 62 | if cmd2 is None: 63 | ls_cmd = cmd1 64 | else: 65 | ls_cmd = cmd1+cmd2 66 | #plpy.info(ls_cmd) 67 | p = subprocess.Popen(ls_cmd,shell=True, stdout=subprocess.PIPE, stderr=subprocess.PIPE, stdin=subprocess.PIPE) 68 | p_stdout = p.stdout.read() 69 | p_stderr = p.stderr.read() 70 | p.wait() 71 | if p.returncode != 0: 72 | plpy.notice(p_stderr) 73 | 74 | sed_cmd = "sed -i 's/[ ]\{1,\}/|/g;/?/d;/^total/d;/^\//d;/^$/d' "+filename 75 | #plpy.info(sed_cmd) 76 | p = subprocess.Popen(sed_cmd,shell=True, stdout=subprocess.PIPE, stderr=subprocess.PIPE, stdin=subprocess.PIPE) 77 | p_stdout = p.stdout.read() 78 | p_stderr = p.stderr.read() 79 | p.wait() 80 | if p.returncode != 0: 81 | plpy.error(p_stderr) 82 | 83 | copy_sql = "copy public.gp_seg_size_ora from '"+filename+"' delimiter '|';" 84 | run_psql_utility(copy_sql) 85 | 86 | insert_sql = "insert into public.gp_seg_table_size (select hostname(),a.oid,a.relnamespace,a.relname,a.reltablespace,a.relfilenode,b.size,b.relfilecount,b.max_modtime from pg_class a join (select split_part(filename,'.',1) as relfilenode,sum(size) size,count(*) relfilecount,max(modtime) max_modtime from gp_seg_size_ora group by 1) b on a.relfilenode::text=b.relfilenode);" 87 | run_psql_utility(insert_sql) 88 | 89 | return "OK" 90 | $$ LANGUAGE plpythonu; 91 | 92 | 93 | --truncate gp_seg_size_ora; 94 | --truncate gp_seg_table_size; 95 | --select gp_segment_id,public.load_files_size() from gp_dist_random('gp_id'); 96 | 97 | 98 | -------------------------------------------------------------------------------- /gpsize/load_files_size_v6.sql: -------------------------------------------------------------------------------- 1 | drop table if exists public.gp_seg_size_ora cascade; 2 | create table public.gp_seg_size_ora 3 | ( 4 | acl text 5 | ,num int 6 | ,sysuser text 7 | ,sysgroup text 8 | ,size numeric 9 | ,modtime timestamp 10 | ,filename text 11 | )distributed randomly; 12 | 13 | drop table if exists public.gp_seg_table_size cascade; 14 | create table public.gp_seg_table_size 15 | ( 16 | hostname text 17 | ,oid oid 18 | ,relnamespace oid 19 | ,relname name 20 | ,reltablespace oid 21 | ,relfilenode oid 22 | ,size numeric 23 | ,relfilecount int 24 | ,max_modtime timestamp 25 | ) distributed randomly; 26 | 27 | 28 | DROP FUNCTION IF EXISTS public.hostname(); 29 | CREATE or replace FUNCTION public.hostname() RETURNS 30 | text 31 | as $$ 32 | import socket 33 | return socket.gethostname() 34 | $$ LANGUAGE plpythonu; 35 | 36 | 37 | 38 | 39 | DROP FUNCTION IF EXISTS public.load_files_size(); 40 | CREATE or REPLACE FUNCTION public.load_files_size() RETURNS text 41 | as $$ 42 | import subprocess 43 | 44 | rows = plpy.execute("select current_database() dbname, current_setting('port') portno;") 45 | (dbname, portno) = (rows[0]["dbname"], rows[0]["portno"]) 46 | rows = plpy.execute("select '/tmp/fs_'||current_setting('gp_dbid')||'.dat' as filename;") 47 | filename = rows[0]["filename"] 48 | 49 | def run_psql_utility(v_sql): 50 | psql_cmd = """PGOPTIONS='-c gp_session_role=utility' psql -v ON_ERROR_STOP=1 -d %s -p %s -A -X -t -c \"%s\" """ % (dbname, portno, v_sql) 51 | #plpy.info(psql_cmd) 52 | p = subprocess.Popen(psql_cmd,shell=True, stdout=subprocess.PIPE, stderr=subprocess.PIPE, stdin=subprocess.PIPE) 53 | p_stdout = p.stdout.read() 54 | p_stderr = p.stderr.read() 55 | p.wait() 56 | if p.returncode != 0: 57 | plpy.error(p_stderr) 58 | 59 | rows = plpy.execute("select 'export LANG=en_US.utf8;ls -l --time-style=''+%Y-%m-%d_%H:%M:%S'' '||current_setting('data_directory')||'/base/'||c.oid||'> /tmp/fs_'||current_setting('gp_dbid')||'.dat ; ' as cmd1 from pg_database c where c.datname=current_database();") 60 | cmd1 = rows[0]["cmd1"] 61 | rows = plpy.execute("select string_agg('ls -l --time-style=''+%Y-%m-%d_%H:%M:%S'' ' ||pg_tablespace_location(oid)||'/'||current_setting('gp_dbid')||'/*/'||(SELECT oid from pg_database where datname=current_database())||' >> /tmp/fs_'||current_setting('gp_dbid')||'.dat',' ; ') as cmd2 from pg_tablespace where oid not in (1663,1664);") 62 | cmd2 = rows[0]["cmd2"] 63 | if cmd2 is None: 64 | ls_cmd = cmd1 65 | else: 66 | ls_cmd = cmd1+cmd2 67 | #plpy.info(ls_cmd) 68 | p = subprocess.Popen(ls_cmd,shell=True, stdout=subprocess.PIPE, stderr=subprocess.PIPE, stdin=subprocess.PIPE) 69 | p_stdout = p.stdout.read() 70 | p_stderr = p.stderr.read() 71 | p.wait() 72 | if p.returncode != 0: 73 | plpy.notice(p_stderr) 74 | 75 | sed_cmd = "sed -i 's/[ ]\{1,\}/|/g;/?/d;/^total/d;/^\//d;/^$/d' "+filename 76 | #plpy.info(sed_cmd) 77 | p = subprocess.Popen(sed_cmd,shell=True, stdout=subprocess.PIPE, stderr=subprocess.PIPE, stdin=subprocess.PIPE) 78 | p_stdout = p.stdout.read() 79 | p_stderr = p.stderr.read() 80 | p.wait() 81 | if p.returncode != 0: 82 | plpy.error(p_stderr) 83 | 84 | copy_sql = "copy public.gp_seg_size_ora from '"+filename+"' delimiter '|';" 85 | run_psql_utility(copy_sql) 86 | 87 | insert_sql = "insert into public.gp_seg_table_size (select hostname(),a.oid,a.relnamespace,a.relname,a.reltablespace,a.relfilenode,b.size,b.relfilecount,b.max_modtime from pg_class a join (select split_part(filename,'.',1) as relfilenode,sum(size) size,count(*) relfilecount,max(modtime) max_modtime from gp_seg_size_ora group by 1) b on a.relfilenode::text=b.relfilenode);" 88 | run_psql_utility(insert_sql) 89 | 90 | return "OK" 91 | $$ LANGUAGE plpythonu; 92 | 93 | 94 | --truncate gp_seg_size_ora; 95 | --truncate gp_seg_table_size; 96 | --select gp_segment_id,public.load_files_size() from gp_dist_random('gp_id'); 97 | 98 | 99 | 100 | 101 | -------------------------------------------------------------------------------- /gpsize/load_files_size_v7.sql: -------------------------------------------------------------------------------- 1 | drop table if exists public.gp_seg_size_ora cascade; 2 | create table public.gp_seg_size_ora 3 | ( 4 | acl text 5 | ,num int 6 | ,sysuser text 7 | ,sysgroup text 8 | ,size numeric 9 | ,modtime timestamp 10 | ,filename text 11 | )distributed randomly; 12 | 13 | drop table if exists public.gp_seg_table_size cascade; 14 | create table public.gp_seg_table_size 15 | ( 16 | hostname text 17 | ,oid oid 18 | ,relnamespace oid 19 | ,relname name 20 | ,reltablespace oid 21 | ,relfilenode oid 22 | ,size numeric 23 | ,relfilecount int 24 | ,max_modtime timestamp 25 | ) distributed randomly; 26 | 27 | 28 | DROP FUNCTION IF EXISTS public.hostname(); 29 | CREATE or replace FUNCTION public.hostname() RETURNS 30 | text 31 | as $$ 32 | import socket 33 | return socket.gethostname() 34 | $$ LANGUAGE plpython3u; 35 | 36 | 37 | 38 | 39 | DROP FUNCTION IF EXISTS public.load_files_size(); 40 | CREATE or REPLACE FUNCTION public.load_files_size() RETURNS text 41 | as $$ 42 | import subprocess 43 | 44 | rows = plpy.execute("select current_database() dbname, current_setting('port') portno;") 45 | (dbname, portno) = (rows[0]["dbname"], rows[0]["portno"]) 46 | rows = plpy.execute("select '/tmp/fs_'||current_setting('gp_dbid')||'.dat' as filename;") 47 | filename = rows[0]["filename"] 48 | 49 | def run_psql_utility(v_sql): 50 | psql_cmd = """PGOPTIONS='-c gp_session_role=utility' psql -v ON_ERROR_STOP=1 -d %s -p %s -A -X -t -c \"%s\" """ % (dbname, portno, v_sql) 51 | #plpy.info(psql_cmd) 52 | p = subprocess.Popen(psql_cmd,shell=True, stdout=subprocess.PIPE, stderr=subprocess.PIPE, stdin=subprocess.PIPE) 53 | p_stdout = p.stdout.read() 54 | p_stderr = p.stderr.read() 55 | p.wait() 56 | if p.returncode != 0: 57 | plpy.error(p_stderr) 58 | 59 | rows = plpy.execute("select 'export LANG=en_US.utf8;ls -l --time-style=''+%Y-%m-%d_%H:%M:%S'' '||current_setting('data_directory')||'/base/'||c.oid||'> /tmp/fs_'||current_setting('gp_dbid')||'.dat ; ' as cmd1 from pg_database c where c.datname=current_database();") 60 | cmd1 = rows[0]["cmd1"] 61 | rows = plpy.execute("select string_agg('ls -l --time-style=''+%Y-%m-%d_%H:%M:%S'' ' ||pg_tablespace_location(oid)||'/'||current_setting('gp_dbid')||'/*/'||(SELECT oid from pg_database where datname=current_database())||' >> /tmp/fs_'||current_setting('gp_dbid')||'.dat',' ; ') as cmd2 from pg_tablespace where oid not in (1663,1664);") 62 | cmd2 = rows[0]["cmd2"] 63 | if cmd2 is None: 64 | ls_cmd = cmd1 65 | else: 66 | ls_cmd = cmd1+cmd2 67 | #plpy.info(ls_cmd) 68 | p = subprocess.Popen(ls_cmd,shell=True, stdout=subprocess.PIPE, stderr=subprocess.PIPE, stdin=subprocess.PIPE) 69 | p_stdout = p.stdout.read() 70 | p_stderr = p.stderr.read() 71 | p.wait() 72 | if p.returncode != 0: 73 | plpy.notice(p_stderr) 74 | 75 | sed_cmd = "sed -i 's/[ ]\{1,\}/|/g;/?/d;/^total/d;/^\//d;/^$/d' "+filename 76 | #plpy.info(sed_cmd) 77 | p = subprocess.Popen(sed_cmd,shell=True, stdout=subprocess.PIPE, stderr=subprocess.PIPE, stdin=subprocess.PIPE) 78 | p_stdout = p.stdout.read() 79 | p_stderr = p.stderr.read() 80 | p.wait() 81 | if p.returncode != 0: 82 | plpy.error(p_stderr) 83 | 84 | copy_sql = "copy public.gp_seg_size_ora from '"+filename+"' delimiter '|';" 85 | run_psql_utility(copy_sql) 86 | 87 | insert_sql = "insert into public.gp_seg_table_size (select hostname(),a.oid,a.relnamespace,a.relname,a.reltablespace,a.relfilenode,b.size,b.relfilecount,b.max_modtime from pg_class a join (select split_part(filename,'.',1) as relfilenode,sum(size) size,count(*) relfilecount,max(modtime) max_modtime from gp_seg_size_ora group by 1) b on a.relfilenode::text=b.relfilenode);" 88 | run_psql_utility(insert_sql) 89 | 90 | return "OK" 91 | $$ LANGUAGE plpython3u; 92 | 93 | 94 | --truncate gp_seg_size_ora; 95 | --truncate gp_seg_table_size; 96 | --select gp_segment_id,public.load_files_size() from gp_dist_random('gp_id'); 97 | 98 | 99 | 100 | 101 | -------------------------------------------------------------------------------- /gpssh-exkeys_gp6/README.txt: -------------------------------------------------------------------------------- 1 | To enabling passwordless SSH in GP cluster, only use in GP6 2 | Step 1. Generate key with ssh-keygen. 3 | Step 2. Add to known_hosts. 4 | Step 3. Use the ssh-copy-id command to add the user's public key to the other hosts, This enables 1-n passwordless SSH. 5 | Step 4. Use gpssh-exkeys utility with your hostfile_exkeys file to enable n-n passwordless SSH. 6 | 7 | 8 | Preparation: 9 | 1. Copy sshpass to /usr/local/bin/ 10 | cp sshpass /usr/local/bin 11 | chmod +x /usr/local/bin/sshpass 12 | 13 | 2. Edit hostfile 14 | 15 | 3. Run script 16 | sh gpssh-exkeys_gp6.sh -f allhosts 17 | 18 | -------------------------------------------------------------------------------- /gpssh-exkeys_gp6/gpssh-exkeys_gp6.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | set +o errexit 3 | 4 | if [ $# -ne 2 ] && [ $# -ne 4 ]; then 5 | echo "invalid parameters!" 6 | echo " 7 | Usage:`basename $0` -f allhosts 8 | or 9 | `basename $0` -f allhosts -e allexpands" 10 | exit 1; 11 | fi 12 | 13 | while getopts "f:e": opts 14 | do 15 | case $opts in 16 | f) allhosts_FILENAME=$OPTARG 17 | ;; 18 | e) allexpands_FILENAME=$OPTARG 19 | ;; 20 | \?) 21 | echo "invalid parameters!" 22 | echo " 23 | Usage:`basename $0` -f allhosts 24 | or 25 | `basename $0` -f allhosts -e allexpands" 26 | exit 1; 27 | ;; 28 | esac 29 | done 30 | 31 | DATETIME=`date +%Y%m%d%H%M%S` 32 | 33 | if [ ! -f "$allhosts_FILENAME" ]; then 34 | echo "Hostfile \"$allhosts_FILENAME\" does not exists!!!" 35 | exit 1 36 | fi 37 | 38 | USERNAME=`whoami` 39 | 40 | read -p "Please input <$USERNAME> password of all hosts: " passwd 41 | 42 | if [ "$allexpands_FILENAME"x = ""x ]; then 43 | ssh-keygen -t rsa -N "" -f $HOME/.ssh/id_rsa -q 44 | if [ -f "$HOME/.ssh/known_hosts" ]; then 45 | echo "Clean up known_hosts" 46 | cp $HOME/.ssh/known_hosts $HOME/.ssh/known_hosts.bak$DATETIME 47 | > $HOME/.ssh/known_hosts 48 | fi 49 | fi 50 | 51 | if [ "$allexpands_FILENAME"x != ""x ]; then 52 | HOSTLIST=`cat $allexpands_FILENAME |grep -v "^$" |grep -v "^#"` 53 | else 54 | HOSTLIST=`cat $allhosts_FILENAME |grep -v "^$" |grep -v "^#"` 55 | fi 56 | for hostname in $HOSTLIST 57 | do 58 | echo "[$hostname] Add known_host and ssh-copy-id ..." 59 | ssh-keygen -R $hostname 60 | ssh-keyscan -H $hostname 1>> $HOME/.ssh/known_hosts 61 | sshpass -p $passwd ssh-copy-id -i $HOME/.ssh/id_rsa.pub $hostname 62 | done 63 | 64 | echo "Running gpssh-exkeys ..." 65 | source /usr/local/greenplum-db/greenplum_path.sh 66 | gpssh-exkeys -f $allhosts_FILENAME 67 | 68 | 69 | 70 | 71 | -------------------------------------------------------------------------------- /gpssh-exkeys_gp6/sshpass: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/davidch3/gp_simpletools/c9724a57217bcaefe0fe16490199258ecb8e548b/gpssh-exkeys_gp6/sshpass -------------------------------------------------------------------------------- /killsession/README.txt: -------------------------------------------------------------------------------- 1 | gp_kill_idle.sh: 2 | 3 | Script use for kill idle session and idle transaction session. Using function pg_terminate_backend. 4 | Sample: sh gp_kill_idle.sh. 5 | Script can setup in crontab, run for each hour. 6 | If you want to change the time last, you can change this two lines in script: 7 | INT_IDLE_TRAN=1 8 | INT_IDLE_CONN=24 9 | -------------------------------------------------------------------------------- /killsession/gp_kill_idle.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | ######################################################################################### 4 | # Objective : To identify the in transaction and sessions for a long time, kill it 5 | # Logging : All logs will be stored in $HOME/gpAdminLogs/gp_kill_idle_YYYYMMDD.log 6 | # Consequences : Connections killed will get the below error messages and they would need to reconnect 7 | # FATAL: terminating connection due to administrator command 8 | # server closed the connection unexpectedly 9 | # This probably means the server terminated abnormally 10 | # before or while processing the request. 11 | # The connection to the server was lost. Attempting reset: Succeeded. 12 | ######################################################################################### 13 | 14 | INT_IDLE_TRAN=1 15 | INT_IDLE_CONN=24 16 | LOGDATE=`date +%Y%m%d` 17 | source /usr/local/greenplum-db/greenplum_path.sh 18 | 19 | loging (){ 20 | # Logging all idle in transaction for more than X hours 21 | psql -t -ac "select usename,procpid,current_query,query_start,backend_start,xact_start from pg_stat_activity where current_query=' in transaction' and now()-xact_start>interval '${INT_IDLE_TRAN} hours'" postgres >> /home/gpadmin/gpAdminLogs/kill_long_idle_${LOGDATE}.log 22 | # Logging all the connections which were idle for more than X hours 23 | psql -t -ac "select usename,procpid,current_query,query_start,backend_start,xact_start from pg_stat_activity where current_query='' and now()-query_start>interval '${INT_IDLE_CONN} hours'" postgres >> /home/gpadmin/gpAdminLogs/kill_long_idle_${LOGDATE}.log 24 | } 25 | 26 | idle_conn () { 27 | # Terminate pid's of IDLE CONNECTIONS for more than X hours : 28 | psql -A -t -c "SELECT 'select pg_terminate_backend('||procpid||');select pg_sleep(1);' from pg_stat_activity where current_query = ' in transaction' and now()-xact_start>interval '${INT_IDLE_TRAN} hours'" postgres | psql -a postgres >> /home/gpadmin/gpAdminLogs/kill_long_idle_${LOGDATE}.log 29 | # Terminate pid's of IDLE CONNECTIONS for more than X hours : 30 | psql -A -t -c "SELECT 'select pg_terminate_backend('||procpid||');select pg_sleep(1);' from pg_stat_activity where current_query = '' and now()-query_start>interval '${INT_IDLE_CONN} hours'" postgres | psql -a postgres >> /home/gpadmin/gpAdminLogs/kill_long_idle_${LOGDATE}.log 31 | } 32 | 33 | date >> /home/gpadmin/gpAdminLogs/gp_kill_idle_${LOGDATE}.log 34 | loging 35 | idle_conn 36 | -------------------------------------------------------------------------------- /killsession/gp_kill_idle_gp6.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | ######################################################################################### 4 | # Objective : To identify the in transaction and sessions for a long time, kill it 5 | # Logging : All logs will be stored in $HOME/gpAdminLogs/gp_kill_idle_YYYYMMDD.log 6 | # Consequences : Connections killed will get the below error messages and they would need to reconnect 7 | # FATAL: terminating connection due to administrator command 8 | # server closed the connection unexpectedly 9 | # This probably means the server terminated abnormally 10 | # before or while processing the request. 11 | # The connection to the server was lost. Attempting reset: Succeeded. 12 | ######################################################################################### 13 | 14 | INT_IDLE_TRAN=3 15 | INT_IDLE_CONN=12 16 | LOGDATE=`date +%Y%m%d` 17 | source /usr/local/greenplum-db/greenplum_path.sh 18 | 19 | loging (){ 20 | # Logging all idle in transaction for more than X hours 21 | psql -t -ac "select usename,pid,query,query_start,backend_start,xact_start from pg_stat_activity where state='idle in transaction' and now()-state_change>interval '${INT_IDLE_TRAN} hours'" postgres >> /home/gpadmin/gpAdminLogs/kill_long_idle_${LOGDATE}.log 22 | # Logging all the connections which were idle for more than X hours 23 | psql -t -ac "select usename,pid,query,query_start,backend_start,xact_start from pg_stat_activity where state='idle' and now()-state_change>interval '${INT_IDLE_CONN} hours'" postgres >> /home/gpadmin/gpAdminLogs/kill_long_idle_${LOGDATE}.log 24 | } 25 | 26 | idle_conn () { 27 | # Terminate pid's of IDLE CONNECTIONS for more than X hours : 28 | psql -A -t -c "SELECT 'select pg_terminate_backend('||pid||');select pg_sleep(1);' from pg_stat_activity where state = 'idle in transaction' and now()-state_change>interval '${INT_IDLE_TRAN} hours'" postgres | psql -a postgres >> /home/gpadmin/gpAdminLogs/kill_long_idle_${LOGDATE}.log 29 | # Terminate pid's of IDLE CONNECTIONS for more than X hours : 30 | psql -A -t -c "SELECT 'select pg_terminate_backend('||pid||');select pg_sleep(1);' from pg_stat_activity where state = 'idle' and now()-state_change>interval '${INT_IDLE_CONN} hours'" postgres | psql -a postgres >> /home/gpadmin/gpAdminLogs/kill_long_idle_${LOGDATE}.log 31 | } 32 | 33 | date >> /home/gpadmin/gpAdminLogs/gp_kill_idle_${LOGDATE}.log 34 | loging 35 | idle_conn 36 | -------------------------------------------------------------------------------- /lock/README.txt: -------------------------------------------------------------------------------- 1 | INFORMATION: 2 | Query table lock on SQL and waiting lock SQL. 3 | 4 | 5 | v_check_lock_tables.sql: 6 | Using for version before gpdb6 7 | select * from v_check_lock_tables; 8 | 9 | 10 | v_check_lock_tables_6.sql: 11 | Using for version gpdb6 12 | select * from v_check_lock_tables; 13 | 14 | 15 | 16 | 17 | -------------------------------------------------------------------------------- /lock/v_check_lock_tables.sql: -------------------------------------------------------------------------------- 1 | 2 | ---new 3 | drop view if exists v_check_lock_tables; 4 | create or replace view v_check_lock_tables 5 | as 6 | select tab1.tablename lock_table,tab1.lockmode wait_lockmode,tab1.usename wait_user,tab1.pid wait_procpid,tab1.xact_start wait_start, 7 | tab1.wait_time,tab1.current_query wait_sql,tab2.lockmode run_lockmode,tab2.usename run_user,tab2.pid run_procpid, 8 | tab2.xact_start xact_start,tab2.xact_time,tab2.current_query run_sql 9 | from ( 10 | select locktype,relation::regclass as tablename,pid,mode as lockmode,usename,bbb.xact_start,substr(bbb.current_query,1,100) as current_query, 11 | now()-bbb.xact_start as wait_time 12 | from pg_locks aaa 13 | inner join pg_stat_activity bbb on aaa.pid=bbb.procpid 14 | where aaa.granted=false and aaa.relation>16384 and aaa.gp_segment_id=-1 and aaa.locktype='relation' 15 | and aaa.mode<>'ShareLock' and bbb.waiting=true 16 | ) tab1 17 | inner join ( 18 | select locktype,relation::regclass as tablename,pid,mode as lockmode,usename,bbb.xact_start,substr(bbb.current_query,1,100) as current_query, 19 | now()-bbb.xact_start as xact_time 20 | from pg_locks aaa 21 | inner join pg_stat_activity bbb on aaa.pid=bbb.procpid 22 | where aaa.granted=true and aaa.relation>16384 and aaa.gp_segment_id=-1 and aaa.locktype='relation' 23 | and aaa.mode<>'ShareLock' 24 | ) tab2 on tab1.tablename=tab2.tablename and tab1.wait_time16384 and aaa.gp_segment_id=-1 and aaa.locktype='relation' 16 | and aaa.mode<>'ShareLock' and bbb.waiting=true 17 | ) tab1 18 | inner join ( 19 | select locktype,relation::regclass as tablename,aaa.pid,mode as lockmode,usename,bbb.xact_start,substr(bbb.query,1,100) as current_query,bbb.state, 20 | now()-bbb.xact_start as xact_time 21 | from pg_locks aaa 22 | inner join pg_stat_activity bbb on aaa.pid=bbb.pid 23 | where aaa.granted=true and aaa.relation>16384 and aaa.gp_segment_id=-1 and aaa.locktype='relation' 24 | and aaa.mode<>'ShareLock' 25 | ) tab2 on tab1.tablename=tab2.tablename and tab1.wait_time16384 and aaa.gp_segment_id=-1 and aaa.locktype='relation' 16 | and aaa.mode<>'ShareLock' and bbb.wait_event_type='Lock' 17 | ) tab1 18 | inner join ( 19 | select locktype,relation::regclass as tablename,aaa.pid,mode as lockmode,usename,bbb.xact_start,substr(bbb.query,1,100) as current_query,bbb.state, 20 | now()-bbb.xact_start as xact_time 21 | from pg_locks aaa 22 | inner join pg_stat_activity bbb on aaa.pid=bbb.pid 23 | where aaa.granted=true and aaa.relation>16384 and aaa.gp_segment_id=-1 and aaa.locktype='relation' 24 | and aaa.mode<>'ShareLock' 25 | ) tab2 on tab1.tablename=tab2.tablename and tab1.wait_time 0 ) { 35 | $num_proc--; 36 | print "Retrieve a child process. num_proc=$num_proc=\n"; 37 | $num_finish++; 38 | } 39 | } 40 | return 0; 41 | } 42 | ## == get the child signal,if the child process exit, then the $num_proc will reduce 1== 43 | 44 | 45 | 46 | ####################### MAIN ####################### 47 | sub main{ 48 | my $pid; 49 | my $childpid; 50 | my $icalc; 51 | 52 | for ($icalc=0; $icalc<$itotal; $icalc++){ 53 | 54 | $pid=fork(); 55 | if(!(defined ($pid))) { 56 | print "Can not fork a child process!!!\n$!\n"; 57 | exit(-1); 58 | } 59 | $childpid=$$; 60 | 61 | if ($pid==0) { 62 | #Child process 63 | 64 | print "I'm a child process, pid=".$childpid."=\n"; 65 | if ($childpid%5 == 0) { 66 | sleep(13); 67 | print "I'm a child process, pid=".$childpid."=. I will exit -1\n"; 68 | exit -1; 69 | } elsif ($childpid%7 == 0) { 70 | `psql -d testdb -ac "select count(*) from to_cdr_partname_varchar_spec33;"`; 71 | print "I'm a child process, pid=".$childpid."=. I run psql. I will exit 0\n"; 72 | exit -1; 73 | } elsif ($childpid%9 == 0) { 74 | `gpcheck ~/allhsots`; 75 | print "I'm a child process, pid=".$childpid."=. I run gpcheck. I will exit 0\n"; 76 | exit -1; 77 | } else { 78 | sleep(9); 79 | print "I'm a child process, pid=".$childpid."=. I will exit 0\n"; 80 | exit 0; 81 | } 82 | 83 | } else { 84 | #Parent process 85 | $num_proc++; 86 | if ($num_finish%10 == 0) { 87 | print "Child process count [".$num_proc."], finish count[".$num_finish."/".$itotal."]\n"; 88 | } 89 | do { 90 | sleep(1); 91 | } until ( $num_proc < $concurrency ); 92 | } 93 | } 94 | 95 | print "waiting for all child finished!\n"; 96 | my $ichd=0; 97 | do { 98 | while ( ($ichd=waitpid(-1, WNOHANG)) > 0 ) { $num_finish++; } 99 | sleep(1); 100 | } until ( $ichd < 0 ); 101 | 102 | #my $ret=0; 103 | #my $rettmp=`psql -ac "select now();"`; 104 | #print $rettmp."\n"; 105 | #$ret=$?>>8; 106 | #print $ret."\n"; 107 | 108 | return 0; 109 | } 110 | 111 | 112 | 113 | my $ret = main(); 114 | exit($ret); 115 | 116 | 117 | 118 | 119 | -------------------------------------------------------------------------------- /perl_template/perl_template.pl: -------------------------------------------------------------------------------- 1 | #!/usr/bin/perl 2 | use strict; 3 | #use lib '/home/gpadmin/script'; 4 | #use Logger; 5 | #use mon_pub; 6 | use Getopt::Long; 7 | 8 | my $cmd_name=$0; 9 | my ($hostname,$port,$database,$username,$password)=("localhost","5432","postgres","gpadmin","gpadmin"); ###default 10 | my ($IS_HELP,$IS_ALL,@CHK_SCHEMA,$SCHEMA_FILE,$JOBS,$LOG_DIR,$GLOBAL_ONLY); 11 | my $fh_log; 12 | my @schema_list; 13 | 14 | my $HELP_MESSAGE = qq{ 15 | Usage: 16 | perl $cmd_name [OPTIONS] 17 | 18 | Options: 19 | --hostname | -h 20 | Master hostname or master host IP. Default: localhost 21 | 22 | --port | -p 23 | GP Master port number, Default: 5432 24 | 25 | --dbname | -d 26 | Database name. If not specified, uses the value specified by the environment variable PGDATABASE, even if PGDATABASE is not specified, return error. 27 | 28 | --username | -d 29 | The super user of GPDB. Default: gpadmin 30 | 31 | --password | -pw 32 | The password of GP user. Default: no password 33 | 34 | --help | -? 35 | Show the help message. 36 | 37 | --all | -a 38 | Check all the schema in database. 39 | 40 | --log-dir | -l 41 | The directory to write the log file. Default: ~/gpAdminLogs. 42 | 43 | --jobs 44 | The number of parallel jobs to healthcheck, include: skew, bloat. Default: 2 45 | 46 | --include-schema 47 | Check (include: skew, bloat) only specified schema(s). --include-schema can be specified multiple times. 48 | 49 | --include-schema-file 50 | A file containing a list of schema to be included in healthcheck. 51 | 52 | --global-info-only 53 | Check and output the global information of GPDB, include: pg_catalog, size, age, gpstate 54 | 55 | Examples: 56 | perl $cmd_name --dbname testdb --all --jobs 3 57 | 58 | perl $cmd_name --dbname testdb --include-schema public --include-schema gpp_sync 59 | 60 | perl $cmd_name --help 61 | 62 | }; 63 | 64 | sub getOption{ 65 | 66 | if($#ARGV == -1){ 67 | print "Input error: \nPlease show help: perl $cmd_name --help\n"; 68 | exit 0; 69 | } 70 | 71 | $JOBS = 2; 72 | $LOG_DIR = "~/gpAdminLogs"; 73 | $SCHEMA_FILE = ""; 74 | 75 | if (length($ENV{PGDATABASE}) > 0) { 76 | $database = $ENV{PGDATABASE}; 77 | } 78 | GetOptions( 79 | 'hostname|h:s' => \$hostname, 80 | 'port|p:s' => \$port, 81 | 'dbname:s' => \$database, 82 | 'username:s' => \$username, 83 | 'password|pw:s' => \$password, 84 | 'help|?!' => \$IS_HELP, 85 | 'a|all!' => \$IS_ALL, 86 | 'include-schema|s:s' => \@CHK_SCHEMA, 87 | 'include-schema-file:s' => \$SCHEMA_FILE, 88 | 'jobs:s' => \$JOBS, 89 | 'log-dir:s' => \$LOG_DIR, 90 | 'global-info-only!' => \$GLOBAL_ONLY, 91 | ); 92 | if(@ARGV != 0){ 93 | print "Input error: [@ARGV]\nPlease show help: perl $cmd_name --help\n"; 94 | exit 0; 95 | } 96 | if($IS_HELP){ 97 | print $HELP_MESSAGE; 98 | exit 0; 99 | } 100 | my $itmp=0; 101 | if ($IS_ALL) { $itmp++; } 102 | if ($#CHK_SCHEMA>=0) { $itmp++; } 103 | if (length($SCHEMA_FILE)>0) { $itmp++; } 104 | if ( $itmp>1 ) { 105 | print "Input error: The following options may not be specified together: all, include-schema, include-schema-file\n"; 106 | exit 0; 107 | } 108 | 109 | #print $hostname."\n".$port."\n".$database."\n".$username."\n".$password."\n".$IS_HELP."\n".$IS_ALL."\n".$#CHK_SCHEMA."\n".$SCHEMA_FILE."\n".$JOBS."\n".$LOG_DIR."\n"; 110 | 111 | } 112 | 113 | sub getCurrentDate 114 | { 115 | my ($sec,$min,$hour,$mday,$mon,$year,$wday,$yday,$isdst) = localtime(time()); 116 | my $current = ""; 117 | 118 | $year += 1900; 119 | $mon = sprintf("%02d", $mon + 1); 120 | $mday = sprintf("%02d", $mday); 121 | $current = "${year}${mon}${mday}"; 122 | 123 | return $current; 124 | } 125 | 126 | sub showTime 127 | { 128 | my ($sec,$min,$hour,$mday,$mon,$year,$wday,$yday,$isdst) = localtime(time()); 129 | my $current = ""; 130 | 131 | $year += 1900; 132 | $mon = sprintf("%02d", $mon + 1); 133 | $mday = sprintf("%02d", $mday); 134 | $hour = sprintf("%02d", $hour); 135 | $min = sprintf("%02d", $min); 136 | $sec = sprintf("%02d", $sec); 137 | 138 | $current = "${year}-${mon}-${mday} ${hour}:${min}:${sec}"; 139 | 140 | return $current; 141 | } 142 | 143 | sub initLog{ 144 | my $logday=getCurrentDate(); 145 | my $logfile=open($fh_log, '>>', "$ENV{HOME}/gpAdminLogs/${cmd_name}_$logday.log"); 146 | unless ($logfile){ 147 | print "[ERROR]:Cound not open logfile $ENV{HOME}/gpAdminLogs/${cmd_name}_$logday.log\n"; 148 | exit -1; 149 | } 150 | } 151 | 152 | sub info{ 153 | my ($printmsg)=@_; 154 | print $fh_log "[".showTime()." INFO] ".$printmsg; 155 | return 0; 156 | } 157 | 158 | sub info_notimestr{ 159 | my ($printmsg)=@_; 160 | print $fh_log $printmsg; 161 | return 0; 162 | } 163 | 164 | sub error{ 165 | my ($printmsg)=@_; 166 | print $fh_log "[".showTime()." ERROR] ".$printmsg; 167 | return 0; 168 | } 169 | 170 | sub closeLog{ 171 | close $fh_log; 172 | return 0; 173 | } 174 | 175 | sub set_env 176 | { 177 | $ENV{"PGHOST"}=$hostname; 178 | $ENV{"PGPORT"}=$port; 179 | $ENV{"PGDATABASE"}=$database; 180 | $ENV{"PGUSER"}=$username; 181 | $ENV{"PGPASSWORD"}=$password; 182 | 183 | return 0; 184 | } 185 | 186 | 187 | 188 | 189 | sub get_schema{ 190 | my ($sql,$ret); 191 | 192 | ###--all 193 | if ($IS_ALL) { 194 | $sql = qq{ select nspname from pg_namespace where nspname not like 'pg%' and nspname not like 'gp%' order by 1; }; 195 | @schema_list = `psql -A -X -t -c "$sql" -h $hostname -p $port -U $username -d $database`; 196 | $ret = $? >> 8; 197 | if ($ret) { 198 | error("Query all schema name error\n"); 199 | exit(1); 200 | } 201 | } 202 | ###--include-schema 203 | if ($#CHK_SCHEMA>=0) { 204 | push @schema_list,@CHK_SCHEMA ; 205 | } 206 | ###--include-schema-file 207 | if (length($SCHEMA_FILE)>0) { 208 | unless (-e $SCHEMA_FILE) { 209 | error "Schema file $SCHEMA_FILE do not exist!\n" ; 210 | exit(1); 211 | }; 212 | unless ((open SCHFILE,"<$SCHEMA_FILE" )) { 213 | showTime();print "open $SCHEMA_FILE error$!\n"; 214 | exit(1); 215 | } 216 | foreach () { 217 | #print; 218 | chomp; 219 | if (!(/^#/) && !(/^$/)) { 220 | push @schema_list,$_; 221 | } 222 | } 223 | close SCHFILE; 224 | } 225 | } 226 | 227 | 228 | sub Gpstate { 229 | my $stateinfo; 230 | my ($sql,$ret); 231 | 232 | #print "---Check gpstate and gp_configuration_history\n"; 233 | info("---gpstate\n"); 234 | $stateinfo = `gpstate -e`; 235 | info_notimestr("\n$stateinfo\n"); 236 | $stateinfo = `gpstate -f`; 237 | info_notimestr("$stateinfo\n"); 238 | 239 | $sql = qq{ select * from gp_configuration_history order by 1 desc limit 50; }; 240 | my $confhis=`psql -A -X -t -c "$sql" -h $hostname -p $port -U $username -d $database`; 241 | $ret = $? >> 8; 242 | if ($ret) { 243 | error("Get gp_configuration_history error\n"); 244 | return(-1); 245 | } 246 | info("---gp_configuration_history\n"); 247 | info_notimestr("$confhis\n"); 248 | } 249 | 250 | 251 | 252 | 253 | sub main{ 254 | my $ret; 255 | 256 | getOption(); 257 | set_env(); 258 | initLog(); 259 | info("-----------------------------------------------------\n"); 260 | info("------Program start\n"); 261 | info("-----------------------------------------------------\n"); 262 | 263 | ######## 264 | get_schema(); 265 | Gpstate(); 266 | 267 | ######## 268 | 269 | info("-----------------------------------------------------\n"); 270 | info("------Program Finished!\n"); 271 | info("-----------------------------------------------------\n"); 272 | closeLog(); 273 | } 274 | 275 | 276 | 277 | main(); 278 | 279 | 280 | 281 | 282 | -------------------------------------------------------------------------------- /pg_catalog/README.txt: -------------------------------------------------------------------------------- 1 | INFORMATION: 2 | Scripts for pg_catalog maintenance. 3 | 4 | 5 | catalog_monitor.pl: 6 | Information: Check size,count,bloat in pg_class/pg_namespace/pg_attribute/pg_partition_rule/pg_statistic 7 | Usage: 8 | perl catalog_monitor.pl dbname 9 | Example: 10 | perl catalog_monitor.pl testdb 11 | 12 | 13 | vacuum_analyze.sh 14 | Information: Using for vacuum analyze all tables in pg_catalog daily, this script is single process. 15 | Usage: 16 | sh vacuum_analyze.sh dbname pg_catalog 17 | Example: 18 | sh vacuum_analyze.sh testdb pg_catalog 19 | 20 | 21 | vacuum_analyze_mproc.sh 22 | Information: Using for vacuum analyze all tables in pg_catalog daily, this script is three processes. 23 | Usage: 24 | sh vacuum_analyze_mproc.sh dbname pg_catalog 25 | Example: 26 | sh vacuum_analyze_mproc.sh testdb pg_catalog 27 | 28 | 29 | -------------------------------------------------------------------------------- /pg_catalog/vacuum_analyze.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | DBNAME=$1 4 | SCHEMA=$2 5 | VCOMMAND="VACUUM ANALYZE" 6 | 7 | source /usr/local/greenplum-db/greenplum_path.sh 8 | 9 | psql -tc "select '$VCOMMAND '||nspname||'.'||relname||';' from pg_class a,pg_namespace b where a.relnamespace=b.oid and b.nspname= '$SCHEMA' and a.relkind='r' and a.relstorage<>'x'" $DBNAME | psql -a $DBNAME -------------------------------------------------------------------------------- /pg_catalog/vacuum_analyze_mproc.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | DBNAME=$1 4 | SCHEMA=$2 5 | VCOMMAND="VACUUM ANALYZE" 6 | 7 | source /usr/local/greenplum-db/greenplum_path.sh 8 | 9 | psql -tc "select '$VCOMMAND '||nspname||'.'||relname||';' from pg_class a,pg_namespace b where a.relnamespace=b.oid and b.nspname= '$SCHEMA' and a.relkind='r' and a.relstorage<>'x'" $DBNAME | xargs -L1 -P3 -Ixx psql $DBNAME -qtAX -ac "xx" -------------------------------------------------------------------------------- /show_privilege_view/README.txt: -------------------------------------------------------------------------------- 1 | Installation: 2 | psql dbname -af show_privelege_info.sql 3 | psql dbname -af view_for_table_privilege.sql 4 | 5 | 6 | Usage: 7 | 8 | select * from view_for_table_privilege where schemaname='public'; 9 | 10 | 11 | 12 | -------------------------------------------------------------------------------- /show_privilege_view/show_privelege_info.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION show_privelege_role(priflag text,nspacl aclitem[]) 2 | RETURNS text AS 3 | $$ 4 | DECLARE 5 | i int; 6 | aclstr text; 7 | pristr text; 8 | username text; 9 | resultstr text; 10 | BEGIN 11 | if array_lower(nspacl,1) is null then 12 | return ''; 13 | end if; 14 | 15 | username := ''; 16 | pristr := '='||priflag||E'\/'; 17 | for i in array_lower(nspacl,1) .. array_upper(nspacl,1) 18 | loop 19 | aclstr := nspacl[i]; 20 | if aclstr ~ pristr then 21 | if substr(aclstr,1,1)='=' then 22 | --public; 23 | username := username||'public;'; 24 | else 25 | --granted role; 26 | username := username||substr(aclstr,1,position('=' in aclstr)-1)||';'; 27 | end if; 28 | end if; 29 | end loop; 30 | if trim(username)!='' then 31 | resultstr := substr(username,1,length(username)-1); 32 | end if; 33 | 34 | return resultstr; 35 | 36 | END; 37 | $$ 38 | LANGUAGE plpgsql volatile; 39 | 40 | 41 | 42 | 43 | ---------------------------------------------------------------- 44 | 45 | CREATE OR REPLACE FUNCTION show_acl_role(aclstr aclitem) 46 | RETURNS text AS 47 | $$ 48 | DECLARE 49 | invar text; 50 | username text; 51 | BEGIN 52 | if aclstr is null then 53 | return ''; 54 | end if; 55 | invar := aclstr; 56 | username := split_part(trim(invar),'=',1); 57 | if trim(username)='' then 58 | username := 'public'; 59 | end if; 60 | 61 | return username; 62 | END; 63 | $$ 64 | LANGUAGE plpgsql volatile; 65 | 66 | CREATE OR REPLACE FUNCTION show_acl_schema(aclstr aclitem) 67 | RETURNS text AS 68 | $$ 69 | DECLARE 70 | i int; 71 | invar text; 72 | pristr text; 73 | resultstr text; 74 | BEGIN 75 | if aclstr is null then 76 | return ''; 77 | end if; 78 | invar := aclstr; 79 | pristr := split_part(split_part(trim(invar),'=',2),E'\/',1); 80 | --raise info '%',pristr; 81 | resultstr := ''; 82 | if pristr ~ 'U' then 83 | resultstr := resultstr||'Usage;'; 84 | end if; 85 | if pristr ~ 'C' then 86 | resultstr := resultstr||'Create;'; 87 | end if; 88 | 89 | return resultstr; 90 | END; 91 | $$ 92 | LANGUAGE plpgsql volatile; 93 | 94 | CREATE OR REPLACE FUNCTION show_acl_table(aclstr aclitem) 95 | RETURNS text AS 96 | $$ 97 | DECLARE 98 | i int; 99 | invar text; 100 | pristr text; 101 | resultstr text; 102 | BEGIN 103 | if aclstr is null then 104 | return ''; 105 | end if; 106 | invar := aclstr; 107 | pristr := split_part(split_part(trim(invar),'=',2),E'\/',1); 108 | resultstr := ''; 109 | if pristr ~ 'r' then 110 | resultstr := resultstr||'Select;'; 111 | end if; 112 | if pristr ~ 'a' then 113 | resultstr := resultstr||'Insert;'; 114 | end if; 115 | if pristr ~ 'w' then 116 | resultstr := resultstr||'Update;'; 117 | end if; 118 | if pristr ~ 'd' then 119 | resultstr := resultstr||'Delete;'; 120 | end if; 121 | if pristr ~ 'D' then 122 | resultstr := resultstr||'Truncate;'; 123 | end if; 124 | 125 | return resultstr; 126 | END; 127 | $$ 128 | LANGUAGE plpgsql volatile; 129 | 130 | 131 | ------------------------------------------------------------ 132 | --schema 133 | select nspname schemaname 134 | ,case when show_acl_role(nspaclstr)='' then rolname else show_acl_role(nspaclstr) end as usename 135 | ,show_acl_schema(nspaclstr) schema_privillege 136 | from 137 | (select nspname,rolname,null as nspaclstr 138 | from pg_namespace a,pg_roles b where a.nspowner=b.oid and a.nspname not like 'pg%' and nspacl is null 139 | union all 140 | select nspname,rolname,unnest(nspacl) as nspaclstr 141 | from pg_namespace a,pg_roles b where a.nspowner=b.oid and a.nspname not like 'pg%' and nspacl is not null 142 | ) foo; 143 | 144 | 145 | 146 | 147 | 148 | 149 | 150 | -------------------------------------------------------------------------------- /show_privilege_view/view_for_table_privilege.sql: -------------------------------------------------------------------------------- 1 | create or replace view view_for_table_privilege as 2 | select schemaname, 3 | tablename, 4 | tabletype, 5 | reltablespace, 6 | case when show_acl_role(relaclstr)='' then rolname else show_acl_role(relaclstr) end as rolname, 7 | case when show_acl_role(relaclstr)=rolname then 'TRUE' when show_acl_role(relaclstr)='' then 'TRUE' else 'FALSE' end as isowner, 8 | case when show_acl_table(relaclstr)='' then 'Select;Insert;Update;Delete;Truncate;' else show_acl_table(relaclstr) end as privelege 9 | from ( 10 | select nspname as schemaname 11 | ,relname as tablename 12 | ,rol.rolname 13 | ,coalesce(tbs.spcname,'pg_default') as reltablespace 14 | ,case when relkind='r' then 'Table' else 'View' end as tabletype 15 | ,null as relaclstr 16 | from pg_class rel inner join pg_namespace nsp on nsp.oid=rel.relnamespace 17 | inner join pg_authid rol on rel.relowner=rol.oid 18 | left join pg_tablespace tbs on rel.reltablespace=tbs.oid 19 | where rel.relkind in ('r','v','x') and rel.relname not like '%_1_prt_%' and rel.relacl is null 20 | union all 21 | select nspname as schemaname 22 | ,relname as tablename 23 | ,rol.rolname 24 | ,coalesce(tbs.spcname,'pg_default') as reltablespace 25 | ,case when relkind='r' then 'Table' else 'View' end as tabletype 26 | ,unnest(rel.relacl) as relaclstr 27 | from pg_class rel inner join pg_namespace nsp on nsp.oid=rel.relnamespace 28 | inner join pg_authid rol on rel.relowner=rol.oid 29 | left join pg_tablespace tbs on rel.reltablespace=tbs.oid 30 | where rel.relkind in ('r','v','x') and rel.relname not like '%_1_prt_%' and rel.relacl is not null 31 | ) as pri; 32 | 33 | -------------------------------------------------------------------------------- /skew/README.txt: -------------------------------------------------------------------------------- 1 | Installation: 2 | For GP4.3 and GP5: 3 | psql dbname -af ./skew/skewcheck_func.sql 4 | For GP6: 5 | psql dbname -af ./skew/skewcheck_func_gp6.sql 6 | For GP7: 7 | psql dbname -af ./skew/skewcheck_func_gp7.sql 8 | 9 | Usage: Check table skew in each schema. example: select * from skewcheck_func('public'); 10 | 11 | Output column: 12 | tablename: Skew table name. 13 | sys_segcount: Total segment instances in GP cluster. 14 | data_segcount: The number of segment instances have data in this table. 15 | maxsize_segid: The max size segmentID in this table. 16 | maxsize: Size of segmentID above. 17 | skew: skew rate, (max - avg)/avg. 18 | dk: Distribution key of table, if null is randomly. 19 | 20 | Even if skew=0, but data_segcount-1 and role='p'; 35 | 36 | drop table if exists skewresult_new2; 37 | create temp table skewresult_new2 ( 38 | tablename varchar(100), 39 | partname varchar(200), 40 | segid int, 41 | cnt bigint 42 | ) distributed randomly; 43 | 44 | v_sql := 'insert into skewresult_new2 45 | select case when position(''_1_prt_'' in nsp.nspname||''.''||rel.relname)>0 then 46 | substr(nsp.nspname||''.''||rel.relname,1,position(''_1_prt_'' in nsp.nspname||''.''||rel.relname)-1) 47 | else nsp.nspname||''.''||rel.relname 48 | end 49 | ,nsp.nspname||''.''||rel.relname 50 | ,rel.gp_segment_id 51 | ,pg_relation_size(E''\"''||nsp.nspname||E''\".\"''||rel.relname||E''\"'') 52 | from gp_dist_random(''pg_class'') rel, pg_namespace nsp 53 | where nsp.oid=rel.relnamespace and rel.relkind=''r'' and relstorage!=''x'' 54 | and nsp.nspname in '||v_schemastr; 55 | execute v_sql; 56 | 57 | drop table if exists skewresult_tmp; 58 | create temp table skewresult_tmp ( 59 | tablename varchar(100), 60 | segid int, 61 | rec_num numeric(30,0) 62 | ) distributed by (tablename); 63 | 64 | insert into skewresult_tmp 65 | select tablename,segid,sum(cnt) as rec_num from skewresult_new2 66 | where tablename in ( 67 | select tablename from skewresult_new2 group by 1 having sum(cnt)>1073741824 68 | ) group by 1,2 having sum(cnt)>0; 69 | 70 | drop table if exists skewresult_tabledk; 71 | create temp table skewresult_tabledk 72 | as 73 | select tablename,string_agg(attname,',' order by attid) dk 74 | from ( 75 | select nsp.nspname||'.'||rel.relname tablename,a.attrnums[attid] attnum,attid,att.attname 76 | from pg_catalog.gp_distribution_policy a, 77 | generate_series(1,50) attid, 78 | pg_attribute att, 79 | pg_class rel, 80 | pg_namespace nsp 81 | where rel.oid=a.localoid and rel.relnamespace=nsp.oid and a.localoid=att.attrelid 82 | and array_upper(a.attrnums,1)>=attid and a.attrnums[attid]=att.attnum 83 | and relname not like '%_1_prt_%' 84 | ) foo 85 | group by 1 86 | distributed randomly; 87 | 88 | drop table if exists tmp_skewresult; 89 | create temp table tmp_skewresult 90 | (tablename text,sys_segcount int,data_segcount int,maxsize_segid int,maxsize bigint,skew numeric(18,2),dk text) 91 | distributed randomly; 92 | 93 | insert into tmp_skewresult 94 | select t1.tablename,i_sys_segcount,t1.segcount,t2.segid max_segid,t2.segsize max_segsize,t3.skew::numeric(18,2),t4.dk 95 | from ( 96 | select tablename,count(*) as segcount from skewresult_tmp 97 | group by 1 having count(*)0.5 126 | ) t3 on t1.tablename=t3.tablename 127 | left join skewresult_tabledk t4 on t1.tablename=t4.tablename 128 | where t2.rn=1; 129 | 130 | 131 | for v_record in 132 | select tablename,sys_segcount,data_segcount,maxsize_segid,pg_size_pretty(maxsize::bigint),skew,dk from tmp_skewresult 133 | order by data_segcount asc,maxsize desc 134 | loop 135 | return next v_record; 136 | end loop; 137 | return; 138 | 139 | END; 140 | $$ 141 | LANGUAGE plpgsql volatile; 142 | -------------------------------------------------------------------------------- /skew/skewcheck_func_gp6.sql: -------------------------------------------------------------------------------- 1 | CREATE TYPE type_skew_resultset as (tablename text,sys_segcount int,data_segcount int,maxsize_segid int,maxsize text,skew numeric(18,2),dk text); 2 | 3 | 4 | 5 | ----s_schema format: 'schema1,schema2,schema3' 6 | CREATE OR REPLACE FUNCTION skewcheck_func(s_schema text) 7 | RETURNS SETOF type_skew_resultset AS 8 | $$ 9 | declare 10 | v_record type_skew_resultset%rowtype; 11 | i_sys_segcount int; 12 | schema_array text[]; 13 | v_schemastr text; 14 | i int; 15 | v_sql text; 16 | 17 | BEGIN 18 | --select * from skewcheck_func('public,dw,ods'); 19 | schema_array := string_to_array(s_schema,','); 20 | --raise info '%,%',array_lower(schema_array,1),array_upper(schema_array,1); 21 | v_schemastr := '('; 22 | i := 1; 23 | while i <= array_upper(schema_array,1) loop 24 | --raise info '%',schema_array[i]; 25 | if i-1 and role='p'; 35 | 36 | drop table if exists skewresult_new2; 37 | create temp table skewresult_new2 ( 38 | tablename varchar(100), 39 | partname varchar(200), 40 | segid int, 41 | cnt bigint 42 | ) distributed randomly; 43 | 44 | v_sql := 'insert into skewresult_new2 45 | select case when position(''_1_prt_'' in nsp.nspname||''.''||rel.relname)>0 then 46 | substr(nsp.nspname||''.''||rel.relname,1,position(''_1_prt_'' in nsp.nspname||''.''||rel.relname)-1) 47 | else nsp.nspname||''.''||rel.relname 48 | end 49 | ,nsp.nspname||''.''||rel.relname 50 | ,rel.gp_segment_id 51 | ,pg_relation_size(E''\"''||nsp.nspname||E''\".\"''||rel.relname||E''\"'') 52 | from gp_dist_random(''pg_class'') rel, pg_namespace nsp 53 | where nsp.oid=rel.relnamespace and rel.relkind=''r'' and relstorage!=''x'' 54 | and nsp.nspname in '||v_schemastr; 55 | execute v_sql; 56 | 57 | drop table if exists skewresult_tmp; 58 | create temp table skewresult_tmp ( 59 | tablename varchar(100), 60 | segid int, 61 | rec_num numeric(30,0) 62 | ) distributed by (tablename); 63 | 64 | insert into skewresult_tmp 65 | select tablename,segid,sum(cnt) as rec_num from skewresult_new2 66 | where tablename in ( 67 | select tablename from skewresult_new2 group by 1 having sum(cnt)>1073741824 68 | ) group by 1,2 having sum(cnt)>0; 69 | 70 | drop table if exists skewresult_tabledk; 71 | create temp table skewresult_tabledk 72 | as 73 | select tablename,string_agg(attname,',' order by attid) dk 74 | from ( 75 | select nsp.nspname||'.'||rel.relname tablename,a.distkey[attid] attnum,attid,att.attname 76 | from pg_catalog.gp_distribution_policy a, 77 | generate_series(0,50) attid, 78 | pg_attribute att, 79 | pg_class rel, 80 | pg_namespace nsp 81 | where rel.oid=a.localoid and rel.relnamespace=nsp.oid and a.localoid=att.attrelid 82 | and array_upper(a.distkey,1)>=attid and a.distkey[attid]=att.attnum 83 | and relname not like '%_1_prt_%' 84 | ) foo 85 | group by 1 86 | distributed randomly; 87 | 88 | drop table if exists tmp_skewresult; 89 | create temp table tmp_skewresult 90 | (tablename text,sys_segcount int,data_segcount int,maxsize_segid int,maxsize bigint,skew numeric(18,2),dk text) 91 | distributed randomly; 92 | 93 | insert into tmp_skewresult 94 | select t1.tablename,i_sys_segcount,t1.segcount,t2.segid max_segid,t2.segsize max_segsize,t3.skew::numeric(18,2),t4.dk 95 | from ( 96 | select tablename,count(*) as segcount from skewresult_tmp 97 | group by 1 having count(*)0.5 126 | ) t3 on t1.tablename=t3.tablename 127 | left join skewresult_tabledk t4 on t1.tablename=t4.tablename 128 | where t2.rn=1; 129 | 130 | 131 | for v_record in 132 | select tablename,sys_segcount,data_segcount,maxsize_segid,pg_size_pretty(maxsize::bigint),skew,dk from tmp_skewresult 133 | order by data_segcount asc,maxsize desc 134 | loop 135 | return next v_record; 136 | end loop; 137 | return; 138 | 139 | END; 140 | $$ 141 | LANGUAGE plpgsql volatile; 142 | 143 | 144 | 145 | CREATE OR REPLACE FUNCTION skewcheck_func() 146 | RETURNS SETOF type_skew_resultset AS 147 | $$ 148 | declare 149 | v_record type_skew_resultset%rowtype; 150 | i_sys_segcount int; 151 | 152 | BEGIN 153 | --select * from skewcheck_func(); 154 | 155 | select count(*) into i_sys_segcount from gp_segment_configuration where content>-1 and role='p'; 156 | 157 | drop table if exists skewresult_new2; 158 | create temp table skewresult_new2 ( 159 | tablename varchar(100), 160 | partname varchar(200), 161 | segid int, 162 | cnt bigint 163 | ) distributed randomly; 164 | insert into skewresult_new2 165 | select case when position('_1_prt_' in nsp.nspname||'.'||rel.relname)>0 then 166 | substr(nsp.nspname||'.'||rel.relname,1,position('_1_prt_' in nsp.nspname||'.'||rel.relname)-1) 167 | else nsp.nspname||'.'||rel.relname 168 | end 169 | ,nsp.nspname||'.'||rel.relname 170 | ,rel.gp_segment_id 171 | ,pg_relation_size(E'\"'||nsp.nspname||E'\".\"'||rel.relname||E'\"') 172 | from gp_dist_random('pg_class') rel, pg_namespace nsp 173 | where nsp.oid=rel.relnamespace and rel.relkind='r' and relstorage!='x' 174 | and nsp.nspname not like 'pg%' and nsp.nspname not like 'gp%'; 175 | 176 | drop table if exists skewresult_tmp; 177 | create temp table skewresult_tmp ( 178 | tablename varchar(100), 179 | segid int, 180 | rec_num numeric(30,0) 181 | ) distributed by (tablename); 182 | 183 | insert into skewresult_tmp 184 | select tablename,segid,sum(cnt) as rec_num from skewresult_new2 185 | where tablename in ( 186 | select tablename from skewresult_new2 group by 1 having sum(cnt)>1073741824 187 | ) group by 1,2 having sum(cnt)>0; 188 | 189 | drop table if exists skewresult_tabledk; 190 | create temp table skewresult_tabledk 191 | as 192 | select tablename,string_agg(attname,',' order by attid) dk 193 | from ( 194 | select nsp.nspname||'.'||rel.relname tablename,a.distkey[attid] attnum,attid,att.attname 195 | from pg_catalog.gp_distribution_policy a, 196 | generate_series(0,50) attid, 197 | pg_attribute att, 198 | pg_class rel, 199 | pg_namespace nsp 200 | where rel.oid=a.localoid and rel.relnamespace=nsp.oid and a.localoid=att.attrelid 201 | and array_upper(a.distkey,1)>=attid and a.distkey[attid]=att.attnum 202 | and relname not like '%_1_prt_%' 203 | ) foo 204 | group by 1 205 | distributed randomly; 206 | 207 | drop table if exists tmp_skewresult; 208 | create temp table tmp_skewresult 209 | (tablename text,sys_segcount int,data_segcount int,maxsize_segid int,maxsize bigint,skew numeric(18,2),dk text) 210 | distributed randomly; 211 | 212 | insert into tmp_skewresult 213 | select t1.tablename,i_sys_segcount,t1.segcount,t2.segid max_segid,t2.segsize max_segsize,t3.skew::numeric(18,2),t4.dk 214 | from ( 215 | select tablename,count(*) as segcount from skewresult_tmp 216 | group by 1 having count(*)0.5 245 | ) t3 on t1.tablename=t3.tablename 246 | left join skewresult_tabledk t4 on t1.tablename=t4.tablename 247 | where t2.rn=1; 248 | 249 | 250 | for v_record in 251 | select tablename,sys_segcount,data_segcount,maxsize_segid,pg_size_pretty(maxsize::bigint),skew,dk from tmp_skewresult 252 | order by data_segcount asc,maxsize desc 253 | loop 254 | return next v_record; 255 | end loop; 256 | return; 257 | 258 | END; 259 | $$ 260 | LANGUAGE plpgsql volatile; 261 | 262 | -------------------------------------------------------------------------------- /skew/skewcheck_func_gp7.sql: -------------------------------------------------------------------------------- 1 | CREATE TYPE type_skew_resultset as (tablename regclass,sys_segcount int,data_segcount int,maxsize_segid int,maxsize text,skew numeric(18,2),dk text); 2 | 3 | 4 | 5 | ----s_schema format: 'schema1,schema2,schema3' 6 | CREATE OR REPLACE FUNCTION skewcheck_func(s_schema text) 7 | RETURNS SETOF type_skew_resultset AS 8 | $$ 9 | declare 10 | v_record type_skew_resultset%rowtype; 11 | i_sys_segcount int; 12 | schema_array text[]; 13 | v_schemastr text; 14 | i int; 15 | v_sql text; 16 | 17 | BEGIN 18 | --select * from skewcheck_func('public,dw,ods'); 19 | schema_array := string_to_array(s_schema,','); 20 | --raise info '%,%',array_lower(schema_array,1),array_upper(schema_array,1); 21 | v_schemastr := '('; 22 | i := 1; 23 | while i <= array_upper(schema_array,1) loop 24 | --raise info '%',schema_array[i]; 25 | if i-1 and role='p'; 35 | 36 | drop table if exists skewresult_new2; 37 | create temp table skewresult_new2 ( 38 | tablename regclass, 39 | partname regclass, 40 | segid int, 41 | cnt bigint 42 | ) distributed by (tablename); 43 | 44 | v_sql := 'insert into skewresult_new2 45 | select case when relispartition then pg_partition_root(rel.oid) 46 | else rel.oid::regclass 47 | end 48 | ,rel.oid::regclass 49 | ,rel.gp_segment_id 50 | ,pg_relation_size(rel.oid) 51 | from gp_dist_random(''pg_class'') rel, pg_namespace nsp 52 | where rel.relnamespace=nsp.oid and rel.relkind=''r'' and nsp.nspname in '||v_schemastr; 53 | execute v_sql; 54 | 55 | drop table if exists skewresult_tmp; 56 | create temp table skewresult_tmp ( 57 | tablename regclass, 58 | segid int, 59 | rec_num numeric(30,0) 60 | ) distributed by (tablename); 61 | 62 | insert into skewresult_tmp 63 | select tablename,segid,sum(cnt) as rec_num from skewresult_new2 64 | where tablename in ( 65 | select tablename from skewresult_new2 group by 1 having sum(cnt)>1073741824 66 | ) group by 1,2 having sum(cnt)>0; 67 | 68 | drop table if exists skewresult_tabledk; 69 | create temp table skewresult_tabledk ( 70 | tablename regclass, 71 | dk text 72 | ) distributed by (tablename); 73 | 74 | v_sql := 'insert into skewresult_tabledk 75 | select tablename,string_agg(attname,'','' order by attid) dk 76 | from ( 77 | select rel.oid::regclass tablename,a.distkey[attid] attnum,attid,att.attname 78 | from pg_catalog.gp_distribution_policy a, 79 | generate_series(0,50) attid, 80 | pg_attribute att, 81 | pg_class rel, 82 | pg_namespace nsp 83 | where rel.relnamespace=nsp.oid and rel.oid=a.localoid and a.localoid=att.attrelid 84 | and array_upper(a.distkey,1)>=attid and a.distkey[attid]=att.attnum and rel.relispartition=false 85 | and nsp.nspname in '||v_schemastr||' 86 | ) foo 87 | group by 1'; 88 | execute v_sql; 89 | 90 | drop table if exists tmp_skewresult; 91 | create temp table tmp_skewresult ( 92 | tablename regclass, 93 | sys_segcount int, 94 | data_segcount int, 95 | maxsize_segid int, 96 | maxsize bigint, 97 | skew numeric(18,2), 98 | dk text 99 | ) distributed by (tablename); 100 | 101 | insert into tmp_skewresult 102 | select t1.tablename,i_sys_segcount,t1.segcount,t2.segid max_segid,t2.segsize max_segsize,t3.skew::numeric(18,2),t4.dk 103 | from ( 104 | select tablename,count(*) as segcount from skewresult_tmp 105 | group by 1 having count(*)0.5 134 | ) t3 on t1.tablename=t3.tablename 135 | left join skewresult_tabledk t4 on t1.tablename=t4.tablename 136 | where t2.rn=1; 137 | 138 | 139 | for v_record in 140 | select tablename,sys_segcount,data_segcount,maxsize_segid,pg_size_pretty(maxsize::bigint),skew,dk from tmp_skewresult 141 | order by data_segcount asc,maxsize desc 142 | loop 143 | return next v_record; 144 | end loop; 145 | return; 146 | 147 | END; 148 | $$ 149 | LANGUAGE plpgsql volatile; 150 | 151 | 152 | 153 | CREATE OR REPLACE FUNCTION skewcheck_func() 154 | RETURNS SETOF type_skew_resultset AS 155 | $$ 156 | declare 157 | v_record type_skew_resultset%rowtype; 158 | i_sys_segcount int; 159 | 160 | BEGIN 161 | --select * from skewcheck_func(); 162 | 163 | select count(*) into i_sys_segcount from gp_segment_configuration where content>-1 and role='p'; 164 | 165 | drop table if exists skewresult_new2; 166 | create temp table skewresult_new2 ( 167 | tablename regclass, 168 | partname regclass, 169 | segid int, 170 | cnt bigint 171 | ) distributed randomly; 172 | 173 | insert into skewresult_new2 174 | select case when relispartition then pg_partition_root(rel.oid) 175 | else rel.oid::regclass 176 | end 177 | ,rel.oid::regclass 178 | ,rel.gp_segment_id 179 | ,pg_relation_size(rel.oid) 180 | from gp_dist_random('pg_class') rel, pg_namespace nsp 181 | where rel.relnamespace=nsp.oid and rel.relkind='r'; 182 | 183 | drop table if exists skewresult_tmp; 184 | create temp table skewresult_tmp ( 185 | tablename varchar(100), 186 | segid int, 187 | rec_num numeric(30,0) 188 | ) distributed by (tablename); 189 | 190 | insert into skewresult_tmp 191 | select tablename,segid,sum(cnt) as rec_num from skewresult_new2 192 | where tablename in ( 193 | select tablename from skewresult_new2 group by 1 having sum(cnt)>1073741824 194 | ) group by 1,2 having sum(cnt)>0; 195 | 196 | drop table if exists skewresult_tabledk; 197 | create temp table skewresult_tabledk 198 | as 199 | select tablename,string_agg(attname,',' order by attid) dk 200 | from ( 201 | select nsp.nspname||'.'||rel.relname tablename,a.distkey[attid] attnum,attid,att.attname 202 | from pg_catalog.gp_distribution_policy a, 203 | generate_series(0,50) attid, 204 | pg_attribute att, 205 | pg_class rel, 206 | pg_namespace nsp 207 | where rel.oid=a.localoid and rel.relnamespace=nsp.oid and a.localoid=att.attrelid 208 | and array_upper(a.distkey,1)>=attid and a.distkey[attid]=att.attnum 209 | and relname not like '%_1_prt_%' 210 | ) foo 211 | group by 1 212 | distributed randomly; 213 | 214 | drop table if exists tmp_skewresult; 215 | create temp table tmp_skewresult 216 | (tablename text,sys_segcount int,data_segcount int,maxsize_segid int,maxsize bigint,skew numeric(18,2),dk text) 217 | distributed randomly; 218 | 219 | insert into tmp_skewresult 220 | select t1.tablename,i_sys_segcount,t1.segcount,t2.segid max_segid,t2.segsize max_segsize,t3.skew::numeric(18,2),t4.dk 221 | from ( 222 | select tablename,count(*) as segcount from skewresult_tmp 223 | group by 1 having count(*)0.5 252 | ) t3 on t1.tablename=t3.tablename 253 | left join skewresult_tabledk t4 on t1.tablename=t4.tablename 254 | where t2.rn=1; 255 | 256 | 257 | for v_record in 258 | select tablename,sys_segcount,data_segcount,maxsize_segid,pg_size_pretty(maxsize::bigint),skew,dk from tmp_skewresult 259 | order by data_segcount asc,maxsize desc 260 | loop 261 | return next v_record; 262 | end loop; 263 | return; 264 | 265 | END; 266 | $$ 267 | LANGUAGE plpgsql volatile; 268 | 269 | -------------------------------------------------------------------------------- /vacuum/README.txt: -------------------------------------------------------------------------------- 1 | AObloat function: 2 | 3 | Install: 4 | psql -d dbname -af ./aobloat/check_ao_bloat.sql 5 | 6 | Example: 7 | select * from AOtable_bloatcheck('schemaname'); 8 | 9 | Information: 10 | Use this function to check bloat of AO table in the schema specified. (Not for heap table) 11 | 12 | 13 | ---------------------------- 14 | gp_vacuum_script: Check bloat table (include: heap / ao tables), vacuum them in parallel. 15 | 16 | Usage: 17 | perl $cmd_name [OPTIONS] 18 | 19 | Options: 20 | --hostname | -h 21 | Master hostname or master host IP. Default: localhost 22 | 23 | --port | -p 24 | GP Master port number, Default: 5432 25 | 26 | --dbname | -d 27 | Database name. If not specified, uses the value specified by the environment variable PGDATABASE, even if PGDATABASE is not specified, return error. 28 | 29 | --username | -u 30 | The super user of GPDB. Default: gpadmin 31 | 32 | --password | -pw 33 | The password of GP user. Default: no password 34 | 35 | --help | -? 36 | Show the help message. 37 | 38 | --all | -a 39 | Check all the schema in database. 40 | 41 | --log-dir | -l 42 | The directory to write the log file. Default: ~/gpAdminLogs. 43 | 44 | --jobs 45 | The number of parallel jobs to vacuum. Default: 2 46 | 47 | --include-schema 48 | Vacuum only specified schema(s). --include-schema can be specified multiple times. 49 | 50 | --include-schema-file 51 | A file containing a list of schema to be vacuum. 52 | 53 | --exclude-schema 54 | vacuum all tables except the tables in the specified schema(s). --exclude-schema can be specified multiple times. 55 | 56 | --exclude-schema-file 57 | A file containing a list of schemas to be excluded for vacuum. 58 | 59 | Examples: 60 | perl $cmd_name -d testdb -u gpadmin --include-schema public --include-schema gpp_sync --jobs 3 61 | 62 | perl $cmd_name -d testdb -u gpadmin --exclude-schema public --exclude-schema dw --jobs 3 63 | 64 | perl $cmd_name --help 65 | 66 | 67 | 68 | 69 | ---------------------------- 70 | gp_reclaim_space.pl: Check bloat table (include: heap / ao tables), using alter table (reorganize=true) to reclaim space immediatly. 71 | 72 | Usage: 73 | perl gp_reclaim_space.pl [OPTIONS] 74 | 75 | Options: 76 | --hostname | -h 77 | Master hostname or master host IP. Default: localhost 78 | 79 | --port | -p 80 | GP Master port number, Default: 5432 81 | 82 | --dbname | -d 83 | Database name. If not specified, uses the value specified by the environment variable PGDATABASE, even if PGDATABASE is not specified, return error. 84 | 85 | --username | -u 86 | The super user of GPDB. Default: gpadmin 87 | 88 | --password | -pw 89 | The password of GP user. Default: no password 90 | 91 | --help | -? 92 | Show the help message. 93 | 94 | --all | -a 95 | Check all the schema in database. 96 | 97 | --jobs 98 | The number of parallel jobs to vacuum. Default: 2 99 | 100 | --include-schema 101 | Vacuum only specified schema(s). Example: dw,dm,ods 102 | 103 | --include-schema-file 104 | A file containing a list of schema to be vacuum. 105 | 106 | --exclude-schema 107 | vacuum all tables except the tables in the specified schema(s). Example: dw,dm,ods. 108 | 109 | --exclude-schema-file 110 | A file containing a list of schemas to be excluded for vacuum. 111 | 112 | --week-day 113 | Run this program on the days of week. Example: 6,7 114 | 115 | --exclude-date 116 | Do not run this program on the days of month. Example: 1,2,5,6. 117 | 118 | --duration 119 | Duration of the program running from beginning to end. Example: 1 for one hour, 0.5 for half an hour. If not specified, do not stop till reclaim all bloat tables. 120 | 121 | Examples: 122 | perl gp_reclaim_space.pl -d testdb -u gpadmin --include-schema gpp_sync,syndata --jobs 3 123 | 124 | perl gp_reclaim_space.pl -d testdb -u gpadmin --include-schema-file /tmp/schema.conf --jobs 3 125 | 126 | perl gp_reclaim_space.pl -d testdb -u gpadmin --exclude-schema dw,public --jobs 3 127 | 128 | perl gp_reclaim_space.pl -d testdb -u gpadmin -s gpp_sync,syndata --jobs 3 --week-day 6,7 --exclude-date 1,2,5,6 --duration 2 129 | 130 | perl gp_reclaim_space.pl -d testdb -u gpadmin -e dw,public --jobs 3 131 | 132 | perl gp_reclaim_space.pl --help 133 | 134 | 135 | 136 | -------------------------------------------------------------------------------- /vacuum/aobloat/check_ao_bloat.sql: -------------------------------------------------------------------------------- 1 | CREATE TYPE type_AOtable_bloat as (reloid bigint,schemaname text,tablename text,percent_hidden float,bloat float); 2 | 3 | 4 | CREATE OR REPLACE FUNCTION check_AOtable_bloat() 5 | RETURNS SETOF type_AOtable_bloat AS 6 | $$ 7 | declare 8 | v_record type_AOtable_bloat%rowtype; 9 | i_oid bigint; 10 | v_schema text; 11 | v_table text; 12 | v_sql text; 13 | v_hidden bigint; 14 | v_total bigint; 15 | BEGIN 16 | set statement_timeout='24h'; 17 | 18 | BEGIN 19 | v_sql := 'drop table if exists ao_aovisimap_hidden; 20 | create temp table ao_aovisimap_hidden as 21 | select rel.oid reloid,nsp.nspname,rel.relname,rel.gp_segment_id segid, 22 | (gp_toolkit.__gp_aovisimap_hidden_typed(rel.oid)::record).* 23 | FROM gp_dist_random(''pg_class'') rel, pg_namespace nsp 24 | where nsp.oid=rel.relnamespace and rel.relkind=''r'' and rel.relstorage in (''a'',''c'')'; 25 | execute v_sql; 26 | EXCEPTION WHEN undefined_table THEN 27 | raise info 'Any relation oid not found because of a concurrent drop operation, skipped!'; 28 | return; 29 | END; 30 | 31 | v_sql := 'select reloid,nspname,relname,sum(hidden) hidden_tupcount,sum(total) total_tupcount from ao_aovisimap_hidden group by 1,2,3'; 32 | for i_oid,v_schema,v_table,v_hidden,v_total in 33 | execute v_sql 34 | loop 35 | v_record.reloid := i_oid; 36 | v_record.schemaname := v_schema; 37 | v_record.tablename := v_table; 38 | 39 | IF v_total > 0 THEN 40 | v_record.percent_hidden := (100 * v_hidden / v_total::numeric)::numeric(5,2); 41 | ELSE 42 | v_record.percent_hidden := 0::numeric(5,2); 43 | END IF; 44 | v_record.bloat := 100 / (100.1-v_record.percent_hidden); 45 | 46 | return next v_record; 47 | end loop; 48 | return; 49 | 50 | END; 51 | $$ 52 | LANGUAGE plpgsql; 53 | 54 | 55 | 56 | ----old function, in_schemaname format: '(''schema1'',''schema2'',''schema3'')' 57 | CREATE OR REPLACE FUNCTION check_AOtable_bloat(in_schemaname text) 58 | RETURNS SETOF type_AOtable_bloat AS 59 | $$ 60 | declare 61 | v_record type_AOtable_bloat%rowtype; 62 | i_oid bigint; 63 | v_schema text; 64 | v_table text; 65 | v_sql text; 66 | v_hidden bigint; 67 | v_total bigint; 68 | BEGIN 69 | set statement_timeout='24h'; 70 | 71 | BEGIN 72 | v_sql := 'drop table if exists ao_aovisimap_hidden; 73 | create temp table ao_aovisimap_hidden as 74 | select rel.oid reloid,nsp.nspname,rel.relname,rel.gp_segment_id segid, 75 | (gp_toolkit.__gp_aovisimap_hidden_typed(rel.oid)::record).* 76 | FROM gp_dist_random(''pg_class'') rel, pg_namespace nsp 77 | where nsp.oid=rel.relnamespace and rel.relkind=''r'' and rel.relstorage in (''a'',''c'') 78 | and nsp.nspname in '||in_schemaname; 79 | execute v_sql; 80 | EXCEPTION WHEN undefined_table THEN 81 | raise info 'Any relation oid not found because of a concurrent drop operation, skipped!'; 82 | return; 83 | END; 84 | 85 | v_sql := 'select reloid,nspname,relname,sum(hidden) hidden_tupcount,sum(total) total_tupcount from ao_aovisimap_hidden group by 1,2,3'; 86 | for i_oid,v_schema,v_table,v_hidden,v_total in 87 | execute v_sql 88 | loop 89 | v_record.reloid := i_oid; 90 | v_record.schemaname := v_schema; 91 | v_record.tablename := v_table; 92 | 93 | IF v_total > 0 THEN 94 | v_record.percent_hidden := (100 * v_hidden / v_total::numeric)::numeric(5,2); 95 | ELSE 96 | v_record.percent_hidden := 0::numeric(5,2); 97 | END IF; 98 | v_record.bloat := 100 / (100.1-v_record.percent_hidden); 99 | 100 | return next v_record; 101 | end loop; 102 | return; 103 | 104 | END; 105 | $$ 106 | LANGUAGE plpgsql; 107 | 108 | 109 | 110 | ----new new new function, in_schemaname format: 'schema1,schema2,schema3' 111 | CREATE OR REPLACE FUNCTION AOtable_bloatcheck(in_schemaname text) 112 | RETURNS SETOF type_AOtable_bloat AS 113 | $$ 114 | declare 115 | v_record type_AOtable_bloat%rowtype; 116 | i_oid bigint; 117 | v_schema text; 118 | v_table text; 119 | v_sql text; 120 | schema_array text[]; 121 | v_schemastr text; 122 | i int; 123 | v_hidden bigint; 124 | v_total bigint; 125 | BEGIN 126 | schema_array := string_to_array(in_schemaname,','); 127 | --raise info '%,%',array_lower(schema_array,1),array_upper(schema_array,1); 128 | v_schemastr := '('; 129 | i := 1; 130 | while i <= array_upper(schema_array,1) loop 131 | --raise info '%',schema_array[i]; 132 | if i 0 THEN 164 | v_record.percent_hidden := (100 * v_hidden / v_total::numeric)::numeric(5,2); 165 | ELSE 166 | v_record.percent_hidden := 0::numeric(5,2); 167 | END IF; 168 | v_record.bloat := 100 / (100.1-v_record.percent_hidden); 169 | 170 | return next v_record; 171 | end loop; 172 | return; 173 | 174 | END; 175 | $$ 176 | LANGUAGE plpgsql; 177 | 178 | 179 | ----new new new function, all schema 180 | CREATE OR REPLACE FUNCTION AOtable_bloatcheck() 181 | RETURNS SETOF type_AOtable_bloat AS 182 | $$ 183 | declare 184 | v_record type_AOtable_bloat%rowtype; 185 | i_oid bigint; 186 | v_schema text; 187 | v_table text; 188 | v_sql text; 189 | schema_array text[]; 190 | v_schemastr text; 191 | i int; 192 | v_hidden bigint; 193 | v_total bigint; 194 | BEGIN 195 | BEGIN 196 | v_sql := 'drop table if exists ao_aovisimap_hidden; 197 | create temp table ao_aovisimap_hidden as 198 | select rel.oid reloid,nsp.nspname,rel.relname,rel.gp_segment_id segid, 199 | (gp_toolkit.__gp_aovisimap_hidden_typed(rel.oid)::record).* 200 | FROM gp_dist_random(''pg_class'') rel, pg_namespace nsp 201 | where nsp.oid=rel.relnamespace and rel.relkind=''r'' and rel.relstorage in (''a'',''c'')'; 202 | execute v_sql; 203 | EXCEPTION WHEN undefined_table THEN 204 | raise info 'Any relation oid not found because of a concurrent drop operation, skipped!'; 205 | return; 206 | END; 207 | 208 | v_sql := 'select reloid,nspname,relname,sum(hidden) hidden_tupcount,sum(total) total_tupcount from ao_aovisimap_hidden group by 1,2,3'; 209 | for i_oid,v_schema,v_table,v_hidden,v_total in 210 | execute v_sql 211 | loop 212 | v_record.reloid := i_oid; 213 | v_record.schemaname := v_schema; 214 | v_record.tablename := v_table; 215 | 216 | IF v_total > 0 THEN 217 | v_record.percent_hidden := (100 * v_hidden / v_total::numeric)::numeric(5,2); 218 | ELSE 219 | v_record.percent_hidden := 0::numeric(5,2); 220 | END IF; 221 | v_record.bloat := 100 / (100.1-v_record.percent_hidden); 222 | 223 | return next v_record; 224 | end loop; 225 | return; 226 | 227 | END; 228 | $$ 229 | LANGUAGE plpgsql; 230 | 231 | -------------------------------------------------------------------------------- /vacuum/aobloat/check_ao_bloat_gp7.sql: -------------------------------------------------------------------------------- 1 | CREATE TYPE type_AOtable_bloat as (reloid bigint,schemaname text,tablename text,percent_hidden float,bloat float); 2 | 3 | 4 | ----new new new function, in_schemaname format: 'schema1,schema2,schema3' 5 | CREATE OR REPLACE FUNCTION AOtable_bloatcheck(in_schemaname text) 6 | RETURNS SETOF type_AOtable_bloat AS 7 | $$ 8 | declare 9 | v_record type_AOtable_bloat%rowtype; 10 | i_oid bigint; 11 | v_schema text; 12 | v_table text; 13 | v_sql text; 14 | schema_array text[]; 15 | v_schemastr text; 16 | i int; 17 | v_hidden bigint; 18 | v_total bigint; 19 | BEGIN 20 | schema_array := string_to_array(in_schemaname,','); 21 | --raise info '%,%',array_lower(schema_array,1),array_upper(schema_array,1); 22 | v_schemastr := '('; 23 | i := 1; 24 | while i <= array_upper(schema_array,1) loop 25 | --raise info '%',schema_array[i]; 26 | if i 0 THEN 58 | v_record.percent_hidden := (100 * v_hidden / v_total::numeric)::numeric(5,2); 59 | ELSE 60 | v_record.percent_hidden := 0::numeric(5,2); 61 | END IF; 62 | v_record.bloat := 100 / (100.1-v_record.percent_hidden); 63 | 64 | return next v_record; 65 | end loop; 66 | return; 67 | 68 | END; 69 | $$ 70 | LANGUAGE plpgsql; 71 | 72 | 73 | ----new new new function, all schema 74 | CREATE OR REPLACE FUNCTION AOtable_bloatcheck() 75 | RETURNS SETOF type_AOtable_bloat AS 76 | $$ 77 | declare 78 | v_record type_AOtable_bloat%rowtype; 79 | i_oid bigint; 80 | v_schema text; 81 | v_table text; 82 | v_sql text; 83 | schema_array text[]; 84 | v_schemastr text; 85 | i int; 86 | v_hidden bigint; 87 | v_total bigint; 88 | BEGIN 89 | BEGIN 90 | v_sql := 'drop table if exists ao_aovisimap_hidden; 91 | create temp table ao_aovisimap_hidden as 92 | select rel.oid reloid,nsp.nspname,rel.relname,rel.gp_segment_id segid, 93 | (gp_toolkit.__gp_aovisimap_hidden_typed(rel.oid)::record).* 94 | FROM gp_dist_random(''pg_class'') rel, pg_namespace nsp 95 | where nsp.oid=rel.relnamespace and rel.relkind=''r'' and rel.relam in (3434,3435)'; 96 | execute v_sql; 97 | EXCEPTION WHEN undefined_table THEN 98 | raise info 'Any relation oid not found because of a concurrent drop operation, skipped!'; 99 | return; 100 | END; 101 | 102 | v_sql := 'select reloid,nspname,relname,sum(hidden) hidden_tupcount,sum(total) total_tupcount from ao_aovisimap_hidden group by 1,2,3'; 103 | for i_oid,v_schema,v_table,v_hidden,v_total in 104 | execute v_sql 105 | loop 106 | v_record.reloid := i_oid; 107 | v_record.schemaname := v_schema; 108 | v_record.tablename := v_table; 109 | 110 | IF v_total > 0 THEN 111 | v_record.percent_hidden := (100 * v_hidden / v_total::numeric)::numeric(5,2); 112 | ELSE 113 | v_record.percent_hidden := 0::numeric(5,2); 114 | END IF; 115 | v_record.bloat := 100 / (100.1-v_record.percent_hidden); 116 | 117 | return next v_record; 118 | end loop; 119 | return; 120 | 121 | END; 122 | $$ 123 | LANGUAGE plpgsql; 124 | 125 | --------------------------------------------------------------------------------