9.5 Assigning Values to and from RecordsYou can modify the values in a record in the following ways:
These assignment methods are described in the sections that follow. 9.5.1 Direct Field Assignment
The assignment operator ( top_customer_rec.total_sales := 0; report_rec.output_generated := check_report_status (report_rec.report_id); In the next example I create a record based on the rain_forest_history table, populate it with values, and then insert a record into that same table:
9.5.2 SELECT INTO from an Implicit CursorUse the implicit cursor SELECT INTO to fill the values in a record. You can SELECT INTO either the record as a whole or the individual fields in the record:
If you SELECT INTO a record, you must be sure that the structure of the select list (columns or expressions) matches that of the record. The INTO clause of an implicit query is the only part of a SQL DML statement in which a PL/SQL record (as an aggregate and not its component fields) can be referenced. 9.5.3 FETCH INTO from an Explicit CursorUse an explicit cursor to FETCH values INTO a record. You can FETCH INTO the record as a whole or into the individual fields in the record:
If you FETCH INTO the record without specifying the fields, you must be sure that the structure of the cursor's select list (columns or expressions) matches that of the record. 9.5.4 Aggregate Assignment
In this last and most powerful approach to record assignments, I change all the values of the record once, through an aggregate assignment or assignment of the group. When you SELECT INTO the entire record without listing its individual fields, you perform a type of aggregate assignment. But you can also change the values of every field in a record simultaneously with the assignment operator ( DECLARE prev_rain_forest_rec rain_forest_history%ROWTYPE; curr_rain_forest_rec rain_forest_history%ROWTYPE; BEGIN ... initialize previous year rain forest data ... -- Transfer data from previous to current records. curr_rain_forest_rec := prev_rain_forest_rec; The result of this aggregate assignment is that the value of each field in the current record is set to the value of the corresponding field record in the previous record. I could also have accomplished this with individual direct assignments from the previous to current records. This would require four separate assignments and lots of typing: curr_rain_forest_rec.country_code := prev_rain_forest_rec.country_code; curr_rain_forest_rec.analysis_date := prev_rain_forest_rec.analysis_date; curr_rain_forest_rec.size_in_acres := prev_rain_forest_rec.size_in_acres; curr_rain_forest_rec.species_lost := prev_rain_forest_rec.species_lost; Which of these two types of assignments would you rather code? Which would you rather have to maintain? I was able to perform this aggregate assignment because both of the records were based on the same rowtype. If the records are not compatible in this way, your assignment will not compile. The next section on record types and record compatibility explores the restrictions on use of aggregate assignments and other record operations.
Copyright (c) 2000 O'Reilly & Associates. All rights reserved. |
|