2011年4月7日 星期四

Make Postgresql partition table create in to a function

要建立Postgresql的partition雖然語法不覆雜,但是若要針對不一樣的table,pkey,index來建會就變的無法很自動,
因此可以用下面此function來簡化所有開立的流程(ps.因為目前系統並沒有parent table的check,因此此function需再自行加上
parent table的check



CREATE OR REPLACE FUNCTION dbaegis_gen_partition_table_f(p_table_name varchar,p_part_col varchar, p_part_date varchar)
RETURNS varchar
LANGUAGE plpgsql
AS
$body$
DECLARE
/*
Description: To Generate the partition table
Usage: select dbaegis_gen_partition_table_f(p_table_name,'sql_login_utc','20110320');
to generate partition table for sql_conns on 2011/3/02
use sql to get the result:true/false
Creation: 2011-04-07 By Marc
*/

r1 record;

ls_current_statement VARCHAR(2000) default '';
v_begin_utc int8;
v_end_utc int8;
v_part_date_str varchar(12);
v_table_sql varchar(1024);
v_pkey_sql varchar(1024);
v_index_sql varchar(1024);
v_grant_sql varchar(1024);

BEGIN

ls_current_statement = 'Validate Date';
select extract(epoch from p_part_date::timestamp) into v_begin_utc;
select extract(epoch from p_part_date::timestamp)-86400 into v_end_utc;
select to_char( p_part_date::timestamp,'YYYY_MM_DD') into v_part_date_str;

ls_current_statement = 'Generate Create table sql';

SELECT 'CREATE TABLE ' ||relname|| '_'||v_part_date_str||' ('||
' CHECK( '||p_part_col||' >= '||v_begin_utc||' AND '||p_part_col||' < '||v_end_utc||' )'||
') INHERITS (' ||relname|| ');' AS table_sql
into v_table_sql
FROM pg_class
WHERE relname = p_table_name;

raise notice '%',v_table_sql;
execute v_table_sql;


ls_current_statement = 'Generate Create primary key sql';
--find Primary Key
SELECT 'ALTER TABLE ONLY ' ||ct.relname|| '_'||v_part_date_str||' ADD CONSTRAINT partition_'||v_part_date_str||'_from_' ||ci.relname|| ' PRIMARY KEY (' ||dbaegis_aggregate_concate (a.attname) || ');' AS pkey_sql
into v_pkey_sql
FROM pg_catalog.pg_namespace n,
pg_catalog.pg_class ct,
pg_catalog.pg_class ci,
pg_catalog.pg_attribute a,
pg_catalog.pg_index i
WHERE ct.oid = i.indrelid
AND ci.oid = i.indexrelid
AND a.attrelid = ci.oid
AND i.indisprimary
AND ct.relname = p_table_name
AND ct.relnamespace = n.oid
AND n.nspname = 'public'
GROUP BY ct.relname, ci.relname;

raise notice '%',v_pkey_sql;
execute v_pkey_sql;

ls_current_statement = 'Generate Create index sql';
for r1 in
SELECT 'CREATE ' ||case i.indisunique WHEN TRUE THEN 'unique ' ELSE '' end|| 'INDEX partition_'||v_part_date_str||'_from_' ||ci.relname|| ' ON ' ||ct.relname|| '_'||v_part_date_str||' USING btree (' ||CASE WHEN i.indexprs IS NULL THEN a.attname ELSE pg_get_indexdef (ci.oid,a.attnum,FALSE) END|| ');' AS index_sql
FROM pg_catalog.pg_namespace n,
pg_catalog.pg_class ct,
pg_catalog.pg_class ci,
pg_catalog.pg_attribute a,
pg_catalog.pg_am am,
pg_catalog.pg_index i
WHERE ct.oid = i.indrelid
AND ci.oid = i.indexrelid
AND a.attrelid = ci.oid
AND ci.relam = am.oid
AND n.oid = ct.relnamespace
AND n.nspname = 'public'
AND ct.relname = p_table_name
AND i.indisprimary = FALSE
ORDER BY i.indisunique desc, i.indisclustered, ci.relname loop
v_index_sql = r1.index_sql;

raise notice '%',v_index_sql;
execute v_index_sql;
end loop;

ls_current_statement = 'Generate Create table grant sql';
SELECT 'GRANT ' ||dbaegis_aggregate_concate (privilege_type) || ' ON TABLE ' ||table_name|| '_'||v_part_date_str||' TO webui;' AS grant_sql
into v_grant_sql
FROM information_schema.table_privileges
WHERE table_schema = 'public'
AND grantee = 'webui'
AND table_name = p_table_name
GROUP BY table_schema, table_name;

raise notice '%',v_grant_sql;
execute v_grant_sql;

return p_table_name|| '_'||v_part_date_str;

EXCEPTION
WHEN OTHERS THEN
RAISE EXCEPTION '<>', ls_current_statement || ' ErrCode: ' || SQLSTATE || '-' || SQLERRM;
return '';
END;
$body$;
/

How to create aggregate varchar with pg function

postgresql 允許使用者自訂Group Function,這是Oracle作不到的,
這裏就一個很實用的aggregate function,把table欄位的字串聯接起來成一筆資料

--先建function
CREATE OR REPLACE FUNCTION dbaegis_concate(text, text)
RETURNS text
LANGUAGE plpgsql
AS
$body$
DECLARE
t text;
BEGIN
IF character_length($1) > 0 AND character_length($2) > 0 THEN
t := $1||','||$2;
ELSIF character_length($1) = 0 AND character_length($2) > 0 THEN
t := ''||$2;
ELSIF character_length($1) > 0 AND character_length($2) = 0 THEN
t := $1;
ELSE t := '';
END IF;

RETURN t;
END;
$body$
VOLATILE
COST 100;
/


--再建aggregate type
CREATE AGGREGATE dbaegis_aggregate_concate(text)
(
sfunc = dbaegis_concate,
stype = text
);
/

2011年3月3日 星期四

重建Database之後,要如何reset postgresql 的serial sequence以符合目前資料的max pkey

1.建立function dbaegis_reset_table_seq_f
2.執行sql: select dbaegis_reset_table_seq_f('customers');

CREATE OR REPLACE FUNCTION dbaegis_reset_table_seq_f(p_table_name varchar)
RETURNS bigint
LANGUAGE plpgsql
AS
$body$
DECLARE

/*
Description: reset the table sequence with current id
Parameter: p_table_name: table name the contain sequence
Return: the max sequence that has been set
Exception: when others return error message
Exampe: select dbaegis_reset_table_seq_f('al_rpt_history');
Creation: 2011-03-03 by Marc Hsiao
*/


ls_current_statement VARCHAR(4096) default '';
v_sql_stmt varchar default '';
r1 record;
r2 record;
v_max_seq bigint default 0;



BEGIN
ls_current_statement = 'Open first cursor';
for r1 in (SELECT 'select (coalesce(max(' ||column_name|| '),0) +1)::bigint as max_seq from ' ||table_name|| ' where ' ||column_name|| ' > 1' as max_seq_sql,
'alter sequence ' ||pg_get_serial_sequence(table_name,column_name) || ' restart with ' AS alter_sql
FROM information_schema.columns
WHERE 1 = 1
and (table_name = p_table_name or p_table_name='')
AND column_default LIKE 'nextval%') loop
ls_current_statement = 'Open second cursor';
for r2 in execute r1.max_seq_sql loop
ls_current_statement = 'assign max_seq';
v_max_seq = r2.max_seq;
ls_current_statement = 'Concate alter statement';
v_sql_stmt = r1.alter_sql||r2.max_seq;
raise notice '%', v_sql_stmt;
ls_current_statement = 'current STMT << '||v_sql_stmt||' >> ';
ls_current_statement = 'Execute alter statement';
execute v_sql_stmt ;
end loop;
end loop;
return v_max_seq;
EXCEPTION
WHEN OTHERS THEN
RAISE EXCEPTION '<<dbaegis_reset_table_seq_f error: table:%, failed to execute: % >>', p_table_name, ls_current_statement || ' ErrCode: ' || SQLSTATE || '-' || SQLERRM;
END;
$body$
COST 100
;





2011年3月2日 星期三

PostgreSQL invalid page header in block xxxx of relation base xxxx

有時遇到table 壞軌,要救回資料可以照以下方式來作
reindex db發生error:

database "prod" failed: ERROR: invalid page header in block 6066 of relation base/16384/25370

依照數字可以找出database跟object
select oid,* from pg_database where oid::varchar='16384';
select oid,* from pg_class where oid::varchar='16384';

修復方法:reindex database 或 table
整個DB reindex:
reindexdb -U postgres -a
單一table Reindex:
psql -U postgres -c "reindex table customers"


ps.若是reindex時還是有大量的error,則在postgresql.conf裏最後一行加上zero_damaged_pages = on,並重啟postgresql database


zero_damaged_pages 說明:(8.0以後的postgresql支援)

Detection of a damaged page header normally causes PostgreSQL to report an error, aborting the current command. Setting zero_damaged_pages to true causes the system to instead report a warning, zero out the damaged page, and continue processing. This behavior will destroy data, namely all the rows on the damaged page. But it allows you to get past the error and retriev

2011年2月28日 星期一

use ftp and tar in shell script

ftp -in 192.168.1.2 << _EOF
quote user tester
quote pass tester
cd /download_folder
lcd /upload_folder
put | "tar -cjvf - test.data" test.data.tar.bz2
bye
_EOF

2011年2月22日 星期二

PostgreSQL check DB, Tablespace, Table, Index Size

PostgreSQL有內建的function可以view各種的Size


--check the tablespace size
SELECT spcname,
pg_size_pretty(pg_tablespace_size(spcname)) as size,
pg_tablespace_size(spcname) as for_sort
FROM pg_tablespace
ORDER BY pg_tablespace_size(spcname) DESC;


--check the database size
SELECT datname,
pg_size_pretty(pg_database_size(datname)) as size,
pg_database_size(datname) as for_sort
FROM pg_database
ORDER BY pg_database_size(datname) DESC;


--check the object size
SELECT relname,reltuples,
pg_size_pretty(pg_relation_size(oid)) as size,
pg_relation_size(oid) as for_sort
FROM pg_class
WHERE relkind IN ('r') --public table
ORDER BY pg_relation_size(oid) DESC;



--check table include index size
SELECT relname,reltuples,
pg_size_pretty(pg_total_relation_size(oid)) as size,
pg_total_relation_size(oid) as for_sort
FROM pg_class
WHERE relkind IN ('r') --public table
ORDER BY pg_total_relation_size(oid) DESC;