No, you were right the first time! You can use dbms_job if you need it to be transactional and you don't need the scheduler enhancements.
Assuming you remove the autonomous transaction that is...
SQL> create table t (
2 x int
3 );
Table created.
SQL>
SQL> create or replace trigger trig
2 after insert on t
3 declare
4 job int;
5 begin
6 dbms_job.submit (
7 job => job,
8 what => 'begin null; end;',
9 next_date => sysdate,
10 interval => 'sysdate + 1/24'
11 );
12 end;
13 /
Trigger created.
SQL>
SQL> insert into t values (1);
1 row created.
SQL>
SQL> select what from user_jobs;
WHAT
-------------------------------------------
begin null; end;
SQL>
SQL> rollback;
Rollback complete.
SQL>
SQL> select * from t;
no rows selected
SQL>
SQL> select what from user_jobs;
no rows selected