- 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
VI.4 Simple queries
If you start up SQL*Plus, you can start browsing around immediately with
the SELECT statement. You don't even need to define a table; Oracle
provides the built-in dual
table for times when you're
interested in a constant or a function:
... or to test your knowledge of three-valued logic (see the "Data Modeling" chapter):
SQL> select 'Hello World' from dual;
'HELLOWORLD
-----------
Hello World
SQL> select 2+2 from dual;
2+2
----------
4
SQL> select sysdate from dual;
SYSDATE
----------
1999-02-14
(any expression involving NULL evaluates to NULL).
SQL> select 4+NULL from dual;
4+NULL
----------
There is nothing magic about the dual
table for these
purposes; you can compute functions using the bboard
table
instead of dual
:
but not everyone wants 55010 copies of the same result. The
select sysdate,2+2,atan2(0, -1) from bboard;
SYSDATE 2+2 ATAN2(0,-1)
---------- ---------- -----------
1999-01-14 4 3.14159265
1999-01-14 4 3.14159265
1999-01-14 4 3.14159265
1999-01-14 4 3.14159265
...
1999-01-14 4 3.14159265
1999-01-14 4 3.14159265
1999-01-14 4 3.14159265
55010 rows selected.
dual
table is predefined during Oracle installation and,
though it is just a plain old table, it is guaranteed to contain only
one row because no user will have sufficient privileges to insert or
delete rows from dual
.
Getting beyond Hello World
To get beyond Hello World, pick a table of interest. As we saw in the introduction,would retrieve all the information from every row of theselect * from users;
users
table. That's good for toy systems but in any
production system, you'd be better off starting with
You don't really want to look at 7352 rows of data, but you would like to see what's in the users table, start off by asking SQL*Plus to query Oracle's data dictionary and figure out what columns are available in the
SQL> select count(*) from users;
COUNT(*)
----------
7352
users
table:
The data dictionary is simply a set of built-in tables that Oracle uses to store information about the objects (tables, triggers, etc.) that have been defined. Thus SQL*Plus isn't performing any black magic when you type
SQL> describe users
Name Null? Type
------------------------------- -------- ----
USER_ID NOT NULL NUMBER(38)
FIRST_NAMES NOT NULL VARCHAR2(100)
LAST_NAME NOT NULL VARCHAR2(100)
PRIV_NAME NUMBER(38)
EMAIL NOT NULL VARCHAR2(100)
PRIV_EMAIL NUMBER(38)
EMAIL_BOUNCING_P CHAR(1)
PASSWORD NOT NULL VARCHAR2(30)
URL VARCHAR2(200)
ON_VACATION_UNTIL DATE
LAST_VISIT DATE
SECOND_TO_LAST_VISIT DATE
REGISTRATION_DATE DATE
REGISTRATION_IP VARCHAR2(50)
ADMINISTRATOR_P CHAR(1)
DELETED_P CHAR(1)
BANNED_P CHAR(1)
BANNING_USER NUMBER(38)
BANNING_NOTE VARCHAR2(4000)
describe
; it is simply querying
user_tab_columns
, a view of some of the tables in Oracle's
data dictionary. You could do the same explicitly, but it is a little
cumbersome.
Here we've had to make sure to put the table name ("USERS") in all-uppercase. Oracle is case-insensitive for table and column names in queries but the data dictionary records names in uppercase. Now that we know the names of the columns in the table, it will be easy to explore.
column fancy_type format a20
select column_name, data_type || '(' || data_length || ')' as fancy_type
from user_tab_columns
where table_name = 'USERS'
order by column_id;
Simple Queries from One Table
A simple query from one table has the following structure:- the select list (which columns in our report)
- the name of the table
- the where clauses (which rows we want to see)
- the order by clauses (how we want the rows arranged)
The
SQL> select email
from users
where email like '%mit.edu';
------------------------------
philg@mit.edu
andy@california.mit.edu
ben@mit.edu
...
wollman@lcs.mit.edu
ghomsy@mit.edu
hal@mit.edu
...
jpearce@mit.edu
richmond@alum.mit.edu
andy_roo@mit.edu
kov@mit.edu
fletch@mit.edu
lsandon@mit.edu
psz@mit.edu
philg@ai.mit.edu
philg@martigny.ai.mit.edu
andy@californnia.mit.edu
ty@mit.edu
teadams@mit.edu
68 rows selected.
email like '%mit.edu'
says "every row where the email
column ends in 'mit.edu'". The percent sign is Oracle's wildcard
character for "zero or more characters". Underscore is the wildcard for
"exactly one character":
Suppose that we notice in the above report some similar email addresses. It is perhaps time to try out the ORDER BY clause:
SQL> select email
from users
where email like '___@mit.edu';
------------------------------
kov@mit.edu
hal@mit.edu
...
ben@mit.edu
psz@mit.edu
Now we can see that this users table was generated by grinding over pre-ArsDigita Community Systems postings starting from 1995. In those bad old days, users typed their email address and name with each posting. Due to typos and people intentionally choosing to use different addresses at various times, we can see that we'll have to build some sort of application to help human beings merge some of the rows in the users table (e.g., all three occurrences of "philg" are in fact the same person (me)).
SQL> select email
from users
where email like '%mit.edu'
order by email;
------------------------------
andy@california.mit.edu
andy@californnia.mit.edu
andy_roo@mit.edu
...
ben@mit.edu
...
hal@mit.edu
...
philg@ai.mit.edu
philg@martigny.ai.mit.edu
philg@mit.edu
Restricting results
Suppose that you were featured on Yahoo in September 1998 and want to see how many users signed up during that month:We've combined two restrictions in the WHERE clause with an AND. We can add another restriction with another AND:
SQL> select count(*)
from users
where registration_date >= '1998-09-01'
and registration_date < '1998-10-01';
COUNT(*)
----------
920
OR and NOT are also available within the WHERE clause. For example, the following query will tell us how many classified ads we have that either have no expiration date or whose expiration date is later than the current date/time.
SQL> select count(*)
from users
where registration_date >= '1998-09-01'
and registration_date < '1998-10-01'
and email like '%mit.edu';
COUNT(*)
----------
35
select count(*)
from classified_ads
where expires >= sysdate
or expires is null;
Subqueries
You can query one table, restricting the rows returned based on information from another table. For example, to find users who have posted at least one classified ad:Conceptually, for each row in the
select user_id, email
from users
where 0 < (select count(*)
from classified_ads
where classified_ads.user_id = users.user_id);
USER_ID EMAIL
---------- -----------------------------------
42485 twm@meteor.com
42489 trunghau@ecst.csuchico.edu
42389 ricardo.carvajal@kbs.msu.edu
42393 gon2foto@gte.net
42399 rob@hawaii.rr.com
42453 stefan9@ix.netcom.com
42346 silverman@pon.net
42153 gallen@wesleyan.edu
...
users
table Oracle is
running the subquery against classified_ads
to see how many
ads are associated with that particular user ID. Keep in mind that this
is only conceptually; the Oracle SQL parser may elect to
execute this query in a more efficient manner.
Another way to describe the same result set is using EXISTS:
This may be more efficient for Oracle to execute since it hasn't been instructed to actually count the number of classified ads for each user, but only to check and see if any are present. Think of EXISTS as a Boolean function that
select user_id, email
from users
where exists (select 1
from classified_ads
where classified_ads.user_id = users.user_id);
- takes a SQL query as its only parameter
- returns TRUE if the query returns any rows at all, regardless of the contents of those rows (this is why we can use the constant 1 as the select list for the subquery)
JOIN
A professional SQL programmer would be unlikely to query for users who'd posted classified ads in the preceding manner. The SQL programmer knows that, inevitably, the publisher will want information from the classified ad table along with the information from the users table. For example, we might want to see the users and, for each user, the sequence of ad postings:Because of the JOIN restriction,
select users.user_id, users.email, classified_ads.posted
from users, classified_ads
where users.user_id = classified_ads.user_id
order by users.email, posted;
USER_ID EMAIL POSTED
---------- ----------------------------------- ----------
39406 102140.1200@compuserve.com 1998-09-30
39406 102140.1200@compuserve.com 1998-10-08
39406 102140.1200@compuserve.com 1998-10-08
39842 102144.2651@compuserve.com 1998-07-02
39842 102144.2651@compuserve.com 1998-07-06
39842 102144.2651@compuserve.com 1998-12-13
...
41284 yme@inetport.com 1998-01-25
41284 yme@inetport.com 1998-02-18
41284 yme@inetport.com 1998-03-08
35389 zhupanov@usa.net 1998-12-10
35389 zhupanov@usa.net 1998-12-10
35389 zhupanov@usa.net 1998-12-10
where users.user_id =
classified_ads.user_id
, we only see those users who have posted
at least one classified ad, i.e., for whom a matching row may be found
in the classified_ads
table. This has the same effect as
the subquery above.
The order by users.email, posted
is key to making sure that
the rows are lumped together by user and then printed in order of
ascending posting time.
OUTER JOIN
Suppose that we want an alphabetical list of all of our users, with classified ad posting dates for those users who have posted classifieds. We can't do a simple JOIN because that will exclude users who haven't posted any ads. What we need is an OUTER JOIN, where Oracle will "stick in NULLs" if it can't find a corresponding row in theclassified_ads
table.
The plus sign after
select users.user_id, users.email, classified_ads.posted
from users, classified_ads
where users.user_id = classified_ads.user_id(+)
order by users.email, posted;
...
USER_ID EMAIL POSTED
---------- ----------------------------------- ----------
52790 dbrager@mindspring.com
37461 dbraun@scdt.intel.com
52791 dbrenner@flash.net
47177 dbronz@free.polbox.pl
37296 dbrouse@enter.net
47178 dbrown@cyberhighway.net
36985 dbrown@uniden.com 1998-03-05
36985 dbrown@uniden.com 1998-03-10
34283 dbs117@amaze.net
52792 dbsikorski@yahoo.com
...
classified_ads.user_id
is our
instruction to Oracle to "add NULL rows if you can't meet this JOIN
constraint".
Extending a simple query into a JOIN
Suppose that you have a query from one table returning almost everything that you need, except for one column that's in another table. Here's a way to develop the JOIN without risking breaking your application:- add the new table to your FROM clause
- add a WHERE constraint to prevent Oracle from building a Cartesian product
- hunt for ambiguous column names in the SELECT list and other portions of the query; prefix these with table names if necessary
- test that you've not broken anything in your zeal to add additional info
- add a new column to the SELECT list
rooms
and
reservations
. The top level page is supposed to show
a user what reservations he or she is current holding:
This produces an unacceptable page because the rooms are referred to by an ID number rather than by name. The name information is in the
select room_id, start_time, end_time
from reservations
where user_id = 37
rooms
table, so we'll have to turn this into a JOIN.
Step 1: add the new table to the FROM clause
We're in a world of hurt because Oracle is now going to join every row in
select room_id, start_time, end_time
from reservations, rooms
where user_id = 37
rooms
with every row in reservations
where
the user_id
matches that of the logged-in user.
Step 2: add a constraint to the WHERE clause
select room_id, start_time, end_time
from reservations, rooms
where user_id = 37
and reservations.room_id = rooms.room_id
Step 3: look for ambiguously defined columns
Bothreservations
and rooms
contain columns
called "room_id". So we need to prefix the room_id
column
in the SELECT list with "reservations.". Note that we don't have to prefix
start_time
and end_time
because these columns
are only present in reservations
.
select reservations.room_id, start_time, end_time
from reservations, rooms
where user_id = 37
and reservations.room_id = rooms.room_id
Step 4: test
Test the query to make sure that you haven't broken anything. You should get back the same rows with the same columns as before.
Step 5: add a new column to the SELECT list
We're finally ready to do what we set out to do: addroom_name
to the list of columns for which we're querying.
select reservations.room_id, start_time, end_time, rooms.room_name
from reservations, rooms
where user_id = 37
and reservations.room_id = rooms.room_id
Reference
- Oracle8 Server SQL Reference, SELECT command section
---
based on SQL for Web Nerds