forked from zwdcdu/oracle
-
Notifications
You must be signed in to change notification settings - Fork 0
/
test3.sql
256 lines (242 loc) · 7.28 KB
/
test3.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
/*
实验三脚本文件:
首先创建自己的账号your_user,然后以system身份登录:
[student@deep02 ~]$sqlplus system/123@localhost/pdborcl
SQL>ALTER USER your_user QUOTA UNLIMITED ON USERS;
SQL>ALTER USER your_user QUOTA UNLIMITED ON USERS02;
SQL>ALTER USER your_user QUOTA UNLIMITED ON USERS03;
SQL>exit
然后以自己的账号your_user身份登录,并运行脚本文件test3.sql:
[student@deep02 ~]$cat test3.sql
[student@deep02 ~]$sqlplus your_user/123@localhost/pdborcl
SQL>@test3.sql
SQL>exit
该脚本在你的账号下创建了两个分区表,orders(一万行数据),order_details(三万行数据)。
参考:
1. oracle分区技术-- interval parition实验及总结
http://blog.chinaunix.net/uid-23284114-id-3304525.html
*/
declare
num number;
begin
select count(1) into num from user_tables where TABLE_NAME = 'ORDER_DETAILS';
if num=1 then
execute immediate 'drop table ORDER_DETAILS cascade constraints PURGE';
end if;
select count(1) into num from user_tables where TABLE_NAME = 'ORDERS';
if num=1 then
execute immediate 'drop table ORDERS cascade constraints PURGE';
end if;
end;
/
CREATE TABLE ORDERS
(
ORDER_ID NUMBER(10, 0) NOT NULL
, CUSTOMER_NAME VARCHAR2(40 BYTE) NOT NULL
, CUSTOMER_TEL VARCHAR2(40 BYTE) NOT NULL
, ORDER_DATE DATE NOT NULL
, EMPLOYEE_ID NUMBER(6, 0) NOT NULL
, DISCOUNT NUMBER(8, 2) DEFAULT 0
, TRADE_RECEIVABLE NUMBER(8, 2) DEFAULT 0
, CONSTRAINT ORDERS_PK PRIMARY KEY
(
ORDER_ID
)
USING INDEX
(
CREATE UNIQUE INDEX ORDERS_PK ON ORDERS (ORDER_ID ASC)
LOGGING
TABLESPACE USERS
PCTFREE 10
INITRANS 2
STORAGE
(
BUFFER_POOL DEFAULT
)
NOPARALLEL
)
ENABLE
)
TABLESPACE USERS
PCTFREE 10
INITRANS 1
STORAGE
(
BUFFER_POOL DEFAULT
)
NOCOMPRESS
NOPARALLEL
PARTITION BY RANGE (ORDER_DATE)
(
PARTITION PARTITION_2015 VALUES LESS THAN (TO_DATE(' 2016-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIAN'))
NOLOGGING
TABLESPACE USERS
PCTFREE 10
INITRANS 1
STORAGE
(
INITIAL 8388608
NEXT 1048576
MINEXTENTS 1
MAXEXTENTS UNLIMITED
BUFFER_POOL DEFAULT
)
NOCOMPRESS NO INMEMORY
, PARTITION PARTITION_2016 VALUES LESS THAN (TO_DATE(' 2017-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIAN'))
NOLOGGING
TABLESPACE USERS
PCTFREE 10
INITRANS 1
STORAGE
(
BUFFER_POOL DEFAULT
)
NOCOMPRESS NO INMEMORY
, PARTITION PARTITION_2017 VALUES LESS THAN (TO_DATE(' 2018-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIAN'))
NOLOGGING
TABLESPACE USERS
PCTFREE 10
INITRANS 1
STORAGE
(
BUFFER_POOL DEFAULT
)
NOCOMPRESS NO INMEMORY
, PARTITION PARTITION_2018 VALUES LESS THAN (TO_DATE(' 2019-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIAN'))
NOLOGGING
TABLESPACE USERS02
PCTFREE 10
INITRANS 1
STORAGE
(
BUFFER_POOL DEFAULT
)
NOCOMPRESS NO INMEMORY
, PARTITION PARTITION_2019 VALUES LESS THAN (TO_DATE(' 2020-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIAN'))
NOLOGGING
TABLESPACE USERS02
PCTFREE 10
INITRANS 1
STORAGE
(
BUFFER_POOL DEFAULT
)
NOCOMPRESS NO INMEMORY
, PARTITION PARTITION_2020 VALUES LESS THAN (TO_DATE(' 2021-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIAN'))
NOLOGGING
TABLESPACE USERS02
PCTFREE 10
INITRANS 1
STORAGE
(
BUFFER_POOL DEFAULT
)
NOCOMPRESS NO INMEMORY
, PARTITION PARTITION_2021 VALUES LESS THAN (TO_DATE(' 2022-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS', 'NLS_CALENDAR=GREGORIAN'))
NOLOGGING
TABLESPACE USERS03
PCTFREE 10
INITRANS 1
STORAGE
(
BUFFER_POOL DEFAULT
)
NOCOMPRESS NO INMEMORY
);
CREATE TABLE order_details
(
id NUMBER(10, 0) NOT NULL
, order_id NUMBER(10, 0) NOT NULL
, product_name VARCHAR2(40 BYTE) NOT NULL
, product_num NUMBER(8, 2) NOT NULL
, product_price NUMBER(8, 2) NOT NULL
, CONSTRAINT order_details_fk1 FOREIGN KEY (order_id)
REFERENCES orders ( order_id )
ENABLE
)
TABLESPACE USERS
PCTFREE 10 INITRANS 1
STORAGE (BUFFER_POOL DEFAULT )
NOCOMPRESS NOPARALLEL
PARTITION BY REFERENCE (order_details_fk1);
declare
dt date;
m number(8,2);
V_EMPLOYEE_ID NUMBER(6);
v_order_id number(10);
v_name varchar2(100);
v_tel varchar2(100);
v number(10,2);
v_order_detail_id number;
begin
/*
system login:
ALTER USER "TEACHER" QUOTA UNLIMITED ON USERS;
ALTER USER "TEACHER" QUOTA UNLIMITED ON USERS02;
ALTER USER "TEACHER" QUOTA UNLIMITED ON USERS03;
*/
v_order_detail_id:=1;
delete from order_details;
delete from orders;
for i in 1..10000
loop
if i mod 6 =0 then
dt:=to_date('2015-3-2','yyyy-mm-dd')+(i mod 60); --PARTITION_2015
elsif i mod 6 =1 then
dt:=to_date('2016-3-2','yyyy-mm-dd')+(i mod 60); --PARTITION_2016
elsif i mod 6 =2 then
dt:=to_date('2017-3-2','yyyy-mm-dd')+(i mod 60); --PARTITION_2017
elsif i mod 6 =3 then
dt:=to_date('2018-3-2','yyyy-mm-dd')+(i mod 60); --PARTITION_2018
elsif i mod 6 =4 then
dt:=to_date('2019-3-2','yyyy-mm-dd')+(i mod 60); --PARTITION_2019
else
dt:=to_date('2020-3-2','yyyy-mm-dd')+(i mod 60); --PARTITION_2020
end if;
V_EMPLOYEE_ID:=CASE I MOD 6 WHEN 0 THEN 11 WHEN 1 THEN 111 WHEN 2 THEN 112
WHEN 3 THEN 12 WHEN 4 THEN 121 ELSE 122 END;
--插入订单
v_order_id:=i;
v_name := 'aa'|| 'aa';
v_name := 'zhang' || i;
v_tel := '139888883' || i;
insert /*+append*/ into ORDERS (ORDER_ID,CUSTOMER_NAME,CUSTOMER_TEL,ORDER_DATE,EMPLOYEE_ID,DISCOUNT)
values (v_order_id,v_name,v_tel,dt,V_EMPLOYEE_ID,dbms_random.value(100,0));
--插入订单y一个订单包括3个产品
v:=dbms_random.value(10000,4000);
v_name:='computer'|| (i mod 3 + 1);
insert /*+append*/ into ORDER_DETAILS(ID,ORDER_ID,PRODUCT_NAME,PRODUCT_NUM,PRODUCT_PRICE)
values (v_order_detail_id,v_order_id,v_name,2,v);
v:=dbms_random.value(1000,50);
v_name:='paper'|| (i mod 3 + 1);
v_order_detail_id:=v_order_detail_id+1;
insert /*+append*/ into ORDER_DETAILS(ID,ORDER_ID,PRODUCT_NAME,PRODUCT_NUM,PRODUCT_PRICE)
values (v_order_detail_id,v_order_id,v_name,3,v);
v:=dbms_random.value(9000,2000);
v_name:='phone'|| (i mod 3 + 1);
v_order_detail_id:=v_order_detail_id+1;
insert /*+append*/ into ORDER_DETAILS(ID,ORDER_ID,PRODUCT_NAME,PRODUCT_NUM,PRODUCT_PRICE)
values (v_order_detail_id,v_order_id,v_name,1,v);
--在触发器关闭的情况下,需要手工计算每个订单的应收金额:
select sum(PRODUCT_NUM*PRODUCT_PRICE) into m from ORDER_DETAILS where ORDER_ID=v_order_id;
if m is null then
m:=0;
end if;
UPDATE ORDERS SET TRADE_RECEIVABLE = m - discount WHERE ORDER_ID=v_order_id;
IF I MOD 1000 =0 THEN
commit; --每次提交会加快插入数据的速度
END IF;
end loop;
end;
/
select count(*) from orders;
select count(*) from order_details;
--以system用户运行:
set autotrace on
select * from your_user.orders where order_date
between to_date('2017-1-1','yyyy-mm-dd') and to_date('2018-6-1','yyyy-mm-dd');
select a.ORDER_ID,a.CUSTOMER_NAME,
b.product_name,b.product_num,b.product_price
from your_user.orders a,your_user.order_details b where
a.ORDER_ID=b.order_id and
a.order_date between to_date('2017-1-1','yyyy-mm-dd') and to_date('2018-6-1','yyyy-mm-dd');