I created a partioned table. But I used incorrect quotation syntax 'MAXVALUE'
. This needs to be MAXVALUE
as below. How can fix this problem?
CREATE TABLE RMOBJECTSPAR (
"OBJ_LIBRARYID" SMALLINT NOT NULL ,
"OBJ_ITEMID" CHAR(26 OCTETS) NOT NULL ,
"OBJ_VERSION" SMALLINT NOT NULL WITH DEFAULT 1 ,
"OBJ_COLLECTIONID" INTEGER NOT NULL ,
"OBJ_MGTCLASSID" SMALLINT NOT NULL ,
"OBJ_STGCLASSID" SMALLINT NOT NULL ,
"OBJ_ATTRIBUTES" SMALLINT NOT NULL WITH DEFAULT 0 ,
"OBJ_RETENTION" INTEGER NOT NULL WITH DEFAULT 0 ,
"OBJ_VOLUMEID" INTEGER NOT NULL ,
"OBJ_STAGEDVOLUMEID" INTEGER NOT NULL WITH DEFAULT -1 ,
"OBJ_PATH" INTEGER NOT NULL ,
"OBJ_STATUS" CHAR(1 OCTETS) NOT NULL ,
"OBJ_SIZE" BIGINT NOT NULL ,
"OBJ_CREATEDATE" TIMESTAMP NOT NULL WITH DEFAULT CURRENT TIMESTAMP ,
"OBJ_UPDATEDATE" TIMESTAMP NOT NULL WITH DEFAULT CURRENT TIMESTAMP ,
"OBJ_REFERENCEDDATE" TIMESTAMP NOT NULL WITH DEFAULT CURRENT TIMESTAMP ,
"OBJ_ACTIONDATE" DATE NOT NULL ,
"OBJ_MGTCLASSDATE" DATE NOT NULL ,
"OBJ_STGCLASSDATE" DATE NOT NULL ,
"OBJ_PLAYSTATUS" CHAR(1 OCTETS) NOT NULL ,
"OBJ_VOLSTATUS" CHAR(1 OCTETS) NOT NULL ,
"OBJ_OBJECTNAME" VARCHAR(128 OCTETS) WITH DEFAULT '' ,
"OBJ_ORGFILENAME" VARCHAR(1024 OCTETS) WITH DEFAULT '' ,
"OBJ_FILENAME" VARCHAR(128 OCTETS) WITH DEFAULT '' ,
"OBJ_MIMETYPE" VARCHAR(128 OCTETS) NOT NULL WITH DEFAULT 'text/html' ,
"OBJ_OFFSET" BIGINT NOT NULL WITH DEFAULT -1 ,
"OBJ_SIGNATURE" VARCHAR(514 OCTETS) FOR BIT DATA )
PARTITION BY RANGE(OBJ_ITEMID)
(
PARTITION par1 STARTING MINVALUE ENDING 'A1001001A14L31C35959J99999' IN OBJECTS,
PARTITION par2 STARTING 'A1001001A14A01A00000A00001' ENDING 'A1001001A14L31C35959J99999' IN OBJECTS01,
PARTITION par3 STARTING 'A1001001A15A01A00000A00001' ENDING 'A1001001A15F31C35959J99999' IN OBJECTS02,
PARTITION par4 STARTING 'A1001001A16G01A00000A00001' ENDING 'A1001001A16L31C35959J99999' IN OBJECTS03,
PARTITION par5 STARTING 'A1001001A16G01A00000A00001' ENDING 'A1001001A16L31C35959J99999' IN OBJECTS04,
PARTITION par6 STARTING 'A1001001A17G01A00000A00001' ENDING 'A1001001A17L31C35959J99999' IN OBJECTS05,
PARTITION par7 STARTING 'A1001001A18G01A00000A00001' ENDING 'A1001001A18L31C35959J99999' IN OBJECTS06,
PARTITION par8 STARTING 'A1001001A19G01A00000A00001' ENDING 'A1001001A19L31C35959J99999' IN OBJECTS07,
PARTITION par9 STARTING 'B0000000000000000000000001' ENDING 'MAXVALUE' IN OBJECTS08
);
sorry we do not have the DB2 Multisystem PTF installed on our iSeries system, so I can't test the SQL statements, but here would be my solution to re-attach par9:
ALTER TABLE RMOBJECTSPAR DETACH PARTITION par9
INTO dummy;
ALTER TABLE RMOBJECTSPAR ATTACH PARTITION par9
STARTING FROM 'B0000000000000000000000001' ENDING AT MAXVALUE IN OBJECTS08
FROM dummy;
This should solve your issue, but please first test to make sure.
On a side note, maybe define your partitions like this instead:
PARTITION BY RANGE(OBJ_ITEMID)
(
PARTITION par1 STARTING MINVALUE ENDING 'A1001001A14A01A00000A00001' EXCLUSIVE IN OBJECTS,
PARTITION par2 STARTING 'A1001001A14A01A00000A00001' IN OBJECTS01,
PARTITION par3 STARTING 'A1001001A15A01A00000A00001' IN OBJECTS02,
PARTITION par4 STARTING 'A1001001A16G01A00000A00001' IN OBJECTS03,
PARTITION par5 STARTING 'A1001001A16G01A00000A00001' IN OBJECTS04,
PARTITION par6 STARTING 'A1001001A17G01A00000A00001' IN OBJECTS05,
PARTITION par7 STARTING 'A1001001A18G01A00000A00001' IN OBJECTS06,
PARTITION par8 STARTING 'A1001001A19G01A00000A00001' IN OBJECTS07,
PARTITION par9 STARTING 'B0000000000000000000000001' ENDING MAXVALUE IN OBJECTS08
);
References I used: