From 3e54d6651caab999f8827c46d60889c27f02af93 Mon Sep 17 00:00:00 2001 From: David Pyke Le Brun Date: Fri, 6 Feb 2015 13:36:40 +0000 Subject: [PATCH] update of old PL/SQL PLpgSQL and SQLPL patch based on current version see [linguist] add support for oracle PLSQL (#1003) --- .gitmodules | 3 + grammars.yml | 2 + lib/linguist/heuristics.rb | 25 ++++ lib/linguist/languages.yml | 29 +++++ samples/PLSQL/myobject.sql | 15 +++ samples/PLSQL/packagebody.pkb | 58 +++++++++ samples/PLSQL/packageheader.pks | 28 +++++ samples/PLSQL/who_called_me.sql | 65 ++++++++++ samples/PLpgSQL/plpgsql_lint-8.4.sql | 165 ++++++++++++++++++++++++ samples/PLpgSQL/plpgsql_lint-9.0.sql | 165 ++++++++++++++++++++++++ samples/PLpgSQL/plpgsql_lint-9.1.sql | 179 +++++++++++++++++++++++++++ samples/PLpgSQL/plpgsql_lint-9.2.sql | 166 +++++++++++++++++++++++++ samples/PLpgSQL/plpgsql_lint-9.3.sql | 166 +++++++++++++++++++++++++ samples/SQL/create_stuff.sql | 21 ++++ samples/SQL/drop_stuff.sql | 13 ++ samples/SQL/dual.sql | 3 + samples/SQLPL/check_reorg.sql | 39 ++++++ samples/SQLPL/comm_amount.db2 | 30 +++++ samples/SQLPL/drop_table.db2 | 13 ++ samples/SQLPL/runstats.sql | 18 +++ samples/SQLPL/trigger.sql | 9 ++ vendor/grammars/Oracle | 1 + 22 files changed, 1213 insertions(+) create mode 100644 samples/PLSQL/myobject.sql create mode 100644 samples/PLSQL/packagebody.pkb create mode 100644 samples/PLSQL/packageheader.pks create mode 100644 samples/PLSQL/who_called_me.sql create mode 100644 samples/PLpgSQL/plpgsql_lint-8.4.sql create mode 100644 samples/PLpgSQL/plpgsql_lint-9.0.sql create mode 100644 samples/PLpgSQL/plpgsql_lint-9.1.sql create mode 100644 samples/PLpgSQL/plpgsql_lint-9.2.sql create mode 100644 samples/PLpgSQL/plpgsql_lint-9.3.sql create mode 100644 samples/SQL/create_stuff.sql create mode 100644 samples/SQL/drop_stuff.sql create mode 100644 samples/SQL/dual.sql create mode 100644 samples/SQLPL/check_reorg.sql create mode 100644 samples/SQLPL/comm_amount.db2 create mode 100644 samples/SQLPL/drop_table.db2 create mode 100644 samples/SQLPL/runstats.sql create mode 100644 samples/SQLPL/trigger.sql create mode 160000 vendor/grammars/Oracle diff --git a/.gitmodules b/.gitmodules index 4e72920d..aefae11d 100644 --- a/.gitmodules +++ b/.gitmodules @@ -594,3 +594,6 @@ [submodule "vendor/grammars/ec.tmbundle"] path = vendor/grammars/ec.tmbundle url = https://github.com/ecere/ec.tmbundle +[submodule "vendor/grammars/Oracle"] + path = vendor/grammars/Oracle + url = git@github.com:mulander/oracle.tmbundle.git diff --git a/grammars.yml b/grammars.yml index 00f2c9b1..398c2a35 100644 --- a/grammars.yml +++ b/grammars.yml @@ -68,6 +68,8 @@ vendor/grammars/NimLime: - source.nim - source.nim_filter - source.nimcfg +vendor/grammars/Oracle/: +- source.plsql.oracle vendor/grammars/PHP-Twig.tmbundle: - text.html.twig vendor/grammars/RDoc.tmbundle: diff --git a/lib/linguist/heuristics.rb b/lib/linguist/heuristics.rb index ee1a3625..3d1899ec 100644 --- a/lib/linguist/heuristics.rb +++ b/lib/linguist/heuristics.rb @@ -223,5 +223,30 @@ module Linguist Language["Text"] end end + disambiguate "PLSQL", "SQLPL", "PLpgSQL", "SQL" do |data| + match = nil + #unique keywords for each language + plpgsqlkeywords = [/^\\i\b/i, /begin ?(work|transaction)?;/i , /AS \$\$/i, /RAISE EXCEPTION/i, /LANGUAGE plpgsql\b/i ] + plsqlkeywords = [ /pragma\b/i , /constructor\W+function\b/i] + #sqlplkeywords = [ ] + + #common keywords that are not SQL + plkeywords = [/begin\b/i,/boolean\b/i, /package\b/i,/exception\b/i, /^end;\b/i ] + + re = Regexp.union(plpgsqlkeywords) + if data.match(re) + match = Language["PLpgSQL"] + else + re = Regexp.union(plsqlkeywords) + if data.match(re) + match= Language["PLSQL"] + else + re = Regexp.union(plkeywords) + match= Language["SQL"] if ! data.match(re) + end + end + + match + end end end diff --git a/lib/linguist/languages.yml b/lib/linguist/languages.yml index e899046e..d2133a5c 100644 --- a/lib/linguist/languages.yml +++ b/lib/linguist/languages.yml @@ -2145,6 +2145,26 @@ PHP: aliases: - inc +#Oracle +PLSQL: + type: programming + ace_mode: sql + tm_scope: Oracle + extensions: + - .pls + - .pkb + - .pks + - .plb + - .sql + +#Postgres +PLpgSQL: + type: programming + ace_mode: pgsql + tm_scope: source.sql + extensions: + - .sql + Pan: type: programming color: '#cc0000' @@ -2675,6 +2695,15 @@ SQL: - .udf - .viw +#IBM DB2 +#SQLPL: + #type: programming + #ace_mode: sql + #tm_scope: source.sql + #extensions: + #- .sql + #- .db2 + STON: type: data group: Smalltalk diff --git a/samples/PLSQL/myobject.sql b/samples/PLSQL/myobject.sql new file mode 100644 index 00000000..dd2a68aa --- /dev/null +++ b/samples/PLSQL/myobject.sql @@ -0,0 +1,15 @@ +create or replace type myobject +AUTHID DEFINER +AS OBJECT +( + m_name varchar2(200), + member function toString RETURN VARCHAR2, + map member function Compare return varchar2 + +) +not instantiable not final; +/ + +prompt create type myarray +create or replace type myarray as table of myobject; +/ diff --git a/samples/PLSQL/packagebody.pkb b/samples/PLSQL/packagebody.pkb new file mode 100644 index 00000000..e5e80d99 --- /dev/null +++ b/samples/PLSQL/packagebody.pkb @@ -0,0 +1,58 @@ +CREATE OR REPLACE PACKAGE BODY linguistpackage +AS + /* + * Package: linguist pacakage body + * Purpose: a sample PLSQL file for linguist to work with + * + * Date: 03/03/2014 + * Author: david pyke le brun + * Comments: initial version + */ + +PROCEDURE proc_1 +IS +BEGIN +NULL; +END; + +-- functions with 1 arg +FUNCTION function1( param1 VARCHAR2 ) RETURN VARCHAR2 +IS +CURSOR c IS +select * from dual; +v c%ROWTYPE; +BEGIN + open c; + fetch c into v; + close c; + + return v; +end; + +FUNCTION function2( param1 NUMBER ) RETURN DATE +IS +BEGIN + return SYSDATE; +end; + +--a few more to use all basic SQL types +FUNCTION function3( param1 TIMESTAMP ) RETURN CHAR +IS +BEGIN +IF 1 = 2 THEN +return 'Y'; +ELSE +return 'N'; +END IF; +return NULL; +END; + + +FUNCTION function4( param1 CLOB ) RETURN BLOB +IS +BEGIN + return null; +END; + +END linguistpackage; +/ diff --git a/samples/PLSQL/packageheader.pks b/samples/PLSQL/packageheader.pks new file mode 100644 index 00000000..408cdca3 --- /dev/null +++ b/samples/PLSQL/packageheader.pks @@ -0,0 +1,28 @@ +CREATE OR REPLACE PACKAGE linguistpackage +AUTHID DEFINER +AS + /* + * Package: linguist pacakage + * Purpose: a sample PLSQL file for linguist to work with + * + * Date: 03/03/2014 + * Author: david pyke le brun + * Comments: initial version + */ + +k_constant CONSTANT NUMBER(10,2) := 3.14; + +--basic procedure +PROCEDURE proc_1; + +-- functions with 1 arg +FUNCTION function1( param1 VARCHAR2 ) RETURN VARCHAR2; +FUNCTION function2( param1 NUMBER ) RETURN DATE; + +--a few more to use all basic SQL types +FUNCTION function3( param1 TIMESTAMP ) RETURN CHAR; +FUNCTION function4( param1 CLOB ) RETURN BLOB; + +END linguistpackage; +/ + diff --git a/samples/PLSQL/who_called_me.sql b/samples/PLSQL/who_called_me.sql new file mode 100644 index 00000000..fee4ed9b --- /dev/null +++ b/samples/PLSQL/who_called_me.sql @@ -0,0 +1,65 @@ +CREATE OR REPLACE PROCEDURE who_called_me +( owner OUT VARCHAR2, + name OUT VARCHAR2, + lineno OUT NUMBER, + caller_t OUT VARCHAR2 , + depth NUMBER DEFAULT 1 +) +AUTHID DEFINER +AS +--depth based version of who_called_me from asktom + call_stack VARCHAR2(4096) default dbms_utility.format_call_stack; + n NUMBER; + found_stack BOOLEAN DEFAULT FALSE; + line VARCHAR2(255); + cnt NUMBER := 0; +BEGIN + LOOP + n := instr( call_stack, chr(10) ); + exit when ( n is NULL or n = 0 ); +-- + line := substr( call_stack, 1, n-1 ); + call_stack := substr( call_stack, n+1 ); +-- + if ( NOT found_stack ) then + if ( line like '%handle%number%name%' ) then + found_stack := TRUE; + end if; + else + cnt := cnt + 1; + -- cnt = 1 is ME + -- cnt = 2 is MY Caller + -- cnt = 3 is Their Caller + if ( cnt = (2+depth) ) then + lineno := to_number(substr( line, 13, 8 )); + line := substr( line, 23 ); --set to rest of line .. change from 21 to 23 + if ( line like 'pr%' ) then + n := length( 'procedure ' ); + elsif ( line like 'fun%' ) then + n := length( 'function ' ); + elsif ( line like 'package body%' ) then + n := length( 'package body ' ); + elsif ( line like 'pack%' ) then + n := length( 'package ' ); + elsif ( line like 'anonymous%' ) then + n := length( 'anonymous block ' ); + else + n := null; + end if; + if ( n is not null ) then + caller_t := ltrim(rtrim(upper(substr( line, 1, n-1 )))); + else + caller_t := 'TRIGGER'; + end if; + + line := substr( line, nvl(n,1) ); + n := instr( line, '.' ); + owner := ltrim(rtrim(substr( line, 1, n-1 ))); + name := LTRIM(RTRIM(SUBSTR( LINE, N+1 ))); + exit; + END IF; + END IF; + END LOOP; +END; +/ + diff --git a/samples/PLpgSQL/plpgsql_lint-8.4.sql b/samples/PLpgSQL/plpgsql_lint-8.4.sql new file mode 100644 index 00000000..72c84469 --- /dev/null +++ b/samples/PLpgSQL/plpgsql_lint-8.4.sql @@ -0,0 +1,165 @@ +load 'plpgsql'; +load 'plpgsql_lint'; + +create table t1(a int, b int); + +create function f1() +returns void as $$ +begin + if false then + update t1 set c = 30; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create function g1(out a int, out b int) +as $$ + select 10,20; +$$ language sql; + +create function f1() +returns void as $$ +declare r record; +begin + r := g1(); + if false then + raise notice '%', r.c; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); +drop function g1(); + +create function g1(out a int, out b int) +returns setof record as $$ +select * from t1; +$$ language sql; + +create function f1() +returns void as $$ +declare r record; +begin + for r in select * from g1() + loop + raise notice '%', r.c; + end loop; +end; +$$ language plpgsql; + +select f1(); + +create or replace function f1() +returns void as $$ +declare r record; +begin + for r in select * from g1() + loop + r.c := 20; + end loop; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); +drop function g1(); + +create function f1() +returns int as $$ +declare r int; +begin + if false then + r := a + b; + end if; + return r; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create or replace function f1() +returns void as $$ +begin + if false then + raise notice '%', 1, 2; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create or replace function f1() +returns void as $$ +begin + if false then + raise notice '% %'; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create or replace function f1() +returns void as $$ +declare r int[]; +begin + if false then + r[c+10] := 20; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + + +create or replace function f1() +returns void as $$ +declare r int; +begin + if false then + r[10] := 20; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create type diagnostic_info_type as ( + status text, + message text, + detail text, + row_count int); + +create or replace function f1() +returns void as $$ +declare + dg record; +begin + dg := NULL::diagnostic_info_type; + if false then + dg.status := '00000'; + dg.mistake := 'hello'; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); diff --git a/samples/PLpgSQL/plpgsql_lint-9.0.sql b/samples/PLpgSQL/plpgsql_lint-9.0.sql new file mode 100644 index 00000000..72c84469 --- /dev/null +++ b/samples/PLpgSQL/plpgsql_lint-9.0.sql @@ -0,0 +1,165 @@ +load 'plpgsql'; +load 'plpgsql_lint'; + +create table t1(a int, b int); + +create function f1() +returns void as $$ +begin + if false then + update t1 set c = 30; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create function g1(out a int, out b int) +as $$ + select 10,20; +$$ language sql; + +create function f1() +returns void as $$ +declare r record; +begin + r := g1(); + if false then + raise notice '%', r.c; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); +drop function g1(); + +create function g1(out a int, out b int) +returns setof record as $$ +select * from t1; +$$ language sql; + +create function f1() +returns void as $$ +declare r record; +begin + for r in select * from g1() + loop + raise notice '%', r.c; + end loop; +end; +$$ language plpgsql; + +select f1(); + +create or replace function f1() +returns void as $$ +declare r record; +begin + for r in select * from g1() + loop + r.c := 20; + end loop; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); +drop function g1(); + +create function f1() +returns int as $$ +declare r int; +begin + if false then + r := a + b; + end if; + return r; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create or replace function f1() +returns void as $$ +begin + if false then + raise notice '%', 1, 2; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create or replace function f1() +returns void as $$ +begin + if false then + raise notice '% %'; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create or replace function f1() +returns void as $$ +declare r int[]; +begin + if false then + r[c+10] := 20; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + + +create or replace function f1() +returns void as $$ +declare r int; +begin + if false then + r[10] := 20; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create type diagnostic_info_type as ( + status text, + message text, + detail text, + row_count int); + +create or replace function f1() +returns void as $$ +declare + dg record; +begin + dg := NULL::diagnostic_info_type; + if false then + dg.status := '00000'; + dg.mistake := 'hello'; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); diff --git a/samples/PLpgSQL/plpgsql_lint-9.1.sql b/samples/PLpgSQL/plpgsql_lint-9.1.sql new file mode 100644 index 00000000..2cc532a1 --- /dev/null +++ b/samples/PLpgSQL/plpgsql_lint-9.1.sql @@ -0,0 +1,179 @@ +load 'plpgsql'; +load 'plpgsql_lint'; + +create table t1(a int, b int); + +create function f1() +returns void as $$ +begin + if false then + update t1 set c = 30; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create function g1(out a int, out b int) +as $$ + select 10,20; +$$ language sql; + +create function f1() +returns void as $$ +declare r record; +begin + r := g1(); + if false then + raise notice '%', r.c; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); +drop function g1(); + +create function g1(out a int, out b int) +returns setof record as $$ +select * from t1; +$$ language sql; + +create function f1() +returns void as $$ +declare r record; +begin + for r in select * from g1() + loop + raise notice '%', r.c; + end loop; +end; +$$ language plpgsql; + +select f1(); + +create or replace function f1() +returns void as $$ +declare r record; +begin + for r in select * from g1() + loop + r.c := 20; + end loop; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); +drop function g1(); + +create function f1() +returns int as $$ +declare r int; +begin + if false then + r := a + b; + end if; + return r; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create or replace function f1() +returns void as $$ +begin + if false then + raise notice '%', 1, 2; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create or replace function f1() +returns void as $$ +begin + if false then + raise notice '% %'; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create or replace function f1() +returns void as $$ +declare r int[]; +begin + if false then + r[c+10] := 20; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + + +create or replace function f1() +returns void as $$ +declare r int; +begin + if false then + r[10] := 20; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create type diagnostic_info_type as ( + status text, + message text, + detail text, + row_count int); + +create or replace function f1() +returns void as $$ +declare dg record; +begin + dg := NULL::diagnostic_info_type; + if false then + dg.status := '00000'; + dg.mistake := 'hello'; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create or replace function f1() +returns void as $$ +declare dg record; +begin + if false then + dg := 10,20; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + diff --git a/samples/PLpgSQL/plpgsql_lint-9.2.sql b/samples/PLpgSQL/plpgsql_lint-9.2.sql new file mode 100644 index 00000000..73da6e67 --- /dev/null +++ b/samples/PLpgSQL/plpgsql_lint-9.2.sql @@ -0,0 +1,166 @@ +load 'plpgsql'; +load 'plpgsql_lint'; + +create table t1(a int, b int); + +create function f1() +returns void as $$ +begin + if false then + update t1 set c = 30; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create function g1(out a int, out b int) +as $$ + select 10,20; +$$ language sql; + +create function f1() +returns void as $$ +declare r record; +begin + r := g1(); + if false then + raise notice '%', r.c; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); +drop function g1(); + +create function g1(out a int, out b int) +returns setof record as $$ +select * from t1; +$$ language sql; + +create function f1() +returns void as $$ +declare r record; +begin + for r in select * from g1() + loop + raise notice '%', r.c; + end loop; +end; +$$ language plpgsql; + +select f1(); + +create or replace function f1() +returns void as $$ +declare r record; +begin + for r in select * from g1() + loop + r.c := 20; + end loop; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); +drop function g1(); + +create function f1() +returns int as $$ +declare r int; +begin + if false then + r := a + b; + end if; + return r; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create or replace function f1() +returns void as $$ +begin + if false then + raise notice '%', 1, 2; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create or replace function f1() +returns void as $$ +begin + if false then + raise notice '% %'; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create or replace function f1() +returns void as $$ +declare r int[]; +begin + if false then + r[c+10] := 20; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + + +create or replace function f1() +returns void as $$ +declare r int; +begin + if false then + r[10] := 20; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create type _exception_type as ( + state text, + message text, + detail text); + +create or replace function f1() +returns void as $$ +declare + _exception record; +begin + _exception := NULL::_exception_type; +exception when others then + get stacked diagnostics + _exception.state = RETURNED_SQLSTATE, + _exception.message = MESSAGE_TEXT, + _exception.detail = PG_EXCEPTION_DETAIL, + _exception.hint = PG_EXCEPTION_HINT; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); diff --git a/samples/PLpgSQL/plpgsql_lint-9.3.sql b/samples/PLpgSQL/plpgsql_lint-9.3.sql new file mode 100644 index 00000000..73da6e67 --- /dev/null +++ b/samples/PLpgSQL/plpgsql_lint-9.3.sql @@ -0,0 +1,166 @@ +load 'plpgsql'; +load 'plpgsql_lint'; + +create table t1(a int, b int); + +create function f1() +returns void as $$ +begin + if false then + update t1 set c = 30; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create function g1(out a int, out b int) +as $$ + select 10,20; +$$ language sql; + +create function f1() +returns void as $$ +declare r record; +begin + r := g1(); + if false then + raise notice '%', r.c; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); +drop function g1(); + +create function g1(out a int, out b int) +returns setof record as $$ +select * from t1; +$$ language sql; + +create function f1() +returns void as $$ +declare r record; +begin + for r in select * from g1() + loop + raise notice '%', r.c; + end loop; +end; +$$ language plpgsql; + +select f1(); + +create or replace function f1() +returns void as $$ +declare r record; +begin + for r in select * from g1() + loop + r.c := 20; + end loop; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); +drop function g1(); + +create function f1() +returns int as $$ +declare r int; +begin + if false then + r := a + b; + end if; + return r; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create or replace function f1() +returns void as $$ +begin + if false then + raise notice '%', 1, 2; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create or replace function f1() +returns void as $$ +begin + if false then + raise notice '% %'; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create or replace function f1() +returns void as $$ +declare r int[]; +begin + if false then + r[c+10] := 20; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + + +create or replace function f1() +returns void as $$ +declare r int; +begin + if false then + r[10] := 20; + end if; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); + +create type _exception_type as ( + state text, + message text, + detail text); + +create or replace function f1() +returns void as $$ +declare + _exception record; +begin + _exception := NULL::_exception_type; +exception when others then + get stacked diagnostics + _exception.state = RETURNED_SQLSTATE, + _exception.message = MESSAGE_TEXT, + _exception.detail = PG_EXCEPTION_DETAIL, + _exception.hint = PG_EXCEPTION_HINT; +end; +$$ language plpgsql; + +select f1(); + +drop function f1(); diff --git a/samples/SQL/create_stuff.sql b/samples/SQL/create_stuff.sql new file mode 100644 index 00000000..edfb569c --- /dev/null +++ b/samples/SQL/create_stuff.sql @@ -0,0 +1,21 @@ + +CREATE TABLE x AS SELECT * FROM DUAL; + +CREATE TABLE y ( +col1 NUMBER NOT NULL , +col2 VARCHAR2(200), +col3 DATE, +col4 TIMESTAMP WITH TIME ZONE NOT NULL +); + + +CREATE USER username IDENTIFIED BY password; + +GRANT CONNECT, RESOURCE TO username; + + +GRANT CREATE TYPE TO username; +GRANT CREATE PROCEDURE TO username; +GRANT CREATE TABLE TO username; +GRANT CREATE VIEW TO username; + diff --git a/samples/SQL/drop_stuff.sql b/samples/SQL/drop_stuff.sql new file mode 100644 index 00000000..7d638eed --- /dev/null +++ b/samples/SQL/drop_stuff.sql @@ -0,0 +1,13 @@ +drop procedure who_called_me; +drop package body linguist_package; +drop package linguist_package; +drop function functionname1; + +drop table x; +drop table y cascade; + +drop type typename1; +drop type typename2; + +drop view viewname1; +drop view viewname2; diff --git a/samples/SQL/dual.sql b/samples/SQL/dual.sql new file mode 100644 index 00000000..8ef5c624 --- /dev/null +++ b/samples/SQL/dual.sql @@ -0,0 +1,3 @@ +--this is the most basic oracle sql command +select * from dual; + diff --git a/samples/SQLPL/check_reorg.sql b/samples/SQLPL/check_reorg.sql new file mode 100644 index 00000000..f8906465 --- /dev/null +++ b/samples/SQLPL/check_reorg.sql @@ -0,0 +1,39 @@ +create procedure check_reorg_tables (in v_schema varchar(128), out v_reorg_counter integer) +begin + + declare loc result_set_locator varying; + + declare schema_out varchar(128); + declare table_out varchar(128); + declare card_out integer; + declare overflow_out integer; + declare npages_out integer; + declare fpages_out integer; + declare active_blocks_out integer; + declare tsize_out integer; + declare f1_out integer; + declare f2_out integer; + declare f3_out integer; + declare reorg_out varchar(3); + declare cursor_end smallint default 0; + + declare continue handler for NOT FOUND + + set cursor_end = 1; + set v_reorg_counter = 0; + + call reorgchk_tb_stats('S', v_schema); + associate result set locator(loc) with procedure reorgchk_tb_stats; + allocate mycursor cursor for result set loc; + + open mycursor; + repeat + fetch from mycursor into schema_out, table_out, card_out, overflow_out, npages_out, fpages_out, active_blocks_out, tsize_out, f1_out, f2_out, f3_out, reorg_out; + if reorg_out <> '---' then + set v_reorg_counter = v_reorg_counter + 1; + end if; + until cursor_end = 1 + end repeat; + close mycursor; + +end! diff --git a/samples/SQLPL/comm_amount.db2 b/samples/SQLPL/comm_amount.db2 new file mode 100644 index 00000000..66efc97c --- /dev/null +++ b/samples/SQLPL/comm_amount.db2 @@ -0,0 +1,30 @@ +DROP FUNCTION COMM_AMOUNT; +CREATE FUNCTION COMM_AMOUNT(SALARY DEC(9,2)) + RETURNS DEC(9,2) + LANGUAGE SQL READS SQL DATA + BEGIN ATOMIC + DECLARE REMAINDER DEC(9,2) DEFAULT 0.0;-- + DECLARE COMM_PAID DEC(9,2) DEFAULT 0.0;-- + DECLARE COMM_INCR INT DEFAULT 1;-- + DECLARE MAX_COMM DEC(9,2) DEFAULT 0.0;-- + + IF (SALARY <= 0) THEN + SIGNAL SQLSTATE '75000' + SET MESSAGE_TEXT = 'Bad Salary';-- + END IF;-- + + SET REMAINDER = SALARY;-- + +L1: WHILE REMAINDER > 0.0 DO + SET COMM_PAID = COMM_PAID + (COMM_INCR * 500.00);-- + SET REMAINDER = REMAINDER-(COMM_INCR * 5000.00);-- + SET COMM_INCR = COMM_INCR + 1;-- + END WHILE L1;-- + + SET MAX_COMM = + (SELECT SUM(SALARY)/100.00 FROM EMPLOYEE);-- + IF (COMM_PAID > MAX_COMM) THEN + SET COMM_PAID = MAX_COMM;-- + END IF;-- + RETURN COMM_PAID;-- +END; diff --git a/samples/SQLPL/drop_table.db2 b/samples/SQLPL/drop_table.db2 new file mode 100644 index 00000000..60e34d8e --- /dev/null +++ b/samples/SQLPL/drop_table.db2 @@ -0,0 +1,13 @@ +DROP TABLE TDEPT; +CREATE TABLE TDEPT (DEPTNO CHAR(4)); + +--#SET TERMINATOR @ +BEGIN ATOMIC + DECLARE COUNT INT DEFAULT 5; + + WHILE COUNT > 0 DO + INSERT INTO TDEPT VALUES 'F'|| + RTRIM(CHAR(COUNT)); + SET COUNT = COUNT - 1; + END WHILE; +END@ diff --git a/samples/SQLPL/runstats.sql b/samples/SQLPL/runstats.sql new file mode 100644 index 00000000..fcd8a46d --- /dev/null +++ b/samples/SQLPL/runstats.sql @@ -0,0 +1,18 @@ +create procedure runstats (out nr_tables integer, out nr_ok integer) +begin + declare SQLCODE integer; + declare stmt varchar(100); + + set nr_tables = 0; + set nr_ok = 0; + + for line as select tabschema, tabname from syscat.tables where type='T' and tabschema='SPODEN' + do + set nr_tables = nr_tables + 1; + set stmt = 'CALL SYSPROC.ADMIN_CMD (RUNSTATS ON TABLE ' concat rtrim(line.tabschema) concat '.' concat line.tabname concat ')'; + execute immediate stmt; + if SQLCODE = 0 then + set nr_ok = nr_ok + 1; + end if; + end for; +end! diff --git a/samples/SQLPL/trigger.sql b/samples/SQLPL/trigger.sql new file mode 100644 index 00000000..5002fa80 --- /dev/null +++ b/samples/SQLPL/trigger.sql @@ -0,0 +1,9 @@ +create trigger CHECK_HIREDATE +no cascade before insert on EMPLOYEE +referencing new as N +for each row mode db2sql +if n.hiredate > current date +then + signal SQLSTATE '75000' + set MESSAGE_TEXT = 'Hire date must be in the past'; +end if! diff --git a/vendor/grammars/Oracle b/vendor/grammars/Oracle new file mode 160000 index 00000000..f5308c9a --- /dev/null +++ b/vendor/grammars/Oracle @@ -0,0 +1 @@ +Subproject commit f5308c9abe377210145ffe606bd8b3ac0088608a