创建自定义数组cron_type_number
本方法中用到了自定义数组,需要单独创建
create or replace type cron_type_number as table of number(4);
创建函数cron_getnexttimeafter()
1 create or replace function cron_getnexttimeafter(cron varchar2,start_time varchar2 default to_char(sysdate,‘yyyy-MM-dd hh24:mi:ss‘)) 2 return varchar2 3 as 4 result_time varchar2(1024);--返回结果 5 type l_cron_type_number is table of number(4) index by binary_integer; 6 type cron_type_array is table of varchar2(128) index by binary_integer; 7 cron_var varchar2(1024); 8 temp_num number; 9 cron_seconds varchar2(512);--秒 10 cron_minutes varchar2(512);--分 11 cron_hours varchar2(512);--时 12 cron_day varchar2(512);--日 13 cron_month varchar2(512);--月 14 cron_week varchar2(512);--星 15 cron_year varchar2(512);--年 16 17 array_seconds cron_type_number;--秒的数组 18 array_minutes cron_type_number;--分的数组 19 array_hours cron_type_number;--时的数组 20 array_day cron_type_number;--日的数组 21 array_month cron_type_number;--月的数组 22 array_week cron_type_number;--星的数组 23 array_year cron_type_number;--年的数组 24 25 start_seconds number default -1;--开始时间-秒 26 start_minutes number default -1;--开始时间-分 27 start_hours number default -1;--开始时间-时 28 start_day number default -1;--开始时间-日 29 start_month number default -1;--开始时间-月 30 start_week_1 number default -1;--开始时间-星-星期几 31 start_week_2 number default -1;--开始时间-星-第几个 32 start_year number default -1;--开始时间-年 33 34 next_seconds number default -1;--预期时间-秒 35 next_minutes number default -1;--预期时间-分 36 next_hours number default -1;--预期时间-时 37 next_day number default -1;--预期时间-日 38 next_month number default -1;--预期时间-月 39 next_week_1 number default -1;--预期时间-星-星期几 40 next_week_2 number default -1;--预期时间-星-第几个 41 next_year number default -1;--预期时间-年 42 43 44 45 ------------------------------------------------------------------------------------------------------ 46 --根据‘,‘分割字符串,生成list 47 function cron_get_str(str varchar2) 48 return cron_type_array is 49 temp_result_array cron_type_array; 50 begin 51 for i in 1..regexp_count(str,‘[^,]+‘)+1 loop 52 temp_result_array(i) := regexp_substr(str,‘[^,]+‘,1,i); 53 end loop; 54 return temp_result_array; 55 end; 56 ------------------------------------------------------------------------------------------------------ 57 --解析字符串,返回运行数组 58 function cron_get_array(str varchar2,min_num number,max_num number) 59 return l_cron_type_number is 60 temp_result_array_number l_cron_type_number; 61 num number default 1; 62 i number default 0; 63 temp_str_1 varchar2(128); 64 temp_str_2 varchar2(128); 65 temp_str_3 varchar2(128); 66 temp_str_4 varchar2(128); 67 temp_min_num number default -1;--周期开始值 68 temp_max_num number default -1;--周期结束值 69 temp_mod_num number default 1;--周期频率/默认为1 70 begin 71 --start获取周期的开始值/结束值 72 ----值为"*"或"?"时,取该字段最大最小值之间的所有值 73 if str = ‘*‘ or str = ‘?‘ then 74 temp_min_num := min_num; 75 temp_max_num := max_num; 76 ----值为"数字"时,取该数字 77 elsif regexp_like(str,‘^[0-9]+$‘) then 78 if to_number(str) between min_num and max_num then 79 temp_min_num := to_number(str); 80 temp_max_num := to_number(str); 81 else 82 raise_application_error(-20001,‘值的范围为‘||min_num||‘"-‘||max_num||‘"‘); 83 end if; 84 ----值包含"/"时,根据"/"切割字符串,前半部分为范围,后半部分为频率 85 elsif str like ‘%/%‘ then 86 temp_str_1 := regexp_substr(str,‘[^/]+‘,1,1); 87 temp_str_2 := regexp_substr(str,‘[^/]+‘,1,2); 88 if regexp_like(temp_str_2,‘^[0-9]+$‘) and (to_number(temp_str_2) between 1 and max_num) then 89 temp_mod_num := to_number(temp_str_2); 90 if temp_str_1 is null or temp_str_1=‘*‘ then 91 temp_min_num := min_num; 92 temp_max_num := max_num; 93 elsif regexp_like(temp_str_1,‘^[0-9]+$‘) and (to_number(temp_str_1)<min_num or to_number(temp_str_1)>max_num) then 94 raise_application_error(-20001,‘符号"/"前的值范围为"‘||min_num||‘-‘||max_num||‘"‘); 95 elsif regexp_like(temp_str_1,‘^[0-9]+$‘) and (to_number(temp_str_1) between min_num and max_num) then 96 temp_min_num := to_number(temp_str_1); 97 temp_max_num := max_num; 98 elsif temp_str_1 like ‘%-%‘ then 99 temp_str_3 := regexp_substr(temp_str_1,‘[^-]+‘,1,1); 100 temp_str_4 := regexp_substr(temp_str_1,‘[^-]+‘,1,2); 101 if regexp_like(temp_str_3,‘^[0-9]+$‘) and regexp_like(temp_str_4,‘^[0-9]+$‘) and (to_number(temp_str_3) between min_num and max_num) and (to_number(temp_str_4) between min_num and max_num) then 102 if to_number(temp_str_3)<=to_number(temp_str_4) then 103 temp_min_num := to_number(temp_str_3); 104 temp_max_num := to_number(temp_str_4); 105 else 106 temp_min_num := to_number(temp_str_3); 107 temp_max_num := to_number(temp_str_4)+max_num-min_num+1;--此处是为了处理秒分时的开始值是0,日月年星的开始值是1,当开始值是0时加1,当开始值是1时不变 108 end if; 109 else raise_application_error(-20001,‘符号"/"前的值格式错误‘); 110 end if; 111 else raise_application_error(-20001,‘符号"/"前的值格式错误‘); 112 end if; 113 else raise_application_error(-20001,‘符号"/"后必须有数字格式的值,且必须>1‘||‘、<=‘||max_num); 114 end if; 115 ----值包含"-"时,取两个值之间的所有值,频率为1 116 elsif str like ‘%-%‘ then 117 temp_str_1 := regexp_substr(str,‘[^-]+‘,1,1); 118 temp_str_2 := regexp_substr(str,‘[^-]+‘,1,2); 119 if regexp_like(temp_str_1,‘^[0-9]+$‘) and regexp_like(temp_str_2,‘^[0-9]+$‘) and (to_number(temp_str_1) between min_num and max_num) and (to_number(temp_str_2) between min_num and max_num) then 120 if to_number(temp_str_1)<=to_number(temp_str_2) then 121 temp_min_num := to_number(temp_str_1); 122 temp_max_num := to_number(temp_str_2); 123 else 124 temp_min_num := to_number(temp_str_1); 125 temp_max_num := to_number(temp_str_2)+max_num-min_num+1;--此处是为了处理秒分时的开始值是0,日月年星的开始值是1,当开始值是0时加1,当开始值是1时不变 126 end if; 127 else raise_application_error(-20001,‘符号"-"前的值格式错误‘); 128 end if; 129 else 130 return temp_result_array_number; 131 end if; 132 --end获取周期的开始值/结束值 133 --start获取周期数组 134 i := temp_min_num; 135 while i<=temp_max_num loop 136 if i<=max_num then 137 temp_result_array_number(num) := i; 138 else 139 temp_result_array_number(num) := i-max_num+min_num-1;--此处是为了处理秒分时的开始值是0,日月年星的开始值是1 140 end if; 141 i := i+temp_mod_num; 142 num := num+1; 143 end loop; 144 --end获取周期数组 145 return temp_result_array_number; 146 end; 147 ------------------------------------------------------------------------------------------------------ 148 --获取运行数组 149 function cron_get_str_array(str varchar2,min_num number,max_num number) 150 return cron_type_number is 151 temp_result_array cron_type_number; 152 num number default 1; 153 temp_array_1 cron_type_array;--临时数组1 154 temp_array_2 l_cron_type_number;--临时数组2 155 begin 156 temp_result_array := cron_type_number(); 157 temp_array_1 := cron_get_str(str); 158 for i in 1..temp_array_1.count loop 159 temp_array_2 := cron_get_array(temp_array_1(i),min_num,max_num); 160 temp_result_array.extend(temp_array_2.count); 161 for j in 1..temp_array_2.count loop 162 temp_result_array(num) := temp_array_2(j); 163 num := num+1; 164 end loop; 165 end loop; 166 return temp_result_array; 167 end; 168 ------------------------------------------------------------------------------------------------------ 169 --根据运行数组/开始时间的实际值,获取下次运行的值 170 function cron_get_next_value(cron_array cron_type_number,start_num number) 171 return number 172 as 173 result_num number; 174 begin 175 select min(to_number(column_value)) into result_num from table(cron_array) where to_number(column_value)>=start_num; 176 if result_num is null then 177 select min(to_number(column_value)) into result_num from table(cron_array); 178 end if; 179 return result_num; 180 end; 181 ------------------------------------------------------------------------------------------------------ 182 --翻译替换,将月份中的英文字符转换为数字 183 function cron_replace_month(str varchar2) 184 return varchar2 185 as 186 result_str varchar2(128); 187 begin 188 result_str := replace(str,‘JAN‘,‘1‘); 189 result_str := replace(result_str,‘FEB‘,‘2‘); 190 result_str := replace(result_str,‘MAR‘,‘3‘); 191 result_str := replace(result_str,‘APR‘,‘4‘); 192 result_str := replace(result_str,‘MAY‘,‘5‘); 193 result_str := replace(result_str,‘JUN‘,‘6‘); 194 result_str := replace(result_str,‘JUL‘,‘7‘); 195 result_str := replace(result_str,‘AUG‘,‘8‘); 196 result_str := replace(result_str,‘SEP‘,‘9‘); 197 result_str := replace(result_str,‘OCT‘,‘10‘); 198 result_str := replace(result_str,‘NOV‘,‘11‘); 199 result_str := replace(result_str,‘DEC‘,‘12‘); 200 return result_str; 201 end; 202 ------------------------------------------------------------------------------------------------------ 203 --翻译替换,将星期中的英文字符转换为数字,特别说明英文中星期日为一周的开始 204 function cron_replace_week(str varchar2) 205 return varchar2 206 as 207 result_str varchar2(128); 208 begin 209 result_str := replace(str,‘SUN‘,‘1‘); 210 result_str := replace(result_str,‘MON‘,‘2‘); 211 result_str := replace(result_str,‘TUE‘,‘3‘); 212 result_str := replace(result_str,‘WED‘,‘4‘); 213 result_str := replace(result_str,‘THU‘,‘5‘); 214 result_str := replace(result_str,‘FRI‘,‘6‘); 215 result_str := replace(result_str,‘SAT‘,‘7‘); 216 return result_str; 217 end; 218 ------------------------------------------------------------------------------------------------------ 219 --校验时间格式是否正确 220 function cron_is_date(str VARCHAR2) 221 return number IS 222 val date; 223 begin 224 val := TO_DATE(NVL(str, ‘w‘), ‘yyyy-mm-dd hh24:mi:ss‘); 225 return 1; 226 exception 227 when others then 228 return 0; 229 end; 230 ------------------------------------------------------------------------------------------------------ 231 ------------------------------------------------------------------------------------------------------ 232 begin 233 --校验开始时间格式 234 if cron_is_date(start_time)=1 then 235 start_seconds := substr(start_time,18,2)+1; 236 start_minutes := substr(start_time,15,2); 237 start_hours := substr(start_time,12,2); 238 start_day := substr(start_time,9,2); 239 start_month := substr(start_time,6,2); 240 --start_week_1 := to_char(to_date(start_time,‘yyyy-MM-dd hh24:mi:ss‘),‘D‘); 241 --start_week_2 := to_char(to_date(start_time,‘yyyy-MM-dd hh24:mi:ss‘),‘W‘); 242 start_year := substr(start_time,1,4); 243 next_year := substr(start_time,1,4); 244 else raise_application_error(-20001,‘开始时间格式错误,正确格式为"yyyy-MM-dd hh24:mi:ss"‘); 245 end if; 246 247 --首尾两端去空格/去空白符换行符/去两个以上空格/转大写 248 cron_var := upper(regexp_replace(replace(replace(replace(trim(cron),chr(9),‘‘),chr(10),‘‘),chr(13),‘‘),‘( ){2,}‘,‘ ‘)); 249 250 --判断格式是否合规,否则提示异常 251 if regexp_count(cron_var,‘ ‘) is null or regexp_count(cron_var,‘ ‘) not in (5,6) then 252 raise_application_error(-20001,‘定时字符串格式错误‘); 253 end if; 254 255 --取值,根据空格分别获取 256 cron_seconds := regexp_substr(cron_var,‘[^ ]+‘,1,1);--秒 257 cron_minutes := regexp_substr(cron_var,‘[^ ]+‘,1,2);--分 258 cron_hours := regexp_substr(cron_var,‘[^ ]+‘,1,3);--时 259 cron_day := regexp_substr(cron_var,‘[^ ]+‘,1,4);--日 260 cron_month := cron_replace_month(regexp_substr(cron_var,‘[^ ]+‘,1,5));--月 261 cron_week := cron_replace_week(regexp_substr(cron_var,‘[^ ]+‘,1,6));--星 262 cron_year := nvl(regexp_substr(cron_var,‘[^ ]+‘,1,7),‘*‘);--年 263 --正则校验格式是否正确 264 265 266 --获取预期的运行数组 267 --为了提高效率,本函数将年的范围限定为1949年-2049年,如果有实际需要,可以酌情调整 268 array_seconds := cron_get_str_array(cron_seconds,0,59); 269 array_minutes := cron_get_str_array(cron_minutes,0,59); 270 array_hours := cron_get_str_array(cron_hours,0,23); 271 array_day := cron_get_str_array(cron_day,1,31); 272 array_month := cron_get_str_array(cron_month,1,12); 273 array_week := cron_get_str_array(cron_week,1,7); 274 array_year := cron_get_str_array(cron_year,1949,2049); 275 276 --------------------------------------------------------------------------------------------------------------------- 277 --初始化超范围的下级 278 <<goto_day_month_year>> 279 select count(0) into temp_num from table(array_year) where column_value=start_year; 280 if temp_num = 0 then 281 select min(column_value) into start_month from table(array_month); 282 select min(column_value) into start_day from table(array_day); 283 select min(column_value) into start_hours from table(array_hours); 284 select min(column_value) into start_minutes from table(array_minutes); 285 select min(column_value) into start_seconds from table(array_seconds); 286 end if; 287 select count(0) into temp_num from table(array_month) where column_value=start_month; 288 if temp_num = 0 then 289 select min(column_value) into start_day from table(array_day); 290 select min(column_value) into start_hours from table(array_hours); 291 select min(column_value) into start_minutes from table(array_minutes); 292 select min(column_value) into start_seconds from table(array_seconds); 293 end if; 294 select count(0) into temp_num from table(array_day) where column_value=start_day; 295 if temp_num = 0 then 296 select min(column_value) into start_hours from table(array_hours); 297 select min(column_value) into start_minutes from table(array_minutes); 298 select min(column_value) into start_seconds from table(array_seconds); 299 end if; 300 select count(0) into temp_num from table(array_hours) where column_value=start_hours; 301 if temp_num = 0 then 302 select min(column_value) into start_minutes from table(array_minutes); 303 select min(column_value) into start_seconds from table(array_seconds); 304 end if; 305 select count(0) into temp_num from table(array_minutes) where column_value=start_minutes; 306 if temp_num = 0 then 307 select min(column_value) into start_seconds from table(array_seconds); 308 end if; 309 --------------------------------------------------------------------------------------------------------------------- 310 --获取预期的运行时间 311 next_seconds := cron_get_next_value(array_seconds,start_seconds); 312 if start_seconds> next_seconds then 313 start_minutes := start_minutes+1; 314 end if; 315 next_minutes := cron_get_next_value(array_minutes,start_minutes); 316 if start_minutes> next_minutes then 317 start_hours := start_hours+1; 318 end if; 319 next_hours := cron_get_next_value(array_hours,start_hours); 320 if start_hours> next_hours then 321 start_day := start_day+1; 322 end if; 323 next_day := cron_get_next_value(array_day,start_day); 324 if start_day> next_day then 325 start_month := start_month+1; 326 end if; 327 next_month := cron_get_next_value(array_month,start_month); 328 --next_week_1 := cron_get_next_value(array_week,start_week_1); 329 if start_month> next_month then 330 start_year := start_year+1; 331 end if; 332 select min(to_number(column_value)) into next_year from table(array_year) where to_number(column_value)>=start_year; 333 if next_year is null then 334 return ‘‘; 335 end if; 336 --判断日期是否合法,不合法则以此为新的开始时间重新计算 337 if next_year<=array_year(array_year.last) and ((mod(next_year,4)!=0 and next_month=2 and next_day=29) or (next_month=2 and next_day=30) or (next_month in(2,4,6,9,11) and next_day=31)) then 338 start_year := next_year; 339 start_month := next_month+1; 340 start_day := 1; 341 goto goto_day_month_year; 342 end if; 343 result_time := lpad(next_year,4,‘0‘)||‘-‘||lpad(next_month,2,‘0‘)||‘-‘||lpad(next_day,2,‘0‘)||‘ ‘||lpad(next_hours,2,‘0‘)||‘:‘||lpad(next_minutes,2,‘0‘)||‘:‘||lpad(next_seconds,2,‘0‘); 344 --dbms_output.put_line(result_time); 345 --判断生成的时间是否合法、是否小于开始时间,如果小于开始时间,则返回为空 346 if cron_is_date(result_time)=0 or result_time<=start_time then 347 result_time := ‘‘; 348 end if; 349 return result_time; 350 end;
调用示例
--因为不存在2月31日,所以执行结果为空 select cron_getnexttimeafter(‘0 0/1 1 31 2 ? 2019-2029‘) from dual;
--执行结果为‘2020-02-02 01:00:00’ select cron_getnexttimeafter(‘0 0/1 1 2 2 ? 2019-2029‘,‘2019-07-07 17:22:00‘) from dual;
--执行结果为当前时间的下一个3月7日0点0分0秒 select cron_getnexttimeafter(‘0 0 0 7 3 ?‘) from dual;