File:  [LON-CAPA] / loncom / interface / lonmysql.pm
Revision 1.36: download - view: text, annotated - select for diffs
Mon Mar 12 17:10:02 2007 UTC (17 years, 2 months ago) by albertel
Branches: MAIN
CVS tags: HEAD
- need to clean usernames and domains of nonword characters to use them as table names

    1: # The LearningOnline Network with CAPA
    2: # MySQL utility functions
    3: #
    4: # $Id: lonmysql.pm,v 1.36 2007/03/12 17:10:02 albertel Exp $
    5: #
    6: # Copyright Michigan State University Board of Trustees
    7: #
    8: # This file is part of the LearningOnline Network with CAPA (LON-CAPA).
    9: #
   10: # LON-CAPA is free software; you can redistribute it and/or modify
   11: # it under the terms of the GNU General Public License as published by
   12: # the Free Software Foundation; either version 2 of the License, or
   13: # (at your option) any later version.
   14: #
   15: # LON-CAPA is distributed in the hope that it will be useful,
   16: # but WITHOUT ANY WARRANTY; without even the implied warranty of
   17: # MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
   18: # GNU General Public License for more details.
   19: #
   20: # You should have received a copy of the GNU General Public License
   21: # along with LON-CAPA; if not, write to the Free Software
   22: # Foundation, Inc., 59 Temple Place, Suite 330, Boston, MA  02111-1307  USA
   23: #
   24: # /home/httpd/html/adm/gpl.txt
   25: #
   26: # http://www.lon-capa.org/
   27: #
   28: ######################################################################
   29: 
   30: package Apache::lonmysql;
   31: 
   32: use strict;
   33: use DBI;
   34: use POSIX qw(strftime mktime);
   35: use Apache::lonnet;
   36: 
   37: my $mysqluser;
   38: my $mysqlpassword;
   39: my $mysqldatabase;
   40: my %db_config;
   41: 
   42: sub set_mysql_user_and_password {
   43:     # If we are running under Apache and LONCAPA, use the LON-CAPA 
   44:     # user and password.  Otherwise...? ? ? ?
   45:     my ($input_mysqluser,$input_mysqlpassword,$input_mysqldatabase) = @_;
   46:     if (! defined($mysqldatabase)) {
   47:         $mysqldatabase = 'loncapa';
   48:     }
   49:     if (defined($input_mysqldatabase)) {
   50:         $mysqldatabase = $input_mysqldatabase;
   51:     }
   52:     if (! defined($mysqluser) || ! defined($mysqlpassword)) {
   53:         if (! eval 'require Apache::lonnet();') {
   54:             $mysqluser = 'www';
   55:             $mysqlpassword = $Apache::lonnet::perlvar{'lonSqlAccess'};
   56:         } else {
   57:             $mysqluser = '';
   58:             $mysqlpassword = '';
   59:         }
   60:     }
   61:     if (defined($input_mysqluser)) {
   62:         $mysqluser = $input_mysqluser;
   63:     } 
   64:     if (defined($input_mysqlpassword)) {
   65:         $mysqlpassword = $input_mysqlpassword;
   66:     }
   67: }
   68: 
   69: ######################################################################
   70: ######################################################################
   71: 
   72: =pod 
   73: 
   74: =head1 Name
   75: 
   76: lonmysql - LONCAPA MySQL utility functions
   77: 
   78: =head1 Synopsis
   79: 
   80: lonmysql contains utility functions to make accessing the mysql loncapa
   81: database easier.  
   82: 
   83: =head1 Description
   84: 
   85: lonmysql does its best to encapsulate all the database/table functions
   86: and provide a common interface.  The goal, however, is not to provide 
   87: a complete reimplementation of the DBI interface.  Instead we try to 
   88: make using mysql as painless as possible.
   89: 
   90: Each table has a numeric ID that is a parameter to most lonmysql
   91: functions.  The table id is returned by &create_table.  If you lose
   92: the table id, it is lost forever.  The table names in MySQL correspond
   93: to $env{'user.name'}.'_'.$env{'user.domain'}.'_'.$table_id. (With all
   94: non-word characters removed form user.name and user.domain) If the
   95: table id is non-numeric, it is assumed to be the full name of a table.
   96: If you pass the table id in a form, you MUST ensure that what you send
   97: to lonmysql is numeric, otherwise you are opening up all the tables in
   98: the MySQL database.
   99: 
  100: =over 4
  101: 
  102: =item Creating a table
  103: 
  104: To create a table, you need a description of its structure.  See the entry
  105: for &create_table for a description of what is needed.
  106: 
  107:  $table_id = &create_table({ 
  108:      id      => 'tableid',      # usually you will use the returned id
  109:      columns => (
  110:                  { name => 'id',
  111:                    type => 'INT',
  112:                    restrictions => 'NOT NULL',
  113:                    primary_key => 'yes',
  114:                    auto_inc    => 'yes'
  115:                    },
  116:                  { name => 'verbage',
  117:                    type => 'TEXT' },
  118:                  ),
  119:                        fulltext => [qw/verbage/],
  120:         });
  121: 
  122: The above command will create a table with two columns, 'id' and 'verbage'.
  123: 
  124: 'id' will be an integer which is autoincremented and non-null.
  125: 
  126: 'verbage' will be of type 'TEXT', which (conceivably) allows any length
  127: text string to be stored.  Depending on your intentions for this database,
  128: setting restrictions => 'NOT NULL' may help you avoid storing empty data.
  129: 
  130: the fulltext element sets up the 'verbage' column for 'FULLTEXT' searching.
  131: 
  132: 
  133: 
  134: =item Storing rows
  135: 
  136: Storing a row in a table requires calling &store_row($table_id,$data)
  137: 
  138: $data is either a hash reference or an array reference.  If it is an array
  139: reference, the data is passed as is (after being escaped) to the 
  140: "INSERT INTO <table> VALUES( ... )" SQL command.  If $data is a hash reference,
  141: the data will be placed into an array in the proper column order for the table
  142: and then passed to the database.
  143: 
  144: An example of inserting into the table created above is:
  145: 
  146: &store_row($table_id,[undef,'I am not a crackpot!']);
  147: 
  148: or equivalently,
  149: 
  150: &store_row($table_id,{ verbage => 'I am not a crackpot!'});
  151: 
  152: Since the above table was created with the first column ('id') as 
  153: autoincrement, providing a value is unnecessary even though the column was
  154: marked as 'NOT NULL'.
  155: 
  156: 
  157: 
  158: =item Retrieving rows
  159: 
  160: Retrieving rows requires calling get_rows:
  161: 
  162: @row = &Apache::lonmysql::get_rows($table_id,$condition)
  163: 
  164: This results in the query "SELECT * FROM <table> HAVING $condition".
  165: 
  166: @row = &Apache::lonmysql::get_rows($table_id,'id>20'); 
  167: 
  168: returns all rows with column 'id' greater than 20.
  169: 
  170: =back
  171: 
  172: =cut
  173: 
  174: ######################################################################
  175: ######################################################################
  176: =pod
  177: 
  178: =head1 Package Variables
  179: 
  180: =over 4
  181: 
  182: =cut
  183: 
  184: ##################################################
  185: ##################################################
  186: 
  187: =pod
  188: 
  189: =item %Tables
  190: 
  191: Holds information regarding the currently open connections.  Each key
  192: in the %Tables hash will be a unique table key.  The value associated 
  193: with a key is a hash reference.  Most values are initialized when the 
  194: table is created.
  195: 
  196: The following entries are allowed in the hash reference:
  197: 
  198: =over 4
  199: 
  200: =item Name
  201: 
  202: Table name.
  203: 
  204: =item Type            
  205: 
  206: The type of table, typically MyISAM.
  207: 
  208: =item Row_format
  209: 
  210: Describes how rows should be stored in the table.  DYNAMIC or STATIC.
  211: 
  212: =item Create_time
  213: 
  214: The date of the tables creation.
  215: 
  216: =item Update_time
  217: 
  218: The date of the last modification of the table.
  219: 
  220: =item Check_time
  221: 
  222: Usually NULL. 
  223: 
  224: =item Avg_row_length
  225: 
  226: The average length of the rows.
  227: 
  228: =item Data_length
  229: 
  230: The length of the data stored in the table (bytes)
  231: 
  232: =item Max_data_length
  233: 
  234: The maximum possible size of the table (bytes).
  235: 
  236: =item Index_length
  237: 
  238: The length of the index for the table (bytes)
  239: 
  240: =item Data_free
  241: 
  242: I have no idea what this is.
  243: 
  244: =item Comment 
  245: 
  246: The comment associated with the table.
  247: 
  248: =item Rows
  249: 
  250: The number of rows in the table.
  251: 
  252: =item Auto_increment
  253: 
  254: The value of the next auto_increment field.
  255: 
  256: =item Create_options
  257: 
  258: I have no idea.
  259: 
  260: =item Col_order
  261: 
  262: an array reference which holds the order of columns in the table.
  263: 
  264: =item row_insert_sth 
  265: 
  266: The statement handler for row inserts.
  267: 
  268: =item row_replace_sth 
  269: 
  270: The statement handler for row inserts.
  271: 
  272: =back
  273: 
  274: Col_order and row_insert_sth are kept internally by lonmysql and are not
  275: part of the usual MySQL table information.
  276: 
  277: =cut
  278: 
  279: ##################################################
  280: ##################################################
  281: my %Tables;
  282: 
  283: ##################################################
  284: ##################################################
  285: =pod
  286: 
  287: =item $errorstring
  288: 
  289: Holds the last error.
  290: 
  291: =cut
  292: ##################################################
  293: ##################################################
  294: my $errorstring;
  295: 
  296: ##################################################
  297: ##################################################
  298: =pod
  299: 
  300: =item $debugstring
  301: 
  302: Describes current events within the package.
  303: 
  304: =cut
  305: ##################################################
  306: ##################################################
  307: my $debugstring;
  308: 
  309: ##################################################
  310: ##################################################
  311: 
  312: =pod
  313: 
  314: =item $dbh
  315: 
  316: The database handler; The actual connection to MySQL via the perl DBI.
  317: 
  318: =cut
  319: 
  320: ##################################################
  321: ##################################################
  322: my $dbh;
  323: 
  324: ##################################################
  325: ##################################################
  326: 
  327: # End of global variable declarations
  328: 
  329: =pod
  330: 
  331: =back
  332: 
  333: =cut
  334: 
  335: ######################################################################
  336: ######################################################################
  337: 
  338: =pod
  339: 
  340: =head1 Internals
  341: 
  342: =over 4
  343: 
  344: =cut
  345: 
  346: ######################################################################
  347: ######################################################################
  348: 
  349: =pod
  350: 
  351: =item &connect_to_db()
  352: 
  353: Inputs: none.  
  354: 
  355: Returns: undef on error, 1 on success.
  356: 
  357: Checks to make sure the database has been connected to.  If not, the
  358: connection is established.  
  359: 
  360: =cut
  361: 
  362: ###############################
  363: sub connect_to_db { 
  364:     return 1 if ($dbh);
  365:     if (! defined($mysqluser) || ! defined($mysqlpassword)) {
  366:         &set_mysql_user_and_password();
  367:     }
  368:     if (! ($dbh = DBI->connect("DBI:mysql:$mysqldatabase",$mysqluser,$mysqlpassword,
  369:                                { RaiseError=>0,PrintError=>0}))) {
  370:         $debugstring = "Unable to connect to loncapa database.";    
  371:         if (! defined($dbh)) {
  372:             $debugstring = "Unable to connect to loncapa database.";
  373:             $errorstring = "dbh was undefined.";
  374:         } elsif ($dbh->err) {
  375:             $errorstring = "Connection error: ".$dbh->errstr;
  376:         }
  377:         return undef;
  378:     }
  379:     $debugstring = "Successfully connected to loncapa database.";    
  380:     # Determine DB configuration
  381:     undef(%db_config);
  382:     my $sth = $dbh->prepare("SHOW VARIABLES");
  383:     $sth->execute();
  384:     if ($sth->err()) {
  385:         $debugstring = "Unable to retrieve db config variables";
  386:         return undef;
  387:     }
  388:     foreach my $row (@{$sth->fetchall_arrayref}) {
  389:         $db_config{$row->[0]} = $row->[1];
  390:     }
  391:     #&Apache::lonnet::logthis("MySQL configuration variables");
  392:     #while (my ($k,$v) = each(%db_config)) {
  393:     #    &Apache::lonnet::logthis("    '$k' => '$v'");
  394:     #}
  395:     #
  396:     return 1;
  397: }
  398: 
  399: ###############################
  400: 
  401: =pod
  402: 
  403: =item &verify_sql_connection()
  404: 
  405: Inputs: none.
  406: 
  407: Returns: 0 (failure) or 1 (success)
  408: 
  409: Checks to make sure the database can be connected to.  It does not
  410: initialize anything in the lonmysql package.
  411: 
  412: =cut
  413: 
  414: ###############################
  415: sub verify_sql_connection {
  416:     if (! defined($mysqluser) || ! defined($mysqlpassword)) {
  417:         &set_mysql_user_and_password();
  418:     }
  419:     my $connection;
  420:     if (! ($connection = DBI->connect("DBI:mysql:loncapa",
  421:                                       $mysqluser,$mysqlpassword,
  422:                                       { RaiseError=>0,PrintError=>0}))) {
  423:         return 0;
  424:     }
  425:     undef($connection);
  426:     return 1;
  427: }
  428: 
  429: ###############################
  430: 
  431: =pod
  432: 
  433: =item &disconnect_from_db()
  434: 
  435: Inputs: none.
  436: 
  437: Returns: Always returns 1.
  438: 
  439: Severs the connection to the mysql database.
  440: 
  441: =cut
  442: 
  443: ###############################
  444: sub disconnect_from_db { 
  445:     foreach (keys(%Tables)) {
  446:         # Supposedly, having statement handlers running around after the
  447:         # database connection has been lost will cause trouble.  So we 
  448:         # kill them off just to be sure.
  449:         if (exists($Tables{$_}->{'row_insert_sth'})) {
  450:             delete($Tables{$_}->{'row_insert_sth'});
  451:         }
  452:         if (exists($Tables{$_}->{'row_replace_sth'})) {
  453:             delete($Tables{$_}->{'row_replace_sth'});
  454:         }
  455:     }
  456:     $dbh->disconnect if ($dbh);
  457:     $debugstring = "Disconnected from database.";
  458:     $dbh = undef;
  459:     return 1;
  460: }
  461: 
  462: ###############################
  463: 
  464: =pod
  465: 
  466: =item &number_of_rows()
  467: 
  468: Input: table identifier
  469: 
  470: Returns: the number of rows in the given table, undef on error.
  471: 
  472: =cut
  473: 
  474: ###############################
  475: sub number_of_rows { 
  476:     my ($table_id) = @_;
  477:     return undef if (! defined(&connect_to_db()));
  478:     return undef if (! defined(&update_table_info($table_id)));
  479:     return $Tables{&translate_id($table_id)}->{'Rows'};
  480: }
  481: ###############################
  482: 
  483: =pod
  484: 
  485: =item &get_dbh()
  486: 
  487: Input: nothing
  488: 
  489: Returns: the database handler, or undef on error.
  490: 
  491: This routine allows the programmer to gain access to the database handler.
  492: Be careful.
  493: 
  494: =cut
  495: 
  496: ###############################
  497: sub get_dbh { 
  498:     return undef if (! defined(&connect_to_db()));
  499:     return $dbh;
  500: }
  501: 
  502: ###############################
  503: 
  504: =pod
  505: 
  506: =item &get_error()
  507: 
  508: Inputs: none.
  509: 
  510: Returns: The last error reported.
  511: 
  512: =cut
  513: 
  514: ###############################
  515: sub get_error {
  516:     return $errorstring;
  517: }
  518: 
  519: ###############################
  520: 
  521: =pod
  522: 
  523: =item &get_debug()
  524: 
  525: Inputs: none.
  526: 
  527: Returns: A string describing the internal state of the lonmysql package.
  528: 
  529: =cut
  530: 
  531: ###############################
  532: sub get_debug {
  533:     return $debugstring;
  534: }
  535: 
  536: ###############################
  537: 
  538: =pod
  539: 
  540: =item &update_table_info()
  541: 
  542: Inputs: table id
  543: 
  544: Returns: undef on error, 1 on success.
  545: 
  546: &update_table_info updates the %Tables hash with current information about
  547: the given table.  
  548: 
  549: The default MySQL table status fields are:
  550: 
  551:    Name             Type            Row_format
  552:    Max_data_length  Index_length    Data_free
  553:    Create_time      Update_time     Check_time
  554:    Avg_row_length   Data_length     Comment 
  555:    Rows             Auto_increment  Create_options
  556: 
  557: Additionally, "Col_order" is updated as well.
  558: 
  559: =cut
  560: 
  561: ###############################
  562: sub update_table_info { 
  563:     my ($table_id) = @_;
  564:     return undef if (! defined(&connect_to_db()));
  565:     my $table_status = &check_table($table_id);
  566:     return undef if (! defined($table_status));
  567:     if (! $table_status) {
  568:         $errorstring = "table $table_id does not exist.";
  569:         return undef;
  570:     }
  571:     my $tablename = &translate_id($table_id);
  572:     #
  573:     # Get MySQLs table status information.
  574:     #
  575:     my $db_command = "SHOW TABLE STATUS FROM loncapa LIKE '$tablename'";
  576:     my $sth = $dbh->prepare($db_command);
  577:     $sth->execute();
  578:     if ($sth->err) {
  579:         $errorstring = "$dbh ATTEMPTED:\n".$db_command."\nRESULTING ERROR:\n".
  580:             $sth->errstr;
  581:         &disconnect_from_db();
  582:         return undef;
  583:     }
  584:     my @column_name = @{$sth->{NAME}};
  585:     #
  586:     my @info=$sth->fetchrow_array;
  587:     for (my $i=0;$i<= $#info ; $i++) {
  588:         if ($column_name[$i] =~ /^(Create_|Update_|Check_)time$/) {
  589:             $Tables{$tablename}->{$column_name[$i]}= 
  590:                 &unsqltime($info[$i]);
  591:         } else {
  592:             $Tables{$tablename}->{$column_name[$i]}= $info[$i];
  593:         }
  594:     }
  595:     #
  596:     # Determine the column order
  597:     #
  598:     $db_command = "DESCRIBE $tablename";
  599:     $sth = $dbh->prepare($db_command);
  600:     $sth->execute();
  601:     if ($sth->err) {
  602:         $errorstring = "$dbh ATTEMPTED:\n".$db_command."\nRESULTING ERROR:\n".
  603:             $sth->errstr;
  604:         &disconnect_from_db();
  605:         return undef;
  606:     }
  607:     my $aref=$sth->fetchall_arrayref;
  608:     $Tables{$tablename}->{'Col_order'}=[]; # Clear values.
  609:     # The values we want are the 'Field' entries, the first column.
  610:     for (my $i=0;$i< @$aref ; $i++) {
  611:         push @{$Tables{$tablename}->{'Col_order'}},$aref->[$i]->[0];
  612:     }
  613:     #
  614:     $debugstring = "Retrieved table info for $tablename";
  615:     return 1;
  616: }
  617: 
  618: ###############################
  619: 
  620: =pod
  621: 
  622: =item &table_information()
  623: 
  624: Inputs: table id
  625: 
  626: Returns: hash with the table status
  627: 
  628: =cut
  629: 
  630: ###############################
  631: sub table_information {
  632:     my $table_id=shift;
  633:     if (&update_table_info($table_id)) {
  634: 	return %{$Tables{$table_id}};
  635:     } else {
  636: 	return ();
  637:     }
  638: }
  639: 
  640: ###############################
  641: 
  642: =pod
  643: 
  644: =item &col_order()
  645: 
  646: Inputs: table id
  647: 
  648: Returns: array with column order
  649: 
  650: =cut
  651: 
  652: ###############################
  653: sub col_order {
  654:     my $table_id=shift;
  655:     if (&update_table_info($table_id)) {
  656: 	return @{$Tables{$table_id}->{'Col_order'}};
  657:     } else {
  658: 	return ();
  659:     }
  660: }
  661: 
  662: ###############################
  663: 
  664: =pod
  665: 
  666: =item &create_table()
  667: 
  668: Inputs: 
  669:     table description, see &build_table_creation_request
  670: Returns:
  671:     undef on error, table id on success.
  672: 
  673: =cut
  674: 
  675: ###############################
  676: sub create_table {
  677:     return undef if (!defined(&connect_to_db($dbh)));
  678:     my ($table_des)=@_;
  679:     my ($request,$table_id) = &build_table_creation_request($table_des);
  680:     #
  681:     # Execute the request to create the table
  682:     #############################################
  683:     my $count = $dbh->do($request);
  684:     if (! defined($count)) {
  685:         $errorstring = "$dbh ATTEMPTED:\n".$request."\nRESULTING ERROR:\n".
  686:             $dbh->errstr();
  687:         return undef;
  688:     }
  689:     my $tablename = &translate_id($table_id);
  690:     delete($Tables{$tablename}) if (exists($Tables{$tablename}));
  691:     return undef if (! defined(&update_table_info($table_id)));
  692:     $debugstring = "Created table $tablename at time ".time.
  693:         " with request\n$request";
  694:     return $table_id;
  695: }
  696: 
  697: ###############################
  698: 
  699: =pod
  700: 
  701: =item build_table_creation_request
  702: 
  703: Input: table description
  704: 
  705:     table description = {
  706:         permanent  => 'yes' or 'no',
  707:         columns => [
  708:                     { name         => 'colA',
  709:                       type         => mysql type,
  710:                       restrictions => 'NOT NULL' or empty,
  711:                       primary_key  => 'yes' or empty,
  712:                       auto_inc     => 'yes' or empty,
  713:                   },
  714:                     { name => 'colB',
  715:                       ...
  716:                   },
  717:                     { name => 'colC',
  718:                       ...
  719:                   },
  720:         ],
  721:         'PRIMARY KEY' => (index_col_name,...),
  722:          KEY => [{ name => 'idx_name', 
  723:                   columns => (col1,col2,..),},],
  724:          INDEX => [{ name => 'idx_name', 
  725:                     columns => (col1,col2,..),},],
  726:          UNIQUE => [{ index => 'yes',
  727:                      name => 'idx_name',
  728:                      columns => (col1,col2,..),},],
  729:          FULLTEXT => [{ index => 'yes',
  730:                        name => 'idx_name',
  731:                        columns => (col1,col2,..),},],
  732: 
  733:     }
  734: 
  735: Returns: scalar string containing mysql commands to create the table
  736: 
  737: =cut
  738: 
  739: ###############################
  740: sub build_table_creation_request {
  741:     my ($table_des)=@_;
  742:     #
  743:     # Build request to create table
  744:     ##################################
  745:     my @Columns;
  746:     my $col_des;
  747:     my $table_id;
  748:     if (exists($table_des->{'id'})) {
  749:         $table_id = $table_des->{'id'};
  750:     } else {
  751:         $table_id = &get_new_table_id();
  752:     }
  753:     my $tablename = &translate_id($table_id);
  754:     &Apache::lonnet::logthis(" hmm $tablename, $table_id, ". $table_des->{'id'});
  755:     my $request = "CREATE TABLE IF NOT EXISTS ".$tablename." ";
  756:     foreach my $coldata (@{$table_des->{'columns'}}) {
  757:         my $column = $coldata->{'name'};
  758:         next if (! defined($column));
  759:         $col_des = '';
  760:         if (lc($coldata->{'type'}) =~ /(enum|set)/) { # 'enum' or 'set'
  761:             $col_des.=$column." ".$coldata->{'type'}."('".
  762:                 join("', '",@{$coldata->{'values'}})."')";
  763:         } else {
  764:             $col_des.=$column." ".$coldata->{'type'};
  765:             if (exists($coldata->{'size'})) {
  766:                 $col_des.="(".$coldata->{'size'}.")";
  767:             }
  768:         }
  769:         # Modifiers
  770:         if (exists($coldata->{'restrictions'})){
  771:             $col_des.=" ".$coldata->{'restrictions'};
  772:         }
  773:         if (exists($coldata->{'default'})) {
  774:             $col_des.=" DEFAULT '".$coldata->{'default'}."'";
  775:         }
  776:         $col_des.=' AUTO_INCREMENT' if (exists($coldata->{'auto_inc'}) &&
  777:                                         ($coldata->{'auto_inc'} eq 'yes'));
  778:         $col_des.=' PRIMARY KEY'    if (exists($coldata->{'primary_key'}) &&
  779:                                         ($coldata->{'primary_key'} eq 'yes'));
  780:     } continue {
  781:         # skip blank items.
  782:         push (@Columns,$col_des) if ($col_des ne '');
  783:     }
  784:     if (exists($table_des->{'PRIMARY KEY'})) {
  785:         push (@Columns,'PRIMARY KEY ('.join(',',@{$table_des->{'PRIMARY KEY'}})
  786:               .')');
  787:     }
  788:     #
  789:     foreach my $indextype ('KEY','INDEX') {
  790:         next if (!exists($table_des->{$indextype}));
  791:         foreach my $indexdescription (@{$table_des->{$indextype}}) {
  792:             my $text = $indextype.' ';
  793:             if (exists($indexdescription->{'name'})) {
  794:                 $text .=$indexdescription->{'name'};
  795:             }
  796:             $text .= ' ('.join(',',@{$indexdescription->{'columns'}}).')';
  797:             push (@Columns,$text);
  798:         }
  799:     }
  800:     #
  801:     foreach my $indextype ('UNIQUE','FULLTEXT') {
  802:         next if (! exists($table_des->{$indextype}));
  803:         foreach my $indexdescription (@{$table_des->{$indextype}}) {
  804:             my $text = $indextype.' ';
  805:             if (exists($indexdescription->{'index'}) &&
  806:                 $indexdescription->{'index'} eq 'yes') {
  807:                 $text .= 'INDEX ';
  808:             }
  809:             if (exists($indexdescription->{'name'})) {
  810:                 $text .=$indexdescription->{'name'};
  811:             }
  812:             $text .= ' ('.join(',',@{$indexdescription->{'columns'}}).')';
  813:             push (@Columns,$text);
  814:         }
  815:     }
  816:     #
  817:     $request .= "(".join(", ",@Columns).") ";
  818:     unless($table_des->{'permanent'} eq 'yes') {
  819:         $request.="COMMENT = 'temporary' ";
  820:     } 
  821:     $request .= "TYPE=MYISAM";
  822:     return $request,$table_id;
  823: }
  824: 
  825: ###############################
  826: 
  827: =pod
  828: 
  829: =item &get_table_prefix()
  830: 
  831: returns the cleaned version of user.name and user.domain for us in table names
  832: 
  833: =cut
  834: 
  835: ###############################
  836: sub get_table_prefix {
  837:     my $clean_name   = $env{'user.name'};
  838:     my $clean_domain = $env{'user.domain'};
  839:     $clean_name =~ s/\W//g;
  840:     $clean_domain =~ s/\W//g;
  841:     return $clean_name.'_'.$clean_domain.'_';
  842: }
  843: 
  844: ###############################
  845: 
  846: =pod
  847: 
  848: =item &get_new_table_id()
  849: 
  850: Used internally to prevent table name collisions.
  851: 
  852: =cut
  853: 
  854: ###############################
  855: sub get_new_table_id {
  856:     my $newid = 0;
  857:     my @tables = &tables_in_db();
  858:     my $prefix = &get_table_prefix();
  859:     foreach (@tables) {
  860:         if (/^\Q$prefix\E(\d+)$/) {
  861:             $newid = $1 if ($1 > $newid);
  862:         }
  863:     }
  864:     return ++$newid;
  865: }
  866: 
  867: ###############################
  868: 
  869: =pod
  870: 
  871: =item &get_rows()
  872: 
  873: Inputs: $table_id,$condition
  874: 
  875: Returns: undef on error, an array ref to (array of) results on success.
  876: 
  877: Internally, this function does a 'SELECT * FROM table WHERE $condition'.
  878: $condition = 'id>0' will result in all rows where column 'id' has a value
  879: greater than 0 being returned.
  880: 
  881: =cut
  882: 
  883: ###############################
  884: sub get_rows {
  885:     my ($table_id,$condition) = @_;
  886:     return undef if (! defined(&connect_to_db()));
  887:     my $table_status = &check_table($table_id);
  888:     return undef if (! defined($table_status));
  889:     if (! $table_status) {
  890:         $errorstring = "table $table_id does not exist.";
  891:         return undef;
  892:     }
  893:     my $tablename = &translate_id($table_id);
  894:     my $request;
  895:     if (defined($condition) && $condition ne '') {
  896:         $request = 'SELECT * FROM '.$tablename.' WHERE '.$condition;
  897:     } else {
  898:         $request = 'SELECT * FROM '.$tablename;
  899:         $condition = 'no condition';
  900:     }
  901:     my $sth=$dbh->prepare($request);
  902:     $sth->execute();
  903:     if ($sth->err) {
  904:         $errorstring = "$dbh ATTEMPTED:\n".$request."\nRESULTING ERROR:\n".
  905:             $sth->errstr;
  906:         $debugstring = "Failed to get rows matching $condition";
  907:         return undef;
  908:     }
  909:     $debugstring = "Got rows matching $condition";
  910:     my @Results = @{$sth->fetchall_arrayref};
  911:     return @Results;
  912: }
  913: 
  914: ###############################
  915: 
  916: =pod
  917: 
  918: =item &store_row()
  919: 
  920: Inputs: table id, row data
  921: 
  922: returns undef on error, 1 on success.
  923: 
  924: =cut
  925: 
  926: ###############################
  927: sub store_row {
  928:     my ($table_id,$rowdata) = @_;
  929:     # 
  930:     return undef if (! defined(&connect_to_db()));
  931:     my $table_status = &check_table($table_id);
  932:     return undef if (! defined($table_status));
  933:     if (! $table_status) {
  934:         $errorstring = "table $table_id does not exist.";
  935:         return undef;
  936:     }
  937:     #
  938:     my $tablename = &translate_id($table_id);
  939:     #
  940:     my $sth;
  941:     if (exists($Tables{$tablename}->{'row_insert_sth'})) {
  942:         $sth = $Tables{$tablename}->{'row_insert_sth'};
  943:     } else {
  944:         # Build the insert statement handler
  945:         return undef if (! defined(&update_table_info($table_id)));
  946:         my $insert_request = 'INSERT INTO '.$tablename.' VALUES(';
  947:         foreach (@{$Tables{$tablename}->{'Col_order'}}) {
  948:             $insert_request.="?,";
  949:         }
  950:         chop $insert_request;
  951:         $insert_request.=")";
  952:         $sth=$dbh->prepare($insert_request);
  953:         $Tables{$tablename}->{'row_insert_sth'}=$sth;
  954:     }
  955:     my @Parameters; 
  956:     if (ref($rowdata) eq 'ARRAY') {
  957:         @Parameters = @$rowdata;
  958:     } elsif (ref($rowdata) eq 'HASH') {
  959:         foreach (@{$Tables{$tablename}->{'Col_order'}}) {
  960:             push(@Parameters,$rowdata->{$_});
  961:         }
  962:     } 
  963:     $sth->execute(@Parameters);
  964:     if ($sth->err) {
  965:         $errorstring = "$dbh ATTEMPTED insert @Parameters RESULTING ERROR:\n".
  966:             $sth->errstr;
  967:         return undef;
  968:     }
  969:     $debugstring = "Stored row.";    
  970:     return 1;
  971: }
  972: 
  973: 
  974: ###############################
  975: 
  976: =pod
  977: 
  978: =item &bulk_store_rows()
  979: 
  980: Inputs: table id, [columns],[[row data1].[row data2],...]
  981: 
  982: returns undef on error, 1 on success.
  983: 
  984: =cut
  985: 
  986: ###############################
  987: sub bulk_store_rows {
  988:     my ($table_id,$columns,$rows) = @_;
  989:     # 
  990:     return undef if (! defined(&connect_to_db()));
  991:     my $dbh = &get_dbh();
  992:     return undef if (! defined($dbh));
  993:     my $table_status = &check_table($table_id);
  994:     return undef if (! defined($table_status));
  995:     if (! $table_status) {
  996:         $errorstring = "table $table_id does not exist.";
  997:         return undef;
  998:     }
  999:     #
 1000:     my $tablename = &translate_id($table_id);
 1001:     #
 1002:     my $request = 'INSERT IGNORE INTO '.$tablename.' ';
 1003:     if (defined($columns) && ref($columns) eq 'ARRAY') {
 1004:         $request .= join(',',@$columns).' ';
 1005:     }
 1006:     if (! defined($rows) || ref($rows) ne 'ARRAY') {
 1007:         $errorstring = "no input rows given.";
 1008:         return undef;
 1009:     }
 1010:     $request .= 'VALUES ';
 1011:     foreach my $row (@$rows) {
 1012:         # avoid doing row stuff here...
 1013:         $request .= '('.join(',',@$row).'),';
 1014:     }
 1015:     $request =~ s/,$//;
 1016:     # $debugstring = "Executed ".$/.$request; # commented out - this is big
 1017:     $dbh->do($request);
 1018:     if ($dbh->err) {
 1019:         $errorstring = 'Attempted '.$/.$request.$/.'Got error '.$dbh->errstr();
 1020:         return undef;
 1021:     }
 1022:     return 1;
 1023: }
 1024: 
 1025: 
 1026: ###############################
 1027: 
 1028: =pod
 1029: 
 1030: =item &replace_row()
 1031: 
 1032: Inputs: table id, row data
 1033: 
 1034: returns undef on error, 1 on success.
 1035: 
 1036: Acts like &store_row() but uses the 'REPLACE' command instead of 'INSERT'.
 1037: 
 1038: =cut
 1039: 
 1040: ###############################
 1041: sub replace_row {
 1042:     my ($table_id,$rowdata) = @_;
 1043:     # 
 1044:     return undef if (! defined(&connect_to_db()));
 1045:     my $table_status = &check_table($table_id);
 1046:     return undef if (! defined($table_status));
 1047:     if (! $table_status) {
 1048:         $errorstring = "table $table_id does not exist.";
 1049:         return undef;
 1050:     }
 1051:     #
 1052:     my $tablename = &translate_id($table_id);
 1053:     #
 1054:     my $sth;
 1055:     if (exists($Tables{$tablename}->{'row_replace_sth'})) {
 1056:         $sth = $Tables{$tablename}->{'row_replace_sth'};
 1057:     } else {
 1058:         # Build the insert statement handler
 1059:         return undef if (! defined(&update_table_info($table_id)));
 1060:         my $replace_request = 'REPLACE INTO '.$tablename.' VALUES(';
 1061:         foreach (@{$Tables{$tablename}->{'Col_order'}}) {
 1062:             $replace_request.="?,";
 1063:         }
 1064:         chop $replace_request;
 1065:         $replace_request.=")";
 1066:         $sth=$dbh->prepare($replace_request);
 1067:         $Tables{$tablename}->{'row_replace_sth'}=$sth;
 1068:     }
 1069:     my @Parameters; 
 1070:     if (ref($rowdata) eq 'ARRAY') {
 1071:         @Parameters = @$rowdata;
 1072:     } elsif (ref($rowdata) eq 'HASH') {
 1073:         foreach (@{$Tables{$tablename}->{'Col_order'}}) {
 1074:             push(@Parameters,$rowdata->{$_});
 1075:         }
 1076:     } 
 1077:     $sth->execute(@Parameters);
 1078:     if ($sth->err) {
 1079:         $errorstring = "$dbh ATTEMPTED replace @Parameters RESULTING ERROR:\n".
 1080:             $sth->errstr;
 1081:         return undef;
 1082:     }
 1083:     $debugstring = "Stored row.";    
 1084:     return 1;
 1085: }
 1086: 
 1087: ###########################################
 1088: 
 1089: =pod
 1090: 
 1091: =item &tables_in_db()
 1092: 
 1093: Returns a list containing the names of all the tables in the database.
 1094: Returns undef on error.
 1095: 
 1096: =cut
 1097: 
 1098: ###########################################
 1099: sub tables_in_db {
 1100:     return undef if (!defined(&connect_to_db()));
 1101:     my $sth=$dbh->prepare('SHOW TABLES');
 1102:     $sth->execute();
 1103:     $sth->execute();
 1104:     my $aref = $sth->fetchall_arrayref;
 1105:     if ($sth->err()) {
 1106:         $errorstring = 
 1107:             "$dbh ATTEMPTED:\n".'fetchall_arrayref after SHOW TABLES'.
 1108:             "\nRESULTING ERROR:\n".$sth->errstr;
 1109:         return undef;
 1110:     }
 1111:     my @table_list;
 1112:     foreach (@$aref) {
 1113:         push(@table_list,$_->[0]);
 1114:     }
 1115:     $debugstring = "Got list of tables in DB: ".join(',',@table_list);
 1116:     return(@table_list);
 1117: }
 1118: 
 1119: ###########################################
 1120: 
 1121: =pod
 1122: 
 1123: =item &translate_id()
 1124: 
 1125: Used internally to translate a numeric table id into a MySQL table name.
 1126: If the input $id contains non-numeric characters it is assumed to have 
 1127: already been translated.
 1128: 
 1129: Checks are NOT performed to see if the table actually exists.
 1130: 
 1131: =cut
 1132: 
 1133: ###########################################
 1134: sub translate_id {
 1135:     my $id = shift;
 1136:     # id should be a digit.  If it is not a digit we assume the given id
 1137:     # is complete and does not need to be translated.
 1138:     return $id if ($id =~ /\D/);  
 1139:     return &get_table_prefix().$id;
 1140: }
 1141: 
 1142: ###########################################
 1143: 
 1144: =pod
 1145: 
 1146: =item &check_table()
 1147: 
 1148: Input: table id
 1149: 
 1150: Checks to see if the requested table exists.  Returns 0 (no), 1 (yes), or 
 1151: undef (error).
 1152: 
 1153: =cut
 1154: 
 1155: ###########################################
 1156: sub check_table {
 1157:     my $table_id = shift;
 1158:     return undef if (!defined(&connect_to_db()));
 1159:     #
 1160:     $table_id = &translate_id($table_id);
 1161:     my @Table_list = &tables_in_db();
 1162:     my $result = 0;
 1163:     foreach (@Table_list) {
 1164:         if ($_ eq $table_id) {
 1165:             $result = 1;
 1166:             last;
 1167:         }
 1168:     }
 1169:     # If it does not exist, make sure we do not have it listed in %Tables
 1170:     delete($Tables{$table_id}) if ((! $result) && exists($Tables{$table_id}));
 1171:     $debugstring = "check_table returned $result for $table_id";
 1172:     return $result;
 1173: }
 1174: 
 1175: ###########################################
 1176: 
 1177: =pod
 1178: 
 1179: =item &remove_from_table()
 1180: 
 1181: Input: $table_id, $column, $value
 1182: 
 1183: Returns: the number of rows deleted.  undef on error.
 1184: 
 1185: Executes a "delete from $tableid where $column like binary '$value'".
 1186: 
 1187: =cut
 1188: 
 1189: ###########################################
 1190: sub remove_from_table {
 1191:     my ($table_id,$column,$value) = @_;
 1192:     return undef if (!defined(&connect_to_db()));
 1193:     #
 1194:     $table_id = &translate_id($table_id);
 1195:     my $command = 'DELETE FROM '.$table_id.' WHERE '.$column.
 1196:         " LIKE BINARY ".$dbh->quote($value);
 1197:     my $sth = $dbh->prepare($command); 
 1198:     unless ($sth->execute()) {
 1199:         $errorstring = "ERROR on execution of ".$command."\n".$sth->errstr;
 1200:         return undef;
 1201:     }
 1202:     $debugstring = $command;
 1203:     my $rows = $sth->rows;
 1204:     return $rows;
 1205: }
 1206: 
 1207: ###########################################
 1208: 
 1209: =pod
 1210: 
 1211: =item drop_table($table_id)
 1212: 
 1213: Issues a 'drop table if exists' command
 1214: 
 1215: =cut
 1216: 
 1217: ###########################################
 1218: 
 1219: sub drop_table {
 1220:     my ($table_id) = @_;
 1221:     return undef if (!defined(&connect_to_db()));
 1222:     #
 1223:     $table_id = &translate_id($table_id);
 1224:     my $command = 'DROP TABLE IF EXISTS '.$table_id;
 1225:     my $sth = $dbh->prepare($command); 
 1226:     $sth->execute();
 1227:     if ($sth->err) {
 1228:         $errorstring = "ERROR on execution of ".$command."\n".$sth->errstr;
 1229:         return undef;
 1230:     }
 1231:     $debugstring = $command;
 1232:     delete($Tables{$table_id}); # remove any knowledge of the table
 1233:     return 1; # if we got here there was no error, so return a 'true' value
 1234: }
 1235: 
 1236: ##########################################
 1237: 
 1238: =pod
 1239: 
 1240: =item fix_table_name 
 1241: 
 1242: Fixes a table name so that it will work with MySQL.
 1243: 
 1244: =cut
 1245: 
 1246: ##########################################
 1247: sub fix_table_name {
 1248:     my ($name) = @_;
 1249:     $name =~ s/^(\d+[eE]\d+)/_$1/;
 1250:     return $name;
 1251: }
 1252: 
 1253: 
 1254: # ---------------------------- convert 'time' format into a datetime sql format
 1255: sub sqltime {
 1256:     my ($sec,$min,$hour,$mday,$mon,$year,$wday,$yday,$isdst) =
 1257: 	localtime(&unsqltime($_[0]));
 1258:     $mon++; $year+=1900;
 1259:     return "$year-$mon-$mday $hour:$min:$sec";
 1260: }
 1261: 
 1262: sub maketime {
 1263:     my %th=@_;
 1264:     return POSIX::mktime(($th{'seconds'},$th{'minutes'},$th{'hours'},
 1265:                           $th{'day'},$th{'month'}-1,
 1266:                           $th{'year'}-1900,0,0,$th{'dlsav'}));
 1267: }
 1268: 
 1269: 
 1270: #########################################
 1271: #
 1272: # Retro-fixing of un-backward-compatible time format
 1273: 
 1274: sub unsqltime {
 1275:     my $timestamp=shift;
 1276:     if ($timestamp=~/^(\d+)\-(\d+)\-(\d+)\s+(\d+)\:(\d+)\:(\d+)$/) {
 1277:         $timestamp=&maketime('year'=>$1,'month'=>$2,'day'=>$3,
 1278:                              'hours'=>$4,'minutes'=>$5,'seconds'=>$6);
 1279:     }
 1280:     return $timestamp;
 1281: }
 1282: 
 1283: 
 1284: 1;
 1285: 
 1286: __END__;
 1287: 
 1288: =pod
 1289: 
 1290: =back
 1291: 
 1292: =cut

FreeBSD-CVSweb <freebsd-cvsweb@FreeBSD.org>