ヘッダーをスキップ
Oracle Rdb SQLリファレンス・マニュアル
リリース7.2
E06178-01
  目次
目次
索引
索引

戻る
戻る
 
次へ
次へ
 

表示されるリテラルの数はUSING句の列数と同じである必要があります。リテラルのデータ型は列のデータ型と一致する必要があります。文字の列の場合は、リテラルを一重引用符で囲みます。

WITH LIMIT OF句の値は、最初の格納時の行の配置にのみ影響します。UPDATE文によって行のデータが変更されUSING句で指定した列の値がWITH LIMIT OF句に指定された値を超えた場合、その行は別の記憶域に移動されません。


使用方法


例1: 複数ファイルのデータベースの記憶域マップの定義

この例では、複数ファイルのデータベースの記憶域マップの定義を示します。CREATE STORAGE MAP文で指定されている表は、サンプル・データベースのものと同じ定義を持ちます。この例で参照された記憶域を作成するCREATE STORAGE AREA句を指定したCREATE DATABASE文の例は、「CREATE STORAGE AREA句」を参照してください。


SQL> -- Declare the database as the default:
SQL> ATTACH 'FILENAME multifile_example';
SQL> --
SQL> CREATE STORAGE MAP EMPLOYEE_MAP FOR EMPLOYEES
cont> STORE USING (EMPLOYEE_ID)
cont>   IN EMPID_LOW WITH LIMIT OF ('00200')
cont>   IN EMPID_MID WITH LIMIT OF ('00500')
cont>   OTHERWISE IN EMPID_OVER;
SQL> --
SQL> CREATE STORAGE MAP RESUME_MAP
cont> STORE LISTS IN EMP_INFO FOR (TABLE1, TABLE2, TABLE3)
cont>       IN RDB$SYSTEM;
SQL> --
SQL> CREATE STORAGE MAP JOB_HISTORY_MAP FOR JOB_HISTORY
cont> STORE IN HISTORIES;
SQL> --
SQL> CREATE STORAGE MAP SALARY_HISTORY_MAP FOR SALARY_HISTORY
cont> STORE IN HISTORIES;
SQL> --
SQL> CREATE STORAGE MAP JOBS_MAP FOR JOBS
cont> STORE IN CODES;
SQL> --
SQL> CREATE STORAGE MAP DEPARTMENTS_MAP FOR DEPARTMENTS
cont> STORE IN CODES;
SQL> --
SQL> CREATE STORAGE MAP COLLEGES_MAP FOR COLLEGES
cont> STORE IN CODES;
SQL> --
SQL> CREATE STORAGE MAP DEGREES_MAP FOR DEGREES
cont> STORE IN EMP_INFO;
SQL> --
SQL> CREATE STORAGE MAP WORK_STATUS_MAP FOR WORK_STATUS
cont> STORE IN HISTORIES;
SQL> --
SQL> --
SQL> -COMMIT;
SQL> --

例2: 均一記憶域に対してしきい値を設定およびオーバーライドする記憶域マップの定義


SQL> CREATE DATABASE FILENAME birdlist
cont>     CREATE STORAGE AREA AREA1
cont>     CREATE STORAGE AREA AREA2
cont>     CREATE STORAGE AREA AREA3
cont>     CREATE STORAGE AREA AREA4
cont>     CREATE TABLE SPECIES
cont>       ( GENUS          CHAR (30),
cont>         SPECIES        CHAR (30),
cont>         COMMON_NAME    CHAR (40),
cont>         FAMILY_NUMBER  INT (3),
cont>         SPECIES_NUMBER INT (3)
cont>       )
cont>     CREATE INDEX I1 ON SPECIES (FAMILY_NUMBER)
cont>     CREATE TABLE SIGHTING
cont>       ( SPECIES_NUMBER INT (3),
cont>         COMMON_NAME    CHAR (40),
cont>         CITY           CHAR (20),
cont>         STATE          CHAR (20),
cont>         SIGHTING_DATE  DATE ANSI,
cont>         NOTES_NUMBER   INT (5))
cont>     CREATE INDEX I2 ON SIGHTING (SPECIES_NUMBER)
cont>     CREATE TABLE FIELD_NOTES
cont>       ( WEATHER        CHAR (30),
cont>         TIDE           CHAR (15),
cont>         SPECIES_NUMBER INT (3),
cont>         SIGHTING_TIME  TIMESTAMP(2),
cont>         NOTES          CHAR (500),
cont>         NOTES_NUMBER   INT (5))
cont>     CREATE INDEX I3 ON FIELD_NOTES (NOTES_NUMBER)
cont> ;
SQL> --
SQL> -- The following CREATE STORAGE MAP statements place and
SQL> -- override thresholds on uniform storage area.
SQL> --
SQL> -- Note that the default threshold clause for the
SQL> -- storage map is not enclosed in parentheses, but each
SQL> -- threshold clause associated with a particular area is.
SQL> --
SQL> CREATE STORAGE MAP M1 FOR SPECIES
cont>     THRESHOLDS ARE (30, 50, 80)
cont>     ENABLE COMPRESSION
cont>     PLACEMENT VIA INDEX I1
cont>     STORE
cont>         IN AREA1
cont>             (THRESHOLD (10) );
SQL> --
SQL> CREATE STORAGE MAP M2 FOR SIGHTING
cont>   THRESHOLD IS (40)
cont>     STORE
cont>   RANDOMLY ACROSS (
cont>       AREA1 (THRESHOLD OF (10) ),
cont>       AREA2 (THRESHOLDS ARE (30, 50, 98) ),
cont>       AREA3
cont>   );
SQL> --
SQL> CREATE STORAGE MAP M3 FOR FIELD_NOTES
cont>   THRESHOLDS OF (50,70,90)
cont>     STORE
cont>       USING (SPECIES_NUMBER, NOTES_NUMBER)
cont>           IN AREA1
cont>               (THRESHOLDS OF (20, 80, 90) )
cont>               WITH LIMIT OF (30, 88)
cont>           IN AREA2
cont>               WITH LIMIT OF (40, 89)
cont>           IN AREA3
cont>               WITH LIMIT OF (50, 90)
cont>           OTHERWISE IN AREA4
cont>               (THRESHOLDS ARE (20, 30, 40));
SQL> --
SQL> SHOW STORAGE MAP *;
User Storage Maps in database with filename birdlist
     M1
 For Table:  SPECIES
 Placement Via Index: I1
 Partitioning is: UPDATABLE
 Store clause:  STORE
        IN AREA1
            (THRESHOLD (10) )

 Partition information for storage map:
 Compression is: ENABLED
  Partition: (1) SYS_P00062
   Storage Area: AREA1

     M2
 For Table:  SIGHTING
 Partitioning is: UPDATABLE
 Store clause:  STORE
  RANDOMLY ACROSS (
      AREA1 (THRESHOLD OF (10) ),
      AREA2 (THRESHOLDS ARE (30, 50, 98) ),
      AREA3
  )

 Partition information for storage map:
 Compression is: ENABLED
  Partition: (1) SYS_P00063
   Storage Area: AREA1
  Partition: (2) SYS_P00064
   Storage Area: AREA2
  Partition: (3) SYS_P00065
   Storage Area: AREA3

     M3
 For Table:  FIELD_NOTES
 Partitioning is: UPDATABLE
 Store clause:  STORE
      USING (SPECIES_NUMBER, NOTES_NUMBER)
          IN AREA1
              (THRESHOLDS OF (20, 80, 90) )
              WITH LIMIT OF (30, 88)
          IN AREA2
              WITH LIMIT OF (40, 89)
          IN AREA3
              WITH LIMIT OF (50, 90)
          OTHERWISE IN AREA4
              (THRESHOLDS ARE (20, 30, 40))

 Partition information for storage map:
 Compression is: ENABLED
  Partition: (1) SYS_P00066
   Storage Area: AREA1
  Partition: (2) SYS_P00067
   Storage Area: AREA2
  Partition: (3) SYS_P00068
   Storage Area: AREA3
  Partition: (4) SYS_P00069
   Storage Area: AREA4

SQL> --
SQL> ROLLBACK;

例3: リストを格納する記憶域マップの作成

この例では、特定の記憶域にリストを格納する記憶域マップを作成します。


SQL> CREATE DATABASE FILENAME test
cont> CREATE STORAGE AREA LISTS1 PAGE FORMAT IS MIXED
cont> CREATE STORAGE AREA LISTS2 PAGE FORMAT IS MIXED
cont>
cont> CREATE TABLE EMPLOYEES
cont>    (EMP_ID CHAR(5),
cont>     RESUME LIST OF BYTE VARYING);
SQL> --
SQL>  CREATE STORAGE MAP LISTS_MAP
cont>     STORE LISTS IN
cont>     (LISTS1,LISTS2) FOR (EMPLOYEES.RESUME)
cont>      FILL SEQUENTIALLY
cont>      IN RDB$SYSTEM;

例4: 代替マップの作成

記憶域マップに続くこの例では、同じMF_PERSONNELデータベースのEMPLOYEES表の代替マッピングを示します。


SQL> create storage map EMPLOYEES_MAP
cont>     for EMPLOYEES
cont>     placement via index EMPLOYEES_HASH
cont>     -- store the primary information horizontally partitioned
cont>     -- across the areas EMPIDS_LOW, EMPIDS_MID and EMPIDS_OVER
cont>     -- disable compress because these columns are accessed often
cont>     store
cont>         columns (EMPLOYEE_ID, LAST_NAME,
cont>                   FIRST_NAME, MIDDLE_INITIAL)
cont>         disable compression
cont>         using (EMPLOYEE_ID)
cont>             in EMPIDS_LOW
cont>                 with limit of ('00200')
cont>             in EMPIDS_MID
cont>                 with limit of ('00400')
cont>             otherwise in EMPIDS_OVER
cont>
cont>     -- place all the address information in EMP_INFO
cont>     -- make sure these character columns are compressed
cont>     -- to remove the trailing spaces
cont>     store
cont>         columns (ADDRESS_DATA_1, ADDRESS_DATA_2, CITY, STATE,
cont>                  POSTAL_CODE)
cont>         enable compression
cont>         in EMP_INFO
cont>
cont>     -- the remaining columns get
cont>     -- written randomly over these areas
cont>     store
cont>         enable compression
cont>         randomly across (SALARY_HISTORY, JOBS);

例5: 水平パーティションおよび垂直パーティションのロギングおよび名前付けの無効化


SQL> CREATE DATABASE FILENAME birdlist
cont>     CREATE STORAGE AREA AREA1
cont>     CREATE STORAGE AREA AREA2
cont>     CREATE STORAGE AREA AREA3
cont>     CREATE STORAGE AREA AREA4
cont>     CREATE STORAGE AREA AREA5
cont>     CREATE STORAGE AREA AREA6
cont>     CREATE STORAGE AREA AREA7
cont>     CREATE STORAGE AREA AREA8
cont>     CREATE TABLE SPECIES
cont>   ( GENUS          CHAR (30),
cont>     SPECIES        CHAR (30),
cont>     COMMON_NAME    CHAR (40),
cont>     FAMILY_NUMBER  INT (3),
cont>     SPECIES_NUMBER INT (3)
cont>   )
cont>     CREATE INDEX I1 ON SPECIES (FAMILY_NUMBER)
cont>     CREATE TABLE SIGHTING
cont>   ( SPECIES_NUMBER INT (3),
cont>     COMMON_NAME    CHAR (40),
cont>     CITY  CHAR (20),
cont>     STATE CHAR (20),
cont>     SIGHTING_DATE  DATE ANSI,
cont>     NOTES_NUMBER INT (5))
cont>     CREATE INDEX I2 ON SIGHTING (SPECIES_NUMBER)
cont>     CREATE TABLE FIELD_NOTES
cont>   ( WEATHER CHAR (30),
cont>     TIDE CHAR (15),
cont>     SIGHTING_TIME TIMESTAMP(2),
cont>     NOTES CHAR (500),
cont>     NOTES_NUMBER INT (5),
cont>     SPECIES_NUMBER INT (3))
cont>     CREATE INDEX I3 ON FIELD_NOTES (NOTES_NUMBER);
SQL> --
SQL> -- Note that the default threshold clause for the
SQL> -- storage map is not enclosed in parentheses, but each
SQL> -- threshold clause associated with a particular area is enclosed
SQL> -- in parentheses.
SQL> --
SQL> CREATE STORAGE MAP M1 FOR SPECIES
cont>     THRESHOLDS ARE (30, 50, 80)
cont>     ENABLE COMPRESSION
cont>     PLACEMENT VIA INDEX I1
cont>     NOLOGGING
cont>     COMMENT IS 'Storage Map for Species'
cont>     STORE
cont>   IN AREA1
cont>       (THRESHOLD (10),
cont>        PARTITION AREA1,
cont>        COMMENT IS 'Partition is AREA1');
SQL> --
SQL> CREATE STORAGE MAP M2 FOR SIGHTING
cont>   THRESHOLD IS (40)
cont>     STORE
cont>   RANDOMLY ACROSS (
cont>       AREA1 (THRESHOLD OF (10),
cont>       PARTITION AREA1),
cont>       AREA2 (THRESHOLDS ARE (30, 50, 98),
cont>       PARTITION AREA2),
cont>       AREA3 (PARTITION AREA3)
cont>   );
SQL> --
SQL> CREATE STORAGE MAP M3 FOR FIELD_NOTES
cont>   THRESHOLDS OF (50,70,90)
cont>     STORE COLUMNS (WEATHER, TIDE, SIGHTING_TIME)
cont>     VERTICAL PARTITION WEATHER_TIDE_SIGHTINGTIME
cont>   USING (SPECIES_NUMBER, NOTES_NUMBER)
cont>       IN AREA1
cont>           (THRESHOLDS OF (20, 80, 90) )
cont>           WITH LIMIT OF (30, 88)
cont>       IN AREA2
cont>           WITH LIMIT OF (40, 89)
cont>       IN AREA3
cont>           WITH LIMIT OF (50, 90)
cont>       OTHERWISE IN AREA4
cont>           (THRESHOLDS ARE (20, 30, 40))
cont>   STORE COLUMNS (NOTES, NOTES_NUMBER, SPECIES_NUMBER)
cont>    VERTICAL PARTITION NOTES_NOTESNUM_SPECIESNUM
cont>    USING (SPECIES_NUMBER)
cont>       IN AREA5
cont>           (THRESHOLDS OF (20, 80, 90) )
cont>           WITH LIMIT OF (30)
cont>       IN AREA6
cont>           WITH LIMIT OF (40)
cont>       IN AREA7
cont>           WITH LIMIT OF (50)
cont>       OTHERWISE IN AREA8
cont>           (THRESHOLDS ARE (20, 30, 40));

例6: データを含む表の記憶域マップの作成


SQL> -- Create table, insert data, and then create a storage map.
SQL> --
SQL> CREATE TABLE MAP_TEST2 (a INTEGER, b CHAR(10));
SQL> INSERT INTO MAP_TEST2 (a, b) VALUES (2, 'Second');
1 row inserted
SQL> CREATE STORAGE MAP MAP_TEST2_MAP FOR MAP_TEST2
cont>     STORE IN RDB$SYSTEM;
SQL> INSERT INTO MAP_TEST2 (a, b) VALUES (22, 'Second2');
1 row inserted
SQL> COMMIT;
SQL> SELECT *,DBKEY FROM MAP_TEST2;
           A   B                             DBKEY
           2   Second                     90:809:0
          22   Second2                    90:809:1
2 rows selected
SQL>
SQL> -- Now alter the storage map and
SQL> -- place it in a different storage area.
SQL>
SQL> ALTER STORAGE MAP MAP_TEST2_MAP
cont>     STORE IN TEST_AREA2;
SQL> COMMIT;
SQL> SELECT *,DBKEY FROM MAP_TEST2;
           A   B                             DBKEY
           2   Second                      91:11:0
          22   Second2                     91:11:1
2 rows selected
SQL>

例7: 無効な記憶域マップ作成の試行


SQL> -- Create table, insert data, and then
SQL> -- create a storage map with invalid attributes.
SQL>
SQL> CREATE TABLE MAP_TEST3 (a INTEGER, b CHAR(10));
SQL> CREATE INDEX MAP_TEST3_INDEX ON MAP_TEST3 (a);
SQL> INSERT INTO MAP_TEST3 (a, b) VALUES (3, 'Third');
1 row inserted
SQL>
SQL> CREATE STORAGE MAP MAP_TEST3_MAP FOR MAP_TEST3
cont>     STORE IN TEST_AREA1;            -- Must be the default area.
%RDB-E-NO_META_UPDATE, metadata update failed
-RDMS-F-RELNOTEMPTY, table "MAP_TEST3" has data in it
-RDMS-E-NOCMPLXMAP, can not use complex map for non-empty table
SQL>
SQL> CREATE STORAGE MAP MAP_TEST3_MAP for MAP_TEST3
cont>     PLACEMENT VIA INDEX MAP_TEST3_INDEX   -- Can't use placement.
cont>     STORE IN RDB$SYSTEM;
%RDB-E-NO_META_UPDATE, metadata update failed
-RDMS-F-RELNOTEMPTY, table "MAP_TEST3" has data in it
-RDMS-E-NOCMPLXMAP, can not use complex map for non-empty table
SQL>
SQL> CREATE STORAGE MAP MAP_TEST3_MAP FOR MAP_TEST3
cont>     DISABLE COMPRESSION               -- Can't change compression.
cont>     STORE IN RDB$SYSTEM;
%RDB-E-NO_META_UPDATE, metadata update failed
-RDMS-F-RELNOTEMPTY, table "MAP_TEST3" has data in it
-RDMS-E-NOCMPLXMAP, can not use complex map for non-empty table
SQL>
SQL> CREATE STORAGE MAP MAP_TEST3_MAP for MAP_TEST3
cont>     THRESHOLDS ARE (50, 60, 70)        -- Can't change thresholds.
cont>     STORE IN RDB$SYSTEM;
%RDB-E-NO_META_UPDATE, metadata update failed
-RDMS-F-RELNOTEMPTY, table "MAP_TEST3" has data in it
-RDMS-E-NOCMPLXMAP, can not use complex map for non-empty table
SQL>
SQL> CREATE STORAGE MAP MAP_TEST3_MAP FOR MAP_TEST3
cont>     STORE ACROSS (RDB$SYSTEM, TEST_AREA2);-- Can't use more than one area.
%RDB-E-NO_META_UPDATE, metadata update failed
-RDMS-F-RELNOTEMPTY, table "MAP_TEST3" has data in it
-RDMS-E-NOCMPLXMAP, can not use complex map for non-empty table
SQL>
SQL> CREATE STORAGE MAP MAP_TEST3_MAP for MAP_TEST3
cont>     STORE COLUMNS (a) in RDB$SYSTEM       -- Can't vertically partition.
cont>     STORE COLUMNS (b) in TEST_AREA2;
%RDB-E-NO_META_UPDATE, metadata update failed
-RDMS-F-RELNOTEMPTY, table "MAP_TEST3" has data in it
-RDMS-E-NOCMPLXMAP, can not use complex map for non-empty table

例8: RMU Extractコマンドを使用したWITH LIMIT OF式の表示

STORE句のWITH LIMIT OF句は、Oracle Rdbが使用するブール式に変換され、挿入されたデータを正しい記憶域に転送します。RMU Extractコマンドを使用すると、これらのブール式を表示できます。次の例に示すように、Item=STORAGE_MAPL修飾子およびOption=FULL修飾子を使用します。


$ RMU/EXTRACT-
_$ /ITEM=STORAGE_MAP-
_$ /OPTION=(MATCH:EMPLOYEES_MAP%,NOHEADER,FULL,FILENAME_ONLY) -
_$ DB$:MF_PERSONNEL
set verify;
set language ENGLISH;
set default date format 'SQL92';
set quoting rules 'SQL92';
set date format DATE 001, TIME 001;
attach 'filename MF_PERSONNEL.RDB';
create storage map EMPLOYEES_MAP
    for EMPLOYEES
    comment is
      ' employees partitioned by "00200" "00400"'
    placement via index EMPLOYEES_HASH
    store
        using (EMPLOYEE_ID)
        -- Partition:
        --        (EMPLOYEE_ID <= '00200')
            in EMPIDS_LOW
                with limit of ('00200')
        -- Partition:
        --        (EMPLOYEE_ID <= '00400')
            in EMPIDS_MID
                with limit of ('00400')
            otherwise in EMPIDS_OVER;

commit work;

例9: SQLマッピング・ルーチン

この例では、記憶域マップのWITH LIMIT OF句に一致するCREATE STORAGE MAP文によって作成されたSQLマッピング・ルーチンを示します。


SQL> create table EMPLOYEES (
cont>     EMPLOYEE_ID      CHAR (5),
cont>     LAST_NAME        CHAR (14),
cont>     FIRST_NAME       CHAR (10),
cont>     MIDDLE_INITIAL   CHAR (1),
cont>     ADDRESS_DATA_1   CHAR (25),
cont>     ADDRESS_DATA_2   CHAR (25),
cont>     CITY             CHAR (20),
cont>     STATE            CHAR (2),
cont>     POSTAL_CODE      CHAR (5),
cont>     SEX              CHAR (1),
cont>     BIRTHDAY         DATE VMS,
cont>     STATUS_CODE      CHAR (1));
SQL>
SQL>     create storage map EMPLOYEES_MAP
cont>         for EMPLOYEES
cont>         comment is
cont>           ' employees partitioned by "00200" "00400"'
cont>         store
cont>             using (EMPLOYEE_ID)
cont>                 in EMPIDS_LOW
cont>                     with limit of ('00200')
cont>                 in EMPIDS_MID
cont>                     with limit of ('00400')
cont>                 otherwise in EMPIDS_OVER;
SQL>
SQL> commit work;
SQL>
SQL> show system modules;
Modules in database with filename MF_PERSONNEL
     RDB$STORAGE_MAPS
SQL>
SQL> show system functions;
Functions in database with filename MF_PERSONNEL
     EMPLOYEES_MAP
SQL>
SQL> show system function EMPLOYEES_MAP;
Information for function EMPLOYEES_MAP

 Function ID is: -2
 Source:
return
    case
        when (:EMPLOYEE_ID <= '00200') then 1
        when (:EMPLOYEE_ID <= '00400') then 2
        else 3
    end case;
 Comment:       Return value for select partition - range 1 .. 3
 Module name is: RDB$STORAGE_MAPS
 Module ID is: -1
 Number of parameters is: 1

Parameter Name                  Data Type        Domain or Type
--------------                  ---------        --------------
                                INTEGER
        Function result datatype
        Return value is passed by value

EMPLOYEE_ID                     CHAR(5)
        Parameter position is 1
        Parameter is IN (read)
        Parameter is passed by reference

例10: LIST記憶域マップの記憶域属性の使用

次の例では、LIST記憶域マップの記憶域属性の使用方法を示します。記憶域属性は、記憶域名の直後にある必要があります(表の記憶域マップを参照)。


SQL> create database
cont>     filename 'DB$:MULTIMEDIA'
cont>
cont>     create storage area PHOTO_AREA1
cont>         filename 'DB$:PHOTO_AREA1'
cont>         page format UNIFORM
cont>
cont>     create storage area PHOTO_AREA2
cont>         filename 'DB$:PHOTO_AREA2'
cont>         page format UNIFORM
cont>
cont>     create storage area TEXT_AREA
cont>         filename 'DB$:TEXT_AREA'
cont>         page format UNIFORM
cont>
cont>     create storage area AUDIO_AREA
cont>         filename 'DB$:AUDIO_AREA'
cont>         page format UNIFORM
cont>
cont>     create storage area DATA_AREA
cont>         filename 'DB$:DATA_AREA'
cont>         page format UNIFORM
cont> ;
SQL>
SQL> create table EMPLOYEES
cont>     (name       char(30),
cont>      dob        date,
cont>      ident      integer,
cont>      photograph list of byte varying (4096) as binary,
cont>      resume     list of byte varying (132) as text,
cont>      review     list of byte varying (80) as text,
cont>      voiceprint list of byte varying (4096) as binary
cont>     );
SQL>
SQL> create storage map EMPLOYEES_MAP
cont>     for EMPLOYEES
cont>     enable compression
cont>     store in DATA_AREA;
SQL>
SQL> create storage map LISTS_MAP
cont>     store lists
cont>         in AUDIO_AREA
cont>                 (thresholds are (89, 99, 100)
cont>                 ,comment is 'The voice clips'
cont>                 ,partition AUDIO_STUFF)
cont>             for (employees.voiceprint)
cont>         in TEXT_AREA
cont>                 (thresholds is (99)
cont>                 ,partition TEXT_DOCUMENTS)
cont>             for (employees.resume, employees.review)
cont>         in (PHOTO_AREA1
cont>                 (comment is 'Happy Smiling Faces?'
cont>                 ,threshold is (99)
cont>                 ,partition PHOTOGRAPHIC_IMAGES_1)
cont>             ,PHOTO_AREA2
cont>                 (comment is 'Happy Smiling Faces?'
cont>                 ,threshold is (99)
cont>                 ,partition PHOTOGRAPHIC_IMAGES_2)
cont>             )
cont>             for (employees.photograph)
cont>             fill randomly
cont>         in RDB$SYSTEM
cont>                 (partition SYSTEM_LARGE_OBJECTS);
SQL>
SQL> show storage map LISTS_MAP;
     LISTS_MAP
 For Lists
 Store clause:          STORE lists
        in AUDIO_AREA
                (thresholds are (89, 99, 100)
                ,comment is 'The voice clips'
                ,partition AUDIO_STUFF)
            for (employees.voiceprint)
        in TEXT_AREA
                (thresholds is (99)
                ,partition TEXT_DOCUMENTS)
            for (employees.resume, employees.review)
        in (PHOTO_AREA1
                (comment is 'Happy Smiling Faces?'
                ,threshold is (99)
                ,partition PHOTOGRAPHIC_IMAGES_1)
            ,PHOTO_AREA2
                (comment is 'Happy Smiling Faces?'
                ,threshold is (99)
                ,partition PHOTOGRAPHIC_IMAGES_2)
            )
            for (employees.photograph)
            fill randomly
        in RDB$SYSTEM
                (partition SYSTEM_LARGE_OBJECTS)

 Partition information for lists map:
 Vertical Partition: VRP_P000
  Partition: (1) AUDIO_STUFF
    Fill Randomly
   Storage Area: AUDIO_AREA
         Thresholds are (89, 99, 100)
 Comment:       The voice clips
  Partition: (2) TEXT_DOCUMENTS
    Fill Randomly
   Storage Area: TEXT_AREA
         Thresholds are (99, 100, 100)
  Partition: (3) PHOTOGRAPHIC_IMAGES_1
    Fill Randomly
   Storage Area: PHOTO_AREA1
         Thresholds are (99, 100, 100)
 Comment:       Happy Smiling Faces?
  Partition: (3) PHOTOGRAPHIC_IMAGES_2
   Storage Area: PHOTO_AREA2
         Thresholds are (99, 100, 100)
 Comment:       Happy Smiling Faces?
  Partition: (4) SYSTEM_LARGE_OBJECTS
    Fill Randomly
   Storage Area: RDB$SYSTEM
SQL>
SQL> commit;