File:  [LON-CAPA] / loncom / interface / loncoursedata.pm
Revision 1.159: download - view: text, annotated - select for diffs
Fri Apr 28 21:14:03 2006 UTC (18 years, 1 month ago) by albertel
Branches: MAIN
CVS tags: HEAD
- adding a response_specific_2 column to the response data table for supporting tasks
- adding the response specific data to the result of the &get_response_data_by_student()

    1: # The LearningOnline Network with CAPA
    2: #
    3: # $Id: loncoursedata.pm,v 1.159 2006/04/28 21:14:03 albertel Exp $
    4: #
    5: # Copyright Michigan State University Board of Trustees
    6: #
    7: # This file is part of the LearningOnline Network with CAPA (LON-CAPA).
    8: #
    9: # LON-CAPA is free software; you can redistribute it and/or modify
   10: # it under the terms of the GNU General Public License as published by
   11: # the Free Software Foundation; either version 2 of the License, or
   12: # (at your option) any later version.
   13: #
   14: # LON-CAPA is distributed in the hope that it will be useful,
   15: # but WITHOUT ANY WARRANTY; without even the implied warranty of
   16: # MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  See the
   17: # GNU General Public License for more details.
   18: #
   19: # You should have received a copy of the GNU General Public License
   20: # along with LON-CAPA; if not, write to the Free Software
   21: # Foundation, Inc., 59 Temple Place, Suite 330, Boston, MA  02111-1307  USA
   22: #
   23: # /home/httpd/html/adm/gpl.txt
   24: #
   25: # http://www.lon-capa.org/
   26: #
   27: ###
   28: 
   29: =pod
   30: 
   31: =head1 NAME
   32: 
   33: loncoursedata
   34: 
   35: =head1 SYNOPSIS
   36: 
   37: Set of functions that download and process student and course information.
   38: 
   39: =head1 PACKAGES USED
   40: 
   41:  Apache::Constants qw(:common :http)
   42:  Apache::lonnet()
   43:  Apache::lonhtmlcommon
   44:  HTML::TokeParser
   45:  GDBM_File
   46: 
   47: =cut
   48: 
   49: package Apache::loncoursedata;
   50: 
   51: use strict;
   52: use Apache::lonnet;
   53: use Apache::lonhtmlcommon;
   54: use Time::HiRes;
   55: use Apache::lonmysql;
   56: use HTML::TokeParser;
   57: use GDBM_File;
   58: 
   59: =pod
   60: 
   61: =head1 DOWNLOAD INFORMATION
   62: 
   63: This section contains all the functions that get data from other servers 
   64: and/or itself.
   65: 
   66: =cut
   67: 
   68: ################################################
   69: ################################################
   70: 
   71: =pod
   72: 
   73: =item &make_into_hash($values);
   74: 
   75: Returns a reference to a hash as described by $values.  $values is
   76: assumed to be the result of 
   77:     join(':',map {&Apache::lonnet::escape($_)} %orighash);
   78: 
   79: This is a helper function for get_current_state.
   80: 
   81: =cut
   82: 
   83: ################################################
   84: ################################################
   85: sub make_into_hash {
   86:     my $values = shift;
   87:     my %tmp = map { &Apache::lonnet::unescape($_); }
   88:                                            split(':',$values);
   89:     return \%tmp;
   90: }
   91: 
   92: 
   93: ################################################
   94: ################################################
   95: 
   96: =pod
   97: 
   98: =head1 LOCAL DATA CACHING SUBROUTINES
   99: 
  100: The local caching is done using MySQL.  There is no fall-back implementation
  101: if MySQL is not running.
  102: 
  103: The programmers interface is to call &get_current_state() or some other
  104: primary interface subroutine (described below).  The internals of this 
  105: storage system are documented here.
  106: 
  107: There are six tables used to store student performance data (the results of
  108: a dumpcurrent).  Each of these tables is created in MySQL with a name of
  109: $courseid_*****, where ***** is 'symb', 'part', or whatever is appropriate 
  110: for the table.  The tables and their purposes are described below.
  111: 
  112: Some notes before we get started.
  113: 
  114: Each table must have a PRIMARY KEY, which is a column or set of columns which
  115: will serve to uniquely identify a row of data.  NULL is not allowed!
  116: 
  117: INDEXes work best on integer data.
  118: 
  119: JOIN is used to combine data from many tables into one output.
  120: 
  121: lonmysql.pm is used for some of the interface, specifically the table creation
  122: calls.  The inserts are done in bulk by directly calling the database handler.
  123: The SELECT ... JOIN statement used to retrieve the data does not have an
  124: interface in lonmysql.pm and I shudder at the thought of writing one.
  125: 
  126: =head3 Table Descriptions
  127: 
  128: =over 4
  129: 
  130: =item Tables used to store meta information
  131: 
  132: The following tables hold data required to keep track of the current status
  133: of a students data in the tables or to look up the students data in the tables.
  134: 
  135: =over 4
  136: 
  137: =item $symb_table
  138: 
  139: The symb_table has two columns.  The first is a 'symb_id' and the second
  140: is the text name for the 'symb' (limited to 64k).  The 'symb_id' is generated
  141: automatically by MySQL so inserts should be done on this table with an
  142: empty first element.  This table has its PRIMARY KEY on the 'symb_id'.
  143: 
  144: =item $part_table
  145: 
  146: The part_table has two columns.  The first is a 'part_id' and the second
  147: is the text name for the 'part' (limited to 100 characters).  The 'part_id' is
  148: generated automatically by MySQL so inserts should be done on this table with
  149: an empty first element.  This table has its PRIMARY KEY on the 'part' (100
  150: characters) and a KEY on 'part_id'.
  151: 
  152: =item $student_table
  153: 
  154: The student_table has 7 columns.  The first is a 'student_id' assigned by 
  155: MySQL.  The second is 'student' which is username:domain.  The third through
  156: fifth are 'section', 'status' (enrollment status), and 'classification' 
  157: (to be used in the future).  The sixth and seventh ('updatetime' and 
  158: 'fullupdatetime') contain the time of last update and full update of student
  159: data.  This table has its PRIMARY KEY on the 'student_id' column and is indexed
  160: on 'student', 'section', and 'status'.
  161: 
  162: =back 
  163: 
  164: =item Tables used to store current status data
  165: 
  166: The following tables store data only about the students current status on 
  167: a problem, meaning only the data related to the last attempt on a problem.
  168: 
  169: =over 4
  170: 
  171: =item $performance_table
  172: 
  173: The performance_table has 9 columns.  The first three are 'symb_id', 
  174: 'student_id', and 'part_id'.  These comprise the PRIMARY KEY for this table
  175: and are directly related to the $symb_table, $student_table, and $part_table
  176: described above.  MySQL does better indexing on numeric items than text,
  177: so we use these three "index tables".  The remaining columns are
  178: 'solved', 'tries', 'awarded', 'award', 'awarddetail', and 'timestamp'.
  179: These are either the MySQL type TINYTEXT or various integers ('tries' and 
  180: 'timestamp').  This table has KEYs of 'student_id' and 'symb_id'.
  181: For use of this table, see the functions described below.
  182: 
  183: =item $parameters_table
  184: 
  185: The parameters_table holds the data that does not fit neatly into the
  186: performance_table.  The parameters table has four columns: 'symb_id',
  187: 'student_id', 'parameter', and 'value'.  'symb_id', 'student_id', and
  188: 'parameter' comprise the PRIMARY KEY for this table.  'parameter' is 
  189: limited to 255 characters.  'value' is limited to 64k characters.
  190: 
  191: =back
  192: 
  193: =item Tables used for storing historic data
  194: 
  195: The following tables are used to store almost all of the transactions a student
  196: has made on a homework problem.  See loncapa/docs/homework/datastorage for 
  197: specific information about each of the parameters stored.  
  198: 
  199: =over 4
  200: 
  201: =item $fulldump_response_table
  202: 
  203: The response table holds data (documented in loncapa/docs/homework/datastorage)
  204: associated with a particular response id which is stored when a student 
  205: attempts a problem.  The following are the columns of the table, in order:
  206: 'symb_id','part_id','response_id','student_id','transaction','tries',
  207: 'awarddetail', 'response_specific', 'response_specific_value',
  208: 'response_specific_2', 'response_specific_value_2', and 'submission
  209: (the text of the students submission).  The primary key is based on the
  210: first five columns listed above.
  211: 
  212: =item $fulldump_part_table
  213: 
  214: The part table holds data (documented in loncapa/docs/homework/datastorage)
  215: associated with a particular part id which is stored when a student attempts
  216: a problem.  The following are the columns of the table, in order:
  217: 'symb_id','part_id','student_id','transaction','tries','award','awarded',
  218: and 'previous'.  The primary key is based on the first five columns listed 
  219: above.
  220: 
  221: =item $fulldump_timestamp_table
  222: 
  223: The timestamp table holds the timestamps of the transactions which are
  224: stored in $fulldump_response_table and $fulldump_part_table.  This data is
  225: about both the response and part data.  Columns: 'symb_id','student_id',
  226: 'transaction', and 'timestamp'.  
  227: The primary key is based on the first 3 columns.
  228: 
  229: =item $weight_table
  230: 
  231: The weight table holds the weight for the problems used in the class.
  232: Whereas the weight of a problem can vary by section and student the data
  233: here is applied to the class as a whole.
  234: Columns: 'symb_id','part_id','response_id','weight'.
  235: 
  236: =back
  237: 
  238: =back
  239: 
  240: =head3 Important Subroutines
  241: 
  242: Here is a brief overview of the subroutines which are likely to be of 
  243: interest:
  244: 
  245: =over 4
  246: 
  247: =item &get_current_state(): programmers interface.
  248: 
  249: =item &init_dbs(): table creation
  250: 
  251: =item &update_student_data(): data storage calls
  252: 
  253: =item &get_student_data_from_performance_cache(): data retrieval
  254: 
  255: =back
  256: 
  257: =head3 Main Documentation
  258: 
  259: =over 4
  260: 
  261: =cut
  262: 
  263: ################################################
  264: ################################################
  265: 
  266: ################################################
  267: ################################################
  268: { # Begin scope of table identifiers
  269: 
  270: my $current_course ='';
  271: my $symb_table;
  272: my $part_table;
  273: my $student_table;
  274: my $performance_table;
  275: my $parameters_table;
  276: my $fulldump_response_table;
  277: my $fulldump_part_table;
  278: my $fulldump_timestamp_table;
  279: my $weight_table;
  280: 
  281: my @Tables;
  282: ################################################
  283: ################################################
  284: 
  285: =pod
  286: 
  287: =item &init_dbs()
  288: 
  289: Input: course id
  290: 
  291: Output: 0 on success, positive integer on error
  292: 
  293: This routine issues the calls to lonmysql to create the tables used to
  294: store student data.
  295: 
  296: =cut
  297: 
  298: ################################################
  299: ################################################
  300: sub init_dbs {
  301:     my ($courseid,$drop) = @_;
  302:     &setup_table_names($courseid);
  303:     #
  304:     # Drop any of the existing tables
  305:     if ($drop) {
  306:         foreach my $table (@Tables) {
  307:             &Apache::lonmysql::drop_table($table);
  308:         }
  309:     }
  310:     #
  311:     # Note - changes to this table must be reflected in the code that 
  312:     # stores the data (calls &Apache::lonmysql::store_row with this table
  313:     # id
  314:     my $symb_table_def = {
  315:         id => $symb_table,
  316:         permanent => 'no',
  317:         columns => [{ name => 'symb_id',
  318:                       type => 'MEDIUMINT UNSIGNED',
  319:                       restrictions => 'NOT NULL',
  320:                       auto_inc     => 'yes', },
  321:                     { name => 'symb',
  322:                       type => 'MEDIUMTEXT',
  323:                       restrictions => 'NOT NULL'},
  324:                     ],
  325:         'PRIMARY KEY' => ['symb_id'],
  326:     };
  327:     #
  328:     my $part_table_def = {
  329:         id => $part_table,
  330:         permanent => 'no',
  331:         columns => [{ name => 'part_id',
  332:                       type => 'MEDIUMINT UNSIGNED',
  333:                       restrictions => 'NOT NULL',
  334:                       auto_inc     => 'yes', },
  335:                     { name => 'part',
  336:                       type => 'VARCHAR(100) BINARY',
  337:                       restrictions => 'NOT NULL'},
  338:                     ],
  339:         'PRIMARY KEY' => ['part (100)'],
  340:         'KEY' => [{ columns => ['part_id']},],
  341:     };
  342:     #
  343:     my $student_table_def = {
  344:         id => $student_table,
  345:         permanent => 'no',
  346:         columns => [{ name => 'student_id',
  347:                       type => 'MEDIUMINT UNSIGNED',
  348:                       restrictions => 'NOT NULL',
  349:                       auto_inc     => 'yes', },
  350:                     { name => 'student',
  351:                       type => 'VARCHAR(100) BINARY',
  352:                       restrictions => 'NOT NULL UNIQUE'},
  353:                     { name => 'section',
  354:                       type => 'VARCHAR(100) BINARY',
  355:                       restrictions => 'NOT NULL'},
  356:                     { name => 'status',
  357:                       type => 'VARCHAR(15) BINARY',
  358:                       restrictions => 'NOT NULL'},
  359:                     { name => 'classification',
  360:                       type => 'VARCHAR(100) BINARY', },
  361:                     { name => 'updatetime',
  362:                       type => 'INT UNSIGNED'},
  363:                     { name => 'fullupdatetime',
  364:                       type => 'INT UNSIGNED'},
  365:                     ],
  366:         'PRIMARY KEY' => ['student_id'],
  367:         'KEY' => [{ columns => ['student (100)',
  368:                                 'section (100)',
  369:                                 'status (15)',]},],
  370:     };
  371:     #
  372:     my $performance_table_def = {
  373:         id => $performance_table,
  374:         permanent => 'no',
  375:         columns => [{ name => 'symb_id',
  376:                       type => 'MEDIUMINT UNSIGNED',
  377:                       restrictions => 'NOT NULL'  },
  378:                     { name => 'student_id',
  379:                       type => 'MEDIUMINT UNSIGNED',
  380:                       restrictions => 'NOT NULL'  },
  381:                     { name => 'part_id',
  382:                       type => 'MEDIUMINT UNSIGNED',
  383:                       restrictions => 'NOT NULL' },
  384:                     { name => 'part',
  385:                       type => 'VARCHAR(100) BINARY',
  386:                       restrictions => 'NOT NULL'},                    
  387:                     { name => 'solved',
  388:                       type => 'TINYTEXT' },
  389:                     { name => 'tries',
  390:                       type => 'SMALLINT UNSIGNED' },
  391:                     { name => 'awarded',
  392:                       type => 'REAL' },
  393:                     { name => 'award',
  394:                       type => 'TINYTEXT' },
  395:                     { name => 'awarddetail',
  396:                       type => 'TINYTEXT' },
  397:                     { name => 'timestamp',
  398:                       type => 'INT UNSIGNED'},
  399:                     ],
  400:         'PRIMARY KEY' => ['symb_id','student_id','part_id'],
  401:         'KEY' => [{ columns=>['student_id'] },
  402:                   { columns=>['symb_id'] },],
  403:     };
  404:     #
  405:     my $fulldump_part_table_def = {
  406:         id => $fulldump_part_table,
  407:         permanent => 'no',
  408:         columns => [
  409:                     { name => 'symb_id',
  410:                       type => 'MEDIUMINT UNSIGNED',
  411:                       restrictions => 'NOT NULL'  },
  412:                     { name => 'part_id',
  413:                       type => 'MEDIUMINT UNSIGNED',
  414:                       restrictions => 'NOT NULL' },
  415:                     { name => 'student_id',
  416:                       type => 'MEDIUMINT UNSIGNED',
  417:                       restrictions => 'NOT NULL'  },
  418:                     { name => 'transaction',
  419:                       type => 'MEDIUMINT UNSIGNED',
  420:                       restrictions => 'NOT NULL' },
  421:                     { name => 'tries',
  422:                       type => 'SMALLINT UNSIGNED',
  423:                       restrictions => 'NOT NULL' },
  424:                     { name => 'award',
  425:                       type => 'TINYTEXT' },
  426:                     { name => 'awarded',
  427:                       type => 'REAL' },
  428:                     { name => 'previous',
  429:                       type => 'SMALLINT UNSIGNED' },
  430: #                    { name => 'regrader',
  431: #                      type => 'TINYTEXT' },
  432: #                    { name => 'afterduedate',
  433: #                      type => 'TINYTEXT' },
  434:                     ],
  435:         'PRIMARY KEY' => ['symb_id','part_id','student_id','transaction'],
  436:         'KEY' => [
  437:                   { columns=>['symb_id'] },
  438:                   { columns=>['part_id'] },
  439:                   { columns=>['student_id'] },
  440:                   ],
  441:     };
  442:     #
  443:     my $fulldump_response_table_def = {
  444:         id => $fulldump_response_table,
  445:         permanent => 'no',
  446:         columns => [
  447:                     { name => 'symb_id',
  448:                       type => 'MEDIUMINT UNSIGNED',
  449:                       restrictions => 'NOT NULL'  },
  450:                     { name => 'part_id',
  451:                       type => 'MEDIUMINT UNSIGNED',
  452:                       restrictions => 'NOT NULL' },
  453:                     { name => 'response_id',
  454:                       type => 'MEDIUMINT UNSIGNED',
  455:                       restrictions => 'NOT NULL'  },
  456:                     { name => 'student_id',
  457:                       type => 'MEDIUMINT UNSIGNED',
  458:                       restrictions => 'NOT NULL'  },
  459:                     { name => 'transaction',
  460:                       type => 'MEDIUMINT UNSIGNED',
  461:                       restrictions => 'NOT NULL' },
  462:                     { name => 'awarddetail',
  463:                       type => 'TINYTEXT' },
  464: #                    { name => 'message',
  465: #                      type => 'CHAR BINARY'},
  466:                     { name => 'response_specific',
  467:                       type => 'TINYTEXT' },
  468:                     { name => 'response_specific_value',
  469:                       type => 'TINYTEXT' },
  470:                     { name => 'response_specific_2',
  471:                       type => 'TINYTEXT' },
  472:                     { name => 'response_specific_value_2',
  473:                       type => 'TINYTEXT' },
  474:                     { name => 'submission',
  475:                       type => 'TEXT'},
  476:                     ],
  477:             'PRIMARY KEY' => ['symb_id','part_id','response_id','student_id',
  478:                               'transaction'],
  479:             'KEY' => [
  480:                       { columns=>['symb_id'] },
  481:                       { columns=>['part_id','response_id'] },
  482:                       { columns=>['student_id'] },
  483:                       ],
  484:     };
  485:     my $fulldump_timestamp_table_def = {
  486:         id => $fulldump_timestamp_table,
  487:         permanent => 'no',
  488:         columns => [
  489:                     { name => 'symb_id',
  490:                       type => 'MEDIUMINT UNSIGNED',
  491:                       restrictions => 'NOT NULL'  },
  492:                     { name => 'student_id',
  493:                       type => 'MEDIUMINT UNSIGNED',
  494:                       restrictions => 'NOT NULL'  },
  495:                     { name => 'transaction',
  496:                       type => 'MEDIUMINT UNSIGNED',
  497:                       restrictions => 'NOT NULL' },
  498:                     { name => 'timestamp',
  499:                       type => 'INT UNSIGNED'},
  500:                     ],
  501:         'PRIMARY KEY' => ['symb_id','student_id','transaction'],
  502:         'KEY' => [
  503:                   { columns=>['symb_id'] },
  504:                   { columns=>['student_id'] },
  505:                   { columns=>['transaction'] },
  506:                   ],
  507:     };
  508:     #
  509:     my $parameters_table_def = {
  510:         id => $parameters_table,
  511:         permanent => 'no',
  512:         columns => [{ name => 'symb_id',
  513:                       type => 'MEDIUMINT UNSIGNED',
  514:                       restrictions => 'NOT NULL'  },
  515:                     { name => 'student_id',
  516:                       type => 'MEDIUMINT UNSIGNED',
  517:                       restrictions => 'NOT NULL'  },
  518:                     { name => 'parameter',
  519:                       type => 'TINYTEXT',
  520:                       restrictions => 'NOT NULL'  },
  521:                     { name => 'value',
  522:                       type => 'MEDIUMTEXT' },
  523:                     ],
  524:         'PRIMARY KEY' => ['symb_id','student_id','parameter (255)'],
  525:     };
  526:     #
  527:     my $weight_table_def = {
  528:         id => $weight_table,
  529:         permanent => 'no',
  530:         columns => [{ name => 'symb_id',
  531:                       type => 'MEDIUMINT UNSIGNED',
  532:                       restrictions => 'NOT NULL'  },
  533:                     { name => 'part_id',
  534:                       type => 'MEDIUMINT UNSIGNED',
  535:                       restrictions => 'NOT NULL'  },
  536:                     { name => 'weight',
  537:                       type => 'REAL',
  538:                       restrictions => 'NOT NULL'  },
  539:                     ],
  540:         'PRIMARY KEY' => ['symb_id','part_id'],
  541:     };
  542:     #
  543:     # Create the tables
  544:     my $tableid;
  545:     $tableid = &Apache::lonmysql::create_table($symb_table_def);
  546:     if (! defined($tableid)) {
  547:         &Apache::lonnet::logthis("error creating symb_table: ".
  548:                                  &Apache::lonmysql::get_error());
  549:         return 1;
  550:     }
  551:     #
  552:     $tableid = &Apache::lonmysql::create_table($part_table_def);
  553:     if (! defined($tableid)) {
  554:         &Apache::lonnet::logthis("error creating part_table: ".
  555:                                  &Apache::lonmysql::get_error());
  556:         return 2;
  557:     }
  558:     #
  559:     $tableid = &Apache::lonmysql::create_table($student_table_def);
  560:     if (! defined($tableid)) {
  561:         &Apache::lonnet::logthis("error creating student_table: ".
  562:                                  &Apache::lonmysql::get_error());
  563:         return 3;
  564:     }
  565:     #
  566:     $tableid = &Apache::lonmysql::create_table($performance_table_def);
  567:     if (! defined($tableid)) {
  568:         &Apache::lonnet::logthis("error creating preformance_table: ".
  569:                                  &Apache::lonmysql::get_error());
  570:         return 5;
  571:     }
  572:     #
  573:     $tableid = &Apache::lonmysql::create_table($parameters_table_def);
  574:     if (! defined($tableid)) {
  575:         &Apache::lonnet::logthis("error creating parameters_table: ".
  576:                                  &Apache::lonmysql::get_error());
  577:         return 6;
  578:     }
  579:     #
  580:     $tableid = &Apache::lonmysql::create_table($fulldump_part_table_def);
  581:     if (! defined($tableid)) {
  582:         &Apache::lonnet::logthis("error creating fulldump_part_table: ".
  583:                                  &Apache::lonmysql::get_error());
  584:         return 7;
  585:     }
  586:     #
  587:     $tableid = &Apache::lonmysql::create_table($fulldump_response_table_def);
  588:     if (! defined($tableid)) {
  589:         &Apache::lonnet::logthis("error creating fulldump_response_table: ".
  590:                                  &Apache::lonmysql::get_error());
  591:         return 8;
  592:     }
  593:     $tableid = &Apache::lonmysql::create_table($fulldump_timestamp_table_def);
  594:     if (! defined($tableid)) {
  595:         &Apache::lonnet::logthis("error creating fulldump_timestamp_table: ".
  596:                                  &Apache::lonmysql::get_error());
  597:         return 9;
  598:     }
  599:     $tableid = &Apache::lonmysql::create_table($weight_table_def);
  600:     if (! defined($tableid)) {
  601:         &Apache::lonnet::logthis("error creating weight_table: ".
  602:                                  &Apache::lonmysql::get_error());
  603:         return 10;
  604:     }
  605:     return 0;
  606: }
  607: 
  608: ################################################
  609: ################################################
  610: 
  611: =pod
  612: 
  613: =item &delete_caches()
  614: 
  615: This routine drops all the tables associated with a course from the 
  616: MySQL database.
  617: 
  618: Input: course id (optional, determined by environment if omitted) 
  619: 
  620: Returns: nothing
  621: 
  622: =cut
  623: 
  624: ################################################
  625: ################################################
  626: sub delete_caches {
  627:     my $courseid = shift;
  628:     $courseid = $env{'request.course.id'} if (! defined($courseid));
  629:     #
  630:     &setup_table_names($courseid);
  631:     #
  632:     my $dbh = &Apache::lonmysql::get_dbh();
  633:     foreach my $table (@Tables) {
  634:         my $command = 'DROP TABLE '.$table.';';
  635:         $dbh->do($command);
  636:         if ($dbh->err) {
  637:             &Apache::lonnet::logthis($command.' resulted in error: '.$dbh->errstr);
  638:         }
  639:     }
  640:     return;
  641: }
  642: 
  643: ################################################
  644: ################################################
  645: 
  646: =pod
  647: 
  648: =item &get_part_id()
  649: 
  650: Get the MySQL id of a problem part string.
  651: 
  652: Input: $part
  653: 
  654: Output: undef on error, integer $part_id on success.
  655: 
  656: =item &get_part()
  657: 
  658: Get the string describing a part from the MySQL id of the problem part.
  659: 
  660: Input: $part_id
  661: 
  662: Output: undef on error, $part string on success.
  663: 
  664: =cut
  665: 
  666: ################################################
  667: ################################################
  668: 
  669: my $have_read_part_table = 0;
  670: my %ids_by_part;
  671: my %parts_by_id;
  672: 
  673: sub get_part_id {
  674:     my ($part) = @_;
  675:     $part = 0 if (! defined($part));
  676:     if (! $have_read_part_table) {
  677:         my @Result = &Apache::lonmysql::get_rows($part_table);
  678:         foreach (@Result) {
  679:             $ids_by_part{$_->[1]}=$_->[0];
  680:         }
  681:         $have_read_part_table = 1;
  682:     }
  683:     if (! exists($ids_by_part{$part})) {
  684:         &Apache::lonmysql::store_row($part_table,[undef,$part]);
  685:         undef(%ids_by_part);
  686:         my @Result = &Apache::lonmysql::get_rows($part_table);
  687:         foreach (@Result) {
  688:             $ids_by_part{$_->[1]}=$_->[0];
  689:         }
  690:     }
  691:     return $ids_by_part{$part} if (exists($ids_by_part{$part}));
  692:     return undef; # error
  693: }
  694: 
  695: sub get_part {
  696:     my ($part_id) = @_;
  697:     if (! exists($parts_by_id{$part_id})  || 
  698:         ! defined($parts_by_id{$part_id}) ||
  699:         $parts_by_id{$part_id} eq '') {
  700:         my @Result = &Apache::lonmysql::get_rows($part_table);
  701:         foreach (@Result) {
  702:             $parts_by_id{$_->[0]}=$_->[1];
  703:         }
  704:     }
  705:     return $parts_by_id{$part_id} if(exists($parts_by_id{$part_id}));
  706:     return undef; # error
  707: }
  708: 
  709: ################################################
  710: ################################################
  711: 
  712: =pod
  713: 
  714: =item &get_symb_id()
  715: 
  716: Get the MySQL id of a symb.
  717: 
  718: Input: $symb
  719: 
  720: Output: undef on error, integer $symb_id on success.
  721: 
  722: =item &get_symb()
  723: 
  724: Get the symb associated with a MySQL symb_id.
  725: 
  726: Input: $symb_id
  727: 
  728: Output: undef on error, $symb on success.
  729: 
  730: =cut
  731: 
  732: ################################################
  733: ################################################
  734: 
  735: my $have_read_symb_table = 0;
  736: my %ids_by_symb;
  737: my %symbs_by_id;
  738: 
  739: sub get_symb_id {
  740:     my ($symb) = @_;
  741:     if (! $have_read_symb_table) {
  742:         my @Result = &Apache::lonmysql::get_rows($symb_table);
  743:         foreach (@Result) {
  744:             $ids_by_symb{$_->[1]}=$_->[0];
  745:         }
  746:         $have_read_symb_table = 1;
  747:     }
  748:     if (! exists($ids_by_symb{$symb})) {
  749:         &Apache::lonmysql::store_row($symb_table,[undef,$symb]);
  750:         undef(%ids_by_symb);
  751:         my @Result = &Apache::lonmysql::get_rows($symb_table);
  752:         foreach (@Result) {
  753:             $ids_by_symb{$_->[1]}=$_->[0];
  754:         }
  755:     }
  756:     return $ids_by_symb{$symb} if(exists( $ids_by_symb{$symb}));
  757:     return undef; # error
  758: }
  759: 
  760: sub get_symb {
  761:     my ($symb_id) = @_;
  762:     if (! exists($symbs_by_id{$symb_id})  || 
  763:         ! defined($symbs_by_id{$symb_id}) ||
  764:         $symbs_by_id{$symb_id} eq '') {
  765:         my @Result = &Apache::lonmysql::get_rows($symb_table);
  766:         foreach (@Result) {
  767:             $symbs_by_id{$_->[0]}=$_->[1];
  768:         }
  769:     }
  770:     return $symbs_by_id{$symb_id} if(exists( $symbs_by_id{$symb_id}));
  771:     return undef; # error
  772: }
  773: 
  774: ################################################
  775: ################################################
  776: 
  777: =pod
  778: 
  779: =item &get_student_id()
  780: 
  781: Get the MySQL id of a student.
  782: 
  783: Input: $sname, $dom
  784: 
  785: Output: undef on error, integer $student_id on success.
  786: 
  787: =item &get_student()
  788: 
  789: Get student username:domain associated with the MySQL student_id.
  790: 
  791: Input: $student_id
  792: 
  793: Output: undef on error, string $student (username:domain) on success.
  794: 
  795: =cut
  796: 
  797: ################################################
  798: ################################################
  799: 
  800: my $have_read_student_table = 0;
  801: my %ids_by_student;
  802: my %students_by_id;
  803: 
  804: sub get_student_id {
  805:     my ($sname,$sdom) = @_;
  806:     my $student = $sname.':'.$sdom;
  807:     if (! $have_read_student_table) {
  808:         my @Result = &Apache::lonmysql::get_rows($student_table);
  809:         foreach (@Result) {
  810:             $ids_by_student{$_->[1]}=$_->[0];
  811:         }
  812:         $have_read_student_table = 1;
  813:     }
  814:     if (! exists($ids_by_student{$student})) {
  815:         &populate_student_table();
  816:         undef(%ids_by_student);
  817:         undef(%students_by_id);
  818:         my @Result = &Apache::lonmysql::get_rows($student_table);
  819:         foreach (@Result) {
  820:             $ids_by_student{$_->[1]}=$_->[0];
  821:         }
  822:     }
  823:     return $ids_by_student{$student} if(exists( $ids_by_student{$student}));
  824:     return undef; # error
  825: }
  826: 
  827: sub get_student {
  828:     my ($student_id) = @_;
  829:     if (! exists($students_by_id{$student_id})  || 
  830:         ! defined($students_by_id{$student_id}) ||
  831:         $students_by_id{$student_id} eq '') {
  832:         my @Result = &Apache::lonmysql::get_rows($student_table);
  833:         foreach (@Result) {
  834:             $students_by_id{$_->[0]}=$_->[1];
  835:         }
  836:     }
  837:     return $students_by_id{$student_id} if(exists($students_by_id{$student_id}));
  838:     return undef; # error
  839: }
  840: 
  841: sub populate_student_table {
  842:     my ($courseid) = @_;
  843:     if (! defined($courseid)) {
  844:         $courseid = $env{'request.course.id'};
  845:     }
  846:     #
  847:     &setup_table_names($courseid);
  848:     &init_dbs($courseid,0);
  849:     my $dbh = &Apache::lonmysql::get_dbh();
  850:     my $request = 'INSERT IGNORE INTO '.$student_table.
  851:         "(student,section,status) VALUES ";
  852:     my $cdom = $env{'course.'.$courseid.'.domain'};
  853:     my $cnum = $env{'course.'.$courseid.'.num'};
  854:     my $classlist = &get_classlist($cdom,$cnum);
  855:     my $student_count=0;
  856:     while (my ($student,$data) = each %$classlist) {
  857:         my ($section,$status) = ($data->[&CL_SECTION()],
  858:                                  $data->[&CL_STATUS()]);
  859:         if ($section eq '' || $section =~ /^\s*$/) {
  860:             $section = 'none';
  861:         }
  862:         $request .= "('".$student."','".$section."','".$status."'),";
  863:         $student_count++;
  864:     }
  865:     return if ($student_count == 0);
  866:     chop($request);
  867:     $dbh->do($request);
  868:     if ($dbh->err()) {
  869:         &Apache::lonnet::logthis("error ".$dbh->errstr().
  870:                                  " occured executing \n".
  871:                                  $request);
  872:     }
  873:     return;
  874: }
  875: 
  876: ################################################
  877: ################################################
  878: 
  879: =pod
  880: 
  881: =item &clear_internal_caches()
  882: 
  883: Causes the internal caches used in get_student_id, get_student,
  884: get_symb_id, get_symb, get_part_id, and get_part to be undef'd.
  885: 
  886: Needs to be called before the first operation with the MySQL database
  887: for a given Apache request.
  888: 
  889: =cut
  890: 
  891: ################################################
  892: ################################################
  893: sub clear_internal_caches {
  894:     $have_read_part_table = 0;
  895:     undef(%ids_by_part);
  896:     undef(%parts_by_id);
  897:     $have_read_symb_table = 0;
  898:     undef(%ids_by_symb);
  899:     undef(%symbs_by_id);
  900:     $have_read_student_table = 0;
  901:     undef(%ids_by_student);
  902:     undef(%students_by_id);
  903: }
  904: 
  905: ################################################
  906: ################################################
  907: 
  908: =pod
  909: 
  910: =item &update_full_student_data($sname,$sdom,$courseid)
  911: 
  912: Does a lonnet::dump on a student to populate the courses tables.
  913: 
  914: Input: $sname, $sdom, $courseid
  915: 
  916: Output: $returnstatus
  917: 
  918: $returnstatus is a string describing any errors that occured.  'okay' is the
  919: default.
  920: 
  921: This subroutine loads a students data using lonnet::dump and inserts
  922: it into the MySQL database.  The inserts are done on three tables, 
  923: $fulldump_response_table, $fulldump_part_table, and $fulldump_timestamp_table.
  924: The INSERT calls are made directly by this subroutine, not through lonmysql 
  925: because we do a 'bulk'insert which takes advantage of MySQLs non-SQL 
  926: compliant INSERT command to insert multiple rows at a time.  
  927: If anything has gone wrong during this process, $returnstatus is updated with 
  928: a description of the error.
  929: 
  930: Once the "fulldump" tables are updated, the tables used for chart and
  931: spreadsheet (which hold only the current state of the student on their
  932: homework, not historical data) are updated.  If all updates have occured 
  933: successfully, $student_table is updated to reflect the time of the update.
  934: 
  935: Notice we do not insert the data and immediately query it.  This means it
  936: is possible for there to be data returned this first time that is not 
  937: available the second time.  CYA.
  938: 
  939: =cut
  940: 
  941: ################################################
  942: ################################################
  943: sub update_full_student_data {
  944:     my ($sname,$sdom,$courseid) = @_;
  945:     #
  946:     # Set up database names
  947:     &setup_table_names($courseid);
  948:     #
  949:     my $student_id = &get_student_id($sname,$sdom);
  950:     my $student = $sname.':'.$sdom;
  951:     #
  952:     my $returnstatus = 'okay';
  953:     #
  954:     # Download students data
  955:     my $time_of_retrieval = time;
  956:     my @tmp = &Apache::lonnet::dumpstore($courseid,$sdom,$sname);
  957:     if (@tmp && $tmp[0] =~ /^error/) {
  958:         $returnstatus = 'error retrieving full student data';
  959:         return $returnstatus;
  960:     } elsif (! @tmp) {
  961:         $returnstatus = 'okay: no student data';
  962:         return $returnstatus;
  963:     }
  964:     my %studentdata = @tmp;
  965:     #
  966:     # Get database handle and clean out the tables 
  967:     my $dbh = &Apache::lonmysql::get_dbh();
  968:     $dbh->do('DELETE FROM '.$fulldump_response_table.' WHERE student_id='.
  969:              $student_id);
  970:     $dbh->do('DELETE FROM '.$fulldump_part_table.' WHERE student_id='.
  971:              $student_id);
  972:     $dbh->do('DELETE FROM '.$fulldump_timestamp_table.' WHERE student_id='.
  973:              $student_id);
  974:     #
  975:     # Parse and store the data into a form we can handle
  976:     my $partdata;
  977:     my $respdata;
  978:     while (my ($key,$value) = each(%studentdata)) {
  979:         next if ($key =~ /^(\d+):(resource$|subnum$|keys:)/);
  980:         my ($transaction,$symb,$parameter) = split(':',$key);
  981:         my $symb_id = &get_symb_id($symb);
  982:         if ($parameter eq 'timestamp') {
  983:             # We can deal with 'timestamp' right away
  984:             my @timestamp_storage = ($symb_id,$student_id,
  985:                                      $transaction,$value);
  986:             my $store_command = 'INSERT IGNORE INTO '.$fulldump_timestamp_table.
  987:                 " VALUES ('".join("','",@timestamp_storage)."');";
  988:             $dbh->do($store_command);
  989:             if ($dbh->err()) {
  990:                 &Apache::lonnet::logthis('unable to execute '.$store_command);
  991:                 &Apache::lonnet::logthis($dbh->errstr());
  992:             }
  993:             next;
  994:         } elsif ($parameter eq 'version') {
  995:             next;
  996:         } elsif ($parameter =~ /^resource\.(.*)\.(tries|
  997:                                                   award|
  998:                                                   awarded|
  999:                                                   previous|
 1000:                                                   solved|
 1001:                                                   awarddetail|
 1002:                                                   submission|
 1003:                                                   submissiongrading|
 1004:                                                   molecule)\s*$/x){
 1005:             # we do not have enough information to store an 
 1006:             # entire row, so we save it up until later.
 1007:             my ($part_and_resp_id,$field) = ($1,$2);
 1008:             my ($part,$part_id,$resp,$resp_id);
 1009:             if ($part_and_resp_id =~ /\./) {
 1010:                 ($part,$resp) = split(/\./,$part_and_resp_id);
 1011:                 $part_id = &get_part_id($part);
 1012:                 $resp_id = &get_part_id($resp);
 1013:             } else {
 1014:                 $part_id = &get_part_id($part_and_resp_id);
 1015:             }
 1016:             # Deal with part specific data
 1017:             if ($field =~ /^(tries|award|awarded|previous)$/) {
 1018:                 $partdata->{$symb_id}->{$part_id}->{$transaction}->{$field}=$value;
 1019:             }
 1020:             # deal with response specific data
 1021:             if (defined($resp_id) &&
 1022:                 $field =~ /^(awarddetail|
 1023:                              submission|
 1024:                              submissiongrading|
 1025:                              molecule)$/x) {
 1026:                 if ($field eq 'submission') {
 1027:                     # We have to be careful with user supplied input.
 1028:                     # most of the time we are okay because it is escaped.
 1029:                     # However, there is one wrinkle: submissions which end in
 1030:                     # and odd number of '\' cause insert errors to occur.  
 1031:                     # Best trap this somehow...
 1032:                     $value = $dbh->quote($value);
 1033:                 }
 1034:                 if ($field eq 'submissiongrading' || 
 1035:                     $field eq 'molecule') {
 1036:                     $respdata->{$symb_id}->{$part_id}->{$resp_id}->{$transaction}->{'response_specific'}=$field;
 1037:                     $respdata->{$symb_id}->{$part_id}->{$resp_id}->{$transaction}->{'response_specific_value'}=$value;
 1038:                 } else {
 1039:                     $respdata->{$symb_id}->{$part_id}->{$resp_id}->{$transaction}->{$field}=$value;
 1040:                 }
 1041:             }
 1042:         }
 1043:     }
 1044:     ##
 1045:     ## Store the part data
 1046:     my $store_command = 'INSERT IGNORE INTO '.$fulldump_part_table.
 1047:         ' VALUES '."\n";
 1048:     my $store_rows = 0;
 1049:     while (my ($symb_id,$hash1) = each (%$partdata)) {
 1050:         while (my ($part_id,$hash2) = each (%$hash1)) {
 1051:             while (my ($transaction,$data) = each (%$hash2)) {
 1052:                 $store_command .= "('".join("','",$symb_id,$part_id,
 1053:                                             $student_id,
 1054:                                             $transaction,
 1055:                                             $data->{'tries'},
 1056:                                             $data->{'award'},
 1057:                                             $data->{'awarded'},
 1058:                                             $data->{'previous'})."'),";
 1059:                 $store_rows++;
 1060:             }
 1061:         }
 1062:     }
 1063:     if ($store_rows) {
 1064:         chop($store_command);
 1065:         $dbh->do($store_command);
 1066:         if ($dbh->err) {
 1067:             $returnstatus = 'error storing part data';
 1068:             &Apache::lonnet::logthis('insert error '.$dbh->errstr());
 1069:             &Apache::lonnet::logthis("While attempting\n".$store_command);
 1070:         }
 1071:     }
 1072:     ##
 1073:     ## Store the response data
 1074:     $store_command = 'INSERT IGNORE INTO '.$fulldump_response_table.
 1075:         ' VALUES '."\n";
 1076:     $store_rows = 0;
 1077:     while (my ($symb_id,$hash1) = each (%$respdata)) {
 1078:         while (my ($part_id,$hash2) = each (%$hash1)) {
 1079:             while (my ($resp_id,$hash3) = each (%$hash2)) {
 1080:                 while (my ($transaction,$data) = each (%$hash3)) {
 1081:                     my $submission = $data->{'submission'};
 1082:                     # We have to be careful with user supplied input.
 1083:                     # most of the time we are okay because it is escaped.
 1084:                     # However, there is one wrinkle: submissions which end in
 1085:                     # and odd number of '\' cause insert errors to occur.  
 1086:                     # Best trap this somehow...
 1087:                     $submission = $dbh->quote($submission);
 1088:                     $store_command .= "('".
 1089:                         join("','",$symb_id,$part_id,
 1090:                              $resp_id,$student_id,
 1091:                              $transaction,
 1092:                              $data->{'awarddetail'},
 1093:                              $data->{'response_specific'},
 1094:                              $data->{'response_specific_value'}),
 1095:                              $data->{'response_specific_2'},
 1096:                              $data->{'response_specific_value_2'}).
 1097:                              "',".$submission."),";
 1098:                     $store_rows++;
 1099:                 }
 1100:             }
 1101:         }
 1102:     }
 1103:     if ($store_rows) {
 1104:         chop($store_command);
 1105:         $dbh->do($store_command);
 1106:         if ($dbh->err) {
 1107:             $returnstatus = 'error storing response data';
 1108:             &Apache::lonnet::logthis('insert error '.$dbh->errstr());
 1109:             &Apache::lonnet::logthis("While attempting\n".$store_command);
 1110:         }
 1111:     }
 1112:     ##
 1113:     ## Update the students "current" data in the performance 
 1114:     ## and parameters tables.
 1115:     my ($status,undef) = &store_student_data
 1116:         ($sname,$sdom,$courseid,
 1117:          &Apache::lonnet::convert_dump_to_currentdump(\%studentdata));
 1118:     if ($returnstatus eq 'okay' && $status ne 'okay') {
 1119:         $returnstatus = 'error storing current data:'.$status;
 1120:     } elsif ($status ne 'okay') {
 1121:         $returnstatus .= ' error storing current data:'.$status;
 1122:     }        
 1123:     ##
 1124:     ## Update the students time......
 1125:     if ($returnstatus eq 'okay') {
 1126:         &store_updatetime($student_id,$time_of_retrieval,$time_of_retrieval);
 1127:         if ($dbh->err) {
 1128:             if ($returnstatus eq 'okay') {
 1129:                 $returnstatus = 'error updating student time';
 1130:             } else {
 1131:                 $returnstatus = 'error updating student time';
 1132:             }
 1133:         }
 1134:     }
 1135:     return $returnstatus;
 1136: }
 1137: 
 1138: ################################################
 1139: ################################################
 1140: 
 1141: =pod
 1142: 
 1143: =item &update_student_data()
 1144: 
 1145: Input: $sname, $sdom, $courseid
 1146: 
 1147: Output: $returnstatus, \%student_data
 1148: 
 1149: $returnstatus is a string describing any errors that occured.  'okay' is the
 1150: default.
 1151: \%student_data is the data returned by a call to lonnet::currentdump.
 1152: 
 1153: This subroutine loads a students data using lonnet::currentdump and inserts
 1154: it into the MySQL database.  The inserts are done on two tables, 
 1155: $performance_table and $parameters_table.  $parameters_table holds the data 
 1156: that is not included in $performance_table.  See the description of 
 1157: $performance_table elsewhere in this file.  The INSERT calls are made
 1158: directly by this subroutine, not through lonmysql because we do a 'bulk'
 1159: insert which takes advantage of MySQLs non-SQL compliant INSERT command to 
 1160: insert multiple rows at a time.  If anything has gone wrong during this
 1161: process, $returnstatus is updated with a description of the error and
 1162: \%student_data is returned.  
 1163: 
 1164: Notice we do not insert the data and immediately query it.  This means it
 1165: is possible for there to be data returned this first time that is not 
 1166: available the second time.  CYA.
 1167: 
 1168: =cut
 1169: 
 1170: ################################################
 1171: ################################################
 1172: sub update_student_data {
 1173:     my ($sname,$sdom,$courseid) = @_;
 1174:     #
 1175:     # Set up database names
 1176:     &setup_table_names($courseid);
 1177:     #
 1178:     my $student_id = &get_student_id($sname,$sdom);
 1179:     my $student = $sname.':'.$sdom;
 1180:     #
 1181:     my $returnstatus = 'okay';
 1182:     #
 1183:     # Download students data
 1184:     my $time_of_retrieval = time;
 1185:     my @tmp = &Apache::lonnet::currentdump($courseid,$sdom,$sname);
 1186:     if ((scalar(@tmp) > 0) && ($tmp[0] =~ /^error:/)) {
 1187:         &Apache::lonnet::logthis('error getting data for '.
 1188:                                  $sname.':'.$sdom.' in course '.$courseid.
 1189:                                  ':'.$tmp[0]);
 1190:         $returnstatus = 'error getting data';
 1191:         return ($returnstatus,undef);
 1192:     }
 1193:     if (scalar(@tmp) < 1) {
 1194:         return ('no data',undef);
 1195:     }
 1196:     my %student_data = @tmp;
 1197:     my @Results = &store_student_data($sname,$sdom,$courseid,\%student_data);
 1198:     #
 1199:     # Set the students update time
 1200:     if ($Results[0] eq 'okay') {
 1201:         &store_updatetime($student_id,$time_of_retrieval);
 1202:     }
 1203:     #
 1204:     return @Results;
 1205: }
 1206: 
 1207: sub store_updatetime {
 1208:     my ($student_id,$updatetime,$fullupdatetime)=@_;
 1209:     my $values = '';
 1210:     if (defined($updatetime)) {
 1211:         $values = 'updatetime='.$updatetime.' ';
 1212:     }
 1213:     if (defined($fullupdatetime)) {
 1214:         if ($values ne '') {
 1215:             $values .= ',';
 1216:         }
 1217:         $values .= 'fullupdatetime='.$fullupdatetime.' ';
 1218:     }
 1219:     return if ($values eq '');
 1220:     my $dbh = &Apache::lonmysql::get_dbh();
 1221:     my $request = 'UPDATE '.$student_table.' SET '.$values.
 1222:         ' WHERE student_id='.$student_id.' LIMIT 1';
 1223:     $dbh->do($request);
 1224: }
 1225: 
 1226: sub store_student_data {
 1227:     my ($sname,$sdom,$courseid,$student_data) = @_;
 1228:     #
 1229:     my $student_id = &get_student_id($sname,$sdom);
 1230:     my $student = $sname.':'.$sdom;
 1231:     #
 1232:     my $returnstatus = 'okay';
 1233:     #
 1234:     # Remove all of the students data from the table
 1235:     my $dbh = &Apache::lonmysql::get_dbh();
 1236:     $dbh->do('DELETE FROM '.$performance_table.' WHERE student_id='.
 1237:              $student_id);
 1238:     $dbh->do('DELETE FROM '.$parameters_table.' WHERE student_id='.
 1239:              $student_id);
 1240:     #
 1241:     # Store away the data
 1242:     #
 1243:     my $starttime = Time::HiRes::time;
 1244:     my $elapsed = 0;
 1245:     my $rows_stored;
 1246:     my $store_parameters_command  = 'INSERT IGNORE INTO '.$parameters_table.
 1247:         ' VALUES '."\n";
 1248:     my $num_parameters = 0;
 1249:     my $store_performance_command = 'INSERT IGNORE INTO '.$performance_table.
 1250:         ' VALUES '."\n";
 1251:     return ('error',undef) if (! defined($dbh));
 1252:     while (my ($current_symb,$param_hash) = each(%{$student_data})) {
 1253:         #
 1254:         # make sure the symb is set up properly
 1255:         my $symb_id = &get_symb_id($current_symb);
 1256:         #
 1257:         # Parameters
 1258:         while (my ($parameter,$value) = each(%$param_hash)) {
 1259:             if ($parameter !~ /(timestamp|resource\.(.*)\.(solved|tries|awarded|award|awarddetail|previous))/) {
 1260:                 my $sql_parameter = "('".join("','",
 1261:                                               $symb_id,$student_id,
 1262:                                               $parameter)."',".
 1263:                                                   $dbh->quote($value)."),\n";
 1264:                 $num_parameters ++;
 1265:                 if ($sql_parameter !~ /''/) {
 1266:                     $store_parameters_command .= $sql_parameter;
 1267:                     #$rows_stored++;
 1268:                 }
 1269:             }
 1270:         }
 1271:         # Performance
 1272:         my %stored;
 1273:         while (my ($parameter,$value) = each(%$param_hash)) {
 1274:             next if ($parameter !~ /^resource\.(.*)\.(solved|awarded)$/);
 1275:             my $part = $1;
 1276: 	    next if ($part =~ /\./);
 1277:             next if (exists($stored{$part}));
 1278:             $stored{$part}++;
 1279:             #
 1280:             my $part_id = &get_part_id($part);
 1281:             next if (!defined($part_id));
 1282:             my $solved  = $value;
 1283:             my $tries   = $param_hash->{'resource.'.$part.'.tries'};
 1284:             my $awarded = $param_hash->{'resource.'.$part.'.awarded'};
 1285:             my $award   = $param_hash->{'resource.'.$part.'.award'};
 1286:             my $awarddetail = $param_hash->{'resource.'.$part.'.awarddetail'};
 1287:             my $timestamp = $param_hash->{'timestamp'};
 1288:             #
 1289:             $solved      = '' if (! defined($solved));
 1290:             $tries       = '' if (! defined($tries));
 1291:             $awarded     = '' if (! defined($awarded));
 1292:             $award       = '' if (! defined($award));
 1293:             $awarddetail = '' if (! defined($awarddetail));
 1294:             my $sql_performance = 
 1295:                 "('".join("','",$symb_id,$student_id,$part_id,$part,
 1296:                                 $solved,$tries,$awarded,$award,
 1297:                                 $awarddetail,$timestamp)."'),\n";
 1298:             $store_performance_command .= $sql_performance;
 1299:             $rows_stored++;
 1300:         }
 1301:     }
 1302:     if (! $rows_stored) { return ($returnstatus, undef); }
 1303:     $store_parameters_command =~ s|,\n$||;
 1304:     $store_performance_command =~ s|,\n$||;
 1305:     my $start = Time::HiRes::time;
 1306:     $dbh->do($store_performance_command);
 1307:     if ($dbh->err()) {
 1308:         &Apache::lonnet::logthis('performance bigass insert error:'.
 1309:                                  $dbh->errstr());
 1310:         &Apache::lonnet::logthis('command = '.$/.$store_performance_command);
 1311:         $returnstatus = 'error: unable to insert performance into database';
 1312:         return ($returnstatus,$student_data);
 1313:     }
 1314:     $dbh->do($store_parameters_command) if ($num_parameters>0);
 1315:     if ($dbh->err()) {
 1316:         &Apache::lonnet::logthis('parameters bigass insert error:'.
 1317:                                  $dbh->errstr());
 1318:         &Apache::lonnet::logthis('command = '.$/.$store_parameters_command);
 1319:         &Apache::lonnet::logthis('rows_stored = '.$rows_stored);
 1320:         &Apache::lonnet::logthis('student_id = '.$student_id);
 1321:         $returnstatus = 'error: unable to insert parameters into database';
 1322:         return ($returnstatus,$student_data);
 1323:     }
 1324:     $elapsed += Time::HiRes::time - $start;
 1325:     return ($returnstatus,$student_data);
 1326: }
 1327: 
 1328: ######################################
 1329: ######################################
 1330: 
 1331: =pod
 1332: 
 1333: =item &ensure_tables_are_set_up($courseid)
 1334: 
 1335: Checks to be sure the MySQL tables for the given class are set up.
 1336: If $courseid is omitted it will be obtained from the environment.
 1337: 
 1338: Returns nothing on success and 'error' on failure
 1339: 
 1340: =cut
 1341: 
 1342: ######################################
 1343: ######################################
 1344: sub ensure_tables_are_set_up {
 1345:     my ($courseid) = @_;
 1346:     $courseid = $env{'request.course.id'} if (! defined($courseid));
 1347:     # 
 1348:     # Clean out package variables
 1349:     &setup_table_names($courseid);
 1350:     #
 1351:     # if the tables do not exist, make them
 1352:     my @CurrentTable = &Apache::lonmysql::tables_in_db();
 1353:     my ($found_symb,$found_student,$found_part,
 1354:         $found_performance,$found_parameters,$found_fulldump_part,
 1355:         $found_fulldump_response,$found_fulldump_timestamp,
 1356:         $found_weight);
 1357:     foreach (@CurrentTable) {
 1358:         $found_symb        = 1 if ($_ eq $symb_table);
 1359:         $found_student     = 1 if ($_ eq $student_table);
 1360:         $found_part        = 1 if ($_ eq $part_table);
 1361:         $found_performance = 1 if ($_ eq $performance_table);
 1362:         $found_parameters  = 1 if ($_ eq $parameters_table);
 1363:         $found_fulldump_part      = 1 if ($_ eq $fulldump_part_table);
 1364:         $found_fulldump_response  = 1 if ($_ eq $fulldump_response_table);
 1365:         $found_fulldump_timestamp = 1 if ($_ eq $fulldump_timestamp_table);
 1366:         $found_weight      = 1 if ($_ eq $weight_table);
 1367:     }
 1368:     if (!$found_symb          || 
 1369:         !$found_student       || !$found_part              ||
 1370:         !$found_performance   || !$found_parameters        ||
 1371:         !$found_fulldump_part || !$found_fulldump_response ||
 1372:         !$found_fulldump_timestamp || !$found_weight ) {
 1373:         if (&init_dbs($courseid,1)) {
 1374:             return 'error';
 1375:         }
 1376:     }
 1377: }
 1378: 
 1379: ################################################
 1380: ################################################
 1381: 
 1382: =pod
 1383: 
 1384: =item &ensure_current_data()
 1385: 
 1386: Input: $sname, $sdom, $courseid
 1387: 
 1388: Output: $status, $data
 1389: 
 1390: This routine ensures the data for a given student is up to date.
 1391: The $student_table is queried to determine the time of the last update.  
 1392: If the students data is out of date, &update_student_data() is called.  
 1393: The return values from the call to &update_student_data() are returned.
 1394: 
 1395: =cut
 1396: 
 1397: ################################################
 1398: ################################################
 1399: sub ensure_current_data {
 1400:     my ($sname,$sdom,$courseid) = @_;
 1401:     my $status = 'okay';   # return value
 1402:     #
 1403:     $courseid = $env{'request.course.id'} if (! defined($courseid));
 1404:     &ensure_tables_are_set_up($courseid);
 1405:     #
 1406:     # Get the update time for the user
 1407:     my $updatetime = 0;
 1408:     my $modifiedtime = &Apache::lonnet::GetFileTimestamp
 1409:         ($sdom,$sname,$courseid.'.db',
 1410:          $Apache::lonnet::perlvar{'lonUsersDir'});
 1411:     #
 1412:     my $student_id = &get_student_id($sname,$sdom);
 1413:     my @Result = &Apache::lonmysql::get_rows($student_table,
 1414:                                              "student_id ='$student_id'");
 1415:     my $data = undef;
 1416:     if (@Result) {
 1417:         $updatetime = $Result[0]->[5];  # Ack!  This is dumb!
 1418:     }
 1419:     if ($modifiedtime > $updatetime) {
 1420:         ($status,$data) = &update_student_data($sname,$sdom,$courseid);
 1421:     }
 1422:     return ($status,$data);
 1423: }
 1424: 
 1425: ################################################
 1426: ################################################
 1427: 
 1428: =pod
 1429: 
 1430: =item &ensure_current_full_data($sname,$sdom,$courseid)
 1431: 
 1432: Input: $sname, $sdom, $courseid
 1433: 
 1434: Output: $status
 1435: 
 1436: This routine ensures the fulldata (the data from a lonnet::dump, not a
 1437: lonnet::currentdump) for a given student is up to date.
 1438: The $student_table is queried to determine the time of the last update.  
 1439: If the students fulldata is out of date, &update_full_student_data() is
 1440: called.  
 1441: 
 1442: The return value from the call to &update_full_student_data() is returned.
 1443: 
 1444: =cut
 1445: 
 1446: ################################################
 1447: ################################################
 1448: sub ensure_current_full_data {
 1449:     my ($sname,$sdom,$courseid) = @_;
 1450:     my $status = 'okay';   # return value
 1451:     #
 1452:     $courseid = $env{'request.course.id'} if (! defined($courseid));
 1453:     &ensure_tables_are_set_up($courseid);
 1454:     #
 1455:     # Get the update time for the user
 1456:     my $modifiedtime = &Apache::lonnet::GetFileTimestamp
 1457:         ($sdom,$sname,$courseid.'.db',
 1458:          $Apache::lonnet::perlvar{'lonUsersDir'});
 1459:     #
 1460:     my $student_id = &get_student_id($sname,$sdom);
 1461:     my @Result = &Apache::lonmysql::get_rows($student_table,
 1462:                                              "student_id ='$student_id'");
 1463:     my $updatetime;
 1464:     if (@Result && ref($Result[0]) eq 'ARRAY') {
 1465:         $updatetime = $Result[0]->[6];
 1466:     }
 1467:     if (! defined($updatetime) || $modifiedtime > $updatetime) {
 1468:         $status = &update_full_student_data($sname,$sdom,$courseid);
 1469:     }
 1470:     return $status;
 1471: }
 1472: 
 1473: ################################################
 1474: ################################################
 1475: 
 1476: =pod
 1477: 
 1478: =item &get_student_data_from_performance_cache()
 1479: 
 1480: Input: $sname, $sdom, $symb, $courseid
 1481: 
 1482: Output: hash reference containing the data for the given student.
 1483: If $symb is undef, all the students data is returned.
 1484: 
 1485: This routine is the heart of the local caching system.  See the description
 1486: of $performance_table, $symb_table, $student_table, and $part_table.  The
 1487: main task is building the MySQL request.  The tables appear in the request
 1488: in the order in which they should be parsed by MySQL.  When searching
 1489: on a student the $student_table is used to locate the 'student_id'.  All
 1490: rows in $performance_table which have a matching 'student_id' are returned,
 1491: with data from $part_table and $symb_table which match the entries in
 1492: $performance_table, 'part_id' and 'symb_id'.  When searching on a symb,
 1493: the $symb_table is processed first, with matching rows grabbed from 
 1494: $performance_table and filled in from $part_table and $student_table in
 1495: that order.  
 1496: 
 1497: Running 'EXPLAIN ' on the 'SELECT' statements generated can be quite 
 1498: interesting, especially if you play with the order the tables are listed.  
 1499: 
 1500: =cut
 1501: 
 1502: ################################################
 1503: ################################################
 1504: sub get_student_data_from_performance_cache {
 1505:     my ($sname,$sdom,$symb,$courseid)=@_;
 1506:     my $student = $sname.':'.$sdom if (defined($sname) && defined($sdom));
 1507:     &setup_table_names($courseid);
 1508:     #
 1509:     # Return hash
 1510:     my $studentdata;
 1511:     #
 1512:     my $dbh = &Apache::lonmysql::get_dbh();
 1513:     my $request = "SELECT ".
 1514:         "d.symb,a.part,a.solved,a.tries,a.awarded,a.award,a.awarddetail,".
 1515:             "a.timestamp ";
 1516:     if (defined($student)) {
 1517:         $request .= "FROM $student_table AS b ".
 1518:             "LEFT JOIN $performance_table AS a ON b.student_id=a.student_id ".
 1519: #            "LEFT JOIN $part_table AS c ON c.part_id = a.part_id ".
 1520:             "LEFT JOIN $symb_table AS d ON d.symb_id = a.symb_id ".
 1521:                 "WHERE student='$student'";
 1522:         if (defined($symb) && $symb ne '') {
 1523:             $request .= " AND d.symb=".$dbh->quote($symb);
 1524:         }
 1525:     } elsif (defined($symb) && $symb ne '') {
 1526:         $request .= "FROM $symb_table as d ".
 1527:             "LEFT JOIN $performance_table AS a ON d.symb_id=a.symb_id ".
 1528: #            "LEFT JOIN $part_table    AS c ON c.part_id = a.part_id ".
 1529:             "LEFT JOIN $student_table AS b ON b.student_id = a.student_id ".
 1530:                 "WHERE symb='".$dbh->quote($symb)."'";
 1531:     }
 1532:     my $starttime = Time::HiRes::time;
 1533:     my $rows_retrieved = 0;
 1534:     my $sth = $dbh->prepare($request);
 1535:     $sth->execute();
 1536:     if ($sth->err()) {
 1537:         &Apache::lonnet::logthis("Unable to execute MySQL request:");
 1538:         &Apache::lonnet::logthis("\n".$request."\n");
 1539:         &Apache::lonnet::logthis("error is:".$sth->errstr());
 1540:         return undef;
 1541:     }
 1542:     foreach my $row (@{$sth->fetchall_arrayref}) {
 1543:         $rows_retrieved++;
 1544:         my ($symb,$part,$solved,$tries,$awarded,$award,$awarddetail,$time) = 
 1545:             (@$row);
 1546:         my $base = 'resource.'.$part;
 1547:         $studentdata->{$symb}->{$base.'.solved'}  = $solved;
 1548:         $studentdata->{$symb}->{$base.'.tries'}   = $tries;
 1549:         $studentdata->{$symb}->{$base.'.awarded'} = $awarded;
 1550:         $studentdata->{$symb}->{$base.'.award'}   = $award;
 1551:         $studentdata->{$symb}->{$base.'.awarddetail'} = $awarddetail;
 1552:         $studentdata->{$symb}->{'timestamp'} = $time if (defined($time) && $time ne '');
 1553:     }
 1554:     ## Get misc parameters
 1555:     $request = 'SELECT c.symb,a.parameter,a.value '.
 1556:         "FROM $student_table AS b ".
 1557:         "LEFT JOIN $parameters_table AS a ON b.student_id=a.student_id ".
 1558:         "LEFT JOIN $symb_table AS c ON c.symb_id = a.symb_id ".
 1559:         "WHERE student='$student'";
 1560:     if (defined($symb) && $symb ne '') {
 1561:         $request .= " AND c.symb=".$dbh->quote($symb);
 1562:     }
 1563:     $sth = $dbh->prepare($request);
 1564:     $sth->execute();
 1565:     if ($sth->err()) {
 1566:         &Apache::lonnet::logthis("Unable to execute MySQL request:");
 1567:         &Apache::lonnet::logthis("\n".$request."\n");
 1568:         &Apache::lonnet::logthis("error is:".$sth->errstr());
 1569:         if (defined($symb) && $symb ne '') {
 1570:             $studentdata = $studentdata->{$symb};
 1571:         }
 1572:         return $studentdata;
 1573:     }
 1574:     #
 1575:     foreach my $row (@{$sth->fetchall_arrayref}) {
 1576:         $rows_retrieved++;
 1577:         my ($symb,$parameter,$value) = (@$row);
 1578:         $studentdata->{$symb}->{$parameter}  = $value;
 1579:     }
 1580:     #
 1581:     if (defined($symb) && $symb ne '') {
 1582:         $studentdata = $studentdata->{$symb};
 1583:     }
 1584:     return $studentdata;
 1585: }
 1586: 
 1587: ################################################
 1588: ################################################
 1589: 
 1590: =pod
 1591: 
 1592: =item &get_current_state()
 1593: 
 1594: Input: $sname,$sdom,$symb,$courseid
 1595: 
 1596: Output: Described below
 1597: 
 1598: Retrieve the current status of a students performance.  $sname and
 1599: $sdom are the only required parameters.  If $symb is undef the results
 1600: of an &Apache::lonnet::currentdump() will be returned.  
 1601: If $courseid is undef it will be retrieved from the environment.
 1602: 
 1603: The return structure is based on &Apache::lonnet::currentdump.  If
 1604: $symb is unspecified, all the students data is returned in a hash of
 1605: the form:
 1606: ( 
 1607:   symb1 => { param1 => value1, param2 => value2 ... },
 1608:   symb2 => { param1 => value1, param2 => value2 ... },
 1609: )
 1610: 
 1611: If $symb is specified, a hash of 
 1612: (
 1613:   param1 => value1, 
 1614:   param2 => value2,
 1615: )
 1616: is returned.
 1617: 
 1618: If no data is found for $symb, or if the student has no performance data,
 1619: an empty list is returned.
 1620: 
 1621: =cut
 1622: 
 1623: ################################################
 1624: ################################################
 1625: sub get_current_state {
 1626:     my ($sname,$sdom,$symb,$courseid,$forcedownload)=@_;
 1627:     #
 1628:     $courseid = $env{'request.course.id'} if (! defined($courseid));
 1629:     #
 1630:     return () if (! defined($sname) || ! defined($sdom));
 1631:     #
 1632:     my ($status,$data) = &ensure_current_data($sname,$sdom,$courseid);
 1633: #    &Apache::lonnet::logthis
 1634: #        ('sname = '.$sname.
 1635: #         ' domain = '.$sdom.
 1636: #         ' status = '.$status.
 1637: #         ' data is '.(defined($data)?'defined':'undefined'));
 1638: #    while (my ($symb,$hash) = each(%$data)) {
 1639: #        &Apache::lonnet::logthis($symb."\n----------------------------------");
 1640: #        while (my ($key,$value) = each (%$hash)) {
 1641: #            &Apache::lonnet::logthis("   ".$key." = ".$value);
 1642: #        }
 1643: #    }
 1644:     #
 1645:     if (defined($data) && defined($symb) && ref($data->{$symb})) {
 1646:         return %{$data->{$symb}};
 1647:     } elsif (defined($data) && ! defined($symb) && ref($data)) {
 1648:         return %$data;
 1649:     } 
 1650:     if ($status eq 'no data') {
 1651:         return ();
 1652:     } else {
 1653:         if ($status ne 'okay' && $status ne '') {
 1654:             &Apache::lonnet::logthis('status = '.$status);
 1655:             return ();
 1656:         }
 1657:         my $returnhash = &get_student_data_from_performance_cache($sname,$sdom,
 1658:                                                       $symb,$courseid);
 1659:         return %$returnhash if (defined($returnhash));
 1660:     }
 1661:     return ();
 1662: }
 1663: 
 1664: ################################################
 1665: ################################################
 1666: 
 1667: =pod
 1668: 
 1669: =item &get_problem_statistics()
 1670: 
 1671: Gather data on a given problem.  The database is assumed to be 
 1672: populated and all local caching variables are assumed to be set
 1673: properly.  This means you need to call &ensure_current_data for
 1674: the students you are concerned with prior to calling this routine.
 1675: 
 1676: Inputs: $Sections, $status, $symb, $part, $courseid, $starttime, $endtime
 1677: 
 1678: =over 4
 1679: 
 1680: =item $Sections Array ref containing section names for students.  
 1681: 'all' is allowed to be the first (and only) item in the array.
 1682: 
 1683: =item $status String describing the status of students
 1684: 
 1685: =item $symb is the symb for the problem.
 1686: 
 1687: =item $part is the part id you need statistics for
 1688: 
 1689: =item $courseid is the course id, of course!
 1690: 
 1691: =item $starttime and $endtime are unix times which to use to limit
 1692: the statistical data.
 1693: 
 1694: =back
 1695: 
 1696: Outputs: See the code for up to date information.  A hash reference is
 1697: returned.  The hash has the following keys defined:
 1698: 
 1699: =over 4
 1700: 
 1701: =item num_students The number of students attempting the problem
 1702:       
 1703: =item tries The total number of tries for the students
 1704:       
 1705: =item max_tries The maximum number of tries taken
 1706:       
 1707: =item mean_tries The average number of tries
 1708:       
 1709: =item num_solved The number of students able to solve the problem
 1710:       
 1711: =item num_override The number of students whose answer is 'correct_by_override'
 1712:       
 1713: =item deg_of_diff The degree of difficulty of the problem
 1714:       
 1715: =item std_tries The standard deviation of the number of tries
 1716:       
 1717: =item skew_tries The skew of the number of tries
 1718: 
 1719: =item per_wrong The number of students attempting the problem who were not
 1720: able to answer it correctly.
 1721: 
 1722: =back
 1723: 
 1724: =cut
 1725: 
 1726: ################################################
 1727: ################################################
 1728: sub get_problem_statistics {
 1729:     my ($Sections,$status,$symb,$part,$courseid,$starttime,$endtime) = @_;
 1730:     return if (! defined($symb) || ! defined($part));
 1731:     $courseid = $env{'request.course.id'} if (! defined($courseid));
 1732:     #
 1733:     &setup_table_names($courseid);
 1734:     my $symb_id = &get_symb_id($symb);
 1735:     my $part_id = &get_part_id($part);
 1736:     my $stats_table = $courseid.'_problem_stats';
 1737:     #
 1738:     my $dbh = &Apache::lonmysql::get_dbh();
 1739:     return undef if (! defined($dbh));
 1740:     #
 1741:     # Clean out the table
 1742:     $dbh->do('DROP TABLE '.$stats_table);  # May return an error
 1743:     my $request = 
 1744:         'CREATE TEMPORARY TABLE '.$stats_table.' '.
 1745:         'SELECT a.student_id,a.solved,a.award,a.awarded,a.tries '.
 1746:         'FROM '.$performance_table.' AS a ';
 1747:     #
 1748:     # See if we need to include some requirements on the students
 1749:     if ((defined($Sections) && lc($Sections->[0]) ne 'all') || 
 1750:         (defined($status)   && lc($status)        ne 'any')) {
 1751:         $request .= 'NATURAL LEFT JOIN '.$student_table.' AS b ';
 1752:     }
 1753:     $request .= ' WHERE a.symb_id='.$symb_id.' AND a.part_id='.$part_id;
 1754:     #
 1755:     # Limit the students included to those specified
 1756:     if (defined($Sections) && lc($Sections->[0]) ne 'all') {
 1757:         $request .= ' AND ('.
 1758:             join(' OR ', map { "b.section='".$_."'" } @$Sections
 1759:                  ).')';
 1760:     }
 1761:     if (defined($status) && lc($status) ne 'any') {
 1762:         $request .= " AND b.status='".$status."'";
 1763:     }
 1764:     #
 1765:     # Limit by starttime and endtime
 1766:     my $time_requirements = undef;
 1767:     if (defined($starttime)) {
 1768:         $time_requirements .= 'a.timestamp>='.$starttime;
 1769:         if (defined($endtime)) {
 1770:             $time_requirements .= ' AND a.timestamp<='.$endtime;
 1771:         }
 1772:     } elsif (defined($endtime)) {
 1773:         $time_requirements .= 'a.timestamp<='.$endtime;
 1774:     }
 1775:     if (defined($time_requirements)) {
 1776:         $request .= ' AND '.$time_requirements;
 1777:     }
 1778:     #
 1779:     # Finally, execute the request to create the temporary table
 1780:     $dbh->do($request);
 1781:     #
 1782:     # Collect the first suite of statistics
 1783:     $request = 'SELECT COUNT(*),SUM(tries),'.
 1784:         'AVG(tries),STD(tries) '.
 1785:         'FROM '.$stats_table;
 1786:     my ($num,$tries,$mean,$STD) = &execute_SQL_request
 1787:         ($dbh,$request);
 1788:     #
 1789:     $request = 'SELECT MAX(tries),MIN(tries) FROM '.$stats_table.
 1790:         ' WHERE awarded>0';
 1791:     if (defined($time_requirements)) {
 1792:         $request .= ' AND '.$time_requirements;
 1793:     }
 1794:     my ($max,$min) = &execute_SQL_request($dbh,$request);
 1795:     #
 1796:     $request = 'SELECT SUM(awarded) FROM '.$stats_table;
 1797:     if (defined($time_requirements)) {
 1798:         $request .= ' AND '.$time_requirements;
 1799:     }
 1800:     my ($Solved) = &execute_SQL_request($dbh,$request);
 1801:     #
 1802:     $request = 'SELECT SUM(awarded) FROM '.$stats_table.
 1803:         " WHERE solved='correct_by_override'";
 1804:     if (defined($time_requirements)) {
 1805:         $request .= ' AND '.$time_requirements;
 1806:     }
 1807:     my ($solved) = &execute_SQL_request($dbh,$request);
 1808:     #
 1809:     $Solved -= $solved;
 1810:     #
 1811:     $num    = 0 if (! defined($num));
 1812:     $tries  = 0 if (! defined($tries));
 1813:     $max    = 0 if (! defined($max));
 1814:     $min    = 0 if (! defined($min));
 1815:     $STD    = 0 if (! defined($STD));
 1816:     $Solved = 0 if (! defined($Solved) || $Solved < 0);
 1817:     $solved = 0 if (! defined($solved));
 1818:     #
 1819:     # Compute the more complicated statistics
 1820:     my $DegOfDiff = 'nan';
 1821:     $DegOfDiff = 1-($Solved)/$tries if ($tries>0);
 1822:     #
 1823:     my $SKEW = 'nan';
 1824:     my $wrongpercent = 0;
 1825:     my $numwrong = 'nan';
 1826:     if ($num > 0) {
 1827:         ($SKEW) = &execute_SQL_request($dbh,'SELECT SQRT(SUM('.
 1828:                                      'POWER(tries - '.$STD.',3)'.
 1829:                                      '))/'.$num.' FROM '.$stats_table);
 1830:         $numwrong = $num-$Solved;
 1831:         $wrongpercent=int(10*100*$numwrong/$num)/10;
 1832:     }
 1833:     #
 1834:     # Drop the temporary table
 1835:     $dbh->do('DROP TABLE '.$stats_table);  # May return an error
 1836:     #
 1837:     # Return result
 1838:     return { num_students => $num,
 1839:              tries        => $tries,
 1840:              max_tries    => $max,
 1841:              min_tries    => $min,
 1842:              mean_tries   => $mean,
 1843:              std_tries    => $STD,
 1844:              skew_tries   => $SKEW,
 1845:              num_solved   => $Solved,
 1846:              num_override => $solved,
 1847:              num_wrong    => $numwrong,
 1848:              per_wrong    => $wrongpercent,
 1849:              deg_of_diff  => $DegOfDiff };
 1850: }
 1851: 
 1852: ##
 1853: ## This is a helper for get_statistics
 1854: sub execute_SQL_request {
 1855:     my ($dbh,$request)=@_;
 1856: #    &Apache::lonnet::logthis($request);
 1857:     my $sth = $dbh->prepare($request);
 1858:     if (!$sth) {
 1859: 	die($dbh->errstr . " SQL: $request");
 1860:     }
 1861:     $sth->execute();
 1862:     my $row = $sth->fetchrow_arrayref();
 1863:     if (ref($row) eq 'ARRAY' && scalar(@$row)>0) {
 1864:         return @$row;
 1865:     }
 1866:     return ();
 1867: }
 1868: 
 1869: ######################################################
 1870: ######################################################
 1871: 
 1872: =pod
 1873: 
 1874: =item &populate_weight_table
 1875: 
 1876: =cut
 1877: 
 1878: ######################################################
 1879: ######################################################
 1880: sub populate_weight_table {
 1881:     my ($courseid) = @_;
 1882:     if (! defined($courseid)) {
 1883:         $courseid = $env{'request.course.id'};
 1884:     }
 1885:     #
 1886:     &setup_table_names($courseid);
 1887:     my $navmap = Apache::lonnavmaps::navmap->new();
 1888:     if (!defined($navmap)) {
 1889:         &Apache::lonnet::logthis('loncoursedata::populate_weight_table:'.$/.
 1890:                                  '  unable to get navmaps resource'.$/.
 1891:                                  '  '.join(' ',(caller)));
 1892:         return;
 1893:     }
 1894:     my @sequences = $navmap->retrieveResources(undef,
 1895:                                                sub { shift->is_map(); },1,0,1);
 1896:     my @resources;
 1897:     foreach my $seq (@sequences) {
 1898:         push(@resources,$navmap->retrieveResources($seq,
 1899:                                                    sub {shift->is_problem();},
 1900:                                                    0,0,0));
 1901:     }
 1902:     if (! scalar(@resources)) {
 1903:         &Apache::lonnet::logthis('loncoursedata::populate_weight_table:'.$/.
 1904:                                  ' no resources returned for '.$courseid);
 1905:         return;
 1906:     }
 1907:     #       Since we use lonnet::EXT to retrieve problem weights,
 1908:     #       to ensure current data we must clear the caches out.
 1909:     &Apache::lonnet::clear_EXT_cache_status();
 1910:     my $dbh = &Apache::lonmysql::get_dbh();
 1911:     my $request = 'INSERT IGNORE INTO '.$weight_table.
 1912:         "(symb_id,part_id,weight) VALUES ";
 1913:     my $weight;
 1914:     foreach my $res (@resources) {
 1915:         my $symb_id = &get_symb_id($res->symb);
 1916:         foreach my $part (@{$res->parts}) {
 1917:             my $part_id = &get_part_id($part);
 1918:             $weight = &Apache::lonnet::EXT('resource.'.$part.'.weight',
 1919:                                            $res->symb,
 1920:                                            undef,undef,undef);
 1921:             if (!defined($weight) || ($weight eq '')) { 
 1922:                 $weight=1;
 1923:             }
 1924:             $request .= "('".$symb_id."','".$part_id."','".$weight."'),";
 1925:         }
 1926:     }
 1927:     $request =~ s/(,)$//;
 1928: #    &Apache::lonnet::logthis('request = '.$/.$request);
 1929:     $dbh->do($request);
 1930:     if ($dbh->err()) {
 1931:         &Apache::lonnet::logthis("error ".$dbh->errstr().
 1932:                                  " occured executing \n".
 1933:                                  $request);
 1934:     }
 1935:     return;
 1936: }
 1937: 
 1938: ##########################################################
 1939: ##########################################################
 1940: 
 1941: =pod
 1942: 
 1943: =item &limit_by_start_end_times
 1944: 
 1945: Build SQL WHERE condition which limits the data collected by the start
 1946: and end times provided
 1947: 
 1948: Inputs: $starttime, $endtime, $table
 1949: 
 1950: Returns: $time_limits
 1951: 
 1952: =cut
 1953: 
 1954: ##########################################################
 1955: ##########################################################
 1956: sub limit_by_start_end_time {
 1957:     my ($starttime,$endtime,$table) = @_;
 1958:     my $time_requirements = undef;
 1959:     if (defined($starttime)) {
 1960:         $time_requirements .= $table.".timestamp>='".$starttime."'";
 1961:         if (defined($endtime)) {
 1962:             $time_requirements .= " AND ".$table.".timestamp<='".$endtime."'";
 1963:         }
 1964:     } elsif (defined($endtime)) {
 1965:         $time_requirements .= $table.".timestamp<='".$endtime."'";
 1966:     }
 1967:     return $time_requirements;
 1968: }
 1969: 
 1970: ##########################################################
 1971: ##########################################################
 1972: 
 1973: =pod
 1974: 
 1975: =item &limit_by_section_and_status
 1976: 
 1977: Build SQL WHERE condition which limits the data collected by section and
 1978: student status.
 1979: 
 1980: Inputs: $Sections (array ref)
 1981:     $enrollment (string: 'any', 'expired', 'active')
 1982:     $tablename The name of the table that holds the student data
 1983: 
 1984: Returns: $student_requirements,$enrollment_requirements
 1985: 
 1986: =cut
 1987: 
 1988: ##########################################################
 1989: ##########################################################
 1990: sub limit_by_section_and_status {
 1991:     my ($Sections,$enrollment,$tablename) = @_;
 1992:     my $student_requirements = undef;
 1993:     if ( (defined($Sections) && $Sections->[0] ne 'all')) {
 1994:         $student_requirements = '('.
 1995:             join(' OR ', map { $tablename.".section='".$_."'" } @$Sections
 1996:                  ).')';
 1997:     }
 1998:     #
 1999:     my $enrollment_requirements=undef;
 2000:     if (defined($enrollment) && $enrollment ne 'Any') {
 2001:         $enrollment_requirements = $tablename.".status='".$enrollment."'";
 2002:     }
 2003:     return ($student_requirements,$enrollment_requirements);
 2004: }
 2005: 
 2006: ######################################################
 2007: ######################################################
 2008: 
 2009: =pod
 2010: 
 2011: =item rank_students_by_scores_on_resources
 2012: 
 2013: Inputs: 
 2014:     $resources: array ref of hash ref.  Each hash ref needs key 'symb'.
 2015:     $Sections: array ref of sections to include,
 2016:     $enrollment: string,
 2017:     $courseid (may be omitted)
 2018:     $starttime (may be omitted)
 2019:     $endtime (may be omitted)
 2020:     $has_award_for (may be omitted)
 2021: 
 2022: Returns; An array of arrays.  The sub arrays contain a student name and
 2023: their score on the resources. $starttime and $endtime constrain the
 2024: list to awards obtained during the given time limits. $has_score_on
 2025: constrains the list to those students who at least attempted the
 2026: resource identified by the given symb, which is used to filter out
 2027: such students for statistics that would be adversely affected by such
 2028: students. 
 2029: 
 2030: =cut
 2031: 
 2032: ######################################################
 2033: ######################################################
 2034: sub RNK_student { return 0; };
 2035: sub RNK_score   { return 1; };
 2036: 
 2037: sub rank_students_by_scores_on_resources {
 2038:     my ($resources,$Sections,$enrollment,$courseid,$starttime,$endtime,$has_award_for) = @_;
 2039:     return if (! defined($resources) || ! ref($resources) eq 'ARRAY');
 2040:     if (! defined($courseid)) {
 2041:         $courseid = $env{'request.course.id'};
 2042:     }
 2043:     #
 2044:     &setup_table_names($courseid);
 2045:     my $dbh = &Apache::lonmysql::get_dbh();
 2046:     my ($section_limits,$enrollment_limits)=
 2047:         &limit_by_section_and_status($Sections,$enrollment,'b');
 2048:     my $symb_limits = '('.join(' OR ',map {'a.symb_id='.&get_symb_id($_);
 2049:                                        } @$resources
 2050:                                ).')';
 2051:     my ($award_col, $award_join, $award_clause) = ('', '', '');
 2052:     if ($has_award_for) {
 2053:         my $resource_id = &get_symb_id($has_award_for);
 2054:         $award_col = ", perf.awarded";
 2055:         $award_join = "LEFT JOIN $performance_table AS perf ON perf.symb_id"
 2056:             ." = $resource_id AND perf.student_id = b.student_id ";
 2057:         $award_clause = "AND perf.awarded IS NOT NULL";
 2058:     }
 2059:     my $time_limits = &limit_by_start_end_time($starttime,$endtime,'a');
 2060:     my $request = "SELECT b.student,SUM(a.awarded*w.weight) AS score "
 2061:         ."$award_col FROM $performance_table AS a ".
 2062:         "NATURAL LEFT JOIN $weight_table AS w ".
 2063:         "LEFT JOIN $student_table AS b ON a.student_id=b.student_id ".
 2064:         "$award_join WHERE ";
 2065:     if (defined($section_limits)) {
 2066:         $request .= $section_limits.' AND ';
 2067:     }
 2068:     if (defined($enrollment_limits)) {
 2069:         $request .= $enrollment_limits.' AND ';
 2070:     }
 2071:     if (defined($time_limits)) {
 2072:         $request .= $time_limits.' AND ';
 2073:     }
 2074:     if ($symb_limits ne '()') {
 2075:         $request .= $symb_limits.' AND ';
 2076:     }
 2077:     $request =~ s/( AND )$//;   # Remove extra conjunction
 2078:     $request =~ s/( WHERE )$//; # In case there were no limits placed on it
 2079:     $request .= " $award_clause GROUP BY a.student_id ORDER BY score";
 2080:     #&Apache::lonnet::logthis('request = '.$/.$request);
 2081:     my $sth = $dbh->prepare($request) or die "Can't prepare $request";
 2082:     $sth->execute();
 2083:     my $rows = $sth->fetchall_arrayref();
 2084:     return ($rows);
 2085: }
 2086: 
 2087: ########################################################
 2088: ########################################################
 2089: 
 2090: =pod
 2091: 
 2092: =item &get_sum_of_scores
 2093: 
 2094: Inputs: $resource (hash ref, needs {'symb'} key),
 2095: $part, (the part id),
 2096: $students (array ref, contents of array are scalars holding 'sname:sdom'),
 2097: $courseid
 2098: 
 2099: Returns: the sum of the score on the problem part over the students and the
 2100:    maximum possible value for the sum (taken from the weight table).
 2101: 
 2102: =cut
 2103: 
 2104: ########################################################
 2105: ########################################################
 2106: sub get_sum_of_scores {
 2107:     my ($symb,$part,$students,$courseid,$starttime,$endtime) = @_;
 2108:     if (! defined($courseid)) {
 2109:         $courseid = $env{'request.course.id'};
 2110:     }
 2111:     if (defined($students) && 
 2112:         ((@$students == 0) ||
 2113:          (@$students == 1 && (! defined($students->[0]) || 
 2114:                               $students->[0] eq ''))
 2115:          )
 2116:         ){
 2117:         undef($students);
 2118:     }
 2119:     #
 2120:     &setup_table_names($courseid);
 2121:     my $dbh = &Apache::lonmysql::get_dbh();
 2122:     my $time_limits = &limit_by_start_end_time($starttime,$endtime,'a');
 2123:     my $request = 'SELECT SUM(a.awarded*w.weight),SUM(w.weight) FROM '.
 2124:         $performance_table.' AS a '.
 2125:         'NATURAL LEFT JOIN '.$weight_table.' AS w ';
 2126:     $request .= 'WHERE a.symb_id='.&get_symb_id($symb).
 2127:         ' AND a.part_id='.&get_part_id($part);
 2128:     if (defined($time_limits)) {
 2129:         $request .= ' AND '.$time_limits;
 2130:     }
 2131:     if (defined($students)) {
 2132:         $request .= ' AND ('.
 2133:             join(' OR ',map {'a.student_id='.&get_student_id(split(':',$_));
 2134:                          } @$students).
 2135:                              ')';
 2136:     }
 2137:     my $sth = $dbh->prepare($request);
 2138:     $sth->execute();
 2139:     my $rows = $sth->fetchrow_arrayref();
 2140:     if ($dbh->err) {
 2141:         &Apache::lonnet::logthis('error 1 = '.$dbh->errstr());
 2142:         &Apache::lonnet::logthis('prepared then executed, fetchrow_arrayrefed'.
 2143:                                  $/.$request);
 2144:         return (undef,undef);
 2145:     }
 2146:     return ($rows->[0],$rows->[1]);
 2147: }
 2148: 
 2149: ########################################################
 2150: ########################################################
 2151: 
 2152: =pod
 2153: 
 2154: =item &score_stats
 2155: 
 2156: Inputs: $Sections, $enrollment, $symbs, $starttime,
 2157:         $endtime, $courseid
 2158: 
 2159: $Sections, $enrollment, $starttime, $endtime, and $courseid are the same as 
 2160: elsewhere in this module.  
 2161: $symbs is an array ref of symbs
 2162: 
 2163: Returns: minimum, maximum, mean, s.d., number of students, and maximum
 2164:   possible of student scores on the given resources
 2165: 
 2166: =cut
 2167: 
 2168: ########################################################
 2169: ########################################################
 2170: sub score_stats {
 2171:     my ($Sections,$enrollment,$symbs,$starttime,$endtime,$courseid)=@_;
 2172:     if (! defined($courseid)) {
 2173:         $courseid = $env{'request.course.id'};
 2174:     }
 2175:     #
 2176:     &setup_table_names($courseid);
 2177:     my $dbh = &Apache::lonmysql::get_dbh();
 2178:     #
 2179:     my ($section_limits,$enrollment_limits)=
 2180:         &limit_by_section_and_status($Sections,$enrollment,'b');
 2181:     my $time_limits = &limit_by_start_end_time($starttime,$endtime,'a');
 2182:     my @Symbids = map { &get_symb_id($_); } @{$symbs};
 2183:     #
 2184:     my $stats_table = $courseid.'_problem_stats';
 2185:     my $symb_restriction = join(' OR ',map {'a.symb_id='.$_;} @Symbids);
 2186:     my $request = 'DROP TABLE '.$stats_table;
 2187:     $dbh->do($request);
 2188:     $request = 
 2189:         'CREATE TEMPORARY TABLE '.$stats_table.' '.
 2190:         'SELECT a.student_id,'.
 2191:         'SUM(a.awarded*w.weight) AS score FROM '.
 2192:         $performance_table.' AS a '.
 2193:         'NATURAL LEFT JOIN '.$weight_table.' AS w '.
 2194:         'LEFT JOIN '.$student_table.' AS b ON a.student_id=b.student_id '.
 2195:         'WHERE ('.$symb_restriction.')';
 2196:     if ($time_limits) {
 2197:         $request .= ' AND '.$time_limits;
 2198:     }
 2199:     if ($section_limits) {
 2200:         $request .= ' AND '.$section_limits;
 2201:     }
 2202:     if ($enrollment_limits) {
 2203:         $request .= ' AND '.$enrollment_limits;
 2204:     }
 2205:     $request .= ' GROUP BY a.student_id';
 2206: #    &Apache::lonnet::logthis('request = '.$/.$request);
 2207:     my $sth = $dbh->prepare($request);
 2208:     $sth->execute();
 2209:     $request = 
 2210:         'SELECT AVG(score),STD(score),MAX(score),MIN(score),COUNT(score) '.
 2211:         'FROM '.$stats_table;
 2212:     my ($ave,$std,$max,$min,$count) = &execute_SQL_request($dbh,$request);
 2213: #    &Apache::lonnet::logthis('request = '.$/.$request);
 2214:     
 2215:     $request = 'SELECT SUM(weight) FROM '.$weight_table.
 2216:         ' AS a WHERE ('.$symb_restriction.')';
 2217:     my ($max_possible) = &execute_SQL_request($dbh,$request);
 2218:     # &Apache::lonnet::logthis('request = '.$/.$request);
 2219:     return($min,$max,$ave,$std,$count,$max_possible);
 2220: }
 2221: 
 2222: 
 2223: ########################################################
 2224: ########################################################
 2225: 
 2226: =pod
 2227: 
 2228: =item &count_stats
 2229: 
 2230: Inputs: $Sections, $enrollment, $symbs, $starttime,
 2231:         $endtime, $courseid
 2232: 
 2233: $Sections, $enrollment, $starttime, $endtime, and $courseid are the same as 
 2234: elsewhere in this module.  
 2235: $symbs is an array ref of symbs
 2236: 
 2237: Returns: minimum, maximum, mean, s.d., and number of students
 2238:   of the number of items correct on the given resources
 2239: 
 2240: =cut
 2241: 
 2242: ########################################################
 2243: ########################################################
 2244: sub count_stats {
 2245:     my ($Sections,$enrollment,$symbs,$starttime,$endtime,$courseid)=@_;
 2246:     if (! defined($courseid)) {
 2247:         $courseid = $env{'request.course.id'};
 2248:     }
 2249:     #
 2250:     &setup_table_names($courseid);
 2251:     my $dbh = &Apache::lonmysql::get_dbh();
 2252:     #
 2253:     my ($section_limits,$enrollment_limits)=
 2254:         &limit_by_section_and_status($Sections,$enrollment,'b');
 2255:     my $time_limits = &limit_by_start_end_time($starttime,$endtime,'a');
 2256:     my @Symbids = map { &get_symb_id($_); } @{$symbs};
 2257:     #
 2258:     my $stats_table = $courseid.'_problem_stats';
 2259:     my $symb_restriction = join(' OR ',map {'a.symb_id='.$_;} @Symbids);
 2260:     my $request = 'DROP TABLE '.$stats_table;
 2261:     $dbh->do($request);
 2262:     $request = 
 2263:         'CREATE TEMPORARY TABLE '.$stats_table.' '.
 2264:         'SELECT a.student_id,'.
 2265:         'SUM(a.awarded) AS count FROM '.
 2266:         $performance_table.' AS a '.
 2267:         'LEFT JOIN '.$student_table.' AS b ON a.student_id=b.student_id '.
 2268:         'WHERE ('.$symb_restriction.')';
 2269:     if ($time_limits) {
 2270:         $request .= ' AND '.$time_limits;
 2271:     }
 2272:     if ($section_limits) {
 2273:         $request .= ' AND '.$section_limits;
 2274:     }
 2275:     if ($enrollment_limits) {
 2276:         $request .= ' AND '.$enrollment_limits;
 2277:     }
 2278:     $request .= ' GROUP BY a.student_id';
 2279: #    &Apache::lonnet::logthis('request = '.$/.$request);
 2280:     my $sth = $dbh->prepare($request);
 2281:     $sth->execute();
 2282:     $request = 
 2283:         'SELECT AVG(count),STD(count),MAX(count),MIN(count),COUNT(count) '.
 2284:         'FROM '.$stats_table;
 2285:     my ($ave,$std,$max,$min,$count) = &execute_SQL_request($dbh,$request);
 2286: #    &Apache::lonnet::logthis('request = '.$/.$request);
 2287:     return($min,$max,$ave,$std,$count);
 2288: }
 2289: 
 2290: ######################################################
 2291: ######################################################
 2292: 
 2293: =pod
 2294: 
 2295: =item get_student_data
 2296: 
 2297: =cut
 2298: 
 2299: ######################################################
 2300: ######################################################
 2301: sub get_student_data {
 2302:     my ($students,$courseid) = @_;
 2303:     $courseid = $env{'request.course.id'} if (! defined($courseid));
 2304:     &setup_table_names($courseid);
 2305:     my $dbh = &Apache::lonmysql::get_dbh();
 2306:     return undef if (! defined($dbh));
 2307:     my $request = 'SELECT '.
 2308:         'student_id, student '.
 2309:         'FROM '.$student_table;
 2310:     if (defined($students)) {
 2311:         $request .= ' WHERE ('.
 2312:             join(' OR ', map {'student_id='.
 2313:                                   &get_student_id($_->{'username'},
 2314:                                                   $_->{'domain'})
 2315:                               } @$students
 2316:                  ).')';
 2317:     }
 2318:     $request.= ' ORDER BY student_id';
 2319:     my $sth = $dbh->prepare($request);
 2320:     $sth->execute();
 2321:     if ($dbh->err) {
 2322:         &Apache::lonnet::logthis('error 2 = '.$dbh->errstr());
 2323:         &Apache::lonnet::logthis('prepared then executed '.$/.$request);
 2324:         return undef;
 2325:     }
 2326:     my $dataset = $sth->fetchall_arrayref();
 2327:     if (ref($dataset) eq 'ARRAY' && scalar(@$dataset)>0) {
 2328:         return $dataset;
 2329:     }
 2330: }
 2331: 
 2332: sub RD_student_id      { return 0; }
 2333: sub RD_awarddetail     { return 1; }
 2334: sub RD_response_eval   { return 2; }
 2335: sub RD_response_eval_2 { return 3; }
 2336: sub RD_submission      { return 4; }
 2337: sub RD_timestamp       { return 5; }
 2338: sub RD_tries           { return 6; }
 2339: sub RD_sname           { return 7; }
 2340: 
 2341: sub get_response_data {
 2342:     my ($Sections,$enrollment,$symb,$response,$courseid) = @_;
 2343:     return undef if (! defined($symb) || 
 2344:                ! defined($response));
 2345:     $courseid = $env{'request.course.id'} if (! defined($courseid));
 2346:     #
 2347:     &setup_table_names($courseid);
 2348:     my $symb_id = &get_symb_id($symb);
 2349:     if (! defined($symb_id)) {
 2350:         &Apache::lonnet::logthis('Unable to find symb for '.$symb.' in '.$courseid);
 2351:         return undef;
 2352:     }
 2353:     my $response_id = &get_part_id($response);
 2354:     if (! defined($response_id)) {
 2355:         &Apache::lonnet::logthis('Unable to find id for '.$response.' in '.$courseid);
 2356:         return undef;
 2357:     }
 2358:     #
 2359:     my $dbh = &Apache::lonmysql::get_dbh();
 2360:     return undef if (! defined($dbh));
 2361:     #
 2362:     my ($student_requirements,$enrollment_requirements) = 
 2363:         &limit_by_section_and_status($Sections,$enrollment,'d');
 2364:     my $request = 'SELECT '.
 2365:         'a.student_id, a.awarddetail, a.response_specific_value, '.
 2366:         'a.response_specific_value_2, a.submission, b.timestamp, '.
 2367: 	'c.tries, d.student '.
 2368:         'FROM '.$fulldump_response_table.' AS a '.
 2369:         'LEFT JOIN '.$fulldump_timestamp_table.' AS b '.
 2370:         'ON a.symb_id=b.symb_id AND a.student_id=b.student_id AND '.
 2371:         'a.transaction = b.transaction '.
 2372:         'LEFT JOIN '.$fulldump_part_table.' AS c '.
 2373:         'ON a.symb_id=c.symb_id AND a.student_id=c.student_id AND '.        
 2374:         'a.part_id=c.part_id AND a.transaction = c.transaction '.
 2375:         'LEFT JOIN '.$student_table.' AS d '.
 2376:         'ON a.student_id=d.student_id '.
 2377:         'WHERE '.
 2378:         'a.symb_id='.$symb_id.' AND a.response_id='.$response_id;
 2379:     if (defined($student_requirements) || defined($enrollment_requirements)) {
 2380:         $request .= ' AND ';
 2381:         if (defined($student_requirements)) {
 2382:             $request .= $student_requirements.' AND ';
 2383:         }
 2384:         if (defined($enrollment_requirements)) {
 2385:             $request .= $enrollment_requirements.' AND ';
 2386:         }
 2387:         $request =~ s/( AND )$//;
 2388:     }
 2389:     $request .= ' ORDER BY b.timestamp';
 2390: #    &Apache::lonnet::logthis("request =\n".$request);
 2391:     my $sth = $dbh->prepare($request);
 2392:     $sth->execute();
 2393:     if ($dbh->err) {
 2394:         &Apache::lonnet::logthis('error 3 = '.$dbh->errstr());
 2395:         &Apache::lonnet::logthis('prepared then executed '.$/.$request);
 2396:         return undef;
 2397:     }
 2398:     my $dataset = $sth->fetchall_arrayref();
 2399:     if (ref($dataset) eq 'ARRAY' && scalar(@$dataset)>0) {
 2400:         # Clear the \'s from around the submission
 2401:         for (my $i =0;$i<scalar(@$dataset);$i++) {
 2402:             $dataset->[$i]->[3] =~ s/(\'$|^\')//g;
 2403:         }
 2404:         return $dataset;
 2405:     }
 2406: }
 2407: 
 2408: 
 2409: sub RDs_awarddetail     { return 3; }
 2410: sub RDs_submission      { return 2; }
 2411: sub RDs_timestamp       { return 1; }
 2412: sub RDs_tries           { return 0; }
 2413: sub RDs_awarded         { return 4; }
 2414: sub RDs_response_eval   { return 5; }
 2415: sub RDs_response_eval_2 { return 6; }
 2416: 
 2417: sub get_response_data_by_student {
 2418:     my ($student,$symb,$response,$courseid) = @_;
 2419:     return undef if (! defined($symb) || 
 2420:                      ! defined($response));
 2421:     $courseid = $env{'request.course.id'} if (! defined($courseid));
 2422:     #
 2423:     &setup_table_names($courseid);
 2424:     my $symb_id = &get_symb_id($symb);
 2425:     my $response_id = &get_part_id($response);
 2426:     #
 2427:     my $student_id = &get_student_id($student->{'username'},
 2428:                                      $student->{'domain'});
 2429:     #
 2430:     my $dbh = &Apache::lonmysql::get_dbh();
 2431:     return undef if (! defined($dbh));
 2432:     my $request = 'SELECT '.
 2433:         'c.tries, b.timestamp, a.submission, a.awarddetail, c.awarded, '.
 2434: 	'a.response_specific_value, a.response_specific_value_2, '.
 2435:         'FROM '.$fulldump_response_table.' AS a '.
 2436:         'LEFT JOIN '.$fulldump_timestamp_table.' AS b '.
 2437:         'ON a.symb_id=b.symb_id AND a.student_id=b.student_id AND '.
 2438:         'a.transaction = b.transaction '.
 2439:         'LEFT JOIN '.$fulldump_part_table.' AS c '.
 2440:         'ON a.symb_id=c.symb_id AND a.student_id=c.student_id AND '.        
 2441:         'a.part_id=c.part_id AND a.transaction = c.transaction '.
 2442:         'LEFT JOIN '.$student_table.' AS d '.
 2443:         'ON a.student_id=d.student_id '.
 2444:         'LEFT JOIN '.$performance_table.' AS e '.
 2445:         'ON a.symb_id=e.symb_id AND a.part_id=e.part_id AND '.
 2446:         'a.student_id=e.student_id AND c.tries=e.tries '.
 2447:         'WHERE '.
 2448:         'a.symb_id='.$symb_id.' AND a.response_id='.$response_id.
 2449:         ' AND a.student_id='.$student_id.' ORDER BY b.timestamp';
 2450: #    &Apache::lonnet::logthis("request =\n".$request);
 2451:     my $sth = $dbh->prepare($request);
 2452:     $sth->execute();
 2453:     if ($dbh->err) {
 2454:         &Apache::lonnet::logthis('error 4 = '.$dbh->errstr());
 2455:         &Apache::lonnet::logthis('prepared then executed '.$/.$request);
 2456:         return undef;
 2457:     }
 2458:     my $dataset = $sth->fetchall_arrayref();
 2459:     if (ref($dataset) eq 'ARRAY' && scalar(@$dataset)>0) {
 2460:         # Clear the \'s from around the submission
 2461:         for (my $i =0;$i<scalar(@$dataset);$i++) {
 2462:             $dataset->[$i]->[2] =~ s/(\'$|^\')//g;
 2463:         }
 2464:         return $dataset;
 2465:     }
 2466:     return undef; # error occurred
 2467: }
 2468: 
 2469: sub RT_student_id { return 0; }
 2470: sub RT_awarded    { return 1; }
 2471: sub RT_tries      { return 2; }
 2472: sub RT_timestamp  { return 3; }
 2473: 
 2474: sub get_response_time_data {
 2475:     my ($sections,$enrollment,$symb,$part,$courseid) = @_;
 2476:     return undef if (! defined($symb) || 
 2477:                      ! defined($part));
 2478:     $courseid = $env{'request.course.id'} if (! defined($courseid));
 2479:     #
 2480:     &setup_table_names($courseid);
 2481:     my $symb_id = &get_symb_id($symb);
 2482:     if (! defined($symb_id)) {
 2483:         &Apache::lonnet::logthis('Unable to find symb for '.$symb.' in '.$courseid);
 2484:         return undef;
 2485:     }
 2486:     my $part_id = &get_part_id($part);
 2487:     if (! defined($part_id)) {
 2488:         &Apache::lonnet::logthis('Unable to find id for '.$part.' in '.$courseid);
 2489:         return undef;
 2490:     }
 2491:     #
 2492:     my $dbh = &Apache::lonmysql::get_dbh();
 2493:     return undef if (! defined($dbh));
 2494:     my ($student_requirements,$enrollment_requirements) = 
 2495:         &limit_by_section_and_status($sections,$enrollment,'d');
 2496:     my $request = 'SELECT '.
 2497:         'a.student_id, a.awarded, a.tries, b.timestamp '.
 2498:         'FROM '.$fulldump_part_table.' AS a '.
 2499:         'LEFT JOIN '.$fulldump_timestamp_table.' AS b '.
 2500:         'ON a.symb_id=b.symb_id AND a.student_id=b.student_id AND '.
 2501:         'a.transaction = b.transaction '.
 2502:         'LEFT JOIN '.$student_table.' as d '.
 2503:         'ON a.student_id=d.student_id '.
 2504:         'WHERE '.
 2505:         'a.symb_id='.$symb_id.' AND a.part_id='.$part_id;
 2506:     if (defined($student_requirements) || defined($enrollment_requirements)) {
 2507:         $request .= ' AND ';
 2508:         if (defined($student_requirements)) {
 2509:             $request .= $student_requirements.' AND ';
 2510:         }
 2511:         if (defined($enrollment_requirements)) {
 2512:             $request .= $enrollment_requirements.' AND ';
 2513:         }
 2514:         $request =~ s/( AND )$//;
 2515:     }
 2516:     $request .= ' ORDER BY b.timestamp';
 2517: #    &Apache::lonnet::logthis("request =\n".$request);
 2518:     my $sth = $dbh->prepare($request);
 2519:     $sth->execute();
 2520:     if ($dbh->err) {
 2521:         &Apache::lonnet::logthis('error 5 = '.$dbh->errstr());
 2522:         &Apache::lonnet::logthis('prepared then executed '.$/.$request);
 2523:         return undef;
 2524:     }
 2525:     my $dataset = $sth->fetchall_arrayref();
 2526:     if (ref($dataset) eq 'ARRAY' && scalar(@$dataset)>0) {
 2527:         return $dataset;
 2528:     }
 2529: 
 2530: }
 2531: 
 2532: ################################################
 2533: ################################################
 2534: 
 2535: =pod
 2536: 
 2537: =item &get_student_scores($Sections,$Symbs,$enrollment,$courseid)
 2538: 
 2539: =cut
 2540: 
 2541: ################################################
 2542: ################################################
 2543: sub get_student_scores {
 2544:     my ($sections,$Symbs,$enrollment,$courseid,$starttime,$endtime) = @_;
 2545:     $courseid = $env{'request.course.id'} if (! defined($courseid));
 2546:     &setup_table_names($courseid);
 2547:     my $dbh = &Apache::lonmysql::get_dbh();
 2548:     return (undef) if (! defined($dbh));
 2549:     my $tmptable = $courseid.'_temp_'.time;
 2550:     my $request = 'DROP TABLE IF EXISTS '.$tmptable;
 2551: #    &Apache::lonnet::logthis('request = '.$/.$request);
 2552:     $dbh->do($request);
 2553:     #
 2554:     my $symb_requirements;
 2555:     if (defined($Symbs)  && @$Symbs) {
 2556:         $symb_requirements = '('.
 2557:             join(' OR ', map{ "(a.symb_id='".&get_symb_id($_->{'symb'}).
 2558:                               "' AND a.part_id='".&get_part_id($_->{'part'}).
 2559:                               "')"
 2560:                               } @$Symbs).')';
 2561:     }
 2562:     #
 2563:     my ($student_requirements,$enrollment_requirements) = 
 2564:         &limit_by_section_and_status($sections,$enrollment,'b');
 2565:     #
 2566:     my $time_requirements = &limit_by_start_end_time($starttime,$endtime,'a');
 2567:     ##
 2568:     $request = 'CREATE TEMPORARY TABLE IF NOT EXISTS '.$tmptable.
 2569:         ' SELECT a.student_id,SUM(a.awarded*c.weight) AS score FROM '.
 2570:         $performance_table.' AS a ';
 2571:     $request .= "LEFT JOIN ".$weight_table.' AS c ON a.symb_id=c.symb_id AND a.part_id=c.part_id ';
 2572:     if (defined($student_requirements) || defined($enrollment_requirements)) {
 2573:         $request .= ' LEFT JOIN '.$student_table.' AS b ON a.student_id=b.student_id';
 2574:     }
 2575:     if (defined($symb_requirements)      || 
 2576:         defined($student_requirements)   ||
 2577:         defined($enrollment_requirements) ) {
 2578:         $request .= ' WHERE ';
 2579:     }
 2580:     if (defined($symb_requirements)) {
 2581:         $request .= $symb_requirements.' AND ';
 2582:     }
 2583:     if (defined($student_requirements)) {
 2584:         $request .= $student_requirements.' AND ';
 2585:     }
 2586:     if (defined($enrollment_requirements)) {
 2587:         $request .= $enrollment_requirements.' AND ';
 2588:     }
 2589:     if (defined($time_requirements)) {
 2590:         $request .= $time_requirements.' AND ';
 2591:     }
 2592:     $request =~ s/ AND $//; # Strip of the trailing ' AND '.
 2593:     $request .= ' GROUP BY a.student_id';
 2594: #    &Apache::lonnet::logthis("request = \n".$request);
 2595:     my $sth = $dbh->prepare($request);
 2596:     $sth->execute();
 2597:     if ($dbh->err) {
 2598:         &Apache::lonnet::logthis('error 6 = '.$dbh->errstr());
 2599:         &Apache::lonnet::logthis('prepared then executed '.$/.$request);
 2600:         return undef;
 2601:     }
 2602:     $request = 'SELECT score,COUNT(*) FROM '.$tmptable.' GROUP BY score';
 2603: #    &Apache::lonnet::logthis("request = \n".$request);
 2604:     $sth = $dbh->prepare($request);
 2605:     $sth->execute();
 2606:     if ($dbh->err) {
 2607:         &Apache::lonnet::logthis('error 7 = '.$dbh->errstr());
 2608:         &Apache::lonnet::logthis('prepared then executed '.$/.$request);
 2609:         return undef;
 2610:     }
 2611:     my $dataset = $sth->fetchall_arrayref();
 2612:     return $dataset;
 2613: }
 2614: 
 2615: ################################################
 2616: ################################################
 2617: 
 2618: =pod
 2619: 
 2620: =item &setup_table_names()
 2621: 
 2622: input: course id
 2623: 
 2624: output: none
 2625: 
 2626: Cleans up the package variables for local caching.
 2627: 
 2628: =cut
 2629: 
 2630: ################################################
 2631: ################################################
 2632: sub setup_table_names {
 2633:     my ($courseid) = @_;
 2634:     if (! defined($courseid)) {
 2635:         $courseid = $env{'request.course.id'};
 2636:     }
 2637:     #
 2638:     if (! defined($current_course) || $current_course ne $courseid) {
 2639:         # Clear out variables
 2640:         $have_read_part_table = 0;
 2641:         undef(%ids_by_part);
 2642:         undef(%parts_by_id);
 2643:         $have_read_symb_table = 0;
 2644:         undef(%ids_by_symb);
 2645:         undef(%symbs_by_id);
 2646:         $have_read_student_table = 0;
 2647:         undef(%ids_by_student);
 2648:         undef(%students_by_id);
 2649:         #
 2650:         $current_course = $courseid;
 2651:     }
 2652:     #
 2653:     # Set up database names
 2654:     my $base_id = $courseid;
 2655:     $symb_table        = $base_id.'_'.'symb';
 2656:     $part_table        = $base_id.'_'.'part';
 2657:     $student_table     = $base_id.'_'.'student';
 2658:     $performance_table = $base_id.'_'.'performance';
 2659:     $parameters_table  = $base_id.'_'.'parameters';
 2660:     $fulldump_part_table      = $base_id.'_'.'partdata';
 2661:     $fulldump_response_table  = $base_id.'_'.'responsedata';
 2662:     $fulldump_timestamp_table = $base_id.'_'.'timestampdata';
 2663:     $weight_table             = $base_id.'_'.'weight';
 2664:     #
 2665:     @Tables = (
 2666:                $symb_table,
 2667:                $part_table,
 2668:                $student_table,
 2669:                $performance_table,
 2670:                $parameters_table,
 2671:                $fulldump_part_table,
 2672:                $fulldump_response_table,
 2673:                $fulldump_timestamp_table,
 2674:                $weight_table,
 2675:                );
 2676:     return;
 2677: }
 2678: 
 2679: ################################################
 2680: ################################################
 2681: 
 2682: =pod
 2683: 
 2684: =back
 2685: 
 2686: =item End of Local Data Caching Subroutines
 2687: 
 2688: =cut
 2689: 
 2690: ################################################
 2691: ################################################
 2692: 
 2693: } # End scope of table identifiers
 2694: 
 2695: ################################################
 2696: ################################################
 2697: 
 2698: =pod
 2699: 
 2700: =head3 Classlist Subroutines
 2701: 
 2702: =item &get_classlist();
 2703: 
 2704: Retrieve the classist of a given class or of the current class.  Student
 2705: information is returned from the classlist.db file and, if needed,
 2706: from the students environment.
 2707: 
 2708: Optional arguments are $cdom, and $cnum (course domain,
 2709: and course number, respectively).  If either is ommitted the course
 2710: will be taken from the current environment ($env{'request.course.id'},
 2711: $env{'course.'.$cid.'.domain'}, and $env{'course.'.$cid.'.num'}).
 2712: 
 2713: Returns a reference to a hash which contains:
 2714:  keys    '$sname:$sdom'
 2715:  values  [$sdom,$sname,$end,$start,$id,$section,$fullname,$status,$type,$lockedtype]
 2716: 
 2717: The constant values CL_SDOM, CL_SNAME, CL_END, etc. can be used
 2718: as indices into the returned list to future-proof clients against
 2719: changes in the list order.
 2720: 
 2721: =cut
 2722: 
 2723: ################################################
 2724: ################################################
 2725: 
 2726: sub CL_SDOM     { return 0; }
 2727: sub CL_SNAME    { return 1; }
 2728: sub CL_END      { return 2; }
 2729: sub CL_START    { return 3; }
 2730: sub CL_ID       { return 4; }
 2731: sub CL_SECTION  { return 5; }
 2732: sub CL_FULLNAME { return 6; }
 2733: sub CL_STATUS   { return 7; }
 2734: sub CL_TYPE     { return 8; }
 2735: sub CL_LOCKEDTYPE   { return 9; }
 2736: 
 2737: sub get_classlist {
 2738:     my ($cdom,$cnum) = @_;
 2739:     my $cid = $cdom.'_'.$cnum;
 2740:     if (!defined($cdom) || !defined($cnum)) {
 2741: 	$cid =  $env{'request.course.id'};
 2742: 	$cdom = $env{'course.'.$cid.'.domain'};
 2743: 	$cnum = $env{'course.'.$cid.'.num'};
 2744:     }
 2745:     my $now = time;
 2746:     #
 2747:     my %classlist=&Apache::lonnet::dump('classlist',$cdom,$cnum);
 2748:     while (my ($student,$info) = each(%classlist)) {
 2749:         if ($student =~ /^(con_lost|error|no_such_host)/i) {
 2750:             &Apache::lonnet::logthis('get_classlist error for '.$cid.':'.$student);
 2751:             return undef;
 2752:         }
 2753:         my ($sname,$sdom) = split(/:/,$student);
 2754:         my @Values = split(/:/,$info);
 2755:         my ($end,$start,$id,$section,$fullname,$type,$lockedtype);
 2756:         if (@Values > 2) {
 2757:             ($end,$start,$id,$section,$fullname,$type,$lockedtype) = @Values;
 2758:         } else { # We have to get the data ourselves
 2759:             ($end,$start) = @Values;
 2760:             $section = &Apache::lonnet::getsection($sdom,$sname,$cid);
 2761:             my %info=&Apache::lonnet::get('environment',
 2762:                                           ['firstname','middlename',
 2763:                                            'lastname','generation','id'],
 2764:                                           $sdom, $sname);
 2765:             my ($tmp) = keys(%info);
 2766:             if ($tmp =~/^(con_lost|error|no_such_host)/i) {
 2767:                 $fullname = 'not available';
 2768:                 $id = 'not available';
 2769:                 &Apache::lonnet::logthis('unable to retrieve environment '.
 2770:                                          'for '.$sname.':'.$sdom);
 2771:             } else {
 2772:                 $fullname = &Apache::lonnet::format_name(@info{qw/firstname middlename lastname generation/},'lastname');
 2773:                 $id = $info{'id'};
 2774:             }
 2775:             # Update the classlist with this students information
 2776:             if ($fullname ne 'not available') {
 2777: 		my $enrolldata = join(':',$end,$start,$id,$section,$fullname);
 2778: 		my $reply=&Apache::lonnet::cput('classlist',
 2779:                                                 {$student => $enrolldata},
 2780:                                                 $cdom,$cnum);
 2781:                 if ($reply !~ /^(ok|delayed)/) {
 2782:                     &Apache::lonnet::logthis('Unable to update classlist for '.
 2783:                                              'student '.$sname.':'.$sdom.
 2784:                                              ' error:'.$reply);
 2785:                 }
 2786:             }
 2787:         }
 2788:         my $status='Expired';
 2789:         if(((!$end) || $now < $end) && ((!$start) || ($now > $start))) {
 2790:             $status='Active';
 2791:         }
 2792:         $classlist{$student} = 
 2793:             [$sdom,$sname,$end,$start,$id,$section,$fullname,$status,$type,$lockedtype];
 2794:     }
 2795:     if (wantarray()) {
 2796:         return (\%classlist,['domain','username','end','start','id',
 2797:                              'section','fullname','status','type','lockedtype']);
 2798:     } else {
 2799:         return \%classlist;
 2800:     }
 2801: }
 2802: 
 2803: # ----- END HELPER FUNCTIONS --------------------------------------------
 2804: 
 2805: 1;
 2806: __END__
 2807: 
 2808: 

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