File:  [LON-CAPA] / loncom / interface / loncoursedata.pm
Revision 1.145: download - view: text, annotated - select for diffs
Mon Mar 7 20:12:08 2005 UTC (19 years, 2 months ago) by matthew
Branches: MAIN
CVS tags: HEAD
Bug 3529: correct problems plot now shows scores instead of parts correct.

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

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