Jelajahi Sumber

module: sipcapture: Changed SQL schema for partitioning table.

     Bug fix: mySQL doesn't support DAYOFWEEK rushing. Changed to
     RANGE condition: TO_DAYS and UNIX_TIMESTAMP. The last one, only for mySQL => 5.1.58
     The two crontab scripts are in example directory.
Alexandr Dubovikov 14 tahun lalu
induk
melakukan
b61b3d2f43

+ 7 - 1
modules/sipcapture/examples/crontabtruncate.pl

@@ -1,5 +1,7 @@
 #!/usr/bin/perl
 
+#DEPRICATED. USE Partitioning scripts.
+
 #Crontab script, to clear table/partition for the next day
 #set crontab at 23:50
 
@@ -7,7 +9,6 @@ my $mysqlstring = "/usr/bin/mysql -uhomer_user -phomer_password -hlocalhost home
 
 #homer node
 my $wday = (localtime())[6] + 1;
-
 #uncomment if you use separate tables
 #Separate tables
 #for(my $i=0; $i < 24; $i++) {
@@ -26,3 +27,8 @@ $mon++;
 
 my $query = sprintf("DELETE FROM sip_capture WHERE `date` < '%d-%02d-%02d 00:00:00' ", $year, $mon, $mday);
 `echo \"$query\"| $mysqlstring`;
+
+#
+#   TODAYS TABLE
+#
+#

+ 86 - 0
modules/sipcapture/examples/partrotate_todays.pl

@@ -0,0 +1,86 @@
+#!/usr/bin/perl
+use DBI;
+
+$table = "sip_capture";
+$dbname = "homer_db";
+$maxparts = 20; #20 days
+$newparts = 1; #new partitions for 1 day. Script must start daily!
+
+my $db = DBI->connect("DBI:mysql:$dbname:localhost:3306", "mysql_login", "mysql_password");
+
+#$db->{PrintError} = 0;
+
+my $query = "SELECT TO_DAYS(NOW()),UNIX_TIMESTAMP(NOW() + INTERVAL 1 DAY)";
+$sth = $db->prepare($query);
+$sth->execute();
+my ($curtodays,$curtstamp) = $sth->fetchrow_array();
+$curtodays+=0; 
+$curtstamp+=0; 
+
+
+my $query = "SELECT COUNT(*) FROM INFORMATION_SCHEMA.PARTITIONS"
+            ."\n WHERE TABLE_NAME='".$table."' AND TABLE_SCHEMA='".$dbname."'";
+$sth = $db->prepare($query);
+$sth->execute();
+my ($partcount) = $sth->fetchrow_array();
+
+while($partcount > ($maxparts + $newparts)) {
+
+    $query = "SELECT PARTITION_NAME, MIN(PARTITION_DESCRIPTION)"
+             ."\n FROM INFORMATION_SCHEMA.PARTITIONS WHERE TABLE_NAME='".$table."'"
+             ."\n AND TABLE_SCHEMA='".$dbname."';";
+             
+    $sth = $db->prepare($query);
+    $sth->execute();
+    my ($minpart,$todays) = $sth->fetchrow_array();
+    $todays+=0;
+    
+    #Dont' delete the partition for the current day or for future. Bad idea!
+    if($curtodays <= $todays) {    
+            $partcount=0;
+            next;
+    }
+        
+    #Delete
+    $query = "ALTER TABLE ".$table." DROP PARTITION ".$minpart;
+    $db->do($query);
+    if (!$db->{Executed}) {
+           print "Couldn't drop partition: $minpart\n";
+           break;
+    }
+}
+
+# < condition
+$curtodays+=1;
+
+#Create new partitions 
+for(my $i=0; $i<$newparts; $i++) {
+
+    $curtodays+=1;
+    
+    ($sec,$min,$hour,$mday,$mon,$year,$wday,$yday,$isdst) = localtime($curtstamp);
+
+    my $newpartname = sprintf("p%04d%02d%02d",($year+=1900),(++$mon),$mday);    
+    
+    $query = "SELECT COUNT(*) "
+             ."\n FROM INFORMATION_SCHEMA.PARTITIONS WHERE TABLE_NAME='".$table."'"
+             ."\n AND TABLE_SCHEMA='".$dbname."' AND PARTITION_NAME='".$newpartname."'"
+             ."\n AND PARTITION_DESCRIPTION = '".$curtodays."'";
+             
+    $sth = $db->prepare($query);
+    $sth->execute();
+    my ($exist) = $sth->fetchrow_array();
+    $exist+=0;
+    
+    if(!$exist) {
+    
+        $query = "ALTER TABLE ".$table." ADD PARTITION (PARTITION ".$newpartname
+             ."\n VALUES LESS THAN (".$curtodays.") ENGINE = MyISAM)";
+        $db->do($query);
+        if (!$db->{Executed}) {
+             print "Couldn't add partition: $newpartname\n";
+        }
+    }
+    
+    $curtstamp += 86400;
+}

+ 93 - 0
modules/sipcapture/examples/partrotate_unixtimestamp.pl

@@ -0,0 +1,93 @@
+#!/usr/bin/perl
+
+use DBI;
+
+$table = "sip_capture";
+$dbname = "homer_db";
+$maxparts = 6; #6 days
+$newparts = 1; #new partitions for 1 day. Script must start daily!
+
+#Hours
+$maxparts*=24;
+$newparts*=24;
+
+my $db = DBI->connect("DBI:mysql:$dbname:localhost:3306", "mysql_login", "mysql_password");
+
+#$db->{PrintError} = 0;
+
+my $query = "SELECT UNIX_TIMESTAMP(CURDATE() - INTERVAL 1 DAY)";
+$sth = $db->prepare($query);
+$sth->execute();
+my ($curtstamp) = $sth->fetchrow_array();
+$curtstamp+=0; 
+
+#print "ZZ: $curtstamp: $maxparts, $newparts\n";
+#exit;
+
+my $query = "SELECT COUNT(*) FROM INFORMATION_SCHEMA.PARTITIONS"
+            ."\n WHERE TABLE_NAME='".$table."' AND TABLE_SCHEMA='".$dbname."'";
+$sth = $db->prepare($query);
+$sth->execute();
+my ($partcount) = $sth->fetchrow_array();
+
+#print "$query\nZ: $partcount\n";
+
+while($partcount > ($maxparts + $newparts)) {
+
+    $query = "SELECT PARTITION_NAME, MIN(PARTITION_DESCRIPTION)"
+             ."\n FROM INFORMATION_SCHEMA.PARTITIONS WHERE TABLE_NAME='".$table."'"
+             ."\n AND TABLE_SCHEMA='".$dbname."';";
+
+    $sth = $db->prepare($query);
+    $sth->execute();
+    my ($minpart,$todaytstamp) = $sth->fetchrow_array();
+    $todaytstamp+=0;
+    
+    #Dont' delete the partition for the current day or for future. Bad idea!
+    if($curtstamp <= $todaytstamp) {    
+          $partcount = 0;
+          next;
+    }
+           
+    #Delete
+    $query = "ALTER TABLE ".$table." DROP PARTITION ".$minpart;
+    $db->do($query);
+    if (!$db->{Executed}) {
+           print "Couldn't drop partition: $minpart\n";
+           break;
+    }
+}
+
+# < condition
+$curtstamp+=(86400);
+
+#Create new partitions 
+for(my $i=0; $i<$newparts; $i++) {
+
+    $oldstamp = $curtstamp;
+    $curtstamp+=3600;
+    
+    ($sec,$min,$hour,$mday,$mon,$year,$wday,$yday,$isdst) = localtime($oldstamp);
+
+    my $newpartname = sprintf("p%04d%02d%02d%02d",($year+=1900),(++$mon),$mday,$hour);    
+    
+    $query = "SELECT COUNT(*) "
+             ."\n FROM INFORMATION_SCHEMA.PARTITIONS WHERE TABLE_NAME='".$table."'"
+             ."\n AND TABLE_SCHEMA='".$dbname."' AND PARTITION_NAME='".$newpartname."'"
+             ."\n AND PARTITION_DESCRIPTION = '".$curtstamp."'";
+             
+    $sth = $db->prepare($query);
+    $sth->execute();
+    my ($exist) = $sth->fetchrow_array();
+    $exist+=0;
+    
+    if(!$exist) {
+    
+        $query = "ALTER TABLE ".$table." ADD PARTITION (PARTITION ".$newpartname
+             ."\n VALUES LESS THAN (".$curtstamp.") ENGINE = MyISAM)";
+        $db->do($query);
+        if (!$db->{Executed}) {
+             print "Couldn't add partition: $newpartname\n";
+        }
+    }    
+}

+ 86 - 0
modules/sipcapture/sql/create_part_unixtimestamp.sql

@@ -0,0 +1,86 @@
+/* 
+ * only for MYSQL >= 5.1.58 and if you expect MASSIV SIP TRAFFIC
+*/
+
+/*!40101 SET @saved_cs_client     = @@character_set_client */;
+/*!40101 SET character_set_client = utf8 */;
+CREATE TABLE `sip_capture` (
+  `id` int(20) NOT NULL AUTO_INCREMENT,
+  `date` timestamp NOT NULL DEFAULT '0000-00-00 00:00:00',
+  `micro_ts` bigint(18) NOT NULL DEFAULT '0',
+  `method` varchar(50) NOT NULL DEFAULT '',
+  `reply_reason` varchar(100) NOT NULL,
+  `ruri` varchar(200) NOT NULL DEFAULT '',
+  `ruri_user` varchar(100) NOT NULL DEFAULT '',
+  `from_user` varchar(100) NOT NULL DEFAULT '',
+  `from_tag` varchar(64) NOT NULL DEFAULT '',
+  `to_user` varchar(100) NOT NULL DEFAULT '',
+  `to_tag` varchar(64) NOT NULL,
+  `pid_user` varchar(100) NOT NULL DEFAULT '',
+  `contact_user` varchar(120) NOT NULL,
+  `auth_user` varchar(120) NOT NULL,
+  `callid` varchar(100) NOT NULL DEFAULT '',
+  `callid_aleg` varchar(100) NOT NULL DEFAULT '',
+  `via_1` varchar(256) NOT NULL,
+  `via_1_branch` varchar(80) NOT NULL,
+  `cseq` varchar(25) NOT NULL,
+  `diversion` varchar(256) NOT NULL,
+  `reason` varchar(200) NOT NULL,
+  `content_type` varchar(256) NOT NULL,
+  `authorization` varchar(256) NOT NULL,
+  `user_agent` varchar(256) NOT NULL,
+  `source_ip` varchar(50) NOT NULL DEFAULT '',
+  `source_port` int(10) NOT NULL,
+  `destination_ip` varchar(50) NOT NULL DEFAULT '',
+  `destination_port` int(10) NOT NULL,
+  `contact_ip` varchar(60) NOT NULL,
+  `contact_port` int(10) NOT NULL,
+  `originator_ip` varchar(60) NOT NULL DEFAULT '',
+  `originator_port` int(10) NOT NULL,
+  `proto` int(5) NOT NULL,
+  `family` int(1) DEFAULT NULL,
+  `rtp_stat` varchar(256) NOT NULL,
+  `type` int(2) NOT NULL,
+  `node` varchar(125) NOT NULL,
+  `msg` longblob NOT NULL,
+  PRIMARY KEY (`id`,`date`),
+  KEY `ruri_user` (`ruri_user`),
+  KEY `from_user` (`from_user`),
+  KEY `to_user` (`to_user`),
+  KEY `pid_user` (`pid_user`),
+  KEY `auth_user` (`auth_user`),
+  KEY `callid_aleg` (`callid_aleg`),
+  KEY `date` (`date`),
+  KEY `callid` (`callid`)
+) ENGINE=MyISAM AUTO_INCREMENT=1 DEFAULT CHARSET=utf8
+PARTITION BY RANGE ( UNIX_TIMESTAMP(`date`) ) (
+PARTITION p2011082500 VALUES LESS THAN (1314216000) ENGINE = MyISAM,
+PARTITION p2011082501 VALUES LESS THAN (1314219600) ENGINE = MyISAM,
+PARTITION p2011082502 VALUES LESS THAN (1314223200) ENGINE = MyISAM,
+PARTITION p2011082503 VALUES LESS THAN (1314226800) ENGINE = MyISAM,
+PARTITION p2011082504 VALUES LESS THAN (1314230400) ENGINE = MyISAM,
+PARTITION p2011082505 VALUES LESS THAN (1314234000) ENGINE = MyISAM,
+PARTITION p2011082506 VALUES LESS THAN (1314237600) ENGINE = MyISAM,
+PARTITION p2011082507 VALUES LESS THAN (1314241200) ENGINE = MyISAM,
+PARTITION p2011082508 VALUES LESS THAN (1314244800) ENGINE = MyISAM,
+PARTITION p2011082509 VALUES LESS THAN (1314248400) ENGINE = MyISAM,
+PARTITION p2011082510 VALUES LESS THAN (1314252000) ENGINE = MyISAM,
+PARTITION p2011082511 VALUES LESS THAN (1314255600) ENGINE = MyISAM,
+PARTITION p2011082512 VALUES LESS THAN (1314259200) ENGINE = MyISAM,
+PARTITION p2011082513 VALUES LESS THAN (1314262800) ENGINE = MyISAM,
+PARTITION p2011082514 VALUES LESS THAN (1314266400) ENGINE = MyISAM,
+PARTITION p2011082515 VALUES LESS THAN (1314270000) ENGINE = MyISAM,
+PARTITION p2011082516 VALUES LESS THAN (1314273600) ENGINE = MyISAM,
+PARTITION p2011082517 VALUES LESS THAN (1314277200) ENGINE = MyISAM,
+PARTITION p2011082518 VALUES LESS THAN (1314280800) ENGINE = MyISAM,
+PARTITION p2011082519 VALUES LESS THAN (1314284400) ENGINE = MyISAM,
+PARTITION p2011082520 VALUES LESS THAN (1314288000) ENGINE = MyISAM,
+PARTITION p2011082521 VALUES LESS THAN (1314291600) ENGINE = MyISAM,
+PARTITION p2011082522 VALUES LESS THAN (1314295200) ENGINE = MyISAM,
+PARTITION p2011082523 VALUES LESS THAN (1314298800) ENGINE = MyISAM,
+PARTITION pmax VALUES LESS THAN (MAXVALUE)
+);
+
+
+/* if your mysql < 5.5 drop maxvalue partition */
+/* alter table homer_capture drop partition pmax; */

+ 19 - 22
modules/sipcapture/sql/sipcapture-create.sql

@@ -1,18 +1,11 @@
--- MySQL dump 10.13  Distrib 5.1.41, for debian-linux-gnu (x86_64)
---
--- Host: localhost    Database: homer_data
--- ------------------------------------------------------
--- Server version	5.1.41-3ubuntu12.10
---
--- Table structure for table `sip_capture`
---
+
 
 DROP TABLE IF EXISTS `sip_capture`;
 /*!40101 SET @saved_cs_client     = @@character_set_client */;
 /*!40101 SET character_set_client = utf8 */;
 CREATE TABLE `sip_capture` (
   `id` int(20) NOT NULL AUTO_INCREMENT,
-  `date` datetime NOT NULL DEFAULT '0000-00-00 00:00:00',
+  `date` timestamp NOT NULL DEFAULT '0000-00-00 00:00:00',
   `micro_ts` bigint(18) NOT NULL DEFAULT '0',
   `method` varchar(50) NOT NULL DEFAULT '',
   `reply_reason` varchar(100) NOT NULL,
@@ -59,17 +52,21 @@ CREATE TABLE `sip_capture` (
   KEY `date` (`date`),
   KEY `callid` (`callid`)
 ) ENGINE=MyISAM AUTO_INCREMENT=1 DEFAULT CHARSET=utf8
-/*!50100 PARTITION BY RANGE ( DAYOFWEEK(`date`))
-SUBPARTITION BY HASH ( HOUR(`date`))
-SUBPARTITIONS 24
-(PARTITION p0 VALUES LESS THAN (2) ENGINE = MyISAM,
- PARTITION p1 VALUES LESS THAN (3) ENGINE = MyISAM,
- PARTITION p2 VALUES LESS THAN (4) ENGINE = MyISAM,
- PARTITION p3 VALUES LESS THAN (5) ENGINE = MyISAM,
- PARTITION p4 VALUES LESS THAN (6) ENGINE = MyISAM,
- PARTITION p5 VALUES LESS THAN (7) ENGINE = MyISAM,
- PARTITION p6 VALUES LESS THAN (8) ENGINE = MyISAM) */;
-/*!40101 SET character_set_client = @saved_cs_client */;
-/*!40103 SET TIME_ZONE=@OLD_TIME_ZONE */;
+PARTITION BY RANGE ( TO_DAYS(`date`) ) (
+PARTITION p20110824 VALUES LESS THAN (734739) ENGINE = MyISAM,
+PARTITION p20110825 VALUES LESS THAN (734740) ENGINE = MyISAM,
+PARTITION p20110826 VALUES LESS THAN (734741) ENGINE = MyISAM,
+PARTITION p20110827 VALUES LESS THAN (734742) ENGINE = MyISAM,
+PARTITION p20110828 VALUES LESS THAN (734743) ENGINE = MyISAM,
+PARTITION p20110829 VALUES LESS THAN (734744) ENGINE = MyISAM,
+PARTITION p20110830 VALUES LESS THAN (734745) ENGINE = MyISAM,
+PARTITION p20110831 VALUES LESS THAN (734746) ENGINE = MyISAM,
+PARTITION p20110901 VALUES LESS THAN (734747) ENGINE = MyISAM,
+PARTITION p20110902 VALUES LESS THAN (734748) ENGINE = MyISAM,
+PARTITION pmax VALUES LESS THAN (MAXVALUE)
+);
+
+/* alter table homer_capture add partition (PARTITION p20110903 VALUES LESS THAN (734749) ENGINE = MyISAM); */
+/* if your mysql < 5.5 drop maxvalue partition */
+/* alter table sip_capture drop partition pmax; */
 
--- Dump completed on 2011-08-18 13:54:21