Cognos Content Store Query – Report Name, Package and Search Path Information

The Cognos Content Store database has a lot of valuable information, however, it is not always so easy to find this information. The following query can be useful for returning REPORT_NAME, PACKAGE and SEARCH-PATH information from the Cognos Content Store database.

Be aware the database structures can be changed with any any patch, fixpack or hotfix to Cognos and this SQL may fail or return wrong results. There is a better method for returning this information by using the Cognos SDK. More info here.

Content Store version:
Cognos 8 running on an Oracle database (also works on Cognos 10)

--=============================================================
--  COGNOS CONTENT STORE QUERY (Oracle database)
--  Use to find list REPORT_NAME, PACKAGE and SEARCH-PATH
--=============================================================
WITH base_query AS
(select classid,
         cmobjects.cmid,
         cmobjects.pcmid,
         cmobjnames.name as report_name
    from cognos_c84.cmobjects, cognos_c84.cmobjnames
   where cmobjects.cmid = cmobjnames.cmid
     and classid in (10)
     and cmobjnames.mapdlocaleid = 24
  union
  select classid,
         cmobjects.cmid  as cmid,
         cmobjects.pcmid,
         cmobjnames.name as report_name
    from cognos_c84.cmobjects, cognos_c84.cmobjnames
   where cmobjects.cmid = cmobjnames.cmid
     and cmobjects.cmid in
         (select distinct cmobjects.pcmid from cognos_c84.cmobjects)
     and cmobjnames.mapdlocaleid = 24)
, ctebuildpath (cmid,pcmid,report_name,Hlevel,classid,directory_path) AS
(select base_query.cmid,
       base_query.pcmid,
       base_query.report_name,
       1 as Hlevel,
       classid,
       to_char(base_query.report_name) as directory_path
  from base_query
where report_name = 'Public Folders' /* add myfolders to retrieve reports from my folders of users */
union all
select recur.cmid,
       recur.pcmid,
       recur.report_name,
       cte.Hlevel + 1 as Hlevel,
       recur.classid,
       to_char(cte.directory_path || ' > ' || recur.report_name) as directory_path
  from base_query recur, ctebuildpath cte
where cte.cmid = recur.pcmid)
, report_spec AS
(select spec,
       cmid,
       instr(spec,'/package[@name=')+15 as startposition,
       instr(spec, ']/model[@name=')-instr(spec,'/package[@name=')-15 as endposition
  from cognos_c84.cmobjprops7
where spec is not null)
--
SELECT report_name,
       dbms_lob.substr(spec, endposition, startposition) as package,
       directory_path
  FROM ctebuildpath cte, report_spec rep
WHERE cte.classid = 10
   and cte.cmid = rep.cmid
order by directory_path, report_name

Thanks to Cognos with Hari for putting this together on a SQL Server Content Store.