File:  [LON-CAPA] / loncom / interface / loncoursedata.pm
Revision 1.169: download - view: text, annotated - select for diffs
Tue May 9 14:38:09 2006 UTC (18 years, 1 month ago) by albertel
Branches: MAIN
CVS tags: HEAD
- changing loncommon::coursegroups to be easier to use

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

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