File:  [LON-CAPA] / loncom / interface / loncoursedata.pm
Revision 1.171: download - view: text, annotated - select for diffs
Thu May 18 01:08:51 2006 UTC (18 years, 1 month ago) by raeburn
Branches: MAIN
CVS tags: HEAD
&coursegroups() and &get_group_settings() moved to longroup.pm, which contains general utility functions for asking about groups.  Also contains &group_changes() which is used to add/drop group memberships as a result of role changes, as determined by group settings for auto-add and auto-drop. 'none' and 'all' are now reserved words which may not be used as section or group names, so they can be used instead of _all and _none  when specifying auto-add and auto-drop settings for all sections or no section roles.

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

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