178 lines
5.5 KiB
Python
Executable File
178 lines
5.5 KiB
Python
Executable File
#!/usr/bin/python2
|
|
|
|
import os
|
|
import re
|
|
import sys
|
|
import cx_Oracle
|
|
import ConfigParser
|
|
from time import sleep
|
|
|
|
HOST_CONF = 'host.conf'
|
|
TABLE_CONF = 'table_partition.cfg'
|
|
|
|
SQL = {}
|
|
SQL_HEAD = '''-- <<FOLD<<
|
|
DECLARE
|
|
A VARCHAR2(16);
|
|
B NUMBER(8);
|
|
NOW DATE;
|
|
FIRST_DAY DATE;
|
|
SQL_ VARCHAR2(256);
|
|
TIME_STAMP NUMBER(16);
|
|
TABLE_NAME VARCHAR2(32);
|
|
LOW_PART_BOUND EXCEPTION;
|
|
NO_EXIST_TABLE EXCEPTION;
|
|
NO_EXIST_PART EXCEPTION;
|
|
THE_ONLY_PART EXCEPTION;
|
|
PRAGMA EXCEPTION_INIT(LOW_PART_BOUND, -14074);
|
|
PRAGMA EXCEPTION_INIT(NO_EXIST_TABLE, -00942);
|
|
PRAGMA EXCEPTION_INIT(NO_EXIST_PART, -02149);
|
|
PRAGMA EXCEPTION_INIT(THE_ONLY_PART, -14083);
|
|
PROCEDURE IGNORE_ERROR_EXECUTE_SQL(SQL_ IN VARCHAR2) IS
|
|
BEGIN
|
|
EXECUTE IMMEDIATE SQL_;
|
|
EXCEPTION
|
|
WHEN LOW_PART_BOUND OR NO_EXIST_TABLE OR NO_EXIST_PART OR THE_ONLY_PART THEN
|
|
NULL;
|
|
END;
|
|
BEGIN
|
|
'''
|
|
# >>FOLD>>
|
|
SQL['day'] = '''-- <<FOLD<<
|
|
FOR A IN
|
|
(SELECT PARTITION_NAME
|
|
FROM USER_TAB_PARTITIONS
|
|
WHERE TABLE_NAME = '{table}' AND
|
|
PARTITION_NAME != 'PART_1' AND
|
|
PARTITION_NAME <= 'PART_' || TO_CHAR(SYSDATE-{n_keep}, 'yyyyMMdd'))
|
|
LOOP
|
|
SQL_ := 'ALTER TABLE {table} DROP PARTITION ' || A.PARTITION_NAME;
|
|
IGNORE_ERROR_EXECUTE_SQL(SQL_);
|
|
END LOOP;
|
|
B := 2;
|
|
NOW := SYSDATE;
|
|
WHILE B < (2 + {n_create})
|
|
LOOP
|
|
FIRST_DAY := TO_DATE(TO_CHAR(NOW + B, 'YYYYMMDD') || '-00:00:00', 'YYYYMMDD-HH24:MI:SS');
|
|
SELECT (FIRST_DAY - TO_DATE('19700101-08:00:00', 'YYYYMMDD-HH24:MI:SS')) * 24 * 60 * 60 INTO TIME_STAMP FROM DUAL;
|
|
SQL_ := 'ALTER TABLE {table} ADD PARTITION PART_' || TO_CHAR(FIRST_DAY, 'YYYYMMDD') || ' VALUES LESS THAN(' || TIME_STAMP || ') TABLESPACE {tablespace}';
|
|
IGNORE_ERROR_EXECUTE_SQL(SQL_);
|
|
B := B + 1;
|
|
END LOOP;
|
|
'''
|
|
# >>FOLD>>
|
|
SQL['month'] = '''-- <<FOLD<<
|
|
FOR A IN
|
|
(SELECT PARTITION_NAME
|
|
FROM USER_TAB_PARTITIONS
|
|
WHERE TABLE_NAME = '{table}' AND
|
|
PARTITION_NAME != 'PART_1' AND
|
|
PARTITION_NAME <= 'PART_' || TO_CHAR(ADD_MONTHS(SYSDATE, -{n_keep}), 'yyyyMM'))
|
|
LOOP
|
|
SQL_ := 'ALTER TABLE {table} DROP PARTITION ' || A.PARTITION_NAME;
|
|
IGNORE_ERROR_EXECUTE_SQL(SQL_);
|
|
END LOOP;
|
|
B := 2;
|
|
NOW := SYSDATE;
|
|
WHILE B < (2 + {n_create})
|
|
LOOP
|
|
FIRST_DAY := TO_DATE(TO_CHAR(ADD_MONTHS(NOW, B), 'YYYYMM') || '01-00:00:00', 'YYYYMMDD-HH24:MI:SS');
|
|
SELECT (FIRST_DAY - TO_DATE('19700101-08:00:00', 'YYYYMMDD-HH24:MI:SS')) * 24 * 60 * 60 INTO TIME_STAMP FROM DUAL;
|
|
SQL_ := 'ALTER TABLE {table} ADD PARTITION PART_' || TO_CHAR(FIRST_DAY, 'YYYYMM') || ' VALUES LESS THAN(' || TIME_STAMP || ') TABLESPACE {tablespace}';
|
|
IGNORE_ERROR_EXECUTE_SQL(SQL_);
|
|
B := B + 1;
|
|
END LOOP;
|
|
'''
|
|
# >>FOLD>>
|
|
SQL['year'] = '''-- <<FOLD<<
|
|
FOR A IN
|
|
(SELECT PARTITION_NAME
|
|
FROM USER_TAB_PARTITIONS
|
|
WHERE TABLE_NAME = '{table}' AND
|
|
PARTITION_NAME != 'PART_1' AND
|
|
PARTITION_NAME <= 'PART_' || (TO_CHAR(SYSDATE, 'yyyy') - {n_keep}))
|
|
LOOP
|
|
SQL_ := 'ALTER TABLE {table} DROP PARTITION ' || A.PARTITION_NAME;
|
|
IGNORE_ERROR_EXECUTE_SQL(SQL_);
|
|
END LOOP;
|
|
B := 2;
|
|
NOW := SYSDATE;
|
|
WHILE B < (2 + {n_create})
|
|
LOOP
|
|
FIRST_DAY := TO_DATE(TO_CHAR(ADD_MONTHS(NOW, B*12), 'YYYY') || '0101-00:00:00', 'YYYYMMDD-HH24:MI:SS');
|
|
SELECT (FIRST_DAY - TO_DATE('19700101-08:00:00', 'YYYYMMDD HH24:MI:SS')) * 24 * 60 * 60 INTO TIME_STAMP FROM DUAL;
|
|
SQL_ := 'ALTER TABLE {table} ADD PARTITION PART_' || TO_CHAR(FIRST_DAY, 'YYYY') || ' VALUES LESS THAN(' || TIME_STAMP || ') TABLESPACE {tablespace}';
|
|
IGNORE_ERROR_EXECUTE_SQL(SQL_);
|
|
B := B + 1;
|
|
END LOOP;
|
|
'''
|
|
# >>FOLD>>
|
|
SQL_FOOT = '''# <<FOLD<<
|
|
END;
|
|
'''
|
|
# >>FOLD>>
|
|
|
|
def generate_plsql(config):# <<FOLD<<
|
|
plsql = SQL_HEAD
|
|
for section in config.sections():
|
|
part_type, n_keep, n_create = section.split('-')
|
|
n_keep = int(n_keep)
|
|
n_create = int(n_create)
|
|
for table in map(lambda x: x.upper(), config.options(section)):
|
|
plsql += SQL[part_type].format(table=table, n_keep=n_keep, n_create=n_create, tablespace=config.get(section, table))
|
|
plsql += SQL_FOOT
|
|
return plsql
|
|
# >>FOLD>>
|
|
|
|
def operate_plsql(db, plsql):# <<FOLD<<
|
|
#print plsql
|
|
cur = db.cursor()
|
|
cur.execute(plsql)
|
|
#try:
|
|
# cur.execute(sql)
|
|
#except Exception, e:
|
|
# matched = 0
|
|
# ignore_errors = ['ORA-00942', 'ORA-02149']
|
|
# for error in ignore_errors:
|
|
# if error in str(e).upper():
|
|
# matched = 1
|
|
# sys.stdout.write('.')
|
|
# sys.stdout.flush()
|
|
# break
|
|
# if not matched:
|
|
# print "\n\033[31mRUN \"%s\" ON %s failed:%s\033[0m"%(sql, ora, str(e))
|
|
cur.close()
|
|
db.close()
|
|
return
|
|
# >>FOLD>>
|
|
|
|
def connect_db():# <<FOLD<<
|
|
config = ConfigParser.ConfigParser()
|
|
config.read(HOST_CONF)
|
|
user = config.get('db', 'user')
|
|
pswd = config.get('db', 'passwd')
|
|
orcl = config.get('db', 'db')
|
|
try:
|
|
db = cx_Oracle.connect(user, pswd, orcl)
|
|
db.autocommit = True
|
|
except Exception, e:
|
|
print 'Connect Oracle failed: %s'%str(e)
|
|
return False
|
|
return db
|
|
# >>FOLD>>
|
|
|
|
def main():# <<FOLD<<
|
|
global config
|
|
while 1:
|
|
config = ConfigParser.ConfigParser()
|
|
config.read(TABLE_CONF)
|
|
plsql = generate_plsql(config)
|
|
db = connect_db()
|
|
if db: operate_plsql(db, plsql)
|
|
sleep(14400)
|
|
# >>FOLD>>
|
|
|
|
if __name__ == '__main__':
|
|
main()
|
|
|