- I OpenACS For Everyone
- I.1 High level information: What is OpenACS?
- I.1.1 Overview
- I.1.2 OpenACS Release Notes
- I.2 OpenACS: robust web development framework
- I.2.1 Introduction
- I.2.2 Basic infrastructure
- I.2.3 Advanced infrastructure
- I.2.4 Domain level tools
- I.1 High level information: What is OpenACS?
- II Administrator's Guide
- II.2 Installation Overview
- II.2.1 Basic Steps
- II.2.2 Prerequisite Software
- II.3 Complete Installation
- II.3.1 Install a Unix-like system and supporting software
- II.3.2 Install Oracle 10g XE on debian
- II.3.2.1 Install Oracle 8.1.7
- II.3.3 Install PostgreSQL
- II.3.4 Install AOLserver 4
- II.3.5 Quick Install of OpenACS
- II.3.5.1 Complex Install OpenACS 5.3
- II.3.6 OpenACS Installation Guide for Windows2000
- II.3.7 OpenACS Installation Guide for Mac OS X
- II.4 Configuring a new OpenACS Site
- II.4.1 Installing OpenACS packages
- II.4.2 Mounting OpenACS packages
- II.4.3 Configuring an OpenACS package
- II.4.4 Setting Permissions on an OpenACS package
- II.4.5 How Do I?
- II.4.6 Configure OpenACS look and feel with templates
- II.5 Upgrading
- II.5.1 Overview
- II.5.2 Upgrading 4.5 or higher to 4.6.3
- II.5.3 Upgrading OpenACS 4.6.3 to 5.0
- II.5.4 Upgrading an OpenACS 5.0.0 or greater installation
- II.5.5 Upgrading the OpenACS files
- II.5.6 Upgrading Platform components
- II.6 Production Environments
- II.6.1 Starting and Stopping an OpenACS instance.
- II.6.2 AOLserver keepalive with inittab
- II.6.3 Running multiple services on one machine
- II.6.4 High Availability/High Performance Configurations
- II.6.5 Staged Deployment for Production Networks
- II.6.6 Installing SSL Support for an OpenACS service
- II.6.7 Set up Log Analysis Reports
- II.6.8 External uptime validation
- II.6.9 Diagnosing Performance Problems
- II.7 Database Management
- II.7.1 Running a PostgreSQL database on another server
- II.7.2 Deleting a tablespace
- II.7.3 Vacuum Postgres nightly
- II.8 Backup and Recovery
- II.8.1 Backup Strategy
- II.8.2 Manual backup and recovery
- II.8.3 Automated Backup
- II.8.4 Using CVS for backup-recovery
- II.A Install Red Hat 8/9
- II.B Install additional supporting software
- II.B.1 Unpack the OpenACS tarball
- II.B.2 Initialize CVS (OPTIONAL)
- II.B.3 Add PSGML commands to emacs init file (OPTIONAL)
- II.B.4 Install Daemontools (OPTIONAL)
- II.B.5 Install qmail (OPTIONAL)
- II.B.6 Install Analog web file analyzer
- II.B.7 Install nspam
- II.B.8 Install Full Text Search
- II.B.9 Install Full Text Search using Tsearch2
- II.B.10 Install Full Text Search using OpenFTS (deprecated see tsearch2)
- II.B.11 Install nsopenssl
- II.B.12 Install tclwebtest.
- II.B.13 Install PHP for use in AOLserver
- II.B.14 Install Squirrelmail for use as a webmail system for OpenACS
- II.B.15 Install PAM Radius for use as external authentication
- II.B.16 Install LDAP for use as external authentication
- II.B.17 Install AOLserver 3.3oacs1
- II.C Credits
- II.C.1 Where did this document come from?
- II.C.2 Linux Install Guides
- II.C.3 Security Information
- II.C.4 Resources
- II.2 Installation Overview
- III For OpenACS Package Developers
- III.9 Development Tutorial
- III.9.1 Creating an Application Package
- III.9.2 Setting Up Database Objects
- III.9.3 Creating Web Pages
- III.9.4 Debugging and Automated Testing
- III.10 Advanced Topics
- III.10.1 Write the Requirements and Design Specs
- III.10.2 Add the new package to CVS
- III.10.3 OpenACS Edit This Page Templates
- III.10.4 Adding Comments
- III.10.5 Admin Pages
- III.10.6 Categories
- III.10.7 Profile your code
- III.10.8 Prepare the package for distribution.
- III.10.9 Distributing upgrades of your package
- III.10.10 Notifications
- III.10.11 Hierarchical data
- III.10.12 Using .vuh files for pretty urls
- III.10.13 Laying out a page with CSS instead of tables
- III.10.14 Sending HTML email from your application
- III.10.15 Basic Caching
- III.10.16 Scheduled Procedures
- III.10.17 Enabling WYSIWYG
- III.10.18 Adding in parameters for your package
- III.10.19 Writing upgrade scripts
- III.10.20 Connect to a second database
- III.10.21 Future Topics
- III.11 Development Reference
- III.11.1 OpenACS Packages
- III.11.2 OpenACS Data Models and the Object System
- III.11.3 The Request Processor
- III.11.4 The OpenACS Database Access API
- III.11.5 Using Templates in OpenACS
- III.11.6 Groups, Context, Permissions
- III.11.7 Writing OpenACS Application Pages
- III.11.8 Parties in OpenACS
- III.11.9 OpenACS Permissions Tediously Explained
- III.11.10 Object Identity
- III.11.11 Programming with AOLserver
- III.11.12 Using Form Builder: building html forms dynamically
- III.12 Engineering Standards
- III.12.1 OpenACS Style Guide
- III.12.2 Release Version Numbering
- III.12.3 Constraint naming standard
- III.12.4 ACS File Naming and Formatting Standards
- III.12.5 PL/SQL Standards
- III.12.6 Variables
- III.12.7 Automated Testing
- III.13 CVS Guidelines
- III.13.1 Using CVS with OpenACS
- III.13.2 OpenACS CVS Concepts
- III.13.3 Contributing code back to OpenACS
- III.13.4 Additional Resources for CVS
- III.14 Documentation Standards
- III.14.1 OpenACS Documentation Guide
- III.14.2 Using PSGML mode in Emacs
- III.14.3 Using nXML mode in Emacs
- III.14.4 Detailed Design Documentation Template
- III.14.5 System/Application Requirements Template
- III.15 TCLWebtest
- III.16 Internationalization
- III.16.1 Internationalization and Localization Overview
- III.16.2 How Internationalization/Localization works in OpenACS
- III.16.4 Design Notes
- III.16.5 Translator's Guide
- III.D Using CVS with an OpenACS Site
- III.9 Development Tutorial
- IV For OpenACS Platform Developers
- IV.17 Kernel Documentation
- IV.17.1 Overview
- IV.17.2 Object Model Requirements
- IV.17.3 Object Model Design
- IV.17.4 Permissions Requirements
- IV.17.5 Permissions Design
- IV.17.6 Groups Requirements
- IV.17.7 Groups Design
- IV.17.8 Subsites Requirements
- IV.17.9 Subsites Design Document
- IV.17.10 Package Manager Requirements
- IV.17.11 Package Manager Design
- IV.17.12 Database Access API
- IV.17.13 OpenACS Internationalization Requirements
- IV.17.14 Security Requirements
- IV.17.15 Security Design
- IV.17.16 Security Notes
- IV.17.17 Request Processor Requirements
- IV.17.18 Request Processor Design
- IV.17.19 Documenting Tcl Files: Page Contracts and Libraries
- IV.17.20 Bootstrapping OpenACS
- IV.17.21 External Authentication Requirements
- IV.18 Releasing OpenACS
- IV.18.1 OpenACS Core and .LRN
- IV.18.2 How to Update the OpenACS.org repository
- IV.18.3 How to package and release an OpenACS Package
- IV.18.4 How to Update the translations
- IV.17 Kernel Documentation
- V Tcl for Web Nerds
- V.1 Tcl for Web Nerds Introduction
- V.2 Basic String Operations
- V.3 List Operations
- V.4 Pattern matching
- V.5 Array Operations
- V.6 Numbers
- V.7 Control Structure
- V.8 Scope, Upvar and Uplevel
- V.9 File Operations
- V.10 Eval
- V.11 Exec
- V.12 Tcl for Web Use
- V.13 OpenACS conventions for TCL
- V.14 Solutions
- VI SQL for Web Nerds
- VI.1 SQL Tutorial
- VI.1.1 SQL Tutorial
- VI.1.2 Answers
- VI.2 SQL for Web Nerds Introduction
- VI.3 Data modeling
- VI.3.1 The Discussion Forum -- philg's personal odyssey
- VI.3.2 Data Types (Oracle)
- VI.3.4 Tables
- VI.3.5 Constraints
- VI.4 Simple queries
- VI.5 More complex queries
- VI.6 Transactions
- VI.7 Triggers
- VI.8 Views
- VI.9 Style
- VI.10 Escaping to the procedural world
- VI.11 Trees
- VI.1 SQL Tutorial
II.6.9 Diagnosing Performance Problems
-
Did performance problems happen overnight, or did they sneak up on you? Any clue what caused the performance problems (e.g. loading 20K users into .LRN)
-
Is the file system out of space? Is the machine swapping to disk constantly?
-
Isolating and solving database problems.
-
Without daily internal maintenance, most databases slowly degrade in performance. For PostGreSQL, see the section called âVacuum Postgres nightlyâ. For Oracle, use
exec dbms_stats.gather_schema_stats('SCHEMA_NAME')
(Andrew Piskorski's Oracle notes). -
You can track the exact amount of time each database query on a page takes:
-
Go to Main Site : Site-Wide Administration : Install Software
-
Click on "Install New Application" in "Install from OpenACS Repository"
-
Choose "ACS Developer Support">
-
After install is complete, restart the server.
-
Browse to Developer Support, which is automatically mounted at
/ds
. -
Turn on Database statistics
-
Browse directly to a slow page and click "Request Information" at the bottom of the page.
-
This should return a list of database queries on the page, including the exact query (so it can be cut-paste into psql or oracle) and the time each query took.
-
-
Identify a runaway Oracle query: first, use
ps aux
ortop
to get the UNIX process ID of a runaway Oracle process.Log in to SQL*Plus as the admin:
[$OPENACS_SERVICE_NAME ~]$ svrmgrl Oracle Server Manager Release 3.1.7.0.0 - Production Copyright (c) 1997, 1999, Oracle Corporation. All Rights Reserved. Oracle8i Enterprise Edition Release 8.1.7.3.0 - Production With the Partitioning option JServer Release 8.1.7.3.0 - Production SVRMGR>
connect internal
Password:See all of the running queries, and match the UNIX PID:
select p.spid -- The UNIX PID ,s.sid ,s.serial# ,p.username as os_user ,s.username ,s.status ,p.terminal ,p.program from v$session s ,v$process p where p.addr = s.paddr order by s.username ,p.spid ,s.sid ,s.serial# ;
See the SQL behind the oracle processes:
select s.username ,s.sid ,s.serial# ,sql.sql_text from v$session s, v$sqltext sql where sql.address = s.sql_address and sql.hash_value = s.sql_hash_value --and upper(s.username) like 'USERNAME%' order by s.username ,s.sid ,s.serial# ,sql.piece ;
To kill a troubled process:
alter system kill session 'SID,SERIAL#'; --substitute values for SID and SERIAL#
-
Identify a runaway Postgres query. First, logging must be enabled in the database. This imposes a performance penalty and should not be done in normal operation.
Edit the file
postgresql.conf
- its location depends on the PostGreSQL installation - and change#stats_command_string = false
to
stats_command_string = true
Next, connect to postgres (
psql service0
) andselect * from pg_stat_activity;
. Typical output should look like:datid | datname | procpid | usesysid | usename | current_query ----------+-------------+---------+----------+---------+----------------- 64344418 | openacs.org | 14122 | 101 | nsadmin | <IDLE> 64344418 | openacs.org | 14123 | 101 | nsadmin | delete from acs_mail_lite_queue where message_id = '2478608'; 64344418 | openacs.org | 14124 | 101 | nsadmin | <IDLE> 64344418 | openacs.org | 14137 | 101 | nsadmin | <IDLE> 64344418 | openacs.org | 14139 | 101 | nsadmin | <IDLE> 64344418 | openacs.org | 14309 | 101 | nsadmin | <IDLE> 64344418 | openacs.org | 14311 | 101 | nsadmin | <IDLE> 64344418 | openacs.org | 14549 | 101 | nsadmin | <IDLE> (8 rows) openacs.org=>
-
The first task is to create an appropriate environment for finding out what is going on inside Oracle. Oracle provides Statspack, a package to monitor and save the state of the v$ performance views. These reports help finding severe problems by exposing summary data about the Oracle wait interface, executed queries. You'll find the installation instructions in $ORACLE_HOME/rdbms/admin/spdoc.txt. Follow the instructions carefully and take periodic snapshots, this way you'll be able to look at historical performance data.
Also turn on the timed_statistics in your init.ora file, so that Statspack reports (and all other Oracle reports) are timed, which makes them a lot more meaningful. The overhead of timing data is about 1% per Oracle Support information.
To be able to get a overview of how Oracle executes a particular query, install "autotrace". I usually follow the instructions here http://asktom.oracle.com/~tkyte/article1/autotrace.html.
The Oracle Cost Based optimizer is a piece of software that tries to find the "optimal" execution plan for a given SQL statement. For that it estimates the costs of running a SQL query in a particular way (by default up to 80.000 permutations are being tested in a Oracle 8i). To get an adequate cost estimate, the CBO needs to have adequate statistics. For that Oracle supplies the dbms_stats package.